-- DONE -- 0. Create a simple users table for future expansion. -- 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 ON DELETE CASCADE, updated_at TIMESTAMPTZ, username TEXT UNIQUE, full_name TEXT, avatar_url TEXT, CONSTRAINT username_length CHECK (char_length(username) >= 3) ); -- DONE -- 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 ); -- DONE -- 2. Create the 'categories' table for normalized category data. CREATE TABLE IF NOT EXISTS public.categories ( id BIGINT PRIMARY KEY GENERATED ALWAYS AS IDENTITY, created_at TIMESTAMPTZ DEFAULT now() NOT NULL, name TEXT NOT NULL UNIQUE ); -- DONE -- 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, image_url TEXT, checksum TEXT UNIQUE, store_id BIGINT REFERENCES public.stores(id), valid_from DATE, valid_to DATE ); -- DONE -- 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) ); -- DONE -- 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, created_at TIMESTAMPTZ DEFAULT now() NOT NULL, user_id UUID NOT NULL REFERENCES public.profiles(id) ON DELETE CASCADE, master_item_id BIGINT NOT NULL REFERENCES public.master_grocery_items(id) ON DELETE CASCADE, UNIQUE(user_id, master_item_id) ); -- DONE -- 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, item TEXT, price_display TEXT, price_in_cents INTEGER, quantity TEXT, quantity_num NUMERIC, unit_price JSONB, flyer_id BIGINT REFERENCES public.flyers(id) ON DELETE CASCADE, master_item_id BIGINT REFERENCES public.master_grocery_items(id) ); -- DONE -- 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, -- e.g., 'PRICE_BELOW', 'PERCENT_OFF_AVERAGE' threshold_value NUMERIC NOT NULL, -- The value for the alert condition (e.g., 299 for a price of $2.99, or 20 for 20%) is_active BOOLEAN DEFAULT true NOT NULL, created_at TIMESTAMPTZ DEFAULT now() NOT NULL, -- A user should only have one type of alert per watched item UNIQUE(user_watched_item_id, alert_type) ); 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).'; -- DONE -- 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 public.profiles(id) ON DELETE CASCADE, content TEXT NOT NULL, -- The message for the user, e.g., "Chicken Thighs are on sale at Superstore!" link_url TEXT, -- A deep link to the relevant flyer or item in the app is_read BOOLEAN DEFAULT false NOT NULL, created_at TIMESTAMPTZ DEFAULT now() NOT NULL ); 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.'; -- DONE -- 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, -- The date this summary applies to min_price_in_cents INTEGER, -- The lowest price found for this item on this day, in cents max_price_in_cents INTEGER, -- The highest price found for this item on this day, in cents avg_price_in_cents INTEGER, -- The average price found for this item on this day, in cents data_points_count INTEGER NOT NULL, -- How many data points were used for this summary 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.'; -- DONE -- 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".'; -- DONE -- 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 public.profiles(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".'; -- DONE 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, -- For items not in the master list, e.g., "Grandma's special spice mix" quantity INTEGER DEFAULT 1 NOT NULL, is_purchased BOOLEAN DEFAULT false NOT NULL, added_at TIMESTAMPTZ DEFAULT now() NOT NULL, -- Ensure a master item is not added twice to the same list UNIQUE(shopping_list_id, master_item_id), -- Ensure one of the item identifiers is present 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.'; -- DONE -- 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 public.profiles(id) ON DELETE CASCADE, correction_type TEXT NOT NULL, -- e.g., 'WRONG_PRICE', 'INCORRECT_ITEM_LINK', 'INVALID_QUANTITY' suggested_value TEXT NOT NULL, -- The proposed new value, stored as text for flexibility. status TEXT DEFAULT 'pending' NOT NULL, -- e.g., 'pending', 'approved', 'rejected' created_at TIMESTAMPTZ DEFAULT now() NOT NULL, reviewed_notes TEXT, -- An admin can leave a note about why a suggestion was approved/rejected. 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.'; -- DONE -- 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 public.profiles(id) ON DELETE CASCADE, master_item_id BIGINT NOT NULL REFERENCES public.master_grocery_items(id) ON DELETE CASCADE, store_id BIGINT NOT NULL REFERENCES public.stores(id) ON DELETE CASCADE, price_in_cents INTEGER NOT NULL, photo_url TEXT, -- Optional: URL to a photo of the price tag for verification. upvotes INTEGER DEFAULT 1 NOT NULL, -- Community validation mechanism. downvotes INTEGER DEFAULT 0 NOT NULL, created_at TIMESTAMPTZ DEFAULT now() NOT NULL, -- A user can only submit one price for an item at a store per day. UNIQUE(user_id, master_item_id, store_id, created_at::date) ); 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.'; -- 14. Pre-populate categories table from a predefined list. 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; -- DONE -- 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".'; -- DONE -- 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), -- Can be null for generic/store-brand items name TEXT NOT NULL, -- e.g., "Prime Raised without Antibiotics Chicken Breast" description TEXT, size TEXT, -- e.g., "4L", "500g" upc_code TEXT UNIQUE, -- Universal Product Code for precise identification UNIQUE(master_item_id, brand_id, name, size) ); 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.'; -- Then, you would update 'flyer_items' to link to this new table. ALTER TABLE public.flyer_items ADD COLUMN IF NOT EXISTS product_id BIGINT REFERENCES public.products(id); -- Enable trigram support for fuzzy string matching CREATE EXTENSION IF NOT EXISTS pg_trgm; -- Add a GIN index to the 'item' column for fast fuzzy text searching. CREATE INDEX IF NOT EXISTS flyer_items_item_trgm_idx ON public.flyer_items USING GIN (item gin_trgm_ops); -- First, enable the PostGIS extension if you haven't already. -- In Supabase, you can do this under Database -> Extensions. -- CREATE EXTENSION IF NOT EXISTS postgis; -- DONE -- 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) ON DELETE CASCADE, address TEXT NOT NULL, city TEXT, province_state TEXT, postal_code TEXT, -- Use the 'geography' type for lat/lon data. location GEOGRAPHY(Point, 4326) ); CREATE INDEX IF NOT EXISTS store_locations_geo_idx ON public.store_locations USING GIST (location); 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.'; -- DONE -- You might also need 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) ); -- done -- 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 public.profiles(id) ON DELETE SET NULL, -- Can be a system recipe (user_id is NULL) or user-submitted name TEXT NOT NULL, description TEXT, instructions TEXT, prep_time_minutes INTEGER, cook_time_minutes INTEGER, servings INTEGER, -- How many people the recipe is intended for. photo_url TEXT, -- Optional nutritional information calories_per_serving INTEGER, protein_grams INTEGER, fat_grams INTEGER, carb_grams INTEGER, -- Aggregated rating data for fast sorting/display avg_rating NUMERIC(3, 2) DEFAULT 0.00, rating_count INTEGER DEFAULT 0, 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.'; -- done -- 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 -- e.g., 'cups', 'tbsp', 'g', 'each' ); COMMENT ON TABLE public.recipe_ingredients IS 'Defines the ingredients and quantities needed for a recipe.'; -- done -- 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".'; -- done -- 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) ); -- done -- 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 public.profiles(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) -- A user can only rate a recipe once. ); -- DONE -- 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 public.profiles(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, CONSTRAINT date_range_check CHECK (end_date >= start_date) ); COMMENT ON TABLE public.menu_plans IS 'Represents a user''s meal plan for a specific period, e.g., "Week of Oct 23".'; -- DONE -- 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, -- e.g., 'Breakfast', 'Lunch', 'Dinner', 'Snack' meal_type TEXT NOT NULL, -- A user can plan the same recipe for multiple meal types on the same day (e.g., leftovers for lunch) ); 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''.'; -- DONE -- 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 public.profiles(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, -- e.g., 'g', 'ml', 'items'. Should align with recipe_ingredients.unit best_before_date DATE, updated_at TIMESTAMPTZ DEFAULT now() NOT NULL, -- A user should only have one entry per master item in their pantry. UNIQUE(user_id, master_item_id) ); 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.'; -- 15. 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 $$; -- 16. Pre-populate initial watched items after master list exists. DO $$ DECLARE tp_id BIGINT; ct_id BIGINT; -- Note: Seeding user-specific data in a generic script is tricky. -- This block is for demonstration. In a real app, users would add their own watched items. -- We'll comment it out to avoid errors if no users exist. -- sample_user_id UUID; BEGIN -- -- Find a user to assign watched items to. -- SELECT id INTO sample_user_id FROM auth.users LIMIT 1; -- -- If a user exists, add some default watched items for them. -- IF sample_user_id IS NOT NULL THEN -- SELECT id INTO tp_id FROM public.master_grocery_items WHERE name = 'toilet paper'; -- SELECT id INTO ct_id FROM public.master_grocery_items WHERE name = 'chicken thighs'; -- IF tp_id IS NOT NULL THEN -- INSERT INTO public.user_watched_items (user_id, master_item_id) -- VALUES (sample_user_id, tp_id) -- ON CONFLICT (user_id, master_item_id) DO NOTHING; -- END IF; -- IF ct_id IS NOT NULL THEN -- INSERT INTO public.user_watched_items (user_id, master_item_id) -- VALUES (sample_user_id, ct_id) -- ON CONFLICT (user_id, master_item_id) DO NOTHING; -- END IF; -- END IF; NULL; -- PL/pgSQL block cannot be empty END $$; -- 17. Enable Row Level Security (RLS) on all tables. This is safe to run multiple times. 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; -- 18. Create policies. Using DROP/CREATE makes this script idempotent and safe to re-run. -- Policies for 'profiles' table -- Profiles are publicly readable 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); -- Users can insert and update their own profile 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); -- Policies for 'stores' table DROP POLICY IF EXISTS "Public read access" ON public.stores; CREATE POLICY "Public read access" ON public.stores FOR SELECT USING (true); -- Policies for 'categories' table DROP POLICY IF EXISTS "Public read access" ON public.categories; CREATE POLICY "Public read access" ON public.categories FOR SELECT USING (true); -- Policies for 'flyers' table DROP POLICY IF EXISTS "Allow public read access to flyers" ON public.flyers; CREATE POLICY "Allow public read access to flyers" ON public.flyers FOR SELECT USING (true); -- Policies for 'flyer_items' table DROP POLICY IF EXISTS "Public read access" ON public.flyer_items; CREATE POLICY "Public read access" ON public.flyer_items FOR SELECT USING (true); -- Policies for 'master_grocery_items' table 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); -- Policies for 'user_watched_items' table -- Users can view their own watched items. DROP POLICY IF EXISTS "Users can view their own watched items." ON public.user_watched_items; CREATE POLICY "Users can view their own watched items." ON public.user_watched_items FOR SELECT USING (auth.uid() = user_id); -- Users can insert, update, and delete their own watched items. 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); -- Policies for 'user_alerts' table 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 ( -- Check that the user owns the parent 'user_watched_item' auth.uid() = (SELECT user_id FROM public.user_watched_items WHERE id = user_watched_item_id) ); -- Policies for 'notifications' table 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); -- Policies for 'item_price_history' table 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); -- Policies for 'master_item_aliases' table 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); -- Note: Write access to aliases should be restricted to an admin or trusted role. -- Policies for 'shopping_lists' table 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); -- Policies for 'shopping_list_items' table 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 ( -- Check that the user owns the parent 'shopping_list' auth.uid() = (SELECT user_id FROM public.shopping_lists WHERE id = shopping_list_id) ); -- Policies for 'suggested_corrections' table 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); -- Note: An admin role would need a separate policy to view/update all suggestions. -- Policies for 'user_submitted_prices' table 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 "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 INSERT, UPDATE, DELETE USING (auth.uid() = user_id) WITH CHECK (auth.uid() = user_id); -- Policies for new product/location tables 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); -- Policies for recipe/menu plan tables 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 "Users can manage their own recipes." ON public.recipes; CREATE POLICY "Users can manage their own recipes." ON public.recipes FOR INSERT, UPDATE, DELETE USING (auth.uid() = user_id); 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); -- Note: Write access to recipe_ingredients should be controlled by who owns the parent recipe. -- A more complex policy or SECURITY DEFINER function would be needed for users to edit ingredients. -- For now, we assume inserts/updates happen via a trusted process or admin role. 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) ); -- Policies for pantry_items table 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 new recipe-related tables 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); 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);