Files
flyer-crawler.projectium.com/sql/triggers.sql

183 lines
7.6 KiB
PL/PgSQL

-- 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 will be called by the trigger.
CREATE OR REPLACE FUNCTION public.handle_new_user()
RETURNS TRIGGER AS $$
DECLARE
new_profile_id UUID;
BEGIN
INSERT INTO public.profiles (id, full_name, avatar_url)
VALUES (new.id, new.raw_user_meta_data->>'full_name', new.raw_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');
RETURN new;
END;
$$ LANGUAGE plpgsql SECURITY DEFINER;
-- This trigger calls the function after a new user is created.
DROP TRIGGER IF EXISTS on_auth_user_created ON auth.users;
CREATE TRIGGER on_auth_user_created
AFTER INSERT ON auth.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 SECURITY DEFINER;
-- 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 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();
-- 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;
BEGIN
-- 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.
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.
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, min_price_in_cents, max_price_in_cents, avg_price_in_cents, data_points_count)
VALUES (NEW.master_item_id, current_summary_date, NEW.price_in_cents, NEW.price_in_cents, NEW.price_in_cents, 1)
ON CONFLICT (master_item_id, summary_date)
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),
-- Recalculate the average price: ((old_avg * old_count) + new_price) / (old_count + 1)
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)),
data_points_count = item_price_history.data_points_count + 1;
END LOOP;
RETURN NEW;
END;
$$ LANGUAGE plpgsql SECURITY DEFINER;
-- 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;
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.
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.
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.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;
-- 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;
ELSE
DELETE FROM public.item_price_history
WHERE master_item_id = OLD.master_item_id AND summary_date = current_summary_date;
END IF;
END LOOP;
RETURN OLD;
END;
$$ LANGUAGE plpgsql SECURITY DEFINER;
-- 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 SECURITY DEFINER;
-- 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();