-- This file contains all trigger functions and trigger definitions for the database. -- 1. Set up the trigger to automatically create a profile when a new user signs up. -- This function is called by a trigger on the `public.users` table. -- It creates a corresponding profile and a default shopping list for the new user. -- It now accepts full_name and avatar_url from the user's metadata. CREATE OR REPLACE FUNCTION public.handle_new_user() RETURNS TRIGGER AS $$ DECLARE new_profile_id UUID; user_meta_data JSONB; BEGIN -- 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 (id, role, full_name, avatar_url) VALUES (new.id, 'user', user_meta_data->>'full_name', user_meta_data->>'avatar_url') RETURNING id INTO new_profile_id; -- Also create a default shopping list for the new user. INSERT INTO public.shopping_lists (user_id, name) VALUES (new_profile_id, 'Main Shopping List'); -- Log the new user event INSERT INTO public.user_activity_log (user_id, activity_type, entity_id, details) VALUES (new.id, 'new_user', new.id, jsonb_build_object('full_name', user_meta_data->>'full_name')); RETURN new; END; $$ LANGUAGE plpgsql; -- This trigger calls the function after a new user is created. DROP TRIGGER IF EXISTS on_auth_user_created ON public.users; CREATE TRIGGER on_auth_user_created AFTER INSERT ON public.users FOR EACH ROW EXECUTE FUNCTION public.handle_new_user(); -- 2. Create a reusable function to automatically update 'updated_at' columns. CREATE OR REPLACE FUNCTION public.handle_updated_at() RETURNS TRIGGER AS $$ BEGIN NEW.updated_at = now(); RETURN NEW; END; $$ LANGUAGE plpgsql; -- Apply the trigger to the 'profiles' table. DROP TRIGGER IF EXISTS on_profile_updated ON public.profiles; CREATE TRIGGER on_profile_updated BEFORE UPDATE ON public.profiles FOR EACH ROW EXECUTE FUNCTION public.handle_updated_at(); -- Apply the trigger to all other tables that have an 'updated_at' column. DROP TRIGGER IF EXISTS on_users_updated ON public.users; CREATE TRIGGER on_users_updated BEFORE UPDATE ON public.users FOR EACH ROW EXECUTE FUNCTION public.handle_updated_at(); DROP TRIGGER IF EXISTS on_stores_updated ON public.stores; CREATE TRIGGER on_stores_updated BEFORE UPDATE ON public.stores FOR EACH ROW EXECUTE FUNCTION public.handle_updated_at(); DROP TRIGGER IF EXISTS on_categories_updated ON public.categories; CREATE TRIGGER on_categories_updated BEFORE UPDATE ON public.categories FOR EACH ROW EXECUTE FUNCTION public.handle_updated_at(); DROP TRIGGER IF EXISTS on_flyers_updated ON public.flyers; CREATE TRIGGER on_flyers_updated BEFORE UPDATE ON public.flyers FOR EACH ROW EXECUTE FUNCTION public.handle_updated_at(); DROP TRIGGER IF EXISTS on_master_grocery_items_updated ON public.master_grocery_items; CREATE TRIGGER on_master_grocery_items_updated BEFORE UPDATE ON public.master_grocery_items FOR EACH ROW EXECUTE FUNCTION public.handle_updated_at(); DROP TRIGGER IF EXISTS on_user_watched_items_updated ON public.user_watched_items; CREATE TRIGGER on_user_watched_items_updated BEFORE UPDATE ON public.user_watched_items FOR EACH ROW EXECUTE FUNCTION public.handle_updated_at(); DROP TRIGGER IF EXISTS on_user_alerts_updated ON public.user_alerts; CREATE TRIGGER on_user_alerts_updated BEFORE UPDATE ON public.user_alerts FOR EACH ROW EXECUTE FUNCTION public.handle_updated_at(); DROP TRIGGER IF EXISTS on_notifications_updated ON public.notifications; CREATE TRIGGER on_notifications_updated BEFORE UPDATE ON public.notifications FOR EACH ROW EXECUTE FUNCTION public.handle_updated_at(); DROP TRIGGER IF EXISTS on_item_price_history_updated ON public.item_price_history; CREATE TRIGGER on_item_price_history_updated BEFORE UPDATE ON public.item_price_history FOR EACH ROW EXECUTE FUNCTION public.handle_updated_at(); -- (Apply to other tables as needed...) -- Apply the trigger to the 'pantry_items' table. DROP TRIGGER IF EXISTS on_pantry_item_updated ON public.pantry_items; CREATE TRIGGER on_pantry_item_updated BEFORE UPDATE ON public.pantry_items FOR EACH ROW EXECUTE FUNCTION public.handle_updated_at(); -- Apply the trigger to the 'recipe_comments' table. DROP TRIGGER IF EXISTS on_recipe_comment_updated ON public.recipe_comments; CREATE TRIGGER on_recipe_comment_updated BEFORE UPDATE ON public.recipe_comments FOR EACH ROW EXECUTE FUNCTION public.handle_updated_at(); -- 3. Create a trigger function to populate the item_price_history table on insert. 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; BEGIN -- 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.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 id = NEW.flyer_id; -- If the flyer dates are not set, we cannot proceed. IF flyer_valid_from IS NULL OR flyer_valid_to IS NULL THEN RETURN NEW; END IF; -- Loop through each day the flyer is valid and update the price history. -- Also loop through each location this flyer is valid for. FOR flyer_location_id IN SELECT store_location_id FROM public.flyer_locations WHERE flyer_id = NEW.flyer_id LOOP FOR current_summary_date IN SELECT generate_series(flyer_valid_from, flyer_valid_to, '1 day'::interval)::date LOOP 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) VALUES (NEW.master_item_id, current_summary_date, flyer_location_id, NEW.price_in_cents, NEW.price_in_cents, NEW.price_in_cents, 1) 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; END LOOP; END LOOP; RETURN NEW; END; $$ LANGUAGE plpgsql; -- Create the trigger on the flyer_items table for insert. 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(); -- 4. Create a trigger function to recalculate price history when a flyer item is deleted. CREATE OR REPLACE FUNCTION public.recalculate_price_history_on_flyer_item_delete() RETURNS TRIGGER AS $$ DECLARE flyer_valid_from DATE; flyer_valid_to DATE; current_summary_date DATE; flyer_location_id BIGINT; new_aggregates RECORD; BEGIN -- Only run if the deleted item was linked to a master item and had a price. IF OLD.master_item_id IS NULL OR OLD.price_in_cents IS NULL THEN RETURN OLD; END IF; -- Get the validity dates of the flyer. SELECT valid_from, valid_to INTO flyer_valid_from, flyer_valid_to FROM public.flyers WHERE id = OLD.flyer_id; -- If the flyer dates are not set, we cannot proceed. IF flyer_valid_from IS NULL OR flyer_valid_to IS NULL THEN RETURN OLD; END IF; -- Loop through each day the flyer was valid to recalculate the history. -- Also loop through each location this flyer was valid for. FOR flyer_location_id IN SELECT store_location_id FROM public.flyer_locations WHERE flyer_id = OLD.flyer_id LOOP FOR current_summary_date IN SELECT generate_series(flyer_valid_from, flyer_valid_to, '1 day'::interval)::date LOOP -- Recalculate aggregates for the master item on this specific day from all other flyers for this specific location. SELECT MIN(fi.price_in_cents) AS min_price, MAX(fi.price_in_cents) AS max_price, ROUND(AVG(fi.price_in_cents)) AS avg_price, COUNT(fi.id) AS data_points INTO new_aggregates FROM public.flyer_items fi JOIN public.flyer_locations fl ON fi.flyer_id = fl.flyer_id JOIN public.flyers f ON fi.flyer_id = f.id WHERE fi.master_item_id = OLD.master_item_id AND fi.price_in_cents IS NOT NULL AND current_summary_date BETWEEN f.valid_from AND f.valid_to AND fl.store_location_id = flyer_location_id; -- If there are still data points, update the summary. Otherwise, delete it. IF new_aggregates.data_points > 0 THEN UPDATE public.item_price_history SET min_price_in_cents = new_aggregates.min_price, max_price_in_cents = new_aggregates.max_price, avg_price_in_cents = new_aggregates.avg_price, data_points_count = new_aggregates.data_points WHERE master_item_id = OLD.master_item_id AND summary_date = current_summary_date AND store_location_id = flyer_location_id; ELSE DELETE FROM public.item_price_history WHERE master_item_id = OLD.master_item_id AND summary_date = current_summary_date AND store_location_id = flyer_location_id; END IF; END LOOP; END LOOP; RETURN OLD; END; $$ LANGUAGE plpgsql; -- Create the trigger on the flyer_items table for DELETE operations. DROP TRIGGER IF EXISTS trigger_recalculate_price_history_on_delete ON public.flyer_items; CREATE TRIGGER trigger_recalculate_price_history_on_delete AFTER DELETE ON public.flyer_items FOR EACH ROW EXECUTE FUNCTION public.recalculate_price_history_on_flyer_item_delete(); -- 5. Trigger function to update the average rating on the recipes table. CREATE OR REPLACE FUNCTION public.update_recipe_rating_aggregates() RETURNS TRIGGER AS $$ BEGIN UPDATE public.recipes SET avg_rating = ( SELECT AVG(rating) FROM public.recipe_ratings WHERE recipe_id = COALESCE(NEW.recipe_id, OLD.recipe_id) ), rating_count = ( SELECT COUNT(*) FROM public.recipe_ratings WHERE recipe_id = COALESCE(NEW.recipe_id, OLD.recipe_id) ) WHERE id = COALESCE(NEW.recipe_id, OLD.recipe_id); RETURN NULL; -- The result is ignored since this is an AFTER trigger. END; $$ LANGUAGE plpgsql; -- Trigger to call the function after any change to recipe_ratings. DROP TRIGGER IF EXISTS on_recipe_rating_change ON public.recipe_ratings; CREATE TRIGGER on_recipe_rating_change AFTER INSERT OR UPDATE OR DELETE ON public.recipe_ratings FOR EACH ROW EXECUTE FUNCTION public.update_recipe_rating_aggregates(); -- 6. Trigger function to log the creation of a new recipe. CREATE OR REPLACE FUNCTION public.log_new_recipe() RETURNS TRIGGER AS $$ BEGIN INSERT INTO public.user_activity_log (user_id, activity_type, entity_id, details) VALUES ( NEW.user_id, 'new_recipe', NEW.id::text, jsonb_build_object('recipe_name', NEW.name) ); RETURN NEW; END; $$ LANGUAGE plpgsql; -- Trigger to call the function after a new recipe is inserted. DROP TRIGGER IF EXISTS on_new_recipe_created ON public.recipes; CREATE TRIGGER on_new_recipe_created AFTER INSERT ON public.recipes FOR EACH ROW EXECUTE FUNCTION public.log_new_recipe(); -- 7. Trigger function to log the creation of a new flyer. CREATE OR REPLACE FUNCTION public.log_new_flyer() RETURNS TRIGGER AS $$ BEGIN INSERT INTO public.user_activity_log (activity_type, entity_id, details) VALUES ( 'new_flyer', NEW.id::text, jsonb_build_object( 'store_name', (SELECT name FROM public.stores WHERE id = NEW.store_id), 'valid_from', NEW.valid_from, 'valid_to', NEW.valid_to ) ); RETURN NEW; END; $$ LANGUAGE plpgsql; -- Trigger to call the function after a new flyer is inserted. DROP TRIGGER IF EXISTS on_new_flyer_created ON public.flyers; CREATE TRIGGER on_new_flyer_created AFTER INSERT ON public.flyers FOR EACH ROW EXECUTE FUNCTION public.log_new_flyer(); -- 8. Trigger function to log when a user favorites a recipe. CREATE OR REPLACE FUNCTION public.log_new_favorite_recipe() RETURNS TRIGGER AS $$ BEGIN INSERT INTO public.user_activity_log (user_id, activity_type, entity_id, details) VALUES ( NEW.user_id, 'favorite_recipe', NEW.recipe_id::text, jsonb_build_object( 'recipe_name', (SELECT name FROM public.recipes WHERE id = NEW.recipe_id) ) ); RETURN NEW; END; $$ LANGUAGE plpgsql; -- Trigger to call the function after a recipe is favorited. DROP TRIGGER IF EXISTS on_new_favorite_recipe ON public.favorite_recipes; CREATE TRIGGER on_new_favorite_recipe AFTER INSERT ON public.favorite_recipes FOR EACH ROW EXECUTE FUNCTION public.log_new_favorite_recipe(); -- 9. Trigger function to log when a user shares a shopping list. CREATE OR REPLACE FUNCTION public.log_new_list_share() RETURNS TRIGGER AS $$ BEGIN INSERT INTO public.user_activity_log (user_id, activity_type, entity_id, details) VALUES ( NEW.shared_by_user_id, 'share_shopping_list', NEW.shopping_list_id::text, jsonb_build_object( 'list_name', (SELECT name FROM public.shopping_lists WHERE id = NEW.shopping_list_id), 'shared_with_name', (SELECT full_name FROM public.profiles WHERE id = NEW.shared_with_user_id) ) ); RETURN NEW; END; $$ LANGUAGE plpgsql; -- Trigger to call the function after a shopping list is shared. DROP TRIGGER IF EXISTS on_new_list_share ON public.shared_shopping_lists; CREATE TRIGGER on_new_list_share AFTER INSERT ON public.shared_shopping_lists FOR EACH ROW EXECUTE FUNCTION public.log_new_list_share(); -- Function to find the best current sale price for a user's watched items. -- This function queries all currently active flyers to find the lowest price -- for each item on a specific user's watchlist. CREATE OR REPLACE FUNCTION public.get_best_sale_prices_for_user(p_user_id UUID) RETURNS TABLE ( master_item_id BIGINT, item_name TEXT, best_price_in_cents INTEGER, store_name TEXT, flyer_id BIGINT, flyer_image_url TEXT, flyer_valid_from DATE, flyer_valid_to DATE ) LANGUAGE plpgsql SECURITY INVOKER -- Runs with the privileges of the calling user. AS $$ BEGIN RETURN QUERY WITH UserWatchedSales AS ( -- This CTE gathers all sales from active flyers that match the user's watched items. SELECT uwi.master_item_id, mgi.name AS item_name, fi.price_in_cents, s.name AS store_name, f.id AS flyer_id, f.image_url AS flyer_image_url, f.valid_from AS flyer_valid_from, f.valid_to AS flyer_valid_to, -- We use ROW_NUMBER to rank sales for the same item, prioritizing the lowest price. ROW_NUMBER() OVER (PARTITION BY uwi.master_item_id ORDER BY fi.price_in_cents ASC, f.valid_to DESC, s.name ASC) as rn FROM public.user_watched_items uwi JOIN public.master_grocery_items mgi ON uwi.master_item_id = mgi.id JOIN public.flyer_items fi ON uwi.master_item_id = fi.master_item_id JOIN public.flyers f ON fi.flyer_id = f.id JOIN public.stores s ON f.store_id = s.id WHERE uwi.user_id = p_user_id AND f.valid_from <= CURRENT_DATE AND f.valid_to >= CURRENT_DATE AND fi.price_in_cents IS NOT NULL ) -- The final select returns only the top-ranked sale (rn = 1) for each item. SELECT uws.master_item_id, uws.item_name, uws.price_in_cents, uws.store_name, uws.flyer_id, uws.flyer_image_url, uws.flyer_valid_from, uws.flyer_valid_to FROM UserWatchedSales uws WHERE uws.rn = 1; END; $$; -- Function to generate a smart shopping list from a menu plan, subtracting pantry items. -- This function calculates the total ingredients needed for a user's menu plan, -- scales them by desired servings, and then subtracts what the user already has -- in their pantry to determine what needs to be bought. CREATE OR REPLACE FUNCTION public.generate_shopping_list_for_menu_plan(p_menu_plan_id BIGINT, p_user_id UUID) RETURNS TABLE ( master_item_id BIGINT, item_name TEXT, required_quantity NUMERIC, pantry_quantity NUMERIC, shopping_list_quantity NUMERIC, unit TEXT ) LANGUAGE plpgsql SECURITY INVOKER -- Runs with the privileges of the calling user. AS $$ BEGIN RETURN QUERY WITH RequiredIngredients AS ( -- This CTE calculates the total quantity of each ingredient needed for the menu plan. -- It accounts for scaling the recipe based on the number of servings the user plans to cook. SELECT ri.master_item_id, ri.unit, SUM( ri.quantity * -- The base ingredient quantity from the recipe -- Calculate the scaling factor. Default to 1 if servings_to_cook is not set. (COALESCE(pm.servings_to_cook, r.servings)::NUMERIC / NULLIF(r.servings, 0)::NUMERIC) ) AS total_required FROM public.menu_plans mp JOIN public.planned_meals pm ON mp.id = pm.menu_plan_id JOIN public.recipe_ingredients ri ON pm.recipe_id = ri.recipe_id JOIN public.recipes r ON pm.recipe_id = r.id -- Join to get the recipe's base servings WHERE mp.id = p_menu_plan_id AND mp.user_id = p_user_id GROUP BY ri.master_item_id, ri.unit ) -- This final select compares the required ingredients with the user's pantry. SELECT req.master_item_id, mgi.name AS item_name, req.total_required AS required_quantity, COALESCE(pi.quantity, 0) AS pantry_quantity, -- Calculate the amount to buy. If pantry has enough, this will be 0 or less, so GREATEST(0, ...) ensures we don't get negative values. GREATEST(0, req.total_required - COALESCE(pi.quantity, 0)) AS shopping_list_quantity, req.unit FROM RequiredIngredients req JOIN public.master_grocery_items mgi ON req.master_item_id = mgi.id LEFT JOIN public.pantry_items pi ON req.master_item_id = pi.master_item_id AND req.unit = pi.unit -- Critical: only subtract if units match to avoid errors (e.g., subtracting 2 "items" from 500 "grams"). AND pi.user_id = p_user_id WHERE -- Only include items that actually need to be purchased. GREATEST(0, req.total_required - COALESCE(pi.quantity, 0)) > 0; END; $$; -- Function to find recipes based on the percentage of their ingredients that are currently on sale. -- For example, you can ask for recipes where at least 50% of the ingredients are on sale. CREATE OR REPLACE FUNCTION public.get_recipes_by_sale_percentage(p_min_sale_percentage NUMERIC DEFAULT 100.0) RETURNS TABLE (recipe_details JSONB) LANGUAGE sql STABLE -- Indicates the function cannot modify the database and is safe for read-only queries. SECURITY INVOKER AS $$ WITH BestCurrentPrices AS ( -- CTE 1: For every distinct item on sale, find its single best price and the store offering it. SELECT bcp.master_item_id, bcp.price_in_cents, bcp.store_name FROM ( SELECT fi.master_item_id, fi.price_in_cents, s.name as store_name, ROW_NUMBER() OVER(PARTITION BY fi.master_item_id ORDER BY fi.price_in_cents ASC, f.valid_to DESC) as rn FROM public.flyer_items fi JOIN public.flyers f ON fi.flyer_id = f.id JOIN public.stores s ON f.store_id = s.id WHERE fi.master_item_id IS NOT NULL AND fi.price_in_cents IS NOT NULL AND CURRENT_DATE BETWEEN f.valid_from AND f.valid_to ) bcp WHERE bcp.rn = 1 ), RecipeIngredientStats AS ( -- CTE 2: For each recipe, count its total ingredients and how many of them are on sale. SELECT ri.recipe_id, COUNT(ri.master_item_id) AS total_ingredients, COUNT(bcp.master_item_id) AS sale_ingredients -- COUNT(column) only counts non-NULL values. FROM public.recipe_ingredients ri LEFT JOIN BestCurrentPrices bcp ON ri.master_item_id = bcp.master_item_id -- Join to count how many ingredients are on sale GROUP BY ri.recipe_id ), EligibleRecipes AS ( -- CTE 3: Filter recipes based on the minimum sale percentage provided as an argument. SELECT ris.recipe_id, ris.total_ingredients, ris.sale_ingredients FROM RecipeIngredientStats ris WHERE ris.total_ingredients > 0 -- Avoid division by zero and recipes with no ingredients AND (ris.sale_ingredients * 100.0 / ris.total_ingredients) >= p_min_sale_percentage ), RecipeSaleDetails AS ( -- CTE 4: Gather details for the eligible recipes and ALL their ingredients, noting which are on sale. SELECT r.id AS recipe_id, r.name AS recipe_name, mgi.name AS item_name, bcp.price_in_cents AS best_price_in_cents, -- This will be NULL if not on sale bcp.store_name -- This will be NULL if not on sale FROM public.recipes r JOIN EligibleRecipes er ON r.id = er.recipe_id -- Join with the filtered eligible recipes JOIN public.recipe_ingredients ri ON r.id = ri.recipe_id JOIN public.master_grocery_items mgi ON ri.master_item_id = mgi.id LEFT JOIN BestCurrentPrices bcp ON ri.master_item_id = bcp.master_item_id -- LEFT JOIN to include all ingredients, not just sale ones. ) -- Final Step: Aggregate the details into a single JSON object for each recipe. SELECT jsonb_build_object( 'id', rsd.recipe_id, 'name', rsd.recipe_name, 'ingredients', jsonb_agg( jsonb_build_object( 'item_name', rsd.item_name, 'on_sale', (rsd.best_price_in_cents IS NOT NULL), 'best_price_in_cents', rsd.best_price_in_cents, 'store_name', rsd.store_name ) ORDER BY (rsd.best_price_in_cents IS NOT NULL) DESC, rsd.item_name ASC -- Show sale items first in the list. ) ) FROM RecipeSaleDetails rsd GROUP BY rsd.recipe_id, rsd.recipe_name; $$; -- Function to add items generated from a menu plan directly to a user's shopping list. -- This acts as a utility function to chain `generate_shopping_list_for_menu_plan` with an INSERT action. CREATE OR REPLACE FUNCTION public.add_menu_plan_to_shopping_list( p_menu_plan_id BIGINT, p_shopping_list_id BIGINT, p_user_id UUID ) RETURNS TABLE ( master_item_id BIGINT, item_name TEXT, quantity_added NUMERIC ) LANGUAGE plpgsql -- SECURITY DEFINER is used here to perform actions with elevated privileges, -- but it's safe because we first perform a strict ownership check inside the function. SECURITY DEFINER AS $$ DECLARE list_owner_id UUID; item_to_add RECORD; BEGIN -- 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 id = p_shopping_list_id; IF list_owner_id IS NULL OR list_owner_id <> p_user_id THEN RAISE EXCEPTION 'Permission denied: You do not own shopping list %', p_shopping_list_id; END IF; -- Loop through the items generated by the smart shopping list function. FOR item_to_add IN SELECT * FROM public.generate_shopping_list_for_menu_plan(p_menu_plan_id, p_user_id) LOOP -- Insert the item into the shopping list. If it already exists, add to the quantity. INSERT INTO public.shopping_list_items (shopping_list_id, master_item_id, quantity) VALUES (p_shopping_list_id, item_to_add.master_item_id, item_to_add.shopping_list_quantity) ON CONFLICT (shopping_list_id, master_item_id) DO UPDATE SET quantity = shopping_list_items.quantity + EXCLUDED.quantity; -- 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; END; $$; -- Function to find recipes that have at least a specified number of ingredients currently on sale. CREATE OR REPLACE FUNCTION public.get_recipes_by_min_sale_ingredients(p_min_sale_ingredients INTEGER) RETURNS TABLE ( recipe_id BIGINT, recipe_name TEXT, description TEXT, sale_ingredients_count BIGINT ) LANGUAGE sql STABLE SECURITY INVOKER AS $$ WITH CurrentSaleItems AS ( -- CTE 1: Get a distinct list of all master item IDs that are currently on sale. SELECT DISTINCT fi.master_item_id FROM public.flyer_items fi JOIN public.flyers f ON fi.flyer_id = f.id WHERE fi.master_item_id IS NOT NULL AND fi.price_in_cents IS NOT NULL AND CURRENT_DATE BETWEEN f.valid_from AND f.valid_to ), RecipeIngredientStats AS ( -- CTE 2: For each recipe, count how many of its ingredients are on the sale list. SELECT ri.recipe_id, COUNT(csi.master_item_id) AS sale_ingredients_count FROM public.recipe_ingredients ri LEFT JOIN CurrentSaleItems csi ON ri.master_item_id = csi.master_item_id GROUP BY ri.recipe_id ) -- Final Step: Select recipes that meet the minimum sale ingredient count and order them. SELECT r.id, r.name, r.description, ris.sale_ingredients_count FROM public.recipes r JOIN RecipeIngredientStats ris ON r.id = ris.recipe_id WHERE ris.sale_ingredients_count >= p_min_sale_ingredients ORDER BY ris.sale_ingredients_count DESC, r.avg_rating DESC; $$; -- Function to find the most frequently advertised items in a given period. -- This helps identify which items go on sale most often. CREATE OR REPLACE FUNCTION public.get_most_frequent_sale_items(days_interval INTEGER, result_limit INTEGER) RETURNS TABLE ( item_name TEXT, sale_occurrence_count BIGINT ) LANGUAGE sql STABLE SECURITY INVOKER AS $$ SELECT mgi.name AS item_name, COUNT(DISTINCT fi.flyer_id) AS sale_occurrence_count -- Count distinct flyers the item appeared in FROM public.flyer_items fi JOIN public.flyers f ON fi.flyer_id = f.id JOIN public.master_grocery_items mgi ON fi.master_item_id = mgi.id WHERE -- Only consider items linked to our master list fi.master_item_id IS NOT NULL -- Filter for flyers that have been active in the last X days AND f.valid_to >= (CURRENT_DATE - (days_interval || ' days')::INTERVAL) AND f.valid_from <= CURRENT_DATE GROUP BY mgi.id, mgi.name ORDER BY sale_occurrence_count DESC LIMIT result_limit; $$; -- Function to find recipes by a specific ingredient AND a specific tag. -- This allows for more refined recipe searching, e.g., "Find me a quick & easy recipe with chicken breast". CREATE OR REPLACE FUNCTION public.find_recipes_by_ingredient_and_tag(p_ingredient_name TEXT, p_tag_name TEXT) RETURNS TABLE ( id BIGINT, name TEXT, description TEXT, prep_time_minutes INTEGER, cook_time_minutes INTEGER, avg_rating NUMERIC ) LANGUAGE sql STABLE SECURITY INVOKER AS $$ SELECT r.id, r.name, r.description, r.prep_time_minutes, r.cook_time_minutes, r.avg_rating FROM public.recipes r WHERE -- Check that the recipe has the required ingredient using an EXISTS subquery. EXISTS ( SELECT 1 FROM public.recipe_ingredients ri JOIN public.master_grocery_items mgi ON ri.master_item_id = mgi.id WHERE ri.recipe_id = r.id AND mgi.name = p_ingredient_name ) AND -- Check that the recipe has the required tag using another EXISTS subquery. EXISTS ( SELECT 1 FROM public.recipe_tags rt JOIN public.tags t ON rt.tag_id = t.id WHERE rt.recipe_id = r.id AND t.name = p_tag_name ) ORDER BY r.avg_rating DESC, r.name ASC; $$; -- Function to suggest a master_item_id for a given flyer item name. -- This function uses trigram similarity to find the best match from both the -- master_grocery_items table and the master_item_aliases table. CREATE OR REPLACE FUNCTION public.suggest_master_item_for_flyer_item(p_flyer_item_name TEXT) RETURNS BIGINT LANGUAGE plpgsql STABLE -- This function does not modify the database. AS $$ DECLARE suggested_id BIGINT; -- 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; BEGIN WITH candidates AS ( -- Search for matches in the primary master_grocery_items table SELECT id AS master_item_id, similarity(name, p_flyer_item_name) AS score FROM public.master_grocery_items WHERE name % p_flyer_item_name -- The '%' operator uses the trigram index for pre-filtering, making the search much faster. UNION ALL -- Search for matches in the master_item_aliases table SELECT master_item_id, similarity(alias, p_flyer_item_name) AS score FROM public.master_item_aliases 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; RETURN suggested_id; END; $$; -- Function to recommend recipes to a user based on their watched items and highly-rated recipes. -- It calculates a score based on ingredient matches from the user's watchlist and similarity -- to other recipes the user has liked. CREATE OR REPLACE FUNCTION public.recommend_recipes_for_user(p_user_id UUID, p_limit INTEGER DEFAULT 10) RETURNS TABLE ( recipe_id BIGINT, recipe_name TEXT, recipe_description TEXT, avg_rating NUMERIC, recommendation_score NUMERIC, recommendation_reason TEXT ) LANGUAGE sql STABLE SECURITY INVOKER AS $$ WITH UserHighRatedRecipes AS ( -- CTE 1: Get recipes the user has rated 4 stars or higher. SELECT rr.recipe_id, rr.rating FROM public.recipe_ratings rr WHERE rr.user_id = p_user_id AND rr.rating >= 4 ), UserWatchedItems AS ( -- CTE 2: Get the user's watchlist of grocery items. SELECT uwi.master_item_id FROM public.user_watched_items uwi WHERE uwi.user_id = p_user_id ), RecipeScores AS ( -- CTE 3: Calculate a score for each recipe based on two factors. SELECT r.id AS recipe_id, -- Score from watched items: +5 points for each watched ingredient in the recipe. ( SELECT 5 * COUNT(*) FROM public.recipe_ingredients ri WHERE ri.recipe_id = r.id AND ri.master_item_id IN (SELECT master_item_id FROM UserWatchedItems) ) AS watched_item_score, -- Score from similarity to highly-rated recipes. ( SELECT COALESCE(SUM( -- +2 points for each shared ingredient with a highly-rated recipe. ( SELECT 2 * COUNT(*) FROM public.recipe_ingredients ri1 JOIN public.recipe_ingredients ri2 ON ri1.master_item_id = ri2.master_item_id WHERE ri1.recipe_id = r.id AND ri2.recipe_id = uhr.recipe_id ) + -- +3 points for each shared tag with a highly-rated recipe. ( SELECT 3 * COUNT(*) FROM public.recipe_tags rt1 JOIN public.recipe_tags rt2 ON rt1.tag_id = rt2.tag_id WHERE rt1.recipe_id = r.id AND rt2.recipe_id = uhr.recipe_id ) ), 0) FROM UserHighRatedRecipes uhr WHERE uhr.recipe_id <> r.id -- Don't compare a recipe to itself. ) AS similarity_score FROM public.recipes r ), RankedRecommendations AS ( -- CTE 4: Combine scores and generate a human-readable reason for the recommendation. SELECT rs.recipe_id, rs.watched_item_score + rs.similarity_score AS total_score, -- Create a reason string based on which score is higher. CASE WHEN rs.watched_item_score > rs.similarity_score THEN 'Contains items from your watchlist' WHEN rs.similarity_score > 0 THEN 'Similar to recipes you''ve liked' ELSE 'A popular recipe you might like' END AS reason FROM RecipeScores rs WHERE rs.watched_item_score + rs.similarity_score > 0 -- Exclude recipes the user has already rated to avoid recommending things they've already seen. AND rs.recipe_id NOT IN (SELECT recipe_id FROM public.recipe_ratings WHERE user_id = p_user_id) ) -- Final Selection: Join back to the recipes table to get full details and order by the final score. SELECT r.id, r.name, r.description, r.avg_rating, rr.total_score, rr.reason FROM RankedRecommendations rr JOIN public.recipes r ON rr.recipe_id = r.id ORDER BY rr.total_score DESC, r.avg_rating DESC, -- As a tie-breaker, prefer higher-rated recipes. r.rating_count DESC, r.name ASC LIMIT p_limit; $$; -- Function to approve a suggested correction and apply it. -- This is a SECURITY DEFINER function to allow an admin to update tables -- they might not have direct RLS access to. CREATE OR REPLACE FUNCTION public.approve_correction(p_correction_id BIGINT) RETURNS void LANGUAGE plpgsql SECURITY DEFINER AS $$ DECLARE correction_record RECORD; BEGIN -- 1. Fetch the correction details, ensuring it's still pending. SELECT * INTO correction_record FROM public.suggested_corrections WHERE id = p_correction_id AND status = 'pending'; IF NOT FOUND THEN RAISE EXCEPTION 'Correction with ID % not found or already processed.', p_correction_id; END IF; -- 2. Apply the correction based on its type. IF correction_record.correction_type = 'INCORRECT_ITEM_LINK' THEN UPDATE public.flyer_items SET master_item_id = correction_record.suggested_value::BIGINT WHERE id = correction_record.flyer_item_id; ELSIF correction_record.correction_type = 'WRONG_PRICE' THEN UPDATE public.flyer_items SET price_in_cents = correction_record.suggested_value::INTEGER WHERE id = correction_record.flyer_item_id; END IF; -- 3. Update the correction status to 'approved'. UPDATE public.suggested_corrections SET status = 'approved', reviewed_at = now() WHERE id = p_correction_id; END; $$; -- Function to find recipes that can be made entirely from items in a user's pantry. -- This function checks each recipe and returns it only if every ingredient is present -- in the specified user's pantry. CREATE OR REPLACE FUNCTION public.find_recipes_from_pantry(p_user_id UUID) RETURNS TABLE( id BIGINT, name TEXT, description TEXT, prep_time_minutes INTEGER, cook_time_minutes INTEGER, avg_rating NUMERIC, missing_ingredients_count BIGINT ) LANGUAGE sql 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 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. 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.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.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; $$; -- Function to suggest alternative units for a given pantry item. -- For example, if a user has 500g of flour, this function might suggest "4.1 cups". CREATE OR REPLACE FUNCTION public.suggest_pantry_item_conversions(p_pantry_item_id BIGINT) RETURNS TABLE ( suggested_quantity NUMERIC, suggested_unit TEXT ) LANGUAGE sql STABLE SECURITY INVOKER AS $$ SELECT -- Calculate the converted quantity by multiplying the original quantity by the conversion factor. -- Round to 2 decimal places for readability. ROUND(pi.quantity * uc.factor, 2) AS suggested_quantity, uc.to_unit AS suggested_unit FROM public.pantry_items pi -- Join with the unit_conversions table to find available conversion rules. JOIN public.unit_conversions uc ON pi.master_item_id = uc.master_item_id AND pi.unit = uc.from_unit WHERE pi.id = p_pantry_item_id -- Exclude suggesting a conversion back to the same unit. AND pi.unit <> uc.to_unit; $$; -- Function to get a user's favorite recipes. CREATE OR REPLACE FUNCTION public.get_user_favorite_recipes(p_user_id UUID) RETURNS TABLE ( id BIGINT, name TEXT, description TEXT, avg_rating NUMERIC, photo_url TEXT ) LANGUAGE sql STABLE SECURITY INVOKER AS $$ SELECT r.id, r.name, r.description, r.avg_rating, r.photo_url FROM public.recipes r JOIN public.favorite_recipes fr ON r.id = fr.recipe_id WHERE fr.user_id = p_user_id ORDER BY r.name ASC; $$; -- Function to get a paginated list of recent activities for the audit log. CREATE OR REPLACE FUNCTION public.get_activity_log(p_limit INTEGER DEFAULT 20, p_offset INTEGER DEFAULT 0) RETURNS TABLE ( id BIGINT, user_id UUID, activity_type TEXT, entity_id TEXT, details JSONB, created_at TIMESTAMPTZ, user_full_name TEXT, user_avatar_url TEXT ) LANGUAGE sql STABLE SECURITY INVOKER AS $$ SELECT al.id, al.user_id, al.activity_type, al.entity_id, al.details, al.created_at, p.full_name AS user_full_name, p.avatar_url AS user_avatar_url FROM public.user_activity_log al -- Join with profiles to get user details for display. -- LEFT JOIN is used because some activities might be system-generated (user_id is NULL). LEFT JOIN public.profiles p ON al.user_id = p.id ORDER BY al.created_at DESC LIMIT p_limit OFFSET p_offset; $$; -- Function to get recipes that are compatible with a user's dietary restrictions (allergies). -- It filters out any recipe containing an ingredient that the user is allergic to. CREATE OR REPLACE FUNCTION public.get_recipes_for_user_diets(p_user_id UUID) RETURNS SETOF public.recipes LANGUAGE sql STABLE SECURITY INVOKER AS $$ WITH UserAllergens AS ( -- CTE 1: Find all master item IDs that are allergens for the given user. SELECT mgi.id FROM public.master_grocery_items mgi JOIN public.dietary_restrictions dr ON mgi.allergy_info->>'type' = dr.name JOIN public.user_dietary_restrictions udr ON dr.id = udr.restriction_id WHERE udr.user_id = p_user_id AND dr.type = 'allergy' AND mgi.is_allergen = true ), ForbiddenRecipes AS ( -- CTE 2: Find all recipe IDs that contain one or more of the user's allergens. SELECT DISTINCT ri.recipe_id FROM public.recipe_ingredients ri WHERE ri.master_item_id IN (SELECT id FROM UserAllergens) ) -- Final Selection: Return all recipes that are NOT in the forbidden list. SELECT * FROM public.recipes r WHERE r.id NOT IN (SELECT recipe_id FROM ForbiddenRecipes) ORDER BY r.avg_rating DESC, r.name ASC; $$; -- Function to get a personalized activity feed for a user based on who they follow. -- It aggregates recent activities from followed users. CREATE OR REPLACE FUNCTION public.get_user_feed(p_user_id UUID, p_limit INTEGER DEFAULT 20, p_offset INTEGER DEFAULT 0) RETURNS TABLE ( id BIGINT, user_id UUID, activity_type TEXT, entity_id TEXT, details JSONB, created_at TIMESTAMPTZ, user_full_name TEXT, user_avatar_url TEXT ) LANGUAGE sql STABLE SECURITY INVOKER AS $$ WITH FollowedUsers AS ( -- CTE 1: Get the IDs of all users that the current user is following. SELECT following_id FROM public.user_follows WHERE follower_id = p_user_id ) -- Final Selection: Get activities from the log where the user_id is in the followed list. SELECT al.id, al.user_id, al.activity_type, al.entity_id, al.details, al.created_at, p.full_name AS user_full_name, p.avatar_url AS user_avatar_url FROM public.user_activity_log al JOIN public.profiles p ON al.user_id = p.id WHERE al.user_id IN (SELECT following_id FROM FollowedUsers) -- We can filter for specific activity types to make the feed more relevant. AND al.activity_type IN ( 'new_recipe', 'favorite_recipe', 'share_shopping_list' -- 'new_recipe_rating' could be added here later ) ORDER BY al.created_at DESC LIMIT p_limit OFFSET p_offset; $$; -- Function to archive a shopping list into a historical shopping trip. -- It creates a shopping_trip record, copies purchased items to shopping_trip_items, -- and then deletes the purchased items from the original shopping list. CREATE OR REPLACE FUNCTION public.complete_shopping_list( p_shopping_list_id BIGINT, p_user_id UUID, p_total_spent_cents INTEGER DEFAULT NULL ) RETURNS BIGINT -- Returns the ID of the new shopping_trip record. LANGUAGE plpgsql SECURITY DEFINER AS $$ DECLARE list_owner_id UUID; new_trip_id BIGINT; BEGIN -- 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 id = p_shopping_list_id; IF list_owner_id IS NULL OR list_owner_id <> p_user_id THEN RAISE EXCEPTION 'Permission denied: You do not own shopping list %', p_shopping_list_id; END IF; -- 1. Create a new shopping_trip record. INSERT INTO public.shopping_trips (user_id, shopping_list_id, total_spent_cents) VALUES (p_user_id, p_shopping_list_id, p_total_spent_cents) RETURNING id INTO new_trip_id; -- 2. Copy purchased items from the shopping list to the new shopping_trip_items table. INSERT INTO public.shopping_trip_items (shopping_trip_id, master_item_id, custom_item_name, quantity) SELECT new_trip_id, master_item_id, custom_item_name, quantity FROM public.shopping_list_items WHERE shopping_list_id = p_shopping_list_id AND is_purchased = true; -- 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; RETURN new_trip_id; END; $$; -- Function to find better deals for items on a recently processed receipt. -- It compares the price paid on the receipt with current flyer prices. CREATE OR REPLACE FUNCTION public.find_deals_for_receipt_items(p_receipt_id BIGINT) RETURNS TABLE ( receipt_item_id BIGINT, master_item_id BIGINT, item_name TEXT, price_paid_cents INTEGER, current_best_price_in_cents INTEGER, potential_savings_cents INTEGER, deal_store_name TEXT, flyer_id BIGINT ) LANGUAGE sql STABLE SECURITY INVOKER AS $$ WITH ReceiptItems AS ( -- CTE 1: Get all matched items from the specified receipt. SELECT ri.id AS receipt_item_id, ri.master_item_id, mgi.name AS item_name, ri.price_paid_cents FROM public.receipt_items ri JOIN public.master_grocery_items mgi ON ri.master_item_id = mgi.id WHERE ri.receipt_id = p_receipt_id AND ri.master_item_id IS NOT NULL ), BestCurrentPrices AS ( -- CTE 2: Find the single best price for every item currently on sale. SELECT DISTINCT ON (fi.master_item_id) fi.master_item_id, fi.price_in_cents, s.name AS store_name, f.id AS flyer_id FROM public.flyer_items fi JOIN public.flyers f ON fi.flyer_id = f.id JOIN public.stores s ON f.store_id = s.id WHERE fi.master_item_id IS NOT NULL AND fi.price_in_cents IS NOT NULL AND CURRENT_DATE BETWEEN f.valid_from AND f.valid_to ORDER BY fi.master_item_id, fi.price_in_cents ASC ) -- Final Selection: Join receipt items with current deals and find savings. SELECT ri.receipt_item_id, ri.master_item_id, ri.item_name, ri.price_paid_cents, bcp.price_in_cents AS current_best_price_in_cents, (ri.price_paid_cents - bcp.price_in_cents) AS potential_savings_cents, bcp.store_name AS deal_store_name, bcp.flyer_id FROM ReceiptItems ri JOIN BestCurrentPrices bcp ON ri.master_item_id = bcp.master_item_id -- Only return rows where the current sale price is better than the price paid. WHERE bcp.price_in_cents < ri.price_paid_cents ORDER BY potential_savings_cents DESC; $$;