more fixin logging, UI update #1, source maps fix
Some checks failed
Deploy to Test Environment / deploy-to-test (push) Failing after 12s

This commit is contained in:
2026-01-21 03:27:44 -08:00
parent eaf229f252
commit 4e5d709973
37 changed files with 3761 additions and 108 deletions

View File

@@ -0,0 +1,141 @@
-- Migration 007: Fix trigger log levels for expected edge cases
-- Date: 2026-01-21
-- Issues:
-- - Bugsink issue 0e1d3dfd-c935-4b0c-aaea-60aa2364e0cd (flyer not found during CASCADE delete)
-- - Bugsink issue 150e86fa-b197-465b-9cbe-63663c63788e (missing validity dates)
-- Problem 1: When a flyer is deleted with ON DELETE CASCADE, the flyer_items trigger
-- tries to update the already-deleted flyer, logging ERROR messages.
-- Solution 1: Change log level from ERROR to INFO since this is expected behavior.
-- Problem 2: When a flyer_item is inserted for a flyer with NULL validity dates,
-- the price history trigger logs ERROR even though it handles it gracefully.
-- Solution 2: Change log level from ERROR to WARNING since the trigger degrades gracefully.
-- Drop and recreate the trigger function with updated log level
DROP FUNCTION IF EXISTS public.update_flyer_item_count() CASCADE;
CREATE OR REPLACE FUNCTION public.update_flyer_item_count()
RETURNS TRIGGER AS $$
DECLARE
v_rows_updated INTEGER;
v_context JSONB;
v_flyer_id BIGINT;
BEGIN
-- Determine which flyer_id to use based on operation
IF (TG_OP = 'INSERT') THEN
v_flyer_id := NEW.flyer_id;
v_context := jsonb_build_object('flyer_id', NEW.flyer_id, 'operation', 'INSERT');
UPDATE public.flyers SET item_count = item_count + 1 WHERE flyer_id = NEW.flyer_id;
ELSIF (TG_OP = 'DELETE') THEN
v_flyer_id := OLD.flyer_id;
v_context := jsonb_build_object('flyer_id', OLD.flyer_id, 'operation', 'DELETE');
UPDATE public.flyers SET item_count = item_count - 1 WHERE flyer_id = OLD.flyer_id;
END IF;
-- Tier 3 logging: Log if flyer not found (expected during CASCADE delete, so INFO level)
GET DIAGNOSTICS v_rows_updated = ROW_COUNT;
IF v_rows_updated = 0 THEN
PERFORM fn_log('INFO', 'update_flyer_item_count',
'Flyer not found for item count update (likely CASCADE delete)',
v_context);
END IF;
RETURN NULL; -- The result is ignored since this is an AFTER trigger.
EXCEPTION
WHEN OTHERS THEN
PERFORM fn_log('ERROR', 'update_flyer_item_count',
'Unexpected error updating flyer item count: ' || SQLERRM,
v_context);
RAISE;
END;
$$ LANGUAGE plpgsql;
-- Recreate the trigger (it was dropped by CASCADE above)
DROP TRIGGER IF EXISTS on_flyer_item_change ON public.flyer_items;
CREATE TRIGGER on_flyer_item_change
AFTER INSERT OR DELETE ON public.flyer_items
FOR EACH ROW EXECUTE FUNCTION public.update_flyer_item_count();
-- Fix 2: Update price history trigger for missing validity dates
DROP FUNCTION IF EXISTS public.update_price_history_on_flyer_item_insert() CASCADE;
CREATE OR REPLACE FUNCTION public.update_price_history_on_flyer_item_insert()
RETURNS TRIGGER AS $$
DECLARE
flyer_valid_from DATE;
flyer_valid_to DATE;
current_summary_date DATE;
flyer_location_id BIGINT;
v_context JSONB;
BEGIN
v_context := jsonb_build_object(
'flyer_item_id', NEW.flyer_item_id,
'flyer_id', NEW.flyer_id,
'master_item_id', NEW.master_item_id,
'price_in_cents', NEW.price_in_cents
);
-- If the item could not be matched, add it to the unmatched queue for review.
IF NEW.master_item_id IS NULL THEN
INSERT INTO public.unmatched_flyer_items (flyer_item_id)
VALUES (NEW.flyer_item_id)
ON CONFLICT (flyer_item_id) DO NOTHING;
END IF;
-- Only run if the new flyer item is linked to a master item and has a price.
IF NEW.master_item_id IS NULL OR NEW.price_in_cents IS NULL THEN
RETURN NEW;
END IF;
-- Get the validity dates of the flyer and the store_id.
SELECT valid_from, valid_to INTO flyer_valid_from, flyer_valid_to
FROM public.flyers
WHERE flyer_id = NEW.flyer_id;
-- Tier 3 logging: Log when flyer has missing validity dates (degrades gracefully)
IF flyer_valid_from IS NULL OR flyer_valid_to IS NULL THEN
PERFORM fn_log('WARNING', 'update_price_history_on_flyer_item_insert',
'Flyer missing validity dates - skipping price history update',
v_context);
RETURN NEW;
END IF;
-- This single, set-based query is much more performant than looping.
-- It generates all date/location pairs and inserts/updates them in one operation.
INSERT INTO public.item_price_history (master_item_id, summary_date, store_location_id, min_price_in_cents, max_price_in_cents, avg_price_in_cents, data_points_count)
SELECT
NEW.master_item_id,
d.day,
fl.store_location_id,
NEW.price_in_cents,
NEW.price_in_cents,
NEW.price_in_cents,
1
FROM public.flyer_locations fl
CROSS JOIN generate_series(flyer_valid_from, flyer_valid_to, '1 day'::interval) AS d(day)
WHERE fl.flyer_id = NEW.flyer_id
ON CONFLICT (master_item_id, summary_date, store_location_id)
DO UPDATE SET
min_price_in_cents = LEAST(item_price_history.min_price_in_cents, EXCLUDED.min_price_in_cents),
max_price_in_cents = GREATEST(item_price_history.max_price_in_cents, EXCLUDED.max_price_in_cents),
avg_price_in_cents = ROUND(((item_price_history.avg_price_in_cents * item_price_history.data_points_count) + EXCLUDED.avg_price_in_cents) / (item_price_history.data_points_count + 1.0)),
data_points_count = item_price_history.data_points_count + 1;
RETURN NEW;
EXCEPTION
WHEN OTHERS THEN
-- Tier 3 logging: Log unexpected errors in trigger
PERFORM fn_log('ERROR', 'update_price_history_on_flyer_item_insert',
'Unexpected error in price history update: ' || SQLERRM,
v_context);
-- Re-raise the exception to ensure trigger failure is visible
RAISE;
END;
$$ LANGUAGE plpgsql;
-- Recreate the trigger (it was dropped by CASCADE above)
DROP TRIGGER IF EXISTS trigger_update_price_history ON public.flyer_items;
CREATE TRIGGER trigger_update_price_history
AFTER INSERT ON public.flyer_items
FOR EACH ROW EXECUTE FUNCTION public.update_price_history_on_flyer_item_insert();