Enhance logging and error handling in PostgreSQL functions; update API endpoints in E2E tests; add Logstash troubleshooting documentation
All checks were successful
Deploy to Test Environment / deploy-to-test (push) Successful in 18m25s

- Added tiered logging and error handling in various PostgreSQL functions to improve observability and error tracking.
- Updated E2E tests to reflect changes in API endpoints for fetching best watched prices.
- Introduced a comprehensive troubleshooting runbook for Logstash to assist in diagnosing common issues in the PostgreSQL observability pipeline.
This commit is contained in:
2026-01-20 10:36:31 -08:00
parent 2e98bc3fc7
commit 0232b9de7a
9 changed files with 2080 additions and 110 deletions

View File

@@ -73,7 +73,25 @@ RETURNS TABLE (
LANGUAGE plpgsql
SECURITY INVOKER -- Runs with the privileges of the calling user.
AS $$
DECLARE
v_watched_items_count INTEGER;
v_result_count INTEGER;
v_context JSONB;
BEGIN
v_context := jsonb_build_object('user_id', p_user_id);
-- Tier 2 logging: Check if user has any watched items
SELECT COUNT(*) INTO v_watched_items_count
FROM public.user_watched_items
WHERE user_id = p_user_id;
IF v_watched_items_count = 0 THEN
PERFORM fn_log('NOTICE', 'get_best_sale_prices_for_user',
'User has no watched items',
v_context);
RETURN; -- Return empty result set
END IF;
RETURN QUERY
WITH UserWatchedSales AS (
-- This CTE gathers all sales from active flyers that match the user's watched items.
@@ -104,6 +122,20 @@ BEGIN
SELECT uws.master_item_id, uws.item_name, uws.price_in_cents, uws.store_name, uws.flyer_id, uws.flyer_icon_url, uws.flyer_image_url, uws.flyer_valid_from, uws.flyer_valid_to
FROM UserWatchedSales uws
WHERE uws.rn = 1;
-- Tier 2 logging: Check if any sales were found
GET DIAGNOSTICS v_result_count = ROW_COUNT;
IF v_result_count = 0 THEN
PERFORM fn_log('NOTICE', 'get_best_sale_prices_for_user',
'No sales found for watched items',
v_context || jsonb_build_object('watched_items_count', v_watched_items_count));
END IF;
EXCEPTION
WHEN OTHERS THEN
PERFORM fn_log('ERROR', 'get_best_sale_prices_for_user',
'Unexpected error getting best sale prices: ' || SQLERRM,
v_context);
RAISE;
END;
$$;
@@ -125,7 +157,42 @@ RETURNS TABLE (
LANGUAGE plpgsql
SECURITY INVOKER -- Runs with the privileges of the calling user.
AS $$
DECLARE
v_menu_plan_exists BOOLEAN;
v_planned_meals_count INTEGER;
v_result_count INTEGER;
v_context JSONB;
BEGIN
v_context := jsonb_build_object(
'menu_plan_id', p_menu_plan_id,
'user_id', p_user_id
);
-- Tier 2 logging: Check if menu plan exists and belongs to user
SELECT EXISTS(
SELECT 1 FROM public.menu_plans
WHERE menu_plan_id = p_menu_plan_id AND user_id = p_user_id
) INTO v_menu_plan_exists;
IF NOT v_menu_plan_exists THEN
PERFORM fn_log('NOTICE', 'generate_shopping_list_for_menu_plan',
'Menu plan not found or does not belong to user',
v_context);
RETURN; -- Return empty result set
END IF;
-- Tier 2 logging: Check if menu plan has any recipes
SELECT COUNT(*) INTO v_planned_meals_count
FROM public.planned_meals
WHERE menu_plan_id = p_menu_plan_id;
IF v_planned_meals_count = 0 THEN
PERFORM fn_log('NOTICE', 'generate_shopping_list_for_menu_plan',
'Menu plan has no recipes',
v_context);
RETURN; -- Return empty result set
END IF;
RETURN QUERY
WITH RequiredIngredients AS (
-- This CTE calculates the total quantity of each ingredient needed for the menu plan.
@@ -163,6 +230,20 @@ BEGIN
WHERE
-- Only include items that actually need to be purchased.
GREATEST(0, req.total_required - COALESCE(pi.quantity, 0)) > 0;
-- Tier 2 logging: Check if any items need to be purchased
GET DIAGNOSTICS v_result_count = ROW_COUNT;
IF v_result_count = 0 THEN
PERFORM fn_log('NOTICE', 'generate_shopping_list_for_menu_plan',
'All ingredients already in pantry (no shopping needed)',
v_context || jsonb_build_object('planned_meals_count', v_planned_meals_count));
END IF;
EXCEPTION
WHEN OTHERS THEN
PERFORM fn_log('ERROR', 'generate_shopping_list_for_menu_plan',
'Unexpected error generating shopping list: ' || SQLERRM,
v_context);
RAISE;
END;
$$;
@@ -458,10 +539,14 @@ STABLE -- This function does not modify the database.
AS $$
DECLARE
suggested_id BIGINT;
best_score REAL;
-- A similarity score between 0 and 1. A higher value means a better match.
-- This threshold can be adjusted based on observed performance. 0.4 is a reasonable starting point.
similarity_threshold REAL := 0.4;
v_context JSONB;
BEGIN
v_context := jsonb_build_object('flyer_item_name', p_flyer_item_name, 'similarity_threshold', similarity_threshold);
WITH candidates AS (
-- Search for matches in the primary master_grocery_items table
SELECT
@@ -480,7 +565,14 @@ BEGIN
WHERE alias % p_flyer_item_name
)
-- Select the master_item_id with the highest similarity score, provided it's above our threshold.
SELECT master_item_id INTO suggested_id FROM candidates WHERE score >= similarity_threshold ORDER BY score DESC, master_item_id LIMIT 1;
SELECT master_item_id, score INTO suggested_id, best_score FROM candidates WHERE score >= similarity_threshold ORDER BY score DESC, master_item_id LIMIT 1;
-- Tier 2 logging: Log when no match found (anomaly detection)
IF suggested_id IS NULL THEN
PERFORM fn_log('INFO', 'suggest_master_item_for_flyer_item',
'No master item match found for flyer item',
v_context || jsonb_build_object('best_score', best_score));
END IF;
RETURN suggested_id;
END;
@@ -500,10 +592,18 @@ RETURNS TABLE (
recommendation_score NUMERIC,
recommendation_reason TEXT
)
LANGUAGE sql
LANGUAGE plpgsql
STABLE
SECURITY INVOKER
AS $$
DECLARE
v_count INTEGER;
v_context JSONB;
BEGIN
v_context := jsonb_build_object('user_id', p_user_id, 'limit', p_limit);
-- Execute the recommendation query
RETURN QUERY
WITH UserHighRatedRecipes AS (
-- CTE 1: Get recipes the user has rated 4 stars or higher.
SELECT rr.recipe_id, rr.rating
@@ -581,6 +681,15 @@ ORDER BY
r.rating_count DESC,
r.name ASC
LIMIT p_limit;
-- Tier 2 logging: Log when no recommendations generated (anomaly detection)
GET DIAGNOSTICS v_count = ROW_COUNT;
IF v_count = 0 THEN
PERFORM fn_log('INFO', 'recommend_recipes_for_user',
'No recipe recommendations generated for user',
v_context);
END IF;
END;
$$;
-- Function to approve a suggested correction and apply it.
@@ -743,49 +852,85 @@ RETURNS TABLE(
avg_rating NUMERIC,
missing_ingredients_count BIGINT
)
LANGUAGE sql
LANGUAGE plpgsql
STABLE
SECURITY INVOKER
AS $$
WITH UserPantryItems AS (
-- CTE 1: Get a distinct set of master item IDs from the user's pantry.
SELECT master_item_id, quantity, unit
DECLARE
v_pantry_item_count INTEGER;
v_result_count INTEGER;
v_context JSONB;
BEGIN
v_context := jsonb_build_object('user_id', p_user_id);
-- Tier 2 logging: Check if user has any pantry items
SELECT COUNT(*) INTO v_pantry_item_count
FROM public.pantry_items
WHERE user_id = p_user_id AND quantity > 0
),
RecipeIngredientStats AS (
-- CTE 2: For each recipe, count its total ingredients and how many of those are in the user's pantry.
WHERE user_id = p_user_id AND quantity > 0;
IF v_pantry_item_count = 0 THEN
PERFORM fn_log('NOTICE', 'find_recipes_from_pantry',
'User has empty pantry',
v_context);
RETURN; -- Return empty result set
END IF;
-- Execute the main query and return results
RETURN QUERY
WITH UserPantryItems AS (
-- CTE 1: Get a distinct set of master item IDs from the user's pantry.
SELECT pi.master_item_id, pi.quantity, pi.unit
FROM public.pantry_items pi
WHERE pi.user_id = p_user_id AND pi.quantity > 0
),
RecipeIngredientStats AS (
-- CTE 2: For each recipe, count its total ingredients and how many of those are in the user's pantry.
SELECT
ri.recipe_id,
-- Count how many ingredients DO NOT meet the pantry requirements.
-- An ingredient is missing if it's not in the pantry OR if the quantity is insufficient.
-- The filter condition handles this logic.
COUNT(*) FILTER (
WHERE upi.master_item_id IS NULL -- The item is not in the pantry at all
OR upi.quantity < ri.quantity -- The user has the item, but not enough of it
) AS missing_ingredients_count
FROM public.recipe_ingredients ri
-- LEFT JOIN to the user's pantry on both item and unit.
-- We only compare quantities if the units match (e.g., 'g' vs 'g').
LEFT JOIN UserPantryItems upi
ON ri.master_item_id = upi.master_item_id
AND ri.unit = upi.unit
GROUP BY ri.recipe_id
)
-- Final Step: Select recipes where the total ingredient count matches the pantry ingredient count.
SELECT
ri.recipe_id,
-- Count how many ingredients DO NOT meet the pantry requirements.
-- An ingredient is missing if it's not in the pantry OR if the quantity is insufficient.
-- The filter condition handles this logic.
COUNT(*) FILTER (
WHERE upi.master_item_id IS NULL -- The item is not in the pantry at all
OR upi.quantity < ri.quantity -- The user has the item, but not enough of it
) AS missing_ingredients_count
FROM public.recipe_ingredients ri
-- LEFT JOIN to the user's pantry on both item and unit.
-- We only compare quantities if the units match (e.g., 'g' vs 'g').
LEFT JOIN UserPantryItems upi
ON ri.master_item_id = upi.master_item_id
AND ri.unit = upi.unit
GROUP BY ri.recipe_id
)
-- Final Step: Select recipes where the total ingredient count matches the pantry ingredient count.
SELECT
r.recipe_id,
r.name,
r.description,
r.prep_time_minutes,
r.cook_time_minutes,
r.avg_rating,
ris.missing_ingredients_count
FROM public.recipes r
JOIN RecipeIngredientStats ris ON r.recipe_id = ris.recipe_id
-- Order by recipes with the fewest missing ingredients first, then by rating.
-- Recipes with 0 missing ingredients are the ones that can be made.
ORDER BY ris.missing_ingredients_count ASC, r.avg_rating DESC, r.name ASC;
r.recipe_id,
r.name,
r.description,
r.prep_time_minutes,
r.cook_time_minutes,
r.avg_rating,
ris.missing_ingredients_count
FROM public.recipes r
JOIN RecipeIngredientStats ris ON r.recipe_id = ris.recipe_id
-- Order by recipes with the fewest missing ingredients first, then by rating.
-- Recipes with 0 missing ingredients are the ones that can be made.
ORDER BY ris.missing_ingredients_count ASC, r.avg_rating DESC, r.name ASC;
-- Tier 2 logging: Check if any recipes were found
GET DIAGNOSTICS v_result_count = ROW_COUNT;
IF v_result_count = 0 THEN
PERFORM fn_log('NOTICE', 'find_recipes_from_pantry',
'No recipes found matching pantry items',
v_context || jsonb_build_object('pantry_item_count', v_pantry_item_count));
END IF;
EXCEPTION
WHEN OTHERS THEN
PERFORM fn_log('ERROR', 'find_recipes_from_pantry',
'Unexpected error finding recipes from pantry: ' || SQLERRM,
v_context);
RAISE;
END;
$$;
-- Function to suggest alternative units for a given pantry item.
@@ -1409,7 +1554,15 @@ DECLARE
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)
@@ -1427,6 +1580,14 @@ BEGIN
FROM public.flyers
WHERE flyer_id = NEW.flyer_id;
-- Tier 3 logging: Log when flyer lookup fails
IF flyer_valid_from IS NULL OR flyer_valid_to IS NULL THEN
PERFORM fn_log('ERROR', 'update_price_history_on_flyer_item_insert',
'Flyer not found or missing validity dates',
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)
@@ -1449,6 +1610,14 @@ BEGIN
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;
@@ -1557,22 +1726,45 @@ DROP FUNCTION IF EXISTS public.update_recipe_rating_aggregates();
CREATE OR REPLACE FUNCTION public.update_recipe_rating_aggregates()
RETURNS TRIGGER AS $$
DECLARE
v_recipe_id BIGINT;
v_rows_updated INTEGER;
v_context JSONB;
BEGIN
v_recipe_id := COALESCE(NEW.recipe_id, OLD.recipe_id);
v_context := jsonb_build_object('recipe_id', v_recipe_id);
UPDATE public.recipes
SET
avg_rating = (
SELECT AVG(rating)
FROM public.recipe_ratings
WHERE recipe_id = COALESCE(NEW.recipe_id, OLD.recipe_id) -- This is correct, no change needed
WHERE recipe_id = v_recipe_id
),
rating_count = (
SELECT COUNT(*)
FROM public.recipe_ratings
WHERE recipe_id = COALESCE(NEW.recipe_id, OLD.recipe_id) -- This is correct, no change needed
WHERE recipe_id = v_recipe_id
)
WHERE recipe_id = COALESCE(NEW.recipe_id, OLD.recipe_id);
WHERE recipe_id = v_recipe_id;
-- Tier 3 logging: Log when recipe update fails
GET DIAGNOSTICS v_rows_updated = ROW_COUNT;
IF v_rows_updated = 0 THEN
PERFORM fn_log('ERROR', 'update_recipe_rating_aggregates',
'Recipe not found for rating aggregate update',
v_context);
END IF;
RETURN NULL; -- The result is ignored since this is an AFTER trigger.
EXCEPTION
WHEN OTHERS THEN
-- Tier 3 logging: Log unexpected errors in trigger
PERFORM fn_log('ERROR', 'update_recipe_rating_aggregates',
'Unexpected error in rating aggregate update: ' || SQLERRM,
v_context);
-- Re-raise the exception to ensure trigger failure is visible
RAISE;
END;
$$ LANGUAGE plpgsql;
@@ -1587,12 +1779,30 @@ DROP FUNCTION IF EXISTS public.log_new_recipe();
CREATE OR REPLACE FUNCTION public.log_new_recipe()
RETURNS TRIGGER AS $$
DECLARE
v_full_name TEXT;
v_context JSONB;
BEGIN
v_context := jsonb_build_object(
'user_id', NEW.user_id,
'recipe_id', NEW.recipe_id,
'recipe_name', NEW.name
);
-- Get user's full name (Tier 3 logging: Log if profile lookup fails)
SELECT full_name INTO v_full_name FROM public.profiles WHERE user_id = NEW.user_id;
IF v_full_name IS NULL THEN
PERFORM fn_log('ERROR', 'log_new_recipe',
'Profile not found for user creating recipe',
v_context);
v_full_name := 'Unknown User';
END IF;
INSERT INTO public.activity_log (user_id, action, display_text, icon, details)
VALUES (
NEW.user_id,
'recipe_created',
(SELECT full_name FROM public.profiles WHERE user_id = NEW.user_id) || ' created a new recipe: ' || NEW.name,
v_full_name || ' created a new recipe: ' || NEW.name,
'chef-hat',
jsonb_build_object('recipe_id', NEW.recipe_id, 'recipe_name', NEW.name)
);
@@ -1601,6 +1811,14 @@ BEGIN
PERFORM public.award_achievement(NEW.user_id, 'First Recipe');
RETURN NEW;
EXCEPTION
WHEN OTHERS THEN
-- Tier 3 logging: Log unexpected errors in trigger
PERFORM fn_log('ERROR', 'log_new_recipe',
'Unexpected error in recipe activity logging: ' || SQLERRM,
v_context);
-- Re-raise the exception to ensure trigger failure is visible
RAISE;
END;
$$ LANGUAGE plpgsql;
@@ -1617,13 +1835,39 @@ DROP FUNCTION IF EXISTS public.update_flyer_item_count();
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
GET DIAGNOSTICS v_rows_updated = ROW_COUNT;
IF v_rows_updated = 0 THEN
PERFORM fn_log('ERROR', 'update_flyer_item_count',
'Flyer not found for item count update',
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;
@@ -1639,27 +1883,55 @@ DROP FUNCTION IF EXISTS public.log_new_flyer();
CREATE OR REPLACE FUNCTION public.log_new_flyer()
RETURNS TRIGGER AS $$
DECLARE
v_store_name TEXT;
v_context JSONB;
BEGIN
v_context := jsonb_build_object(
'flyer_id', NEW.flyer_id,
'store_id', NEW.store_id,
'uploaded_by', NEW.uploaded_by,
'valid_from', NEW.valid_from,
'valid_to', NEW.valid_to
);
-- If the flyer was uploaded by a registered user, award the 'First-Upload' achievement.
-- The award_achievement function handles checking if the user already has it.
IF NEW.uploaded_by IS NOT NULL THEN
PERFORM public.award_achievement(NEW.uploaded_by, 'First-Upload');
END IF;
-- Get store name (Tier 3 logging: Log if store lookup fails)
SELECT name INTO v_store_name FROM public.stores WHERE store_id = NEW.store_id;
IF v_store_name IS NULL THEN
PERFORM fn_log('ERROR', 'log_new_flyer',
'Store not found for flyer',
v_context);
v_store_name := 'Unknown Store';
END IF;
INSERT INTO public.activity_log (user_id, action, display_text, icon, details)
VALUES (
NEW.uploaded_by, -- Log the user who uploaded it
'flyer_uploaded',
'A new flyer for ' || (SELECT name FROM public.stores WHERE store_id = NEW.store_id) || ' has been uploaded.',
'A new flyer for ' || v_store_name || ' has been uploaded.',
'file-text',
jsonb_build_object(
'flyer_id', NEW.flyer_id,
'store_name', (SELECT name FROM public.stores WHERE store_id = NEW.store_id),
'store_name', v_store_name,
'valid_from', to_char(NEW.valid_from, 'YYYY-MM-DD'),
'valid_to', to_char(NEW.valid_to, 'YYYY-MM-DD')
)
);
RETURN NEW;
EXCEPTION
WHEN OTHERS THEN
-- Tier 3 logging: Log unexpected errors in trigger
PERFORM fn_log('ERROR', 'log_new_flyer',
'Unexpected error in flyer activity logging: ' || SQLERRM,
v_context);
-- Re-raise the exception to ensure trigger failure is visible
RAISE;
END;
$$ LANGUAGE plpgsql;
@@ -1674,14 +1946,41 @@ DROP FUNCTION IF EXISTS public.log_new_favorite_recipe();
CREATE OR REPLACE FUNCTION public.log_new_favorite_recipe()
RETURNS TRIGGER AS $$
DECLARE
v_user_name TEXT;
v_recipe_name TEXT;
v_context JSONB;
BEGIN
v_context := jsonb_build_object(
'user_id', NEW.user_id,
'recipe_id', NEW.recipe_id
);
-- Get user name (Tier 3 logging: Log if profile lookup fails)
SELECT full_name INTO v_user_name FROM public.profiles WHERE user_id = NEW.user_id;
IF v_user_name IS NULL THEN
PERFORM fn_log('ERROR', 'log_new_favorite_recipe',
'Profile not found for user',
v_context);
v_user_name := 'Unknown User';
END IF;
-- Get recipe name (Tier 3 logging: Log if recipe lookup fails)
SELECT name INTO v_recipe_name FROM public.recipes WHERE recipe_id = NEW.recipe_id;
IF v_recipe_name IS NULL THEN
PERFORM fn_log('ERROR', 'log_new_favorite_recipe',
'Recipe not found',
v_context);
v_recipe_name := 'Unknown Recipe';
END IF;
INSERT INTO public.activity_log (user_id, action, display_text, icon, details)
VALUES (
NEW.user_id,
'recipe_favorited',
(SELECT full_name FROM public.profiles WHERE user_id = NEW.user_id) || ' favorited the recipe: ' || (SELECT name FROM public.recipes WHERE recipe_id = NEW.recipe_id),
v_user_name || ' favorited the recipe: ' || v_recipe_name,
'heart',
jsonb_build_object(
jsonb_build_object(
'recipe_id', NEW.recipe_id
)
);
@@ -1689,6 +1988,12 @@ BEGIN
-- Award 'First Favorite' achievement.
PERFORM public.award_achievement(NEW.user_id, 'First Favorite');
RETURN NEW;
EXCEPTION
WHEN OTHERS THEN
PERFORM fn_log('ERROR', 'log_new_favorite_recipe',
'Unexpected error in favorite recipe activity logging: ' || SQLERRM,
v_context);
RAISE;
END;
$$ LANGUAGE plpgsql;
@@ -1703,16 +2008,44 @@ DROP FUNCTION IF EXISTS public.log_new_list_share();
CREATE OR REPLACE FUNCTION public.log_new_list_share()
RETURNS TRIGGER AS $$
DECLARE
v_user_name TEXT;
v_list_name TEXT;
v_context JSONB;
BEGIN
v_context := jsonb_build_object(
'shared_by_user_id', NEW.shared_by_user_id,
'shopping_list_id', NEW.shopping_list_id,
'shared_with_user_id', NEW.shared_with_user_id
);
-- Get user name (Tier 3 logging: Log if profile lookup fails)
SELECT full_name INTO v_user_name FROM public.profiles WHERE user_id = NEW.shared_by_user_id;
IF v_user_name IS NULL THEN
PERFORM fn_log('ERROR', 'log_new_list_share',
'Profile not found for sharing user',
v_context);
v_user_name := 'Unknown User';
END IF;
-- Get list name (Tier 3 logging: Log if list lookup fails)
SELECT name INTO v_list_name FROM public.shopping_lists WHERE shopping_list_id = NEW.shopping_list_id;
IF v_list_name IS NULL THEN
PERFORM fn_log('ERROR', 'log_new_list_share',
'Shopping list not found',
v_context);
v_list_name := 'Unknown List';
END IF;
INSERT INTO public.activity_log (user_id, action, display_text, icon, details)
VALUES (
NEW.shared_by_user_id,
'list_shared',
(SELECT full_name FROM public.profiles WHERE user_id = NEW.shared_by_user_id) || ' shared a shopping list.',
v_user_name || ' shared a shopping list.',
'share-2',
jsonb_build_object(
'shopping_list_id', NEW.shopping_list_id,
'list_name', (SELECT name FROM public.shopping_lists WHERE shopping_list_id = NEW.shopping_list_id),
'list_name', v_list_name,
'shared_with_user_id', NEW.shared_with_user_id
)
);
@@ -1720,6 +2053,12 @@ BEGIN
-- Award 'List Sharer' achievement.
PERFORM public.award_achievement(NEW.shared_by_user_id, 'List Sharer');
RETURN NEW;
EXCEPTION
WHEN OTHERS THEN
PERFORM fn_log('ERROR', 'log_new_list_share',
'Unexpected error in list share activity logging: ' || SQLERRM,
v_context);
RAISE;
END;
$$ LANGUAGE plpgsql;
@@ -1734,12 +2073,30 @@ DROP FUNCTION IF EXISTS public.log_new_recipe_collection_share();
CREATE OR REPLACE FUNCTION public.log_new_recipe_collection_share()
RETURNS TRIGGER AS $$
DECLARE
v_user_name TEXT;
v_context JSONB;
BEGIN
v_context := jsonb_build_object(
'shared_by_user_id', NEW.shared_by_user_id,
'recipe_collection_id', NEW.recipe_collection_id,
'shared_with_user_id', NEW.shared_with_user_id
);
-- Get user name (Tier 3 logging: Log if profile lookup fails)
SELECT full_name INTO v_user_name FROM public.profiles WHERE user_id = NEW.shared_by_user_id;
IF v_user_name IS NULL THEN
PERFORM fn_log('ERROR', 'log_new_recipe_collection_share',
'Profile not found for sharing user',
v_context);
v_user_name := 'Unknown User';
END IF;
-- Log the activity
INSERT INTO public.activity_log (user_id, action, display_text, icon, details)
VALUES (
NEW.shared_by_user_id, 'recipe_collection_shared',
(SELECT full_name FROM public.profiles WHERE user_id = NEW.shared_by_user_id) || ' shared a recipe collection.',
v_user_name || ' shared a recipe collection.',
'book',
jsonb_build_object('collection_id', NEW.recipe_collection_id, 'shared_with_user_id', NEW.shared_with_user_id)
);
@@ -1747,6 +2104,12 @@ BEGIN
-- Award 'Recipe Sharer' achievement.
PERFORM public.award_achievement(NEW.shared_by_user_id, 'Recipe Sharer');
RETURN NEW;
EXCEPTION
WHEN OTHERS THEN
PERFORM fn_log('ERROR', 'log_new_recipe_collection_share',
'Unexpected error in recipe collection share activity logging: ' || SQLERRM,
v_context);
RAISE;
END;
$$ LANGUAGE plpgsql;
@@ -1799,14 +2162,38 @@ DROP FUNCTION IF EXISTS public.increment_recipe_fork_count();
CREATE OR REPLACE FUNCTION public.increment_recipe_fork_count()
RETURNS TRIGGER AS $$
DECLARE
v_rows_updated INTEGER;
v_context JSONB;
BEGIN
-- Only run if the recipe is a fork (original_recipe_id is not null).
IF NEW.original_recipe_id IS NOT NULL THEN
v_context := jsonb_build_object(
'recipe_id', NEW.recipe_id,
'original_recipe_id', NEW.original_recipe_id,
'user_id', NEW.user_id
);
-- Tier 3 logging: Log if original recipe not found
UPDATE public.recipes SET fork_count = fork_count + 1 WHERE recipe_id = NEW.original_recipe_id;
GET DIAGNOSTICS v_rows_updated = ROW_COUNT;
IF v_rows_updated = 0 THEN
PERFORM fn_log('ERROR', 'increment_recipe_fork_count',
'Original recipe not found for fork count increment',
v_context);
END IF;
-- Award 'First Fork' achievement.
PERFORM public.award_achievement(NEW.user_id, 'First Fork');
END IF;
RETURN NEW;
EXCEPTION
WHEN OTHERS THEN
PERFORM fn_log('ERROR', 'increment_recipe_fork_count',
'Unexpected error incrementing fork count: ' || SQLERRM,
v_context);
RAISE;
END;
$$ LANGUAGE plpgsql;