database expansion prior to creating on server - also error cleanup, some logging - DONE now for testing hehehe
Some checks are pending
Deploy to Web Server flyer-crawler.projectium.com / deploy (push) Has started running
Some checks are pending
Deploy to Web Server flyer-crawler.projectium.com / deploy (push) Has started running
This commit is contained in:
@@ -1,5 +1,340 @@
|
||||
-- This file contains all trigger functions and trigger definitions for the database.
|
||||
|
||||
-- Function to find the best current sale price for a user's watched items.
|
||||
-- 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)
|
||||
@@ -52,7 +52,19 @@ BEGIN
|
||||
ON CONFLICT (name) DO NOTHING;
|
||||
END $$;
|
||||
|
||||
-- 2. Pre-populate the brands and products tables.
|
||||
-- 2. Pre-populate the categories table from a predefined list.
|
||||
DO $$
|
||||
BEGIN
|
||||
INSERT INTO public.categories (name) VALUES
|
||||
('Fruits & Vegetables'), ('Meat & Seafood'), ('Dairy & Eggs'), ('Bakery & Bread'),
|
||||
('Pantry & Dry Goods'), ('Beverages'), ('Frozen Foods'), ('Snacks'), ('Household & Cleaning'),
|
||||
('Personal Care & Health'), ('Baby & Child'), ('Pet Supplies'), ('Deli & Prepared Foods'),
|
||||
('Canned Goods'), ('Condiments & Spices'), ('Breakfast & Cereal'), ('Organic'),
|
||||
('International Foods'), ('Other/Miscellaneous')
|
||||
ON CONFLICT (name) DO NOTHING;
|
||||
END $$;
|
||||
|
||||
-- 3. Pre-populate the brands and products tables.
|
||||
-- This block adds common brands and links them to specific products.
|
||||
DO $$
|
||||
DECLARE
|
||||
@@ -98,7 +110,7 @@ BEGIN
|
||||
ON CONFLICT (upc_code) DO NOTHING;
|
||||
END $$;
|
||||
|
||||
-- 3. Pre-populate the master_item_aliases table.
|
||||
-- 4. Pre-populate the master_item_aliases table.
|
||||
-- This block adds common alternative names for master items to improve fuzzy matching.
|
||||
DO $$
|
||||
DECLARE
|
||||
@@ -131,7 +143,7 @@ BEGIN
|
||||
ON CONFLICT (alias) DO NOTHING;
|
||||
END $$;
|
||||
|
||||
-- 4. Pre-populate recipes, ingredients, and tags to make the recommendation engine effective.
|
||||
-- 5. Pre-populate recipes, ingredients, and tags to make the recommendation engine effective.
|
||||
DO $$
|
||||
DECLARE
|
||||
-- Recipe IDs
|
||||
@@ -199,7 +211,7 @@ BEGIN
|
||||
ON CONFLICT (recipe_id, tag_id) DO NOTHING;
|
||||
END $$;
|
||||
|
||||
-- 5. Pre-populate the unit_conversions table with common cooking conversions.
|
||||
-- 6. Pre-populate the unit_conversions table with common cooking conversions.
|
||||
-- Factors are for converting 1 unit of `from_unit` to the `to_unit`.
|
||||
DO $$
|
||||
DECLARE
|
||||
@@ -227,14 +239,14 @@ BEGIN
|
||||
ON CONFLICT (master_item_id, from_unit, to_unit) DO NOTHING;
|
||||
END $$;
|
||||
|
||||
-- 6. Pre-populate the dietary_restrictions table.
|
||||
-- 7. Pre-populate the dietary_restrictions table.
|
||||
INSERT INTO public.dietary_restrictions (name, type) VALUES
|
||||
('Vegetarian', 'diet'), ('Vegan', 'diet'), ('Gluten-Free', 'diet'), ('Keto', 'diet'),
|
||||
('Dairy', 'allergy'), ('Eggs', 'allergy'), ('Fish', 'allergy'), ('Shellfish', 'allergy'),
|
||||
('Tree Nuts', 'allergy'), ('Peanuts', 'allergy'), ('Soy', 'allergy'), ('Wheat', 'allergy')
|
||||
ON CONFLICT (name) DO NOTHING;
|
||||
|
||||
-- 7. Pre-populate the appliances table.
|
||||
-- 8. Pre-populate the appliances table.
|
||||
INSERT INTO public.appliances (name) VALUES
|
||||
('Oven'), ('Microwave'), ('Stovetop'), ('Blender'), ('Food Processor'),
|
||||
('Stand Mixer'), ('Hand Mixer'), ('Air Fryer'), ('Instant Pot'), ('Slow Cooker'),
|
||||
|
||||
File diff suppressed because it is too large
Load Diff
@@ -33,11 +33,12 @@ CREATE TABLE IF NOT EXISTS public.users (
|
||||
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
|
||||
email TEXT NOT NULL UNIQUE,
|
||||
password_hash TEXT NOT NULL,
|
||||
refresh_token TEXT, -- Stores the long-lived refresh token for re-authentication.
|
||||
created_at TIMESTAMPTZ DEFAULT now() NOT NULL
|
||||
refresh_token TEXT,
|
||||
created_at TIMESTAMPTZ DEFAULT now() NOT NULL,
|
||||
updated_at TIMESTAMPTZ DEFAULT now() NOT NULL
|
||||
);
|
||||
COMMENT ON TABLE public.users IS 'Stores user authentication information, replacing Supabase auth.';
|
||||
|
||||
COMMENT ON COLUMN public.users.refresh_token IS 'Stores the long-lived refresh token for re-authentication.';
|
||||
-- Add an index on the refresh_token for faster lookups when refreshing tokens.
|
||||
CREATE INDEX IF NOT EXISTS idx_users_refresh_token ON public.users(refresh_token);
|
||||
|
||||
@@ -49,27 +50,33 @@ CREATE INDEX IF NOT EXISTS idx_users_refresh_token ON public.users(refresh_token
|
||||
-- 1. Create the 'stores' table for normalized store data.
|
||||
CREATE TABLE IF NOT EXISTS public.stores (
|
||||
id BIGINT PRIMARY KEY GENERATED ALWAYS AS IDENTITY,
|
||||
created_at TIMESTAMPTZ DEFAULT now() NOT NULL,
|
||||
name TEXT NOT NULL UNIQUE,
|
||||
logo_url TEXT
|
||||
logo_url TEXT,
|
||||
created_at TIMESTAMPTZ DEFAULT now() NOT NULL,
|
||||
updated_at TIMESTAMPTZ DEFAULT now() NOT NULL,
|
||||
created_by UUID REFERENCES public.users(id) ON DELETE SET NULL
|
||||
);
|
||||
COMMENT ON TABLE public.stores IS 'Stores metadata for grocery store chains (e.g., Safeway, Kroger).';
|
||||
|
||||
-- 2. Create the 'categories' table for normalized category data.
|
||||
CREATE TABLE IF NOT EXISTS public.categories (
|
||||
id BIGINT PRIMARY KEY GENERATED ALWAYS AS IDENTITY,
|
||||
name TEXT NOT NULL UNIQUE
|
||||
name TEXT NOT NULL UNIQUE,
|
||||
created_at TIMESTAMPTZ DEFAULT now() NOT NULL,
|
||||
updated_at TIMESTAMPTZ DEFAULT now() NOT NULL
|
||||
);
|
||||
COMMENT ON TABLE public.categories IS 'Stores a predefined list of grocery item categories (e.g., ''Fruits & Vegetables'', ''Dairy & Eggs'').';
|
||||
|
||||
-- 4. Create the 'master_grocery_items' table. This is the master dictionary.
|
||||
CREATE TABLE IF NOT EXISTS public.master_grocery_items (
|
||||
id BIGINT PRIMARY KEY GENERATED ALWAYS AS IDENTITY,
|
||||
created_at TIMESTAMPTZ DEFAULT now() NOT NULL,
|
||||
name TEXT NOT NULL UNIQUE,
|
||||
category_id BIGINT REFERENCES public.categories(id),
|
||||
is_allergen BOOLEAN DEFAULT false,
|
||||
allergy_info JSONB
|
||||
allergy_info JSONB,
|
||||
created_at TIMESTAMPTZ DEFAULT now() NOT NULL,
|
||||
updated_at TIMESTAMPTZ DEFAULT now() NOT NULL,
|
||||
created_by UUID REFERENCES public.users(id) ON DELETE SET NULL
|
||||
);
|
||||
COMMENT ON TABLE public.master_grocery_items IS 'The master dictionary of canonical grocery items. Each item has a unique name and is linked to a category.';
|
||||
CREATE INDEX IF NOT EXISTS idx_master_grocery_items_category_id ON public.master_grocery_items(category_id);
|
||||
@@ -77,14 +84,15 @@ CREATE INDEX IF NOT EXISTS idx_master_grocery_items_category_id ON public.master
|
||||
-- 3. Create the 'flyers' table with its full, final schema.
|
||||
CREATE TABLE IF NOT EXISTS public.flyers (
|
||||
id BIGINT PRIMARY KEY GENERATED ALWAYS AS IDENTITY,
|
||||
created_at TIMESTAMPTZ DEFAULT now() NOT NULL,
|
||||
file_name TEXT NOT NULL,
|
||||
image_url TEXT NOT NULL,
|
||||
checksum TEXT UNIQUE,
|
||||
store_id BIGINT REFERENCES public.stores(id),
|
||||
valid_from DATE,
|
||||
valid_to DATE,
|
||||
store_address TEXT
|
||||
store_address TEXT,
|
||||
created_at TIMESTAMPTZ DEFAULT now() NOT NULL,
|
||||
updated_at TIMESTAMPTZ DEFAULT now() NOT NULL
|
||||
);
|
||||
COMMENT ON TABLE public.flyers IS 'Stores metadata for each processed flyer, linking it to a store and its validity period.';
|
||||
CREATE INDEX IF NOT EXISTS idx_flyers_store_id ON public.flyers(store_id);
|
||||
@@ -98,7 +106,6 @@ COMMENT ON COLUMN public.flyers.store_address IS 'The physical store address if
|
||||
-- 6. Create the 'flyer_items' table with its full, final schema.
|
||||
CREATE TABLE IF NOT EXISTS public.flyer_items (
|
||||
id BIGINT PRIMARY KEY GENERATED ALWAYS AS IDENTITY,
|
||||
created_at TIMESTAMPTZ DEFAULT now() NOT NULL,
|
||||
flyer_id BIGINT REFERENCES public.flyers(id) ON DELETE CASCADE,
|
||||
item TEXT NOT NULL,
|
||||
price_display TEXT NOT NULL,
|
||||
@@ -109,9 +116,9 @@ CREATE TABLE IF NOT EXISTS public.flyer_items (
|
||||
view_count INTEGER DEFAULT 0 NOT NULL,
|
||||
click_count INTEGER DEFAULT 0 NOT NULL,
|
||||
category_id BIGINT REFERENCES public.categories(id),
|
||||
category_name TEXT, -- Denormalized for easier display
|
||||
unit_price JSONB, -- {"value": 1.99, "unit": "lb"}
|
||||
product_id BIGINT -- Future use for specific product linking
|
||||
category_name TEXT,
|
||||
unit_price JSONB,
|
||||
product_id BIGINT
|
||||
);
|
||||
COMMENT ON TABLE public.flyer_items IS 'Stores individual items extracted from a specific flyer.';
|
||||
CREATE INDEX IF NOT EXISTS idx_flyer_items_flyer_id ON public.flyer_items(flyer_id);
|
||||
@@ -137,12 +144,15 @@ CREATE INDEX IF NOT EXISTS flyer_items_item_trgm_idx ON public.flyer_items USING
|
||||
-- 0. Create a table for public user profiles.
|
||||
-- This table is linked to the auth.users table and stores non-sensitive user data.
|
||||
CREATE TABLE IF NOT EXISTS public.profiles (
|
||||
id UUID PRIMARY KEY REFERENCES public.users(id) ON DELETE CASCADE,
|
||||
updated_at TIMESTAMPTZ,
|
||||
id UUID PRIMARY KEY REFERENCES public.users(id) ON DELETE CASCADE,
|
||||
full_name TEXT,
|
||||
avatar_url TEXT,
|
||||
preferences JSONB,
|
||||
role TEXT CHECK (role IN ('admin', 'user'))
|
||||
role TEXT CHECK (role IN ('admin', 'user')),
|
||||
created_at TIMESTAMPTZ DEFAULT now() NOT NULL,
|
||||
updated_at TIMESTAMPTZ DEFAULT now() NOT NULL,
|
||||
created_by UUID REFERENCES public.users(id) ON DELETE SET NULL,
|
||||
updated_by UUID REFERENCES public.users(id) ON DELETE SET NULL
|
||||
);
|
||||
COMMENT ON TABLE public.profiles IS 'Stores public-facing user data, linked to the private auth.users table.';
|
||||
|
||||
@@ -151,7 +161,8 @@ CREATE TABLE IF NOT EXISTS public.user_watched_items (
|
||||
id BIGINT PRIMARY KEY GENERATED ALWAYS AS IDENTITY,
|
||||
user_id UUID NOT NULL REFERENCES public.users(id) ON DELETE CASCADE,
|
||||
master_item_id BIGINT NOT NULL REFERENCES public.master_grocery_items(id) ON DELETE CASCADE,
|
||||
created_at TIMESTAMPTZ DEFAULT now() NOT NULL,
|
||||
created_at TIMESTAMPTZ DEFAULT now() NOT NULL,
|
||||
updated_at TIMESTAMPTZ DEFAULT now() NOT NULL,
|
||||
UNIQUE(user_id, master_item_id)
|
||||
);
|
||||
COMMENT ON TABLE public.user_watched_items IS 'A linking table that represents a user''s personal watchlist of grocery items.';
|
||||
@@ -164,7 +175,8 @@ CREATE TABLE IF NOT EXISTS public.user_alerts (
|
||||
alert_type TEXT NOT NULL CHECK (alert_type IN ('PRICE_BELOW', 'PERCENT_OFF_AVERAGE')),
|
||||
threshold_value NUMERIC NOT NULL,
|
||||
is_active BOOLEAN DEFAULT true NOT NULL,
|
||||
created_at TIMESTAMPTZ DEFAULT now() NOT NULL
|
||||
created_at TIMESTAMPTZ DEFAULT now() NOT NULL,
|
||||
updated_at TIMESTAMPTZ DEFAULT now() NOT NULL
|
||||
);
|
||||
COMMENT ON TABLE public.user_alerts IS 'Stores user-configured alert rules for their watched items.';
|
||||
COMMENT ON COLUMN public.user_alerts.alert_type IS 'The condition that triggers the alert, e.g., ''PRICE_BELOW''.';
|
||||
@@ -179,7 +191,8 @@ CREATE TABLE IF NOT EXISTS public.notifications (
|
||||
content TEXT NOT NULL,
|
||||
link_url TEXT,
|
||||
is_read BOOLEAN DEFAULT false NOT NULL,
|
||||
created_at TIMESTAMPTZ DEFAULT now() NOT NULL
|
||||
created_at TIMESTAMPTZ DEFAULT now() NOT NULL,
|
||||
updated_at TIMESTAMPTZ DEFAULT now() NOT NULL
|
||||
);
|
||||
COMMENT ON TABLE public.notifications IS 'A central log of notifications generated for users, such as price alerts.';
|
||||
COMMENT ON COLUMN public.notifications.content IS 'The notification message displayed to the user.';
|
||||
@@ -197,7 +210,9 @@ CREATE TABLE IF NOT EXISTS public.item_price_history (
|
||||
max_price_in_cents INTEGER,
|
||||
avg_price_in_cents INTEGER,
|
||||
data_points_count INTEGER DEFAULT 0 NOT NULL,
|
||||
UNIQUE(master_item_id, summary_date, store_location_id)
|
||||
UNIQUE(master_item_id, summary_date, store_location_id),
|
||||
created_at TIMESTAMPTZ DEFAULT now() NOT NULL,
|
||||
updated_at TIMESTAMPTZ DEFAULT now() NOT NULL
|
||||
);
|
||||
COMMENT ON TABLE public.item_price_history IS 'Serves as a summary table to speed up charting and analytics.';
|
||||
COMMENT ON COLUMN public.item_price_history.summary_date IS 'The date for which the price data is summarized.';
|
||||
@@ -209,7 +224,9 @@ CREATE INDEX IF NOT EXISTS idx_item_price_history_store_location_id ON public.it
|
||||
CREATE TABLE IF NOT EXISTS public.master_item_aliases (
|
||||
id BIGINT PRIMARY KEY GENERATED ALWAYS AS IDENTITY,
|
||||
master_item_id BIGINT NOT NULL REFERENCES public.master_grocery_items(id) ON DELETE CASCADE,
|
||||
alias TEXT NOT NULL UNIQUE
|
||||
alias TEXT NOT NULL UNIQUE,
|
||||
created_at TIMESTAMPTZ DEFAULT now() NOT NULL,
|
||||
updated_at TIMESTAMPTZ DEFAULT now() NOT NULL
|
||||
);
|
||||
COMMENT ON TABLE public.master_item_aliases IS 'Stores synonyms or alternative names for master items to improve matching.';
|
||||
COMMENT ON COLUMN public.master_item_aliases.alias IS 'An alternative name, e.g., "Ground Chuck" for the master item "Ground Beef".';
|
||||
@@ -221,7 +238,8 @@ CREATE TABLE IF NOT EXISTS public.shopping_lists (
|
||||
id BIGINT PRIMARY KEY GENERATED ALWAYS AS IDENTITY,
|
||||
user_id UUID NOT NULL REFERENCES public.users(id) ON DELETE CASCADE,
|
||||
name TEXT NOT NULL,
|
||||
created_at TIMESTAMPTZ DEFAULT now() NOT NULL
|
||||
created_at TIMESTAMPTZ DEFAULT now() NOT NULL,
|
||||
updated_at TIMESTAMPTZ DEFAULT now() NOT NULL
|
||||
);
|
||||
COMMENT ON TABLE public.shopping_lists IS 'Stores user-created shopping lists, e.g., "Weekly Groceries".';
|
||||
CREATE INDEX IF NOT EXISTS idx_shopping_lists_user_id ON public.shopping_lists(user_id);
|
||||
@@ -236,6 +254,7 @@ CREATE TABLE IF NOT EXISTS public.shopping_list_items (
|
||||
is_purchased BOOLEAN DEFAULT false NOT NULL,
|
||||
notes TEXT,
|
||||
added_at TIMESTAMPTZ DEFAULT now() NOT NULL,
|
||||
updated_at TIMESTAMPTZ DEFAULT now() NOT NULL,
|
||||
CONSTRAINT must_have_item_identifier CHECK (master_item_id IS NOT NULL OR custom_item_name IS NOT NULL)
|
||||
);
|
||||
COMMENT ON TABLE public.shopping_list_items IS 'Contains individual items for a specific shopping list.';
|
||||
@@ -252,7 +271,8 @@ CREATE TABLE IF NOT EXISTS public.shared_shopping_lists (
|
||||
shared_by_user_id UUID NOT NULL REFERENCES public.users(id) ON DELETE CASCADE,
|
||||
shared_with_user_id UUID NOT NULL REFERENCES public.users(id) ON DELETE CASCADE,
|
||||
permission_level TEXT NOT NULL CHECK (permission_level IN ('view', 'edit')),
|
||||
created_at TIMESTAMPTZ DEFAULT now() NOT NULL,
|
||||
created_at TIMESTAMPTZ DEFAULT now() NOT NULL,
|
||||
updated_at TIMESTAMPTZ DEFAULT now() NOT NULL,
|
||||
UNIQUE(shopping_list_id, shared_with_user_id)
|
||||
);
|
||||
COMMENT ON TABLE public.shared_shopping_lists IS 'Allows users to share shopping lists with others and set permissions.';
|
||||
@@ -267,7 +287,8 @@ CREATE TABLE IF NOT EXISTS public.shared_menu_plans (
|
||||
shared_by_user_id UUID NOT NULL REFERENCES public.users(id) ON DELETE CASCADE,
|
||||
shared_with_user_id UUID NOT NULL REFERENCES public.users(id) ON DELETE CASCADE,
|
||||
permission_level TEXT NOT NULL CHECK (permission_level IN ('view', 'edit')),
|
||||
created_at TIMESTAMPTZ DEFAULT now() NOT NULL,
|
||||
created_at TIMESTAMPTZ DEFAULT now() NOT NULL,
|
||||
updated_at TIMESTAMPTZ DEFAULT now() NOT NULL,
|
||||
UNIQUE(menu_plan_id, shared_with_user_id)
|
||||
);
|
||||
COMMENT ON TABLE public.shared_menu_plans IS 'Allows users to share and collaborate on meal plans.';
|
||||
@@ -284,7 +305,8 @@ CREATE TABLE IF NOT EXISTS public.suggested_corrections (
|
||||
status TEXT DEFAULT 'pending' NOT NULL,
|
||||
created_at TIMESTAMPTZ DEFAULT now() NOT NULL,
|
||||
reviewed_notes TEXT,
|
||||
reviewed_at TIMESTAMPTZ
|
||||
reviewed_at TIMESTAMPTZ,
|
||||
updated_at TIMESTAMPTZ DEFAULT now() NOT NULL
|
||||
);
|
||||
COMMENT ON TABLE public.suggested_corrections IS 'A queue for user-submitted data corrections, enabling crowdsourced data quality improvements.';
|
||||
COMMENT ON COLUMN public.suggested_corrections.correction_type IS 'The type of error the user is reporting.';
|
||||
@@ -304,7 +326,8 @@ CREATE TABLE IF NOT EXISTS public.user_submitted_prices (
|
||||
photo_url TEXT,
|
||||
upvotes INTEGER DEFAULT 0 NOT NULL,
|
||||
downvotes INTEGER DEFAULT 0 NOT NULL,
|
||||
created_at TIMESTAMPTZ DEFAULT now() NOT NULL
|
||||
created_at TIMESTAMPTZ DEFAULT now() NOT NULL,
|
||||
updated_at TIMESTAMPTZ DEFAULT now() NOT NULL
|
||||
);
|
||||
COMMENT ON TABLE public.user_submitted_prices IS 'Stores item prices submitted by users directly from physical stores.';
|
||||
COMMENT ON COLUMN public.user_submitted_prices.photo_url IS 'URL to user-submitted photo evidence of the price.';
|
||||
@@ -319,7 +342,8 @@ CREATE TABLE IF NOT EXISTS public.unmatched_flyer_items (
|
||||
status TEXT DEFAULT 'pending' NOT NULL CHECK (status IN ('pending', 'reviewed', 'ignored')),
|
||||
created_at TIMESTAMPTZ DEFAULT now() NOT NULL,
|
||||
reviewed_at TIMESTAMPTZ,
|
||||
UNIQUE(flyer_item_id)
|
||||
UNIQUE(flyer_item_id),
|
||||
updated_at TIMESTAMPTZ DEFAULT now() NOT NULL
|
||||
);
|
||||
COMMENT ON TABLE public.unmatched_flyer_items IS 'A queue for reviewing flyer items that the system failed to automatically match.';
|
||||
CREATE INDEX IF NOT EXISTS idx_unmatched_flyer_items_flyer_item_id ON public.unmatched_flyer_items(flyer_item_id);
|
||||
@@ -329,7 +353,9 @@ CREATE TABLE IF NOT EXISTS public.brands (
|
||||
id BIGINT PRIMARY KEY GENERATED ALWAYS AS IDENTITY,
|
||||
name TEXT NOT NULL UNIQUE,
|
||||
logo_url TEXT,
|
||||
store_id BIGINT REFERENCES public.stores(id) ON DELETE SET NULL
|
||||
store_id BIGINT REFERENCES public.stores(id) ON DELETE SET NULL,
|
||||
created_at TIMESTAMPTZ DEFAULT now() NOT NULL,
|
||||
updated_at TIMESTAMPTZ DEFAULT now() NOT NULL
|
||||
);
|
||||
COMMENT ON TABLE public.brands IS 'Stores brand names like "Coca-Cola", "Maple Leaf", or "Kraft".';
|
||||
COMMENT ON COLUMN public.brands.store_id IS 'If this is a store-specific brand (e.g., President''s Choice), this links to the parent store.';
|
||||
@@ -343,7 +369,9 @@ CREATE TABLE IF NOT EXISTS public.products (
|
||||
name TEXT NOT NULL,
|
||||
description TEXT,
|
||||
size TEXT,
|
||||
upc_code TEXT UNIQUE
|
||||
upc_code TEXT UNIQUE,
|
||||
created_at TIMESTAMPTZ DEFAULT now() NOT NULL,
|
||||
updated_at TIMESTAMPTZ DEFAULT now() NOT NULL
|
||||
);
|
||||
COMMENT ON TABLE public.products IS 'Represents a specific, sellable product, combining a generic item with a brand and size.';
|
||||
COMMENT ON COLUMN public.products.upc_code IS 'Universal Product Code, if available, for exact product matching.';
|
||||
@@ -364,7 +392,9 @@ CREATE TABLE IF NOT EXISTS public.store_locations (
|
||||
city TEXT,
|
||||
province_state TEXT,
|
||||
postal_code TEXT,
|
||||
location GEOGRAPHY(Point, 4326)
|
||||
location GEOGRAPHY(Point, 4326),
|
||||
created_at TIMESTAMPTZ DEFAULT now() NOT NULL,
|
||||
updated_at TIMESTAMPTZ DEFAULT now() NOT NULL
|
||||
);
|
||||
COMMENT ON TABLE public.store_locations IS 'Stores physical locations of stores with geographic data for proximity searches.';
|
||||
COMMENT ON COLUMN public.store_locations.location IS 'Geographic coordinates (longitude, latitude) of the store.';
|
||||
@@ -379,7 +409,9 @@ CREATE INDEX IF NOT EXISTS store_locations_geo_idx ON public.store_locations USI
|
||||
CREATE TABLE IF NOT EXISTS public.flyer_locations (
|
||||
flyer_id BIGINT NOT NULL REFERENCES public.flyers(id) ON DELETE CASCADE,
|
||||
store_location_id BIGINT NOT NULL REFERENCES public.store_locations(id) ON DELETE CASCADE,
|
||||
PRIMARY KEY (flyer_id, store_location_id)
|
||||
PRIMARY KEY (flyer_id, store_location_id),
|
||||
created_at TIMESTAMPTZ DEFAULT now() NOT NULL,
|
||||
updated_at TIMESTAMPTZ DEFAULT now() NOT NULL
|
||||
);
|
||||
COMMENT ON TABLE public.flyer_locations IS 'A linking table associating a single flyer with multiple store locations where its deals are valid.';
|
||||
CREATE INDEX IF NOT EXISTS idx_flyer_locations_flyer_id ON public.flyer_locations(flyer_id);
|
||||
@@ -404,7 +436,8 @@ CREATE TABLE IF NOT EXISTS public.recipes (
|
||||
avg_rating NUMERIC(2,1) DEFAULT 0.0,
|
||||
status TEXT DEFAULT 'private' NOT NULL CHECK (status IN ('private', 'pending_review', 'public')),
|
||||
rating_count INTEGER DEFAULT 0 NOT NULL,
|
||||
created_at TIMESTAMPTZ DEFAULT now() NOT NULL
|
||||
created_at TIMESTAMPTZ DEFAULT now() NOT NULL,
|
||||
updated_at TIMESTAMPTZ DEFAULT now() NOT NULL
|
||||
);
|
||||
COMMENT ON TABLE public.recipes IS 'Stores recipes that can be used to generate shopping lists.';
|
||||
COMMENT ON COLUMN public.recipes.servings IS 'The number of servings this recipe yields.';
|
||||
@@ -419,7 +452,9 @@ CREATE TABLE IF NOT EXISTS public.recipe_ingredients (
|
||||
recipe_id BIGINT NOT NULL REFERENCES public.recipes(id) ON DELETE CASCADE,
|
||||
master_item_id BIGINT NOT NULL REFERENCES public.master_grocery_items(id),
|
||||
quantity NUMERIC NOT NULL,
|
||||
unit TEXT NOT NULL
|
||||
unit TEXT NOT NULL,
|
||||
created_at TIMESTAMPTZ DEFAULT now() NOT NULL,
|
||||
updated_at TIMESTAMPTZ DEFAULT now() NOT NULL
|
||||
);
|
||||
COMMENT ON TABLE public.recipe_ingredients IS 'Defines the ingredients and quantities needed for a recipe.';
|
||||
CREATE INDEX IF NOT EXISTS idx_recipe_ingredients_recipe_id ON public.recipe_ingredients(recipe_id);
|
||||
@@ -431,7 +466,9 @@ CREATE TABLE IF NOT EXISTS public.recipe_ingredient_substitutions (
|
||||
recipe_ingredient_id BIGINT NOT NULL REFERENCES public.recipe_ingredients(id) ON DELETE CASCADE,
|
||||
substitute_master_item_id BIGINT NOT NULL REFERENCES public.master_grocery_items(id) ON DELETE CASCADE,
|
||||
notes TEXT,
|
||||
UNIQUE(recipe_ingredient_id, substitute_master_item_id)
|
||||
UNIQUE(recipe_ingredient_id, substitute_master_item_id),
|
||||
created_at TIMESTAMPTZ DEFAULT now() NOT NULL,
|
||||
updated_at TIMESTAMPTZ DEFAULT now() NOT NULL
|
||||
);
|
||||
COMMENT ON TABLE public.recipe_ingredient_substitutions IS 'Stores suggested alternative ingredients for a recipe item (e.g., "butter" for "olive oil").';
|
||||
CREATE INDEX IF NOT EXISTS idx_recipe_ingredient_substitutions_recipe_ingredient_id ON public.recipe_ingredient_substitutions(recipe_ingredient_id);
|
||||
@@ -440,7 +477,9 @@ CREATE INDEX IF NOT EXISTS idx_recipe_ingredient_substitutions_substitute_master
|
||||
-- A table to store a predefined list of tags for recipes.
|
||||
CREATE TABLE IF NOT EXISTS public.tags (
|
||||
id BIGINT PRIMARY KEY GENERATED ALWAYS AS IDENTITY,
|
||||
name TEXT NOT NULL UNIQUE
|
||||
name TEXT NOT NULL UNIQUE,
|
||||
created_at TIMESTAMPTZ DEFAULT now() NOT NULL,
|
||||
updated_at TIMESTAMPTZ DEFAULT now() NOT NULL
|
||||
);
|
||||
COMMENT ON TABLE public.tags IS 'Stores tags for categorizing recipes, e.g., "Vegetarian", "Quick & Easy".';
|
||||
|
||||
@@ -449,7 +488,9 @@ COMMENT ON TABLE public.tags IS 'Stores tags for categorizing recipes, e.g., "Ve
|
||||
CREATE TABLE IF NOT EXISTS public.recipe_tags (
|
||||
recipe_id BIGINT NOT NULL REFERENCES public.recipes(id) ON DELETE CASCADE,
|
||||
tag_id BIGINT NOT NULL REFERENCES public.tags(id) ON DELETE CASCADE,
|
||||
PRIMARY KEY (recipe_id, tag_id)
|
||||
PRIMARY KEY (recipe_id, tag_id),
|
||||
created_at TIMESTAMPTZ DEFAULT now() NOT NULL,
|
||||
updated_at TIMESTAMPTZ DEFAULT now() NOT NULL
|
||||
);
|
||||
COMMENT ON TABLE public.recipe_tags IS 'A linking table to associate multiple tags with a single recipe.';
|
||||
CREATE INDEX IF NOT EXISTS idx_recipe_tags_recipe_id ON public.recipe_tags(recipe_id);
|
||||
@@ -459,7 +500,9 @@ CREATE INDEX IF NOT EXISTS idx_recipe_tags_tag_id ON public.recipe_tags(tag_id);
|
||||
CREATE TABLE IF NOT EXISTS public.recipe_appliances (
|
||||
recipe_id BIGINT NOT NULL REFERENCES public.recipes(id) ON DELETE CASCADE,
|
||||
appliance_id BIGINT NOT NULL REFERENCES public.appliances(id) ON DELETE CASCADE,
|
||||
PRIMARY KEY (recipe_id, appliance_id)
|
||||
PRIMARY KEY (recipe_id, appliance_id),
|
||||
created_at TIMESTAMPTZ DEFAULT now() NOT NULL,
|
||||
updated_at TIMESTAMPTZ DEFAULT now() NOT NULL
|
||||
);
|
||||
COMMENT ON TABLE public.recipe_appliances IS 'Links recipes to the specific kitchen appliances they require.';
|
||||
CREATE INDEX IF NOT EXISTS idx_recipe_appliances_recipe_id ON public.recipe_appliances(recipe_id);
|
||||
@@ -473,7 +516,8 @@ CREATE TABLE IF NOT EXISTS public.recipe_ratings (
|
||||
rating INTEGER NOT NULL CHECK (rating >= 1 AND rating <= 5),
|
||||
comment TEXT,
|
||||
created_at TIMESTAMPTZ DEFAULT now() NOT NULL,
|
||||
UNIQUE(recipe_id, user_id)
|
||||
UNIQUE(recipe_id, user_id),
|
||||
updated_at TIMESTAMPTZ DEFAULT now() NOT NULL
|
||||
);
|
||||
COMMENT ON TABLE public.recipe_ratings IS 'Stores individual user ratings for recipes, ensuring a user can only rate a recipe once.';
|
||||
CREATE INDEX IF NOT EXISTS idx_recipe_ratings_recipe_id ON public.recipe_ratings(recipe_id);
|
||||
@@ -488,7 +532,7 @@ CREATE TABLE IF NOT EXISTS public.recipe_comments (
|
||||
content TEXT NOT NULL,
|
||||
status TEXT DEFAULT 'visible' NOT NULL CHECK (status IN ('visible', 'hidden', 'reported')),
|
||||
created_at TIMESTAMPTZ DEFAULT now() NOT NULL,
|
||||
updated_at TIMESTAMPTZ
|
||||
updated_at TIMESTAMPTZ DEFAULT now() NOT NULL
|
||||
);
|
||||
COMMENT ON TABLE public.recipe_comments IS 'Allows for threaded discussions and comments on recipes.';
|
||||
CREATE INDEX IF NOT EXISTS idx_recipe_comments_recipe_id ON public.recipe_comments(recipe_id);
|
||||
@@ -501,7 +545,8 @@ CREATE TABLE IF NOT EXISTS public.menu_plans (
|
||||
name TEXT NOT NULL,
|
||||
start_date DATE NOT NULL,
|
||||
end_date DATE NOT NULL,
|
||||
created_at TIMESTAMPTZ DEFAULT now() NOT NULL
|
||||
created_at TIMESTAMPTZ DEFAULT now() NOT NULL,
|
||||
updated_at TIMESTAMPTZ DEFAULT now() NOT NULL
|
||||
);
|
||||
COMMENT ON TABLE public.menu_plans IS 'Represents a user''s meal plan for a specific period, e.g., "Week of Oct 23".';
|
||||
CREATE INDEX IF NOT EXISTS idx_menu_plans_user_id ON public.menu_plans(user_id);
|
||||
@@ -512,9 +557,11 @@ CREATE TABLE IF NOT EXISTS public.planned_meals (
|
||||
id BIGINT PRIMARY KEY GENERATED ALWAYS AS IDENTITY,
|
||||
menu_plan_id BIGINT NOT NULL REFERENCES public.menu_plans(id) ON DELETE CASCADE,
|
||||
recipe_id BIGINT NOT NULL REFERENCES public.recipes(id) ON DELETE CASCADE,
|
||||
plan_date DATE NOT NULL,
|
||||
meal_type TEXT NOT NULL, -- e.g., 'Breakfast', 'Lunch', 'Dinner'
|
||||
servings_to_cook INTEGER
|
||||
plan_date DATE NOT NULL,
|
||||
meal_type TEXT NOT NULL,
|
||||
servings_to_cook INTEGER,
|
||||
created_at TIMESTAMPTZ DEFAULT now() NOT NULL,
|
||||
updated_at TIMESTAMPTZ DEFAULT now() NOT NULL
|
||||
);
|
||||
COMMENT ON TABLE public.planned_meals IS 'Assigns a recipe to a specific day and meal type within a user''s menu plan.';
|
||||
COMMENT ON COLUMN public.planned_meals.meal_type IS 'The designated meal for the recipe, e.g., ''Breakfast'', ''Lunch'', ''Dinner''.';
|
||||
@@ -532,7 +579,7 @@ CREATE TABLE IF NOT EXISTS public.pantry_items (
|
||||
best_before_date DATE,
|
||||
pantry_location_id BIGINT REFERENCES public.pantry_locations(id) ON DELETE SET NULL,
|
||||
notification_sent_at TIMESTAMPTZ,
|
||||
updated_at TIMESTAMPTZ DEFAULT now() NOT NULL,
|
||||
updated_at TIMESTAMPTZ DEFAULT now() NOT NULL,
|
||||
UNIQUE(user_id, master_item_id, unit)
|
||||
);
|
||||
COMMENT ON TABLE public.pantry_items IS 'Tracks a user''s personal inventory of grocery items to enable smart shopping lists.';
|
||||
@@ -549,7 +596,8 @@ CREATE TABLE IF NOT EXISTS public.password_reset_tokens (
|
||||
user_id UUID NOT NULL REFERENCES public.users(id) ON DELETE CASCADE,
|
||||
token_hash TEXT NOT NULL UNIQUE,
|
||||
expires_at TIMESTAMPTZ NOT NULL,
|
||||
created_at TIMESTAMPTZ DEFAULT now() NOT NULL
|
||||
created_at TIMESTAMPTZ DEFAULT now() NOT NULL,
|
||||
updated_at TIMESTAMPTZ DEFAULT now() NOT NULL
|
||||
);
|
||||
COMMENT ON TABLE public.password_reset_tokens IS 'Stores secure, single-use tokens for password reset requests.';
|
||||
COMMENT ON COLUMN public.password_reset_tokens.token_hash IS 'A bcrypt hash of the reset token sent to the user.';
|
||||
@@ -566,7 +614,9 @@ CREATE TABLE IF NOT EXISTS public.unit_conversions (
|
||||
from_unit TEXT NOT NULL,
|
||||
to_unit TEXT NOT NULL,
|
||||
factor NUMERIC NOT NULL,
|
||||
UNIQUE(master_item_id, from_unit, to_unit)
|
||||
UNIQUE(master_item_id, from_unit, to_unit),
|
||||
created_at TIMESTAMPTZ DEFAULT now() NOT NULL,
|
||||
updated_at TIMESTAMPTZ DEFAULT now() NOT NULL
|
||||
);
|
||||
COMMENT ON TABLE public.unit_conversions IS 'Stores item-specific unit conversion factors (e.g., grams of flour to cups).';
|
||||
COMMENT ON COLUMN public.unit_conversions.factor IS 'The multiplication factor to convert from_unit to to_unit.';
|
||||
@@ -578,7 +628,9 @@ CREATE TABLE IF NOT EXISTS public.user_item_aliases (
|
||||
user_id UUID NOT NULL REFERENCES public.users(id) ON DELETE CASCADE,
|
||||
master_item_id BIGINT NOT NULL REFERENCES public.master_grocery_items(id) ON DELETE CASCADE,
|
||||
alias TEXT NOT NULL,
|
||||
UNIQUE(user_id, alias)
|
||||
UNIQUE(user_id, alias),
|
||||
created_at TIMESTAMPTZ DEFAULT now() NOT NULL,
|
||||
updated_at TIMESTAMPTZ DEFAULT now() NOT NULL
|
||||
);
|
||||
COMMENT ON TABLE public.user_item_aliases IS 'Allows users to create personal aliases for grocery items (e.g., "Dad''s Cereal").';
|
||||
CREATE INDEX IF NOT EXISTS idx_user_item_aliases_user_id ON public.user_item_aliases(user_id);
|
||||
@@ -589,7 +641,8 @@ CREATE TABLE IF NOT EXISTS public.favorite_recipes (
|
||||
user_id UUID NOT NULL REFERENCES public.users(id) ON DELETE CASCADE,
|
||||
recipe_id BIGINT NOT NULL REFERENCES public.recipes(id) ON DELETE CASCADE,
|
||||
created_at TIMESTAMPTZ DEFAULT now() NOT NULL,
|
||||
PRIMARY KEY (user_id, recipe_id)
|
||||
PRIMARY KEY (user_id, recipe_id),
|
||||
updated_at TIMESTAMPTZ DEFAULT now() NOT NULL
|
||||
);
|
||||
COMMENT ON TABLE public.favorite_recipes IS 'A simple linking table for users to mark their favorite recipes.';
|
||||
CREATE INDEX IF NOT EXISTS idx_favorite_recipes_user_id ON public.favorite_recipes(user_id);
|
||||
@@ -600,7 +653,8 @@ CREATE TABLE IF NOT EXISTS public.favorite_stores (
|
||||
user_id UUID NOT NULL REFERENCES public.users(id) ON DELETE CASCADE,
|
||||
store_id BIGINT NOT NULL REFERENCES public.stores(id) ON DELETE CASCADE,
|
||||
created_at TIMESTAMPTZ DEFAULT now() NOT NULL,
|
||||
PRIMARY KEY (user_id, store_id)
|
||||
PRIMARY KEY (user_id, store_id),
|
||||
updated_at TIMESTAMPTZ DEFAULT now() NOT NULL
|
||||
);
|
||||
COMMENT ON TABLE public.favorite_stores IS 'A simple linking table for users to mark their favorite stores.';
|
||||
CREATE INDEX IF NOT EXISTS idx_favorite_stores_user_id ON public.favorite_stores(user_id);
|
||||
@@ -613,7 +667,8 @@ CREATE TABLE IF NOT EXISTS public.user_activity_log (
|
||||
activity_type TEXT NOT NULL,
|
||||
entity_id TEXT,
|
||||
details JSONB,
|
||||
created_at TIMESTAMPTZ DEFAULT now() NOT NULL
|
||||
created_at TIMESTAMPTZ DEFAULT now() NOT NULL,
|
||||
updated_at TIMESTAMPTZ DEFAULT now() NOT NULL
|
||||
);
|
||||
COMMENT ON TABLE public.user_activity_log IS 'Logs key user actions for analytics and behavior analysis.';
|
||||
CREATE INDEX IF NOT EXISTS idx_user_activity_log_user_id ON public.user_activity_log(user_id);
|
||||
@@ -624,7 +679,8 @@ CREATE TABLE IF NOT EXISTS public.recipe_collections (
|
||||
user_id UUID NOT NULL REFERENCES public.users(id) ON DELETE CASCADE,
|
||||
name TEXT NOT NULL,
|
||||
description TEXT,
|
||||
created_at TIMESTAMPTZ DEFAULT now() NOT NULL
|
||||
created_at TIMESTAMPTZ DEFAULT now() NOT NULL,
|
||||
updated_at TIMESTAMPTZ DEFAULT now() NOT NULL
|
||||
);
|
||||
COMMENT ON TABLE public.recipe_collections IS 'Allows users to create personal collections of recipes (e.g., "Holiday Baking").';
|
||||
CREATE INDEX IF NOT EXISTS idx_recipe_collections_user_id ON public.recipe_collections(user_id);
|
||||
@@ -634,7 +690,8 @@ CREATE TABLE IF NOT EXISTS public.recipe_collection_items (
|
||||
collection_id BIGINT NOT NULL REFERENCES public.recipe_collections(id) ON DELETE CASCADE,
|
||||
recipe_id BIGINT NOT NULL REFERENCES public.recipes(id) ON DELETE CASCADE,
|
||||
added_at TIMESTAMPTZ DEFAULT now() NOT NULL,
|
||||
PRIMARY KEY (collection_id, recipe_id)
|
||||
PRIMARY KEY (collection_id, recipe_id),
|
||||
updated_at TIMESTAMPTZ DEFAULT now() NOT NULL
|
||||
);
|
||||
COMMENT ON TABLE public.recipe_collection_items IS 'Links recipes to a user-defined collection.';
|
||||
CREATE INDEX IF NOT EXISTS idx_recipe_collection_items_collection_id ON public.recipe_collection_items(collection_id);
|
||||
@@ -644,7 +701,9 @@ CREATE INDEX IF NOT EXISTS idx_recipe_collection_items_recipe_id ON public.recip
|
||||
CREATE TABLE IF NOT EXISTS public.dietary_restrictions (
|
||||
id BIGINT PRIMARY KEY GENERATED ALWAYS AS IDENTITY,
|
||||
name TEXT NOT NULL UNIQUE,
|
||||
type TEXT NOT NULL CHECK (type IN ('diet', 'allergy'))
|
||||
type TEXT NOT NULL CHECK (type IN ('diet', 'allergy')),
|
||||
created_at TIMESTAMPTZ DEFAULT now() NOT NULL,
|
||||
updated_at TIMESTAMPTZ DEFAULT now() NOT NULL
|
||||
);
|
||||
COMMENT ON TABLE public.dietary_restrictions IS 'A predefined list of common diets (e.g., Vegan) and allergies (e.g., Nut Allergy).';
|
||||
|
||||
@@ -652,7 +711,9 @@ COMMENT ON TABLE public.dietary_restrictions IS 'A predefined list of common die
|
||||
CREATE TABLE IF NOT EXISTS public.user_dietary_restrictions (
|
||||
user_id UUID NOT NULL REFERENCES public.users(id) ON DELETE CASCADE,
|
||||
restriction_id BIGINT NOT NULL REFERENCES public.dietary_restrictions(id) ON DELETE CASCADE,
|
||||
PRIMARY KEY (user_id, restriction_id)
|
||||
PRIMARY KEY (user_id, restriction_id),
|
||||
created_at TIMESTAMPTZ DEFAULT now() NOT NULL,
|
||||
updated_at TIMESTAMPTZ DEFAULT now() NOT NULL
|
||||
);
|
||||
COMMENT ON TABLE public.user_dietary_restrictions IS 'Connects users to their selected dietary needs and allergies.';
|
||||
CREATE INDEX IF NOT EXISTS idx_user_dietary_restrictions_user_id ON public.user_dietary_restrictions(user_id);
|
||||
@@ -669,7 +730,8 @@ CREATE TABLE IF NOT EXISTS public.receipts (
|
||||
status TEXT DEFAULT 'pending' NOT NULL CHECK (status IN ('pending', 'processing', 'completed', 'failed')),
|
||||
raw_text TEXT,
|
||||
created_at TIMESTAMPTZ DEFAULT now() NOT NULL,
|
||||
processed_at TIMESTAMPTZ
|
||||
processed_at TIMESTAMPTZ,
|
||||
updated_at TIMESTAMPTZ DEFAULT now() NOT NULL
|
||||
);
|
||||
COMMENT ON TABLE public.receipts IS 'Stores uploaded user receipts for purchase tracking and analysis.';
|
||||
CREATE INDEX IF NOT EXISTS idx_receipts_user_id ON public.receipts(user_id);
|
||||
@@ -684,7 +746,9 @@ CREATE TABLE IF NOT EXISTS public.receipt_items (
|
||||
price_paid_cents INTEGER NOT NULL,
|
||||
master_item_id BIGINT REFERENCES public.master_grocery_items(id),
|
||||
product_id BIGINT REFERENCES public.products(id),
|
||||
status TEXT DEFAULT 'unmatched' NOT NULL CHECK (status IN ('unmatched', 'matched', 'needs_review', 'ignored'))
|
||||
status TEXT DEFAULT 'unmatched' NOT NULL CHECK (status IN ('unmatched', 'matched', 'needs_review', 'ignored')),
|
||||
created_at TIMESTAMPTZ DEFAULT now() NOT NULL,
|
||||
updated_at TIMESTAMPTZ DEFAULT now() NOT NULL
|
||||
);
|
||||
COMMENT ON TABLE public.receipt_items IS 'Stores individual line items extracted from a user receipt.';
|
||||
CREATE INDEX IF NOT EXISTS idx_receipt_items_receipt_id ON public.receipt_items(receipt_id);
|
||||
@@ -693,7 +757,9 @@ CREATE INDEX IF NOT EXISTS idx_receipt_items_master_item_id ON public.receipt_it
|
||||
-- A table to store a predefined list of kitchen appliances.
|
||||
CREATE TABLE IF NOT EXISTS public.appliances (
|
||||
id BIGINT PRIMARY KEY GENERATED ALWAYS AS IDENTITY,
|
||||
name TEXT NOT NULL UNIQUE
|
||||
name TEXT NOT NULL UNIQUE,
|
||||
created_at TIMESTAMPTZ DEFAULT now() NOT NULL,
|
||||
updated_at TIMESTAMPTZ DEFAULT now() NOT NULL
|
||||
);
|
||||
COMMENT ON TABLE public.appliances IS 'A predefined list of kitchen appliances (e.g., Air Fryer, Instant Pot).';
|
||||
|
||||
@@ -701,7 +767,9 @@ COMMENT ON TABLE public.appliances IS 'A predefined list of kitchen appliances (
|
||||
CREATE TABLE IF NOT EXISTS public.user_appliances (
|
||||
user_id UUID NOT NULL REFERENCES public.users(id) ON DELETE CASCADE,
|
||||
appliance_id BIGINT NOT NULL REFERENCES public.appliances(id) ON DELETE CASCADE,
|
||||
PRIMARY KEY (user_id, appliance_id)
|
||||
PRIMARY KEY (user_id, appliance_id),
|
||||
created_at TIMESTAMPTZ DEFAULT now() NOT NULL,
|
||||
updated_at TIMESTAMPTZ DEFAULT now() NOT NULL
|
||||
);
|
||||
COMMENT ON TABLE public.user_appliances IS 'Tracks the kitchen appliances a user owns to help with recipe recommendations.';
|
||||
CREATE INDEX IF NOT EXISTS idx_user_appliances_user_id ON public.user_appliances(user_id);
|
||||
@@ -712,7 +780,8 @@ CREATE TABLE IF NOT EXISTS public.user_follows (
|
||||
follower_id UUID NOT NULL REFERENCES public.users(id) ON DELETE CASCADE,
|
||||
following_id UUID NOT NULL REFERENCES public.users(id) ON DELETE CASCADE,
|
||||
created_at TIMESTAMPTZ DEFAULT now() NOT NULL,
|
||||
PRIMARY KEY (follower_id, following_id),
|
||||
PRIMARY KEY (follower_id, following_id),
|
||||
updated_at TIMESTAMPTZ DEFAULT now() NOT NULL,
|
||||
CONSTRAINT cant_follow_self CHECK (follower_id <> following_id)
|
||||
);
|
||||
COMMENT ON TABLE public.user_follows IS 'Stores user following relationships to build a social graph.';
|
||||
@@ -723,7 +792,9 @@ CREATE INDEX IF NOT EXISTS idx_user_follows_following_id ON public.user_follows(
|
||||
CREATE TABLE IF NOT EXISTS public.pantry_locations (
|
||||
id BIGINT PRIMARY KEY GENERATED ALWAYS AS IDENTITY,
|
||||
user_id UUID NOT NULL REFERENCES public.users(id) ON DELETE CASCADE,
|
||||
name TEXT NOT NULL,
|
||||
name TEXT NOT NULL,
|
||||
created_at TIMESTAMPTZ DEFAULT now() NOT NULL,
|
||||
updated_at TIMESTAMPTZ DEFAULT now() NOT NULL,
|
||||
UNIQUE(user_id, name)
|
||||
);
|
||||
COMMENT ON TABLE public.pantry_locations IS 'User-defined locations for organizing pantry items (e.g., "Fridge", "Freezer", "Spice Rack").';
|
||||
@@ -736,7 +807,8 @@ CREATE TABLE IF NOT EXISTS public.search_queries (
|
||||
query_text TEXT NOT NULL,
|
||||
result_count INTEGER,
|
||||
was_successful BOOLEAN,
|
||||
created_at TIMESTAMPTZ DEFAULT now() NOT NULL
|
||||
created_at TIMESTAMPTZ DEFAULT now() NOT NULL,
|
||||
updated_at TIMESTAMPTZ DEFAULT now() NOT NULL
|
||||
);
|
||||
COMMENT ON TABLE public.search_queries IS 'Logs user search queries to analyze search effectiveness and identify gaps in data.';
|
||||
COMMENT ON COLUMN public.search_queries.was_successful IS 'Indicates if the user interacted with a search result.';
|
||||
@@ -748,7 +820,8 @@ CREATE TABLE IF NOT EXISTS public.shopping_trips (
|
||||
user_id UUID NOT NULL REFERENCES public.users(id) ON DELETE CASCADE,
|
||||
shopping_list_id BIGINT REFERENCES public.shopping_lists(id) ON DELETE SET NULL,
|
||||
completed_at TIMESTAMPTZ DEFAULT now() NOT NULL,
|
||||
total_spent_cents INTEGER
|
||||
total_spent_cents INTEGER,
|
||||
updated_at TIMESTAMPTZ DEFAULT now() NOT NULL
|
||||
);
|
||||
COMMENT ON TABLE public.shopping_trips IS 'A historical record of a completed shopping trip.';
|
||||
COMMENT ON COLUMN public.shopping_trips.total_spent_cents IS 'The total amount spent on this shopping trip, if provided by the user.';
|
||||
@@ -760,7 +833,9 @@ CREATE TABLE IF NOT EXISTS public.shopping_trip_items (
|
||||
master_item_id BIGINT REFERENCES public.master_grocery_items(id),
|
||||
custom_item_name TEXT,
|
||||
quantity NUMERIC NOT NULL,
|
||||
price_paid_cents INTEGER,
|
||||
price_paid_cents INTEGER,
|
||||
created_at TIMESTAMPTZ DEFAULT now() NOT NULL,
|
||||
updated_at TIMESTAMPTZ DEFAULT now() NOT NULL,
|
||||
CONSTRAINT trip_must_have_item_identifier CHECK (master_item_id IS NOT NULL OR custom_item_name IS NOT NULL)
|
||||
);
|
||||
COMMENT ON TABLE public.shopping_trip_items IS 'A historical log of items purchased during a shopping trip.';
|
||||
@@ -775,7 +850,8 @@ CREATE TABLE IF NOT EXISTS public.shopping_trips (
|
||||
user_id UUID NOT NULL REFERENCES public.users(id) ON DELETE CASCADE,
|
||||
shopping_list_id BIGINT REFERENCES public.shopping_lists(id) ON DELETE SET NULL,
|
||||
completed_at TIMESTAMPTZ DEFAULT now() NOT NULL,
|
||||
total_spent_cents INTEGER
|
||||
total_spent_cents INTEGER,
|
||||
updated_at TIMESTAMPTZ DEFAULT now() NOT NULL
|
||||
);
|
||||
COMMENT ON TABLE public.shopping_trips IS 'A historical record of a completed shopping trip.';
|
||||
COMMENT ON COLUMN public.shopping_trips.total_spent_cents IS 'The total amount spent on this shopping trip, if provided by the user.';
|
||||
@@ -789,7 +865,9 @@ CREATE TABLE IF NOT EXISTS public.shopping_trip_items (
|
||||
master_item_id BIGINT REFERENCES public.master_grocery_items(id),
|
||||
custom_item_name TEXT,
|
||||
quantity NUMERIC NOT NULL,
|
||||
price_paid_cents INTEGER,
|
||||
price_paid_cents INTEGER,
|
||||
created_at TIMESTAMPTZ DEFAULT now() NOT NULL,
|
||||
updated_at TIMESTAMPTZ DEFAULT now() NOT NULL,
|
||||
CONSTRAINT trip_must_have_item_identifier CHECK (master_item_id IS NOT NULL OR custom_item_name IS NOT NULL)
|
||||
);
|
||||
COMMENT ON TABLE public.shopping_trip_items IS 'A historical log of items purchased during a shopping trip.';
|
||||
@@ -1822,6 +1900,60 @@ AS $$
|
||||
ORDER BY potential_savings_cents DESC;
|
||||
$$;
|
||||
|
||||
-- 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;
|
||||
$$;
|
||||
|
||||
/**
|
||||
* Creates a personal, editable copy (a "fork") of a public recipe for a user.
|
||||
* @param userId The ID of the user forking the recipe.
|
||||
* @param originalRecipeId The ID of the recipe to fork.
|
||||
* @returns A promise that resolves to the newly created forked Recipe object.
|
||||
*/
|
||||
-- Function to create a personal, editable copy (a "fork") of a public recipe for a user.
|
||||
CREATE OR REPLACE FUNCTION public.fork_recipe(p_user_id UUID, p_original_recipe_id BIGINT)
|
||||
RETURNS SETOF public.recipes
|
||||
LANGUAGE sql
|
||||
SECURITY INVOKER
|
||||
AS $$
|
||||
-- The entire forking logic is now encapsulated in a single, atomic database function.
|
||||
SELECT * FROM public.fork_recipe(p_user_id, p_original_recipe_id);
|
||||
$$;
|
||||
|
||||
-- ============================================================================
|
||||
-- PART 7: TRIGGERS
|
||||
-- ============================================================================
|
||||
@@ -1874,6 +2006,36 @@ 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
|
||||
|
||||
14
sql/test_setup.sql
Normal file
14
sql/test_setup.sql
Normal file
@@ -0,0 +1,14 @@
|
||||
-- ============================================================================
|
||||
-- TEST DATABASE SETUP SCRIPT
|
||||
-- ============================================================================
|
||||
-- Purpose:
|
||||
-- This script creates a temporary database and a dedicated user for running
|
||||
-- integration tests during a CI/CD pipeline. It is intended to be run by a
|
||||
-- PostgreSQL superuser (e.g., 'postgres').
|
||||
|
||||
-- Create a new role for the test runner. In a real-world scenario, use a more secure password managed via secrets.
|
||||
CREATE ROLE test_runner WITH LOGIN PASSWORD 'a_secure_test_password';
|
||||
|
||||
-- Create the test database and set the owner to our new test role.
|
||||
-- This ensures the test runner has full permissions on this database only.
|
||||
CREATE DATABASE "flyer-crawler-test" WITH OWNER = test_runner;
|
||||
14
sql/test_teardown.sql
Normal file
14
sql/test_teardown.sql
Normal file
@@ -0,0 +1,14 @@
|
||||
-- ============================================================================
|
||||
-- TEST DATABASE TEARDOWN SCRIPT
|
||||
-- ============================================================================
|
||||
-- Purpose:
|
||||
-- This script cleans up the temporary database and user created for testing.
|
||||
-- It should be run after the test suite has completed.
|
||||
|
||||
-- Terminate any active connections to the test database to allow it to be dropped.
|
||||
SELECT pg_terminate_backend(pg_stat_activity.pid)
|
||||
FROM pg_stat_activity
|
||||
WHERE pg_stat_activity.datname = 'flyer-crawler-test';
|
||||
|
||||
DROP DATABASE IF EXISTS "flyer-crawler-test";
|
||||
DROP ROLE IF EXISTS test_runner;
|
||||
305
sql/triggers.sql
305
sql/triggers.sql
@@ -1,305 +0,0 @@
|
||||
-- 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 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();
|
||||
Reference in New Issue
Block a user