-- ============================================================================ -- PERMISSION FIX (v3 - Ownership) -- ============================================================================ -- The following command addresses "permission denied" errors by setting the -- owner of the 'public' schema to 'postgres'. This user is typically the one -- running scripts in the Supabase SQL Editor. The schema owner has all -- necessary privileges, including creating extensions and tables. ALTER SCHEMA public OWNER TO postgres; -- Grant the service_role to the postgres user, who is running this script. -- This is necessary for a later step where we change the ownership of a -- trigger function to the service_role. GRANT service_role TO postgres; -- ============================================================================ -- MASTER SCHEMA SCRIPT -- ============================================================================ -- Purpose: -- This file contains the master SQL schema for the entire Supabase database. -- It is designed to be a "one-click" script that can be run in the Supabase -- SQL Editor to set up the entire backend from scratch, including: -- 1. Enabling required Postgres extensions. -- 2. Creating all tables with relationships and constraints. -- 3. Seeding essential initial data (categories, master items). -- 4. Creating the necessary storage buckets. -- 5. Applying comprehensive Row Level Security (RLS) policies. -- 6. Defining database functions for business logic. -- 7. Setting up triggers for automation (e.g., creating user profiles). -- -- Usage: -- For a fresh setup, run this entire script. To reset the environment, -- first run 'delete_all_tables.sql.txt' and then run this script. -- ============================================================================ -- PART 0: EXTENSIONS -- ============================================================================ -- Enable necessary PostgreSQL extensions. -- postgis: For storing and querying geographic data (store locations). -- pg_trgm: For trigram-based fuzzy string matching (improving item searches). CREATE EXTENSION IF NOT EXISTS postgis; CREATE EXTENSION IF NOT EXISTS pg_trgm; -- ============================================================================ -- PART 1: TABLE CREATION -- ============================================================================ -- 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 ); 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 ); 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) ); 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.'; -- 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 ); COMMENT ON TABLE public.flyers IS 'Stores metadata for each processed flyer, linking it to a store and its validity period.'; COMMENT ON COLUMN public.flyers.file_name IS 'The original name of the uploaded flyer file (e.g., "flyer_week_1.pdf").'; COMMENT ON COLUMN public.flyers.image_url IS 'The public URL of the primary flyer image stored in Supabase Storage.'; COMMENT ON COLUMN public.flyers.checksum IS 'A SHA-256 hash of the original file content to prevent duplicate processing.'; COMMENT ON COLUMN public.flyers.store_id IS 'Foreign key linking this flyer to a specific store in the `stores` table.'; COMMENT ON COLUMN public.flyers.valid_from IS 'The start date of the sale period for this flyer, extracted by the AI.'; COMMENT ON COLUMN public.flyers.valid_to IS 'The end date of the sale period for this flyer, extracted by the AI.'; COMMENT ON COLUMN public.flyers.store_address IS 'The physical store address if it was successfully extracted from the flyer image.'; -- 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, price_in_cents INTEGER, quantity TEXT NOT NULL, quantity_num NUMERIC, master_item_id BIGINT REFERENCES public.master_grocery_items(id), 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 ); COMMENT ON TABLE public.flyer_items IS 'Stores individual items extracted from a specific flyer.'; COMMENT ON COLUMN public.flyer_items.flyer_id IS 'Foreign key linking this item to its parent flyer in the `flyers` table.'; COMMENT ON COLUMN public.flyer_items.item IS 'The raw item name as it appears in the flyer (e.g., "Granny Smith Apples").'; COMMENT ON COLUMN public.flyer_items.price_display IS 'The raw price string from the flyer (e.g., "$3.99", "2 for $5.00").'; COMMENT ON COLUMN public.flyer_items.price_in_cents IS 'The normalized price for a single item, in cents, for easier sorting and comparison.'; COMMENT ON COLUMN public.flyer_items.quantity IS 'The raw quantity or deal description string (e.g., "per lb", "500g bag").'; COMMENT ON COLUMN public.flyer_items.quantity_num IS 'The parsed primary numeric value from the quantity string (e.g., 500 from "500g").'; COMMENT ON COLUMN public.flyer_items.master_item_id IS 'Foreign key linking this flyer item to its canonical entry in `master_grocery_items`. Null if no match was found.'; COMMENT ON COLUMN public.flyer_items.category_id IS 'Foreign key to the item''s category. Can be redundant if master_item_id is set, but useful.'; COMMENT ON COLUMN public.flyer_items.category_name IS 'The denormalized name of the category for faster UI display without extra joins.'; COMMENT ON COLUMN public.flyer_items.unit_price IS 'A JSONB object storing the calculated unit price (e.g., {"value": 1.99, "unit": "lb"}) for standardized price comparisons.'; COMMENT ON COLUMN public.flyer_items.product_id IS 'A foreign key for future use, to link to a specific product with a UPC code in the `products` table.'; -- Add a GIN index to the 'item' column for fast fuzzy text searching. -- This requires the pg_trgm extension. CREATE INDEX IF NOT EXISTS flyer_items_item_trgm_idx ON public.flyer_items USING GIN (item gin_trgm_ops); -- 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 auth.users(id) ON DELETE CASCADE, updated_at TIMESTAMPTZ, full_name TEXT, avatar_url TEXT, preferences JSONB ); COMMENT ON TABLE public.profiles IS 'Stores public-facing user data, linked to the private auth.users table.'; -- 5. Create the 'user_watched_items' table. This links to the master list. CREATE TABLE IF NOT EXISTS public.user_watched_items ( id BIGINT PRIMARY KEY GENERATED ALWAYS AS IDENTITY, user_id UUID NOT NULL REFERENCES auth.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, 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.'; -- 7. Create a table for user-defined alerts on watched items. CREATE TABLE IF NOT EXISTS public.user_alerts ( id BIGINT PRIMARY KEY GENERATED ALWAYS AS IDENTITY, user_watched_item_id BIGINT NOT NULL REFERENCES public.user_watched_items(id) ON DELETE CASCADE, 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 ); 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''.'; COMMENT ON COLUMN public.user_alerts.threshold_value IS 'The numeric threshold for the alert condition (e.g., price in cents, or percentage).'; -- 8. Create a table to store notifications for users. CREATE TABLE IF NOT EXISTS public.notifications ( id BIGINT PRIMARY KEY GENERATED ALWAYS AS IDENTITY, user_id UUID NOT NULL REFERENCES auth.users(id) ON DELETE CASCADE, content TEXT NOT NULL, link_url TEXT, is_read BOOLEAN DEFAULT false NOT NULL, created_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.'; COMMENT ON COLUMN public.notifications.link_url IS 'A URL to navigate to when the notification is clicked.'; -- 9. Create a table for aggregated, historical price data for master items. CREATE TABLE IF NOT EXISTS public.item_price_history ( id BIGINT PRIMARY KEY GENERATED ALWAYS AS IDENTITY, master_item_id BIGINT NOT NULL REFERENCES public.master_grocery_items(id) ON DELETE CASCADE, summary_date DATE NOT NULL, min_price_in_cents INTEGER, max_price_in_cents INTEGER, avg_price_in_cents INTEGER, data_points_count INTEGER DEFAULT 0 NOT NULL, UNIQUE(master_item_id, summary_date) ); 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.'; -- 10. Create a table to map various names to a single master grocery item. 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 ); 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".'; -- 11. Create tables for user shopping lists. CREATE TABLE IF NOT EXISTS public.shopping_lists ( id BIGINT PRIMARY KEY GENERATED ALWAYS AS IDENTITY, user_id UUID NOT NULL REFERENCES auth.users(id) ON DELETE CASCADE, name TEXT NOT NULL, created_at TIMESTAMPTZ DEFAULT now() NOT NULL ); COMMENT ON TABLE public.shopping_lists IS 'Stores user-created shopping lists, e.g., "Weekly Groceries".'; CREATE TABLE IF NOT EXISTS public.shopping_list_items ( id BIGINT PRIMARY KEY GENERATED ALWAYS AS IDENTITY, shopping_list_id BIGINT NOT NULL REFERENCES public.shopping_lists(id) ON DELETE CASCADE, master_item_id BIGINT REFERENCES public.master_grocery_items(id), custom_item_name TEXT, quantity NUMERIC DEFAULT 1 NOT NULL, is_purchased BOOLEAN DEFAULT false NOT NULL, added_at TIMESTAMPTZ DEFAULT now() NOT NULL, UNIQUE(shopping_list_id, master_item_id), 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.'; COMMENT ON COLUMN public.shopping_list_items.custom_item_name IS 'For items not in the master list, e.g., "Grandma''s special spice mix".'; COMMENT ON COLUMN public.shopping_list_items.is_purchased IS 'Lets users check items off their list as they shop.'; -- 12. Create a table to store user-submitted corrections for flyer items. CREATE TABLE IF NOT EXISTS public.suggested_corrections ( id BIGINT PRIMARY KEY GENERATED ALWAYS AS IDENTITY, flyer_item_id BIGINT NOT NULL REFERENCES public.flyer_items(id) ON DELETE CASCADE, user_id UUID NOT NULL REFERENCES auth.users(id), correction_type TEXT NOT NULL, suggested_value TEXT NOT NULL, status TEXT DEFAULT 'pending' NOT NULL, created_at TIMESTAMPTZ DEFAULT now() NOT NULL, reviewed_notes TEXT, reviewed_at TIMESTAMPTZ ); 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.'; COMMENT ON COLUMN public.suggested_corrections.suggested_value IS 'The corrected value proposed by the user (e.g., a new price or master_item_id).'; COMMENT ON COLUMN public.suggested_corrections.status IS 'The moderation status of the correction: pending, approved, or rejected.'; -- 13. Create a table for prices submitted directly by users from in-store. CREATE TABLE IF NOT EXISTS public.user_submitted_prices ( id BIGINT PRIMARY KEY GENERATED ALWAYS AS IDENTITY, user_id UUID NOT NULL REFERENCES auth.users(id), master_item_id BIGINT NOT NULL REFERENCES public.master_grocery_items(id), store_id BIGINT NOT NULL REFERENCES public.stores(id), price_in_cents INTEGER NOT NULL, photo_url TEXT, upvotes INTEGER DEFAULT 0 NOT NULL, downvotes INTEGER DEFAULT 0 NOT NULL, created_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.'; COMMENT ON COLUMN public.user_submitted_prices.upvotes IS 'Community validation score indicating accuracy.'; -- A table to store brand information. CREATE TABLE IF NOT EXISTS public.brands ( id BIGINT PRIMARY KEY GENERATED ALWAYS AS IDENTITY, name TEXT NOT NULL UNIQUE ); COMMENT ON TABLE public.brands IS 'Stores brand names like "Coca-Cola", "Maple Leaf", or "Kraft".'; -- A table for specific products, linking a master item with a brand and size. CREATE TABLE IF NOT EXISTS public.products ( id BIGINT PRIMARY KEY GENERATED ALWAYS AS IDENTITY, master_item_id BIGINT NOT NULL REFERENCES public.master_grocery_items(id), brand_id BIGINT REFERENCES public.brands(id), name TEXT NOT NULL, description TEXT, size TEXT, upc_code TEXT UNIQUE ); 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.'; -- Link flyer_items to the new products table. -- This is done via ALTER TABLE because 'products' is created after 'flyer_items'. ALTER TABLE public.flyer_items ADD CONSTRAINT flyer_items_product_id_fkey FOREIGN KEY (product_id) REFERENCES public.products(id); -- A table to store individual store locations with geographic data. CREATE TABLE IF NOT EXISTS public.store_locations ( id BIGINT PRIMARY KEY GENERATED ALWAYS AS IDENTITY, store_id BIGINT NOT NULL REFERENCES public.stores(id), address TEXT NOT NULL, city TEXT, province_state TEXT, postal_code TEXT, location GEOGRAPHY(Point, 4326) ); 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.'; -- Add a GIST index for efficient geographic queries. -- This requires the postgis extension. CREATE INDEX IF NOT EXISTS store_locations_geo_idx ON public.store_locations USING GIST (location); -- A linking table if one flyer is valid for multiple locations. 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) ); COMMENT ON TABLE public.flyer_locations IS 'A linking table associating a single flyer with multiple store locations where its deals are valid.'; -- A table to store recipes, which can be user-created or pre-populated. CREATE TABLE IF NOT EXISTS public.recipes ( id BIGINT PRIMARY KEY GENERATED ALWAYS AS IDENTITY, user_id UUID REFERENCES auth.users(id), name TEXT NOT NULL, description TEXT, instructions TEXT, prep_time_minutes INTEGER, cook_time_minutes INTEGER, servings INTEGER, photo_url TEXT, calories_per_serving INTEGER, protein_grams NUMERIC, fat_grams NUMERIC, carb_grams NUMERIC, avg_rating NUMERIC(2,1) DEFAULT 0.0 NOT NULL, rating_count INTEGER DEFAULT 0 NOT NULL, created_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.'; -- A linking table for ingredients required for each recipe. CREATE TABLE IF NOT EXISTS public.recipe_ingredients ( id BIGINT PRIMARY KEY GENERATED ALWAYS AS IDENTITY, 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 ); COMMENT ON TABLE public.recipe_ingredients IS 'Defines the ingredients and quantities needed for a recipe.'; -- 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 ); COMMENT ON TABLE public.tags IS 'Stores tags for categorizing recipes, e.g., "Vegetarian", "Quick & Easy".'; -- A linking table to associate multiple tags with a recipe. 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) ); COMMENT ON TABLE public.recipe_tags IS 'A linking table to associate multiple tags with a single recipe.'; -- A table to store individual user ratings for recipes. CREATE TABLE IF NOT EXISTS public.recipe_ratings ( id BIGINT PRIMARY KEY GENERATED ALWAYS AS IDENTITY, recipe_id BIGINT NOT NULL REFERENCES public.recipes(id) ON DELETE CASCADE, user_id UUID NOT NULL REFERENCES auth.users(id) ON DELETE CASCADE, rating INTEGER NOT NULL CHECK (rating >= 1 AND rating <= 5), comment TEXT, created_at TIMESTAMPTZ DEFAULT now() NOT NULL, UNIQUE(recipe_id, user_id) ); COMMENT ON TABLE public.recipe_ratings IS 'Stores individual user ratings for recipes, ensuring a user can only rate a recipe once.'; -- A table to store a user's collection of planned meals for a date range. CREATE TABLE IF NOT EXISTS public.menu_plans ( id BIGINT PRIMARY KEY GENERATED ALWAYS AS IDENTITY, user_id UUID NOT NULL REFERENCES auth.users(id) ON DELETE CASCADE, name TEXT NOT NULL, start_date DATE NOT NULL, end_date DATE NOT NULL, created_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".'; -- A table to associate a recipe with a specific date and meal type within a menu plan. 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 ); 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''.'; -- A table to track the grocery items a user currently has in their pantry. CREATE TABLE IF NOT EXISTS public.pantry_items ( id BIGINT PRIMARY KEY GENERATED ALWAYS AS IDENTITY, user_id UUID NOT NULL REFERENCES auth.users(id) ON DELETE CASCADE, master_item_id BIGINT NOT NULL REFERENCES public.master_grocery_items(id) ON DELETE CASCADE, quantity NUMERIC NOT NULL, unit TEXT, best_before_date DATE, 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.'; COMMENT ON COLUMN public.pantry_items.quantity IS 'The current amount of the item. Convention: use grams for weight, mL for volume where applicable.'; COMMENT ON COLUMN public.pantry_items.unit IS 'e.g., ''g'', ''ml'', ''items''. Should align with recipe_ingredients.unit and quantity convention.'; -- ============================================================================ -- PART 2: DATA SEEDING -- ============================================================================ -- Pre-populate the categories table. 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; -- Pre-populate the master grocery items dictionary. DO $$ DECLARE fv_cat_id BIGINT; ms_cat_id BIGINT; de_cat_id BIGINT; bb_cat_id BIGINT; pdg_cat_id BIGINT; bev_cat_id BIGINT; ff_cat_id BIGINT; snk_cat_id BIGINT; hc_cat_id BIGINT; pch_cat_id BIGINT; bc_cat_id BIGINT; ps_cat_id BIGINT; dpf_cat_id BIGINT; cg_cat_id BIGINT; cs_cat_id BIGINT; bkc_cat_id BIGINT; BEGIN SELECT id INTO fv_cat_id FROM public.categories WHERE name = 'Fruits & Vegetables'; SELECT id INTO ms_cat_id FROM public.categories WHERE name = 'Meat & Seafood'; SELECT id INTO de_cat_id FROM public.categories WHERE name = 'Dairy & Eggs'; SELECT id INTO bb_cat_id FROM public.categories WHERE name = 'Bakery & Bread'; SELECT id INTO pdg_cat_id FROM public.categories WHERE name = 'Pantry & Dry Goods'; SELECT id INTO bev_cat_id FROM public.categories WHERE name = 'Beverages'; SELECT id INTO ff_cat_id FROM public.categories WHERE name = 'Frozen Foods'; SELECT id INTO snk_cat_id FROM public.categories WHERE name = 'Snacks'; SELECT id INTO hc_cat_id FROM public.categories WHERE name = 'Household & Cleaning'; SELECT id INTO pch_cat_id FROM public.categories WHERE name = 'Personal Care & Health'; SELECT id INTO bc_cat_id FROM public.categories WHERE name = 'Baby & Child'; SELECT id INTO ps_cat_id FROM public.categories WHERE name = 'Pet Supplies'; SELECT id INTO dpf_cat_id FROM public.categories WHERE name = 'Deli & Prepared Foods'; SELECT id INTO cg_cat_id FROM public.categories WHERE name = 'Canned Goods'; SELECT id INTO cs_cat_id FROM public.categories WHERE name = 'Condiments & Spices'; SELECT id INTO bkc_cat_id FROM public.categories WHERE name = 'Breakfast & Cereal'; INSERT INTO public.master_grocery_items (name, category_id) VALUES ('apples', fv_cat_id), ('bananas', fv_cat_id), ('oranges', fv_cat_id), ('grapes', fv_cat_id), ('strawberries', fv_cat_id), ('blueberries', fv_cat_id), ('raspberries', fv_cat_id), ('avocados', fv_cat_id), ('tomatoes', fv_cat_id), ('potatoes', fv_cat_id), ('onions', fv_cat_id), ('garlic', fv_cat_id), ('carrots', fv_cat_id), ('broccoli', fv_cat_id), ('spinach', fv_cat_id), ('lettuce', fv_cat_id), ('bell peppers', fv_cat_id), ('cucumbers', fv_cat_id), ('mushrooms', fv_cat_id), ('lemons', fv_cat_id), ('limes', fv_cat_id), ('celery', fv_cat_id), ('corn', fv_cat_id), ('sweet potatoes', fv_cat_id), ('zucchini', fv_cat_id), ('cauliflower', fv_cat_id), ('green beans', fv_cat_id), ('peas', fv_cat_id), ('asparagus', fv_cat_id), ('chicken breast', ms_cat_id), ('chicken thighs', ms_cat_id), ('ground beef', ms_cat_id), ('steak', ms_cat_id), ('pork chops', ms_cat_id), ('bacon', ms_cat_id), ('sausage', ms_cat_id), ('salmon', ms_cat_id), ('shrimp', ms_cat_id), ('tilapia', ms_cat_id), ('cod', ms_cat_id), ('tuna', ms_cat_id), ('ham', ms_cat_id), ('turkey', ms_cat_id), ('milk', de_cat_id), ('cheese', de_cat_id), ('yogurt', de_cat_id), ('butter', de_cat_id), ('eggs', de_cat_id), ('cream cheese', de_cat_id), ('sour cream', de_cat_id), ('cottage cheese', de_cat_id), ('bread', bb_cat_id), ('bagels', bb_cat_id), ('tortillas', bb_cat_id), ('croissants', bb_cat_id), ('muffins', bb_cat_id), ('baguette', bb_cat_id), ('pita bread', bb_cat_id), ('rice', pdg_cat_id), ('pasta', pdg_cat_id), ('flour', pdg_cat_id), ('sugar', pdg_cat_id), ('salt', pdg_cat_id), ('pepper', pdg_cat_id), ('olive oil', pdg_cat_id), ('vegetable oil', pdg_cat_id), ('canned tomatoes', pdg_cat_id), ('canned beans', pdg_cat_id), ('peanut butter', pdg_cat_id), ('jam', pdg_cat_id), ('honey', pdg_cat_id), ('syrup', pdg_cat_id), ('nuts', pdg_cat_id), ('dried fruit', pdg_cat_id), ('crackers', pdg_cat_id), ('quinoa', pdg_cat_id), ('lentils', pdg_cat_id), ('water', bev_cat_id), ('juice', bev_cat_id), ('soda', bev_cat_id), ('coffee', bev_cat_id), ('tea', bev_cat_id), ('almond milk', bev_cat_id), ('soy milk', bev_cat_id), ('coconut water', bev_cat_id), ('frozen pizza', ff_cat_id), ('frozen vegetables', ff_cat_id), ('frozen fruit', ff_cat_id), ('ice cream', ff_cat_id), ('frozen dinners', ff_cat_id), ('french fries', ff_cat_id), ('frozen fish', ff_cat_id), ('chips', snk_cat_id), ('pretzels', snk_cat_id), ('popcorn', snk_cat_id), ('granola bars', snk_cat_id), ('cookies', snk_cat_id), ('chocolate', snk_cat_id), ('candy', snk_cat_id), ('paper towels', hc_cat_id), ('toilet paper', hc_cat_id), ('trash bags', hc_cat_id), ('dish soap', hc_cat_id), ('laundry detergent', hc_cat_id), ('all-purpose cleaner', hc_cat_id), ('sponges', hc_cat_id), ('soap', pch_cat_id), ('shampoo', pch_cat_id), ('conditioner', pch_cat_id), ('toothpaste', pch_cat_id), ('deodorant', pch_cat_id), ('vitamins', pch_cat_id), ('pain reliever', pch_cat_id), ('diapers', bc_cat_id), ('baby wipes', bc_cat_id), ('baby food', bc_cat_id), ('formula', bc_cat_id), ('dog food', ps_cat_id), ('cat food', ps_cat_id), ('cat litter', ps_cat_id), ('deli meat', dpf_cat_id), ('deli cheese', dpf_cat_id), ('rotisserie chicken', dpf_cat_id), ('prepared salads', dpf_cat_id), ('canned soup', cg_cat_id), ('canned corn', cg_cat_id), ('canned tuna', cg_cat_id), ('canned chicken', cg_cat_id), ('ketchup', cs_cat_id), ('mustard', cs_cat_id), ('mayonnaise', cs_cat_id), ('soy sauce', cs_cat_id), ('hot sauce', cs_cat_id), ('bbq sauce', cs_cat_id), ('salad dressing', cs_cat_id), ('cinnamon', cs_cat_id), ('oregano', cs_cat_id), ('paprika', cs_cat_id), ('garlic powder', cs_cat_id), ('cereal', bkc_cat_id), ('oatmeal', bkc_cat_id), ('granola', bkc_cat_id), ('pancake mix', bkc_cat_id) ON CONFLICT (name) DO NOTHING; END $$; -- ============================================================================ -- PART 3: STORAGE -- ============================================================================ -- Create the storage bucket for flyers if it doesn't exist. INSERT INTO storage.buckets (id, name, public) VALUES ('flyers', 'flyers', true) ON CONFLICT (id) DO NOTHING; -- ============================================================================ -- PART 4: ROW LEVEL SECURITY (RLS) -- ============================================================================ -- Enable RLS on all tables. ALTER TABLE public.profiles ENABLE ROW LEVEL SECURITY; ALTER TABLE public.stores ENABLE ROW LEVEL SECURITY; ALTER TABLE public.categories ENABLE ROW LEVEL SECURITY; ALTER TABLE public.flyers ENABLE ROW LEVEL SECURITY; ALTER TABLE public.flyer_items ENABLE ROW LEVEL SECURITY; ALTER TABLE public.master_grocery_items ENABLE ROW LEVEL SECURITY; ALTER TABLE public.user_watched_items ENABLE ROW LEVEL SECURITY; ALTER TABLE public.user_alerts ENABLE ROW LEVEL SECURITY; ALTER TABLE public.notifications ENABLE ROW LEVEL SECURITY; ALTER TABLE public.item_price_history ENABLE ROW LEVEL SECURITY; ALTER TABLE public.master_item_aliases ENABLE ROW LEVEL SECURITY; ALTER TABLE public.shopping_lists ENABLE ROW LEVEL SECURITY; ALTER TABLE public.shopping_list_items ENABLE ROW LEVEL SECURITY; ALTER TABLE public.suggested_corrections ENABLE ROW LEVEL SECURITY; ALTER TABLE public.user_submitted_prices ENABLE ROW LEVEL SECURITY; ALTER TABLE public.brands ENABLE ROW LEVEL SECURITY; ALTER TABLE public.products ENABLE ROW LEVEL SECURITY; ALTER TABLE public.store_locations ENABLE ROW LEVEL SECURITY; ALTER TABLE public.flyer_locations ENABLE ROW LEVEL SECURITY; ALTER TABLE public.recipes ENABLE ROW LEVEL SECURITY; ALTER TABLE public.recipe_ingredients ENABLE ROW LEVEL SECURITY; ALTER TABLE public.menu_plans ENABLE ROW LEVEL SECURITY; ALTER TABLE public.planned_meals ENABLE ROW LEVEL SECURITY; ALTER TABLE public.tags ENABLE ROW LEVEL SECURITY; ALTER TABLE public.recipe_tags ENABLE ROW LEVEL SECURITY; ALTER TABLE public.recipe_ratings ENABLE ROW LEVEL SECURITY; ALTER TABLE public.pantry_items ENABLE ROW LEVEL SECURITY; -- Create policies. DROP POLICY IF EXISTS "Public profiles are viewable by everyone." ON public.profiles; CREATE POLICY "Public profiles are viewable by everyone." ON public.profiles FOR SELECT USING (true); DROP POLICY IF EXISTS "Users can update their own profile." ON public.profiles; CREATE POLICY "Users can update their own profile." ON public.profiles FOR UPDATE USING (auth.uid() = id) WITH CHECK (auth.uid() = id); -- **FIX**: Add policy to allow service_role to insert new profiles via the handle_new_user trigger. DROP POLICY IF EXISTS "Allow service_role to insert new profiles" ON public.profiles; CREATE POLICY "Allow service_role to insert new profiles" ON public.profiles FOR INSERT TO service_role WITH CHECK (true); -- Public read access for most public data DROP POLICY IF EXISTS "Public read access" ON public.stores; CREATE POLICY "Public read access" ON public.stores FOR SELECT USING (true); DROP POLICY IF EXISTS "Public read access" ON public.categories; CREATE POLICY "Public read access" ON public.categories FOR SELECT USING (true); DROP POLICY IF EXISTS "Public read access" ON public.flyers; CREATE POLICY "Public read access" ON public.flyers FOR SELECT USING (true); DROP POLICY IF EXISTS "Public read access" ON public.flyer_items; CREATE POLICY "Public read access" ON public.flyer_items FOR SELECT USING (true); DROP POLICY IF EXISTS "Public read access" ON public.master_grocery_items; CREATE POLICY "Public read access" ON public.master_grocery_items FOR SELECT USING (true); DROP POLICY IF EXISTS "Public read access for price history" ON public.item_price_history; CREATE POLICY "Public read access for price history" ON public.item_price_history FOR SELECT USING (true); DROP POLICY IF EXISTS "Aliases are publicly viewable." ON public.master_item_aliases; CREATE POLICY "Aliases are publicly viewable." ON public.master_item_aliases FOR SELECT USING (true); DROP POLICY IF EXISTS "Public read access" ON public.brands; CREATE POLICY "Public read access" ON public.brands FOR SELECT USING (true); DROP POLICY IF EXISTS "Public read access" ON public.products; CREATE POLICY "Public read access" ON public.products FOR SELECT USING (true); DROP POLICY IF EXISTS "Public read access" ON public.store_locations; CREATE POLICY "Public read access" ON public.store_locations FOR SELECT USING (true); DROP POLICY IF EXISTS "Public read access" ON public.flyer_locations; CREATE POLICY "Public read access" ON public.flyer_locations FOR SELECT USING (true); DROP POLICY IF EXISTS "Submitted prices are publicly viewable." ON public.user_submitted_prices; CREATE POLICY "Submitted prices are publicly viewable." ON public.user_submitted_prices FOR SELECT USING (true); DROP POLICY IF EXISTS "Recipes are publicly viewable." ON public.recipes; CREATE POLICY "Recipes are publicly viewable." ON public.recipes FOR SELECT USING (true); DROP POLICY IF EXISTS "Recipe ingredients are publicly viewable." ON public.recipe_ingredients; CREATE POLICY "Recipe ingredients are publicly viewable." ON public.recipe_ingredients FOR SELECT USING (true); DROP POLICY IF EXISTS "Tags are publicly viewable." ON public.tags; CREATE POLICY "Tags are publicly viewable." ON public.tags FOR SELECT USING (true); DROP POLICY IF EXISTS "Recipe-tag links are publicly viewable." ON public.recipe_tags; CREATE POLICY "Recipe-tag links are publicly viewable." ON public.recipe_tags FOR SELECT USING (true); DROP POLICY IF EXISTS "Recipe ratings are publicly viewable." ON public.recipe_ratings; CREATE POLICY "Recipe ratings are publicly viewable." ON public.recipe_ratings FOR SELECT USING (true); -- Authenticated write access for core data tables DROP POLICY IF EXISTS "Allow full access for authenticated users" ON public.stores; CREATE POLICY "Allow full access for authenticated users" ON public.stores FOR ALL TO authenticated USING (true) WITH CHECK (true); DROP POLICY IF EXISTS "Allow full access for authenticated users" ON public.categories; CREATE POLICY "Allow full access for authenticated users" ON public.categories FOR ALL TO authenticated USING (true) WITH CHECK (true); DROP POLICY IF EXISTS "Allow full access for authenticated users" ON public.flyers; CREATE POLICY "Allow full access for authenticated users" ON public.flyers FOR ALL TO authenticated USING (true) WITH CHECK (true); DROP POLICY IF EXISTS "Allow full access for authenticated users" ON public.flyer_items; CREATE POLICY "Allow full access for authenticated users" ON public.flyer_items FOR ALL TO authenticated USING (true) WITH CHECK (true); DROP POLICY IF EXISTS "Allow anon users to manage test items" ON public.flyer_items; CREATE POLICY "Allow anon users to manage test items" ON public.flyer_items FOR ALL TO anon USING (item LIKE 'DB_SELF_TEST_ITEM_%') WITH CHECK (item LIKE 'DB_SELF_TEST_ITEM_%'); DROP POLICY IF EXISTS "Allow full access for authenticated users" ON public.master_grocery_items; CREATE POLICY "Allow full access for authenticated users" ON public.master_grocery_items FOR ALL TO authenticated USING (true) WITH CHECK (true); DROP POLICY IF EXISTS "Allow full access for authenticated users" ON public.brands; CREATE POLICY "Allow full access for authenticated users" ON public.brands FOR ALL TO authenticated USING (true) WITH CHECK (true); DROP POLICY IF EXISTS "Allow full access for authenticated users" ON public.products; CREATE POLICY "Allow full access for authenticated users" ON public.products FOR ALL TO authenticated USING (true) WITH CHECK (true); -- User-specific policies DROP POLICY IF EXISTS "Users can manage their own watched items." ON public.user_watched_items; CREATE POLICY "Users can manage their own watched items." ON public.user_watched_items FOR ALL USING (auth.uid() = user_id) WITH CHECK (auth.uid() = user_id); DROP POLICY IF EXISTS "Users can manage their own alerts" ON public.user_alerts; CREATE POLICY "Users can manage their own alerts" ON public.user_alerts FOR ALL USING (auth.uid() = (SELECT user_id FROM public.user_watched_items WHERE id = user_watched_item_id)); DROP POLICY IF EXISTS "Users can manage their own notifications" ON public.notifications; CREATE POLICY "Users can manage their own notifications" ON public.notifications FOR ALL USING (auth.uid() = user_id) WITH CHECK (auth.uid() = user_id); DROP POLICY IF EXISTS "Users can manage their own shopping lists." ON public.shopping_lists; CREATE POLICY "Users can manage their own shopping lists." ON public.shopping_lists FOR ALL USING (auth.uid() = user_id) WITH CHECK (auth.uid() = user_id); -- **FIX**: Add policy to allow service_role to insert new shopping_lists via the handle_new_user trigger. DROP POLICY IF EXISTS "Allow service_role to insert new shopping lists" ON public.shopping_lists; CREATE POLICY "Allow service_role to insert new shopping lists" ON public.shopping_lists FOR INSERT TO service_role WITH CHECK (true); DROP POLICY IF EXISTS "Users can manage items in their own shopping lists." ON public.shopping_list_items; CREATE POLICY "Users can manage items in their own shopping lists." ON public.shopping_list_items FOR ALL USING (auth.uid() = (SELECT user_id FROM public.shopping_lists WHERE id = shopping_list_id)); DROP POLICY IF EXISTS "Users can manage their own suggestions." ON public.suggested_corrections; CREATE POLICY "Users can manage their own suggestions." ON public.suggested_corrections FOR ALL USING (auth.uid() = user_id) WITH CHECK (auth.uid() = user_id); DROP POLICY IF EXISTS "Users can manage their own submitted prices." ON public.user_submitted_prices; CREATE POLICY "Users can manage their own submitted prices." ON public.user_submitted_prices FOR ALL USING (auth.uid() = user_id) WITH CHECK (auth.uid() = user_id); DROP POLICY IF EXISTS "Users can manage their own recipes." ON public.recipes; CREATE POLICY "Users can manage their own recipes." ON public.recipes FOR ALL USING (auth.uid() = user_id) WITH CHECK (auth.uid() = user_id); DROP POLICY IF EXISTS "Users can manage their own menu plans." ON public.menu_plans; CREATE POLICY "Users can manage their own menu plans." ON public.menu_plans FOR ALL USING (auth.uid() = user_id); DROP POLICY IF EXISTS "Users can manage meals in their own menu plans." ON public.planned_meals; CREATE POLICY "Users can manage meals in their own menu plans." ON public.planned_meals FOR ALL USING (auth.uid() = (SELECT user_id FROM public.menu_plans WHERE id = menu_plan_id)); DROP POLICY IF EXISTS "Users can manage their own recipe ratings." ON public.recipe_ratings; CREATE POLICY "Users can manage their own recipe ratings." ON public.recipe_ratings FOR ALL USING (auth.uid() = user_id); DROP POLICY IF EXISTS "Users can manage their own pantry items." ON public.pantry_items; CREATE POLICY "Users can manage their own pantry items." ON public.pantry_items FOR ALL USING (auth.uid() = user_id); -- Policies for the 'flyers' storage bucket DROP POLICY IF EXISTS "Allow public access to flyers storage" ON storage.objects; CREATE POLICY "Allow public access to flyers storage" ON storage.objects FOR SELECT TO public USING (bucket_id = 'flyers'); DROP POLICY IF EXISTS "Allow authenticated users to manage flyers" ON storage.objects; CREATE POLICY "Allow authenticated users to manage flyers" ON storage.objects FOR ALL TO authenticated USING (bucket_id = 'flyers'); DROP POLICY IF EXISTS "Allow anon users to manage test files" ON storage.objects; CREATE POLICY "Allow anon users to manage test files" ON storage.objects FOR ALL TO anon USING (bucket_id = 'flyers' AND name LIKE 'storage-self-test-%') WITH CHECK (bucket_id = 'flyers' AND name LIKE 'storage-self-test-%'); -- ============================================================================ -- PART 5: DATABASE FUNCTIONS -- ============================================================================ -- 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. RLS policies will apply. 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. RLS policies will apply. 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 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 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 FROM RecipeIngredientStats ris WHERE ris.total_ingredients > 0 -- Avoid division by zero 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 the ingredient is not on sale. bcp.store_name FROM public.recipes r JOIN EligibleRecipes er ON r.id = er.recipe_id 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 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; $$; -- ============================================================================ -- PART 6: SYSTEM CHECK HELPER FUNCTIONS -- These functions are called by the 'system-check' Edge Function to inspect -- the database state without exposing schema details to the client. They are -- defined as `SECURITY DEFINER` to bypass RLS for inspection purposes. -- ============================================================================ DROP FUNCTION IF EXISTS public.check_schema(); CREATE OR REPLACE FUNCTION public.check_schema() RETURNS json LANGUAGE sql SECURITY DEFINER AS $$ SELECT json_build_object( 'tables', (SELECT array_agg(table_name) FROM information_schema.tables WHERE table_schema = 'public') ); $$; DROP FUNCTION IF EXISTS public.check_rls(); CREATE OR REPLACE FUNCTION public.check_rls() RETURNS TABLE(table_name text, policy_name text) LANGUAGE sql SECURITY DEFINER AS $$ SELECT tablename::text, policyname::text FROM pg_policies WHERE schemaname = 'public'; $$; DROP FUNCTION IF EXISTS public.check_trigger_security(); CREATE OR REPLACE FUNCTION public.check_trigger_security() RETURNS TABLE(function_name text, is_security_definer boolean, owner_role text) LANGUAGE sql SECURITY DEFINER AS $$ SELECT p.proname::text, p.prosecdef, r.rolname::text FROM pg_proc p JOIN pg_roles r ON p.proowner = r.oid WHERE p.proname = 'handle_new_user'; $$; -- ============================================================================ -- PART 7: TRIGGERS -- ============================================================================ -- 1. Set up the trigger to automatically create a profile when a new user signs up. -- This function will be called by the trigger. -- It is set to SECURITY DEFINER and owned by service_role to ensure it can -- insert into public tables, bypassing the restrictive permissions of the -- internal supabase_auth_admin role that invokes 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(); -- Grant ownership to the service_role to align with RLS policies. ALTER FUNCTION public.handle_new_user() OWNER TO service_role; -- 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();