all the new shiny things
All checks were successful
Deploy to Test Environment / deploy-to-test (push) Successful in 15m54s
All checks were successful
Deploy to Test Environment / deploy-to-test (push) Successful in 15m54s
This commit is contained in:
@@ -1,6 +1,55 @@
|
||||
-- sql/Initial_triggers_and_functions.sql
|
||||
-- This file contains all trigger functions and trigger definitions for the database.
|
||||
|
||||
-- ============================================================================
|
||||
-- PART 0: OBSERVABILITY HELPERS (ADR-050)
|
||||
-- ============================================================================
|
||||
-- These functions provide structured logging capabilities for database functions.
|
||||
-- Logs are emitted via RAISE statements and can be captured by Logstash for
|
||||
-- forwarding to error tracking systems (see ADR-015).
|
||||
|
||||
-- Function to emit structured log messages from PL/pgSQL functions.
|
||||
-- This enables observability for database operations that might otherwise fail silently.
|
||||
DROP FUNCTION IF EXISTS public.fn_log(TEXT, TEXT, TEXT, JSONB);
|
||||
|
||||
CREATE OR REPLACE FUNCTION public.fn_log(
|
||||
p_level TEXT, -- 'DEBUG', 'INFO', 'NOTICE', 'WARNING', 'ERROR'
|
||||
p_function_name TEXT, -- The calling function name
|
||||
p_message TEXT, -- Human-readable message
|
||||
p_context JSONB DEFAULT NULL -- Additional context (user_id, params, etc.)
|
||||
)
|
||||
RETURNS void
|
||||
LANGUAGE plpgsql
|
||||
AS $$
|
||||
DECLARE
|
||||
log_line TEXT;
|
||||
BEGIN
|
||||
-- Build structured JSON log line for Logstash parsing
|
||||
log_line := jsonb_build_object(
|
||||
'timestamp', now(),
|
||||
'level', p_level,
|
||||
'source', 'postgresql',
|
||||
'function', p_function_name,
|
||||
'message', p_message,
|
||||
'context', COALESCE(p_context, '{}'::jsonb)
|
||||
)::text;
|
||||
|
||||
-- Use appropriate RAISE level based on severity
|
||||
-- Note: We use RAISE LOG for errors to ensure they're always captured
|
||||
-- regardless of client_min_messages setting
|
||||
CASE UPPER(p_level)
|
||||
WHEN 'DEBUG' THEN RAISE DEBUG '%', log_line;
|
||||
WHEN 'INFO' THEN RAISE INFO '%', log_line;
|
||||
WHEN 'NOTICE' THEN RAISE NOTICE '%', log_line;
|
||||
WHEN 'WARNING' THEN RAISE WARNING '%', log_line;
|
||||
WHEN 'ERROR' THEN RAISE LOG '%', log_line;
|
||||
ELSE RAISE NOTICE '%', log_line;
|
||||
END CASE;
|
||||
END;
|
||||
$$;
|
||||
|
||||
COMMENT ON FUNCTION public.fn_log IS 'Emits structured JSON log messages for database function observability (ADR-050)';
|
||||
|
||||
-- ============================================================================
|
||||
-- PART 3: DATABASE FUNCTIONS
|
||||
-- ============================================================================
|
||||
@@ -223,13 +272,32 @@ AS $$
|
||||
DECLARE
|
||||
list_owner_id UUID;
|
||||
item_to_add RECORD;
|
||||
v_items_added INTEGER := 0;
|
||||
v_context JSONB;
|
||||
BEGIN
|
||||
-- Build context for logging
|
||||
v_context := jsonb_build_object(
|
||||
'user_id', p_user_id,
|
||||
'menu_plan_id', p_menu_plan_id,
|
||||
'shopping_list_id', p_shopping_list_id
|
||||
);
|
||||
|
||||
-- Security Check: Ensure the user calling this function owns the target shopping list.
|
||||
SELECT user_id INTO list_owner_id
|
||||
FROM public.shopping_lists
|
||||
WHERE shopping_list_id = p_shopping_list_id;
|
||||
|
||||
IF list_owner_id IS NULL OR list_owner_id <> p_user_id THEN
|
||||
IF list_owner_id IS NULL THEN
|
||||
PERFORM fn_log('WARNING', 'add_menu_plan_to_shopping_list',
|
||||
'Shopping list not found',
|
||||
v_context);
|
||||
RAISE EXCEPTION 'Permission denied: You do not own shopping list %', p_shopping_list_id;
|
||||
END IF;
|
||||
|
||||
IF list_owner_id <> p_user_id THEN
|
||||
PERFORM fn_log('WARNING', 'add_menu_plan_to_shopping_list',
|
||||
'Permission denied: user does not own list',
|
||||
v_context || jsonb_build_object('list_owner_id', list_owner_id));
|
||||
RAISE EXCEPTION 'Permission denied: You do not own shopping list %', p_shopping_list_id;
|
||||
END IF;
|
||||
|
||||
@@ -244,9 +312,16 @@ BEGIN
|
||||
DO UPDATE SET
|
||||
quantity = shopping_list_items.quantity + EXCLUDED.quantity;
|
||||
|
||||
v_items_added := v_items_added + 1;
|
||||
|
||||
-- Return the details of the item that was added/updated.
|
||||
RETURN QUERY SELECT item_to_add.master_item_id, item_to_add.item_name, item_to_add.shopping_list_quantity;
|
||||
END LOOP;
|
||||
|
||||
-- Log completion (items_added = 0 is normal if pantry has everything)
|
||||
PERFORM fn_log('INFO', 'add_menu_plan_to_shopping_list',
|
||||
'Menu plan items added to shopping list',
|
||||
v_context || jsonb_build_object('items_added', v_items_added));
|
||||
END;
|
||||
$$;
|
||||
|
||||
@@ -520,16 +595,30 @@ SECURITY DEFINER
|
||||
AS $$
|
||||
DECLARE
|
||||
correction_record RECORD;
|
||||
v_context JSONB;
|
||||
BEGIN
|
||||
-- Build context for logging
|
||||
v_context := jsonb_build_object('correction_id', p_correction_id);
|
||||
|
||||
-- 1. Fetch the correction details, ensuring it's still pending.
|
||||
SELECT * INTO correction_record
|
||||
FROM public.suggested_corrections
|
||||
WHERE suggested_correction_id = p_correction_id AND status = 'pending';
|
||||
|
||||
IF NOT FOUND THEN
|
||||
PERFORM fn_log('WARNING', 'approve_correction',
|
||||
'Correction not found or already processed',
|
||||
v_context);
|
||||
RAISE EXCEPTION 'Correction with ID % not found or already processed.', p_correction_id;
|
||||
END IF;
|
||||
|
||||
-- Add correction details to context
|
||||
v_context := v_context || jsonb_build_object(
|
||||
'correction_type', correction_record.correction_type,
|
||||
'flyer_item_id', correction_record.flyer_item_id,
|
||||
'suggested_value', correction_record.suggested_value
|
||||
);
|
||||
|
||||
-- 2. Apply the correction based on its type.
|
||||
IF correction_record.correction_type = 'INCORRECT_ITEM_LINK' THEN
|
||||
UPDATE public.flyer_items
|
||||
@@ -545,6 +634,11 @@ BEGIN
|
||||
UPDATE public.suggested_corrections
|
||||
SET status = 'approved', reviewed_at = now()
|
||||
WHERE suggested_correction_id = p_correction_id;
|
||||
|
||||
-- Log successful correction approval
|
||||
PERFORM fn_log('INFO', 'approve_correction',
|
||||
'Correction approved and applied',
|
||||
v_context);
|
||||
END;
|
||||
$$;
|
||||
|
||||
@@ -566,7 +660,14 @@ SECURITY INVOKER
|
||||
AS $$
|
||||
DECLARE
|
||||
new_recipe_id BIGINT;
|
||||
v_context JSONB;
|
||||
BEGIN
|
||||
-- Build context for logging
|
||||
v_context := jsonb_build_object(
|
||||
'user_id', p_user_id,
|
||||
'original_recipe_id', p_original_recipe_id
|
||||
);
|
||||
|
||||
-- 1. Create a copy of the recipe, linking it to the new user and the original recipe.
|
||||
INSERT INTO public.recipes (
|
||||
user_id,
|
||||
@@ -605,6 +706,9 @@ BEGIN
|
||||
|
||||
-- If the original recipe didn't exist, new_recipe_id will be null.
|
||||
IF new_recipe_id IS NULL THEN
|
||||
PERFORM fn_log('WARNING', 'fork_recipe',
|
||||
'Original recipe not found',
|
||||
v_context);
|
||||
RETURN;
|
||||
END IF;
|
||||
|
||||
@@ -613,6 +717,11 @@ BEGIN
|
||||
INSERT INTO public.recipe_tags (recipe_id, tag_id) SELECT new_recipe_id, tag_id FROM public.recipe_tags WHERE recipe_id = p_original_recipe_id;
|
||||
INSERT INTO public.recipe_appliances (recipe_id, appliance_id) SELECT new_recipe_id, appliance_id FROM public.recipe_appliances WHERE recipe_id = p_original_recipe_id;
|
||||
|
||||
-- Log successful fork
|
||||
PERFORM fn_log('INFO', 'fork_recipe',
|
||||
'Recipe forked successfully',
|
||||
v_context || jsonb_build_object('new_recipe_id', new_recipe_id));
|
||||
|
||||
-- 3. Return the newly created recipe record.
|
||||
RETURN QUERY SELECT * FROM public.recipes WHERE recipe_id = new_recipe_id;
|
||||
END;
|
||||
@@ -889,13 +998,32 @@ AS $$
|
||||
DECLARE
|
||||
list_owner_id UUID;
|
||||
new_trip_id BIGINT;
|
||||
v_items_count INTEGER;
|
||||
v_context JSONB;
|
||||
BEGIN
|
||||
-- Build context for logging
|
||||
v_context := jsonb_build_object(
|
||||
'user_id', p_user_id,
|
||||
'shopping_list_id', p_shopping_list_id,
|
||||
'total_spent_cents', p_total_spent_cents
|
||||
);
|
||||
|
||||
-- Security Check: Ensure the user calling this function owns the target shopping list.
|
||||
SELECT user_id INTO list_owner_id
|
||||
FROM public.shopping_lists
|
||||
WHERE shopping_list_id = p_shopping_list_id;
|
||||
|
||||
IF list_owner_id IS NULL OR list_owner_id <> p_user_id THEN
|
||||
IF list_owner_id IS NULL THEN
|
||||
PERFORM fn_log('WARNING', 'complete_shopping_list',
|
||||
'Shopping list not found',
|
||||
v_context);
|
||||
RAISE EXCEPTION 'Permission denied: You do not own shopping list %', p_shopping_list_id;
|
||||
END IF;
|
||||
|
||||
IF list_owner_id <> p_user_id THEN
|
||||
PERFORM fn_log('WARNING', 'complete_shopping_list',
|
||||
'Permission denied: user does not own list',
|
||||
v_context || jsonb_build_object('list_owner_id', list_owner_id));
|
||||
RAISE EXCEPTION 'Permission denied: You do not own shopping list %', p_shopping_list_id;
|
||||
END IF;
|
||||
|
||||
@@ -910,10 +1038,17 @@ BEGIN
|
||||
FROM public.shopping_list_items
|
||||
WHERE shopping_list_id = p_shopping_list_id AND is_purchased = true;
|
||||
|
||||
GET DIAGNOSTICS v_items_count = ROW_COUNT;
|
||||
|
||||
-- 3. Delete the purchased items from the original shopping list.
|
||||
DELETE FROM public.shopping_list_items
|
||||
WHERE shopping_list_id = p_shopping_list_id AND is_purchased = true;
|
||||
|
||||
-- Log successful completion
|
||||
PERFORM fn_log('INFO', 'complete_shopping_list',
|
||||
'Shopping list completed successfully',
|
||||
v_context || jsonb_build_object('trip_id', new_trip_id, 'items_archived', v_items_count));
|
||||
|
||||
RETURN new_trip_id;
|
||||
END;
|
||||
$$;
|
||||
@@ -1047,13 +1182,19 @@ AS $$
|
||||
DECLARE
|
||||
v_achievement_id BIGINT;
|
||||
v_points_value INTEGER;
|
||||
v_context JSONB;
|
||||
BEGIN
|
||||
-- Build context for logging
|
||||
v_context := jsonb_build_object('user_id', p_user_id, 'achievement_name', p_achievement_name);
|
||||
|
||||
-- Find the achievement by name to get its ID and point value.
|
||||
SELECT achievement_id, points_value INTO v_achievement_id, v_points_value
|
||||
FROM public.achievements WHERE name = p_achievement_name;
|
||||
|
||||
-- If the achievement doesn't exist, do nothing.
|
||||
-- If the achievement doesn't exist, log warning and return.
|
||||
IF v_achievement_id IS NULL THEN
|
||||
PERFORM fn_log('WARNING', 'award_achievement',
|
||||
'Achievement not found: ' || p_achievement_name, v_context);
|
||||
RETURN;
|
||||
END IF;
|
||||
|
||||
@@ -1065,9 +1206,12 @@ BEGIN
|
||||
ON CONFLICT (user_id, achievement_id) DO NOTHING;
|
||||
|
||||
-- If the insert was successful (i.e., the user didn't have the achievement),
|
||||
-- update their total points. The `GET DIAGNOSTICS` command checks the row count of the last query.
|
||||
-- update their total points and log success.
|
||||
IF FOUND THEN
|
||||
UPDATE public.profiles SET points = points + v_points_value WHERE user_id = p_user_id;
|
||||
PERFORM fn_log('INFO', 'award_achievement',
|
||||
'Achievement awarded: ' || p_achievement_name,
|
||||
v_context || jsonb_build_object('points_awarded', v_points_value));
|
||||
END IF;
|
||||
END;
|
||||
$$;
|
||||
@@ -1165,13 +1309,25 @@ RETURNS TRIGGER AS $$
|
||||
DECLARE
|
||||
new_profile_id UUID;
|
||||
user_meta_data JSONB;
|
||||
v_context JSONB;
|
||||
BEGIN
|
||||
-- Build context for logging
|
||||
v_context := jsonb_build_object('user_id', new.user_id, 'email', new.email);
|
||||
|
||||
-- The user's metadata (full_name, avatar_url) is passed via a temporary session variable.
|
||||
user_meta_data := current_setting('my_app.user_metadata', true)::JSONB;
|
||||
|
||||
INSERT INTO public.profiles (user_id, role, full_name, avatar_url)
|
||||
VALUES (new.user_id, 'user', user_meta_data->>'full_name', user_meta_data->>'avatar_url')
|
||||
RETURNING user_id INTO new_profile_id;
|
||||
-- Create the user profile
|
||||
BEGIN
|
||||
INSERT INTO public.profiles (user_id, role, full_name, avatar_url)
|
||||
VALUES (new.user_id, 'user', user_meta_data->>'full_name', user_meta_data->>'avatar_url')
|
||||
RETURNING user_id INTO new_profile_id;
|
||||
EXCEPTION WHEN OTHERS THEN
|
||||
PERFORM fn_log('ERROR', 'handle_new_user',
|
||||
'Failed to create profile: ' || SQLERRM,
|
||||
v_context || jsonb_build_object('sqlstate', SQLSTATE));
|
||||
RAISE;
|
||||
END;
|
||||
|
||||
-- Also create a default shopping list for the new user.
|
||||
INSERT INTO public.shopping_lists (user_id, name)
|
||||
@@ -1179,12 +1335,20 @@ BEGIN
|
||||
|
||||
-- Log the new user event
|
||||
INSERT INTO public.activity_log (user_id, action, display_text, icon, details)
|
||||
VALUES (new.user_id, 'user_registered',
|
||||
VALUES (new.user_id, 'user_registered',
|
||||
COALESCE(user_meta_data->>'full_name', new.email) || ' has registered.',
|
||||
'user-plus',
|
||||
'user-plus',
|
||||
jsonb_build_object('email', new.email)
|
||||
);
|
||||
|
||||
|
||||
-- Award the 'Welcome Aboard' achievement for new user registration
|
||||
PERFORM public.award_achievement(new.user_id, 'Welcome Aboard');
|
||||
|
||||
-- Log successful user creation
|
||||
PERFORM fn_log('INFO', 'handle_new_user',
|
||||
'New user created successfully',
|
||||
v_context || jsonb_build_object('full_name', user_meta_data->>'full_name'));
|
||||
|
||||
RETURN new;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
Reference in New Issue
Block a user