-- sql/initial_schema.sql -- ============================================================================ -- ============================================================================ -- PART 2: TABLES -- ============================================================================ -- 0. NEW TABLE: A centralized table for storing all physical addresses. CREATE TABLE IF NOT EXISTS public.addresses ( address_id BIGINT PRIMARY KEY GENERATED ALWAYS AS IDENTITY, address_line_1 TEXT NOT NULL UNIQUE, city TEXT NOT NULL, province_state TEXT NOT NULL, postal_code TEXT NOT NULL, country TEXT NOT NULL, address_line_2 TEXT, latitude NUMERIC(9, 6), longitude NUMERIC(9, 6), location GEOGRAPHY(Point, 4326), created_at TIMESTAMPTZ DEFAULT now() NOT NULL, updated_at TIMESTAMPTZ DEFAULT now() NOT NULL, CONSTRAINT addresses_address_line_1_check CHECK (TRIM(address_line_1) <> ''), CONSTRAINT addresses_city_check CHECK (TRIM(city) <> ''), CONSTRAINT addresses_province_state_check CHECK (TRIM(province_state) <> ''), CONSTRAINT addresses_postal_code_check CHECK (TRIM(postal_code) <> ''), CONSTRAINT addresses_country_check CHECK (TRIM(country) <> ''), CONSTRAINT addresses_latitude_check CHECK (latitude >= -90 AND latitude <= 90), CONSTRAINT addresses_longitude_check CHECK (longitude >= -180 AND longitude <= 180) ); COMMENT ON TABLE public.addresses IS 'A centralized table for storing all physical addresses for users and stores.'; COMMENT ON COLUMN public.addresses.latitude IS 'The geographic latitude.'; COMMENT ON COLUMN public.addresses.longitude IS 'The geographic longitude.'; COMMENT ON COLUMN public.addresses.location IS 'A PostGIS geography type for efficient spatial queries.'; CREATE INDEX IF NOT EXISTS addresses_location_idx ON public.addresses USING GIST (location); -- 1. Users table for authentication. CREATE TABLE IF NOT EXISTS public.users ( user_id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), email TEXT NOT NULL UNIQUE, password_hash TEXT, refresh_token TEXT, failed_login_attempts INTEGER DEFAULT 0 CHECK (failed_login_attempts >= 0), last_failed_login TIMESTAMPTZ, last_login_at TIMESTAMPTZ, last_login_ip TEXT, created_at TIMESTAMPTZ DEFAULT now() NOT NULL, updated_at TIMESTAMPTZ DEFAULT now() NOT NULL, CONSTRAINT users_email_check CHECK (email ~* '^[A-Za-z0-9._%+-]+@[A-Za-z0-9.-]+\.[A-Za-z]{2,}$'), CONSTRAINT users_password_hash_check CHECK (password_hash IS NULL OR TRIM(password_hash) <> '') ); COMMENT ON TABLE public.users IS 'Stores user authentication information.'; COMMENT ON COLUMN public.users.refresh_token IS 'Stores the long-lived refresh token for re-authentication.'; COMMENT ON COLUMN public.users.failed_login_attempts IS 'Tracks the number of consecutive failed login attempts.'; COMMENT ON COLUMN public.users.last_failed_login IS 'Timestamp of the last failed login attempt.'; COMMENT ON COLUMN public.users.last_login_at IS 'Timestamp of the last successful login.'; COMMENT ON COLUMN public.users.last_login_ip IS 'The IP address from which the user last successfully logged in.'; -- Add an index on the refresh_token for faster lookups when refreshing tokens. CREATE INDEX IF NOT EXISTS idx_users_refresh_token ON public.users(refresh_token); CREATE UNIQUE INDEX IF NOT EXISTS idx_users_email ON public.users (email); CREATE INDEX IF NOT EXISTS idx_users_created_at ON public.users (created_at DESC); -- 2. Log key user activities for analytics. -- This needs to be created early as many triggers will insert into it. CREATE TABLE IF NOT EXISTS public.activity_log ( activity_log_id BIGINT PRIMARY KEY GENERATED ALWAYS AS IDENTITY, user_id UUID REFERENCES public.users(user_id) ON DELETE SET NULL, action TEXT NOT NULL, display_text TEXT NOT NULL, icon TEXT, details JSONB, created_at TIMESTAMPTZ DEFAULT now() NOT NULL, updated_at TIMESTAMPTZ DEFAULT now() NOT NULL, CONSTRAINT activity_log_action_check CHECK (TRIM(action) <> ''), CONSTRAINT activity_log_display_text_check CHECK (TRIM(display_text) <> '') ); COMMENT ON TABLE public.activity_log IS 'Logs key user and system actions for auditing and display in an activity feed.'; -- This composite index is more efficient for user-specific activity feeds ordered by date. CREATE INDEX IF NOT EXISTS idx_activity_log_user_id_created_at ON public.activity_log(user_id, created_at DESC); -- 3. for public user profiles. -- This table is linked to the users table and stores non-sensitive user data. -- This table now references the new `addresses` table for the user's home address. CREATE TABLE IF NOT EXISTS public.profiles ( user_id UUID PRIMARY KEY REFERENCES public.users(user_id) ON DELETE CASCADE, full_name TEXT, avatar_url TEXT, address_id BIGINT REFERENCES public.addresses(address_id) ON DELETE SET NULL, points INTEGER DEFAULT 0 NOT NULL CHECK (points >= 0), preferences JSONB, role TEXT CHECK (role IN ('admin', 'user')), created_at TIMESTAMPTZ DEFAULT now() NOT NULL, updated_at TIMESTAMPTZ DEFAULT now() NOT NULL, CONSTRAINT profiles_full_name_check CHECK (full_name IS NULL OR TRIM(full_name) <> ''), CONSTRAINT profiles_avatar_url_check CHECK (avatar_url IS NULL OR avatar_url ~* '^https://?.*'), created_by UUID REFERENCES public.users(user_id) ON DELETE SET NULL, updated_by UUID REFERENCES public.users(user_id) ON DELETE SET NULL ); COMMENT ON TABLE public.profiles IS 'Stores public-facing user data, linked to the public.users table.'; COMMENT ON COLUMN public.profiles.address_id IS 'A foreign key to the user''s primary address in the `addresses` table.'; -- This index is crucial for the gamification leaderboard feature. CREATE INDEX IF NOT EXISTS idx_profiles_points_leaderboard ON public.profiles (points DESC, full_name ASC); COMMENT ON COLUMN public.profiles.points IS 'A simple integer column to store a user''s total accumulated points from achievements.'; -- 4. The 'stores' table for normalized store data. CREATE TABLE IF NOT EXISTS public.stores ( store_id BIGINT PRIMARY KEY GENERATED ALWAYS AS IDENTITY, name TEXT NOT NULL UNIQUE, logo_url TEXT, created_at TIMESTAMPTZ DEFAULT now() NOT NULL, updated_at TIMESTAMPTZ DEFAULT now() NOT NULL, CONSTRAINT stores_name_check CHECK (TRIM(name) <> ''), CONSTRAINT stores_logo_url_check CHECK (logo_url IS NULL OR logo_url ~* '^https://?.*'), created_by UUID REFERENCES public.users(user_id) ON DELETE SET NULL ); COMMENT ON TABLE public.stores IS 'Stores metadata for grocery store chains (e.g., Safeway, Kroger).'; -- 5. The 'categories' table for normalized category data. CREATE TABLE IF NOT EXISTS public.categories ( category_id BIGINT PRIMARY KEY GENERATED ALWAYS AS IDENTITY, name TEXT NOT NULL UNIQUE, created_at TIMESTAMPTZ DEFAULT now() NOT NULL, updated_at TIMESTAMPTZ DEFAULT now() NOT NULL, CONSTRAINT categories_name_check CHECK (TRIM(name) <> '') ); COMMENT ON TABLE public.categories IS 'Stores a predefined list of grocery item categories (e.g., ''Fruits & Vegetables'', ''Dairy & Eggs'').'; -- 6. flyers' table CREATE TABLE IF NOT EXISTS public.flyers ( flyer_id BIGINT PRIMARY KEY GENERATED ALWAYS AS IDENTITY, file_name TEXT NOT NULL, image_url TEXT NOT NULL, icon_url TEXT, checksum TEXT UNIQUE, store_id BIGINT REFERENCES public.stores(store_id) ON DELETE CASCADE, valid_from DATE, valid_to DATE, store_address TEXT, status TEXT DEFAULT 'processed' NOT NULL CHECK (status IN ('processed', 'needs_review', 'archived')), item_count INTEGER DEFAULT 0 NOT NULL CHECK (item_count >= 0), uploaded_by UUID REFERENCES public.users(user_id) ON DELETE SET NULL, created_at TIMESTAMPTZ DEFAULT now() NOT NULL, updated_at TIMESTAMPTZ DEFAULT now() NOT NULL, CONSTRAINT flyers_valid_dates_check CHECK (valid_to >= valid_from), CONSTRAINT flyers_file_name_check CHECK (TRIM(file_name) <> ''), CONSTRAINT flyers_image_url_check CHECK (image_url ~* '^https://?.*'), CONSTRAINT flyers_icon_url_check CHECK (icon_url IS NULL OR icon_url ~* '^https://?.*'), CONSTRAINT flyers_checksum_check CHECK (checksum IS NULL OR length(checksum) = 64) ); COMMENT ON TABLE public.flyers IS 'Stores metadata for each processed flyer, linking it to a store and its validity period.'; CREATE INDEX IF NOT EXISTS idx_flyers_store_id ON public.flyers(store_id); 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 on Server for now.'; COMMENT ON COLUMN public.flyers.icon_url IS 'The public URL of the 64x64 icon version of the flyer image.'; 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.'; COMMENT ON COLUMN public.flyers.status IS 'The processing status of the flyer, e.g., if it needs manual review.'; COMMENT ON COLUMN public.flyers.item_count IS 'A cached count of the number of items in this flyer, maintained by a trigger.'; COMMENT ON COLUMN public.flyers.uploaded_by IS 'The user who uploaded the flyer. Can be null for anonymous or system uploads.'; CREATE INDEX IF NOT EXISTS idx_flyers_status ON public.flyers(status); CREATE INDEX IF NOT EXISTS idx_flyers_created_at ON public.flyers (created_at DESC); CREATE INDEX IF NOT EXISTS idx_flyers_valid_to_file_name ON public.flyers (valid_to DESC, file_name ASC); CREATE INDEX IF NOT EXISTS idx_flyers_status ON public.flyers(status); -- 7. The 'master_grocery_items' table. This is the master dictionary. CREATE TABLE IF NOT EXISTS public.master_grocery_items ( master_grocery_item_id BIGINT PRIMARY KEY GENERATED ALWAYS AS IDENTITY, name TEXT NOT NULL UNIQUE, category_id BIGINT REFERENCES public.categories(category_id) ON DELETE SET NULL, is_allergen BOOLEAN DEFAULT false, allergy_info JSONB, created_at TIMESTAMPTZ DEFAULT now() NOT NULL, updated_at TIMESTAMPTZ DEFAULT now() NOT NULL, created_by UUID REFERENCES public.users(user_id) ON DELETE SET NULL, CONSTRAINT master_grocery_items_name_check CHECK (TRIM(name) <> '') ); COMMENT ON TABLE public.master_grocery_items IS 'The master dictionary of canonical grocery items. Each item has a unique name and is linked to a category.'; CREATE INDEX IF NOT EXISTS idx_master_grocery_items_category_id ON public.master_grocery_items(category_id); CREATE INDEX IF NOT EXISTS idx_master_grocery_items_name ON public.master_grocery_items (name); -- 8. The 'user_watched_items' table. This links to the master list. CREATE TABLE IF NOT EXISTS public.user_watched_items ( user_watched_item_id BIGINT PRIMARY KEY GENERATED ALWAYS AS IDENTITY, user_id UUID NOT NULL REFERENCES public.users(user_id) ON DELETE CASCADE, master_item_id BIGINT NOT NULL REFERENCES public.master_grocery_items(master_grocery_item_id) ON DELETE CASCADE, created_at TIMESTAMPTZ DEFAULT now() NOT NULL, updated_at TIMESTAMPTZ DEFAULT now() NOT NULL, UNIQUE(user_id, master_item_id) ); COMMENT ON TABLE public.user_watched_items IS 'A linking table that represents a user''s personal watchlist of grocery items.'; CREATE INDEX IF NOT EXISTS idx_user_watched_items_master_item_id ON public.user_watched_items(master_item_id); -- 23. Store brand information. (Moved up due to dependency in flyer_items) CREATE TABLE IF NOT EXISTS public.brands ( brand_id BIGINT PRIMARY KEY GENERATED ALWAYS AS IDENTITY, name TEXT NOT NULL UNIQUE, logo_url TEXT, store_id BIGINT REFERENCES public.stores(store_id) ON DELETE SET NULL, created_at TIMESTAMPTZ DEFAULT now() NOT NULL, updated_at TIMESTAMPTZ DEFAULT now() NOT NULL, CONSTRAINT brands_name_check CHECK (TRIM(name) <> ''), CONSTRAINT brands_logo_url_check CHECK (logo_url IS NULL OR logo_url ~* '^https://?.*') ); COMMENT ON TABLE public.brands IS 'Stores brand names like "Coca-Cola", "Maple Leaf", or "Kraft".'; COMMENT ON COLUMN public.brands.store_id IS 'If this is a store-specific brand (e.g., President''s Choice), this links to the parent store.'; -- 24. For specific products, linking a master item with a brand and size. (Moved up due to dependency in flyer_items) CREATE TABLE IF NOT EXISTS public.products ( product_id BIGINT PRIMARY KEY GENERATED ALWAYS AS IDENTITY, master_item_id BIGINT NOT NULL REFERENCES public.master_grocery_items(master_grocery_item_id) ON DELETE CASCADE, brand_id BIGINT REFERENCES public.brands(brand_id) ON DELETE SET NULL, name TEXT NOT NULL, description TEXT, size TEXT, upc_code TEXT UNIQUE, created_at TIMESTAMPTZ DEFAULT now() NOT NULL, updated_at TIMESTAMPTZ DEFAULT now() NOT NULL, CONSTRAINT products_name_check CHECK (TRIM(name) <> ''), CONSTRAINT products_upc_code_check CHECK (upc_code IS NULL OR upc_code ~ '^[0-9]{8,14}$') ); 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.'; COMMENT ON COLUMN public.products.brand_id IS 'Can be null for generic/store-brand items.'; COMMENT ON COLUMN public.products.name IS 'Prime Raised without Antibiotics Chicken Breast.'; COMMENT ON COLUMN public.products.size IS 'e.g., "4L", "500g".'; CREATE INDEX IF NOT EXISTS idx_products_master_item_id ON public.products(master_item_id); CREATE INDEX IF NOT EXISTS idx_products_brand_id ON public.products(brand_id); -- 9. The 'flyer_items' table. This stores individual items from flyers. CREATE TABLE IF NOT EXISTS public.flyer_items ( flyer_item_id BIGINT PRIMARY KEY GENERATED ALWAYS AS IDENTITY, flyer_id BIGINT REFERENCES public.flyers(flyer_id) ON DELETE CASCADE, item TEXT NOT NULL, price_display TEXT NOT NULL, price_in_cents INTEGER CHECK (price_in_cents IS NULL OR price_in_cents >= 0), quantity_num NUMERIC, quantity TEXT NOT NULL, category_id BIGINT REFERENCES public.categories(category_id) ON DELETE SET NULL, category_name TEXT, unit_price JSONB, view_count INTEGER DEFAULT 0 NOT NULL CHECK (view_count >= 0), click_count INTEGER DEFAULT 0 NOT NULL CHECK (click_count >= 0), master_item_id BIGINT REFERENCES public.master_grocery_items(master_grocery_item_id) ON DELETE SET NULL, product_id BIGINT REFERENCES public.products(product_id) ON DELETE SET NULL, created_at TIMESTAMPTZ DEFAULT now() NOT NULL, updated_at TIMESTAMPTZ DEFAULT now() NOT NULL, CONSTRAINT flyer_items_item_check CHECK (TRIM(item) <> ''), CONSTRAINT flyer_items_price_display_check CHECK (TRIM(price_display) <> ''), CONSTRAINT flyer_items_quantity_check CHECK (TRIM(quantity) <> ''), CONSTRAINT flyer_items_category_name_check CHECK (category_name IS NULL OR TRIM(category_name) <> '') ); 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.'; CREATE INDEX IF NOT EXISTS idx_flyer_items_flyer_id ON public.flyer_items(flyer_id); CREATE INDEX IF NOT EXISTS idx_flyer_items_master_item_id ON public.flyer_items(master_item_id); CREATE INDEX IF NOT EXISTS idx_flyer_items_category_id ON public.flyer_items(category_id); CREATE INDEX IF NOT EXISTS idx_flyer_items_product_id ON public.flyer_items(product_id); -- Add a GIN index to the 'item' column for fast fuzzy text searching. -- This partial index is optimized for queries that find the best price for an item. CREATE INDEX IF NOT EXISTS idx_flyer_items_master_item_price ON public.flyer_items (master_item_id, price_in_cents ASC) WHERE price_in_cents IS NOT NULL; -- 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); -- 10. For user-defined alerts on watched items. CREATE TABLE IF NOT EXISTS public.user_alerts ( user_alert_id BIGINT PRIMARY KEY GENERATED ALWAYS AS IDENTITY, user_watched_item_id BIGINT NOT NULL REFERENCES public.user_watched_items(user_watched_item_id) ON DELETE CASCADE, alert_type TEXT NOT NULL CHECK (alert_type IN ('PRICE_BELOW', 'PERCENT_OFF_AVERAGE')), threshold_value NUMERIC NOT NULL CHECK (threshold_value > 0), is_active BOOLEAN DEFAULT true NOT NULL, created_at TIMESTAMPTZ DEFAULT now() NOT NULL, updated_at TIMESTAMPTZ DEFAULT now() NOT NULL ); COMMENT ON TABLE public.user_alerts IS 'Stores user-configured alert rules for their watched items.'; COMMENT ON COLUMN public.user_alerts.alert_type IS 'The condition that triggers the alert, e.g., ''PRICE_BELOW''.'; COMMENT ON COLUMN public.user_alerts.threshold_value IS 'The numeric threshold for the alert condition (e.g., price in cents, or percentage).'; CREATE INDEX IF NOT EXISTS idx_user_alerts_user_watched_item_id ON public.user_alerts(user_watched_item_id); -- 11. Store notifications for users. CREATE TABLE IF NOT EXISTS public.notifications ( notification_id BIGINT PRIMARY KEY GENERATED ALWAYS AS IDENTITY, user_id UUID NOT NULL REFERENCES public.users(user_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, updated_at TIMESTAMPTZ DEFAULT now() NOT NULL, CONSTRAINT notifications_content_check CHECK (TRIM(content) <> '') ); 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.'; CREATE INDEX IF NOT EXISTS idx_notifications_user_id ON public.notifications(user_id); CREATE INDEX IF NOT EXISTS idx_notifications_user_id_created_at ON public.notifications (user_id, created_at DESC); -- 12. Store individual store locations with geographic data. CREATE TABLE IF NOT EXISTS public.store_locations ( store_location_id BIGINT PRIMARY KEY GENERATED ALWAYS AS IDENTITY, store_id BIGINT REFERENCES public.stores(store_id) ON DELETE CASCADE, address_id BIGINT NOT NULL REFERENCES public.addresses(address_id) ON DELETE CASCADE, UNIQUE(store_id, address_id), created_at TIMESTAMPTZ DEFAULT now() NOT NULL, updated_at TIMESTAMPTZ DEFAULT now() NOT NULL ); COMMENT ON TABLE public.store_locations IS 'Stores physical locations of stores with geographic data for proximity searches.'; CREATE INDEX IF NOT EXISTS idx_store_locations_store_id ON public.store_locations(store_id); -- 13. For aggregated, historical price data for master items. CREATE TABLE IF NOT EXISTS public.item_price_history ( item_price_history_id BIGINT PRIMARY KEY GENERATED ALWAYS AS IDENTITY, master_item_id BIGINT NOT NULL REFERENCES public.master_grocery_items(master_grocery_item_id) ON DELETE CASCADE, summary_date DATE NOT NULL, store_location_id BIGINT REFERENCES public.store_locations(store_location_id) ON DELETE CASCADE, min_price_in_cents INTEGER CHECK (min_price_in_cents IS NULL OR min_price_in_cents >= 0), max_price_in_cents INTEGER CHECK (max_price_in_cents IS NULL OR max_price_in_cents >= 0), avg_price_in_cents INTEGER CHECK (avg_price_in_cents IS NULL OR avg_price_in_cents >= 0), data_points_count INTEGER DEFAULT 0 NOT NULL CHECK (data_points_count >= 0), UNIQUE(master_item_id, summary_date, store_location_id), created_at TIMESTAMPTZ DEFAULT now() NOT NULL, updated_at TIMESTAMPTZ DEFAULT now() NOT NULL, CONSTRAINT item_price_history_price_order_check CHECK (min_price_in_cents <= max_price_in_cents) ); 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.'; COMMENT ON COLUMN public.item_price_history.min_price_in_cents IS 'The lowest price found for this item on this day, in cents,'; COMMENT ON COLUMN public.item_price_history.max_price_in_cents IS 'The highest price found for this item on this day, in cents.'; COMMENT ON COLUMN public.item_price_history.avg_price_in_cents IS 'The average price found for this item on this day, in cents.'; COMMENT ON COLUMN public.item_price_history.data_points_count IS 'How many data points were used for this summary.'; CREATE INDEX IF NOT EXISTS idx_item_price_history_master_item_id ON public.item_price_history(master_item_id); CREATE INDEX IF NOT EXISTS idx_item_price_history_store_location_id ON public.item_price_history(store_location_id); -- 14. Map various names to a single master grocery item. CREATE TABLE IF NOT EXISTS public.master_item_aliases ( master_item_alias_id BIGINT PRIMARY KEY GENERATED ALWAYS AS IDENTITY, master_item_id BIGINT NOT NULL REFERENCES public.master_grocery_items(master_grocery_item_id) ON DELETE CASCADE, alias TEXT NOT NULL UNIQUE, created_at TIMESTAMPTZ DEFAULT now() NOT NULL, updated_at TIMESTAMPTZ DEFAULT now() NOT NULL, CONSTRAINT master_item_aliases_alias_check CHECK (TRIM(alias) <> '') ); 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".'; CREATE INDEX IF NOT EXISTS idx_master_item_aliases_master_item_id ON public.master_item_aliases(master_item_id); -- 15. For user shopping lists. CREATE TABLE IF NOT EXISTS public.shopping_lists ( shopping_list_id BIGINT PRIMARY KEY GENERATED ALWAYS AS IDENTITY, user_id UUID NOT NULL REFERENCES public.users(user_id) ON DELETE CASCADE, name TEXT NOT NULL, created_at TIMESTAMPTZ DEFAULT now() NOT NULL, updated_at TIMESTAMPTZ DEFAULT now() NOT NULL, CONSTRAINT shopping_lists_name_check CHECK (TRIM(name) <> '') ); COMMENT ON TABLE public.shopping_lists IS 'Stores user-created shopping lists, e.g., "Weekly Groceries".'; CREATE INDEX IF NOT EXISTS idx_shopping_lists_user_id ON public.shopping_lists(user_id); -- 16. For items in a user's shopping list. CREATE TABLE IF NOT EXISTS public.shopping_list_items ( shopping_list_item_id BIGINT PRIMARY KEY GENERATED ALWAYS AS IDENTITY, shopping_list_id BIGINT NOT NULL REFERENCES public.shopping_lists(shopping_list_id) ON DELETE CASCADE, master_item_id BIGINT REFERENCES public.master_grocery_items(master_grocery_item_id) ON DELETE CASCADE, custom_item_name TEXT, quantity NUMERIC DEFAULT 1 NOT NULL CHECK (quantity > 0), is_purchased BOOLEAN DEFAULT false NOT NULL, notes TEXT, added_at TIMESTAMPTZ DEFAULT now() NOT NULL, updated_at TIMESTAMPTZ DEFAULT now() NOT NULL, CONSTRAINT must_have_item_identifier CHECK (master_item_id IS NOT NULL OR custom_item_name IS NOT NULL), CONSTRAINT shopping_list_items_custom_item_name_check CHECK (custom_item_name IS NULL OR TRIM(custom_item_name) <> '') ); 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.'; CREATE INDEX IF NOT EXISTS idx_shopping_list_items_shopping_list_id ON public.shopping_list_items(shopping_list_id); CREATE INDEX IF NOT EXISTS idx_shopping_list_items_master_item_id ON public.shopping_list_items(master_item_id); CREATE TABLE IF NOT EXISTS public.shared_shopping_lists ( shared_shopping_list_id BIGINT PRIMARY KEY GENERATED ALWAYS AS IDENTITY, shopping_list_id BIGINT NOT NULL REFERENCES public.shopping_lists(shopping_list_id) ON DELETE CASCADE, shared_by_user_id UUID NOT NULL REFERENCES public.users(user_id) ON DELETE CASCADE, shared_with_user_id UUID NOT NULL REFERENCES public.users(user_id) ON DELETE CASCADE, permission_level TEXT NOT NULL CHECK (permission_level IN ('view', 'edit')), created_at TIMESTAMPTZ DEFAULT now() NOT NULL, updated_at TIMESTAMPTZ DEFAULT now() NOT NULL, UNIQUE(shopping_list_id, shared_with_user_id) ); COMMENT ON TABLE public.shared_shopping_lists IS 'Allows users to share shopping lists with others and set permissions.'; CREATE INDEX IF NOT EXISTS idx_shared_shopping_lists_shopping_list_id ON public.shared_shopping_lists(shopping_list_id); CREATE INDEX IF NOT EXISTS idx_shared_shopping_lists_shared_by_user_id ON public.shared_shopping_lists(shared_by_user_id); CREATE INDEX IF NOT EXISTS idx_shared_shopping_lists_shared_with_user_id ON public.shared_shopping_lists(shared_with_user_id); -- 18. Store a user's collection of planned meals for a date range. CREATE TABLE IF NOT EXISTS public.menu_plans ( menu_plan_id BIGINT PRIMARY KEY GENERATED ALWAYS AS IDENTITY, user_id UUID NOT NULL REFERENCES public.users(user_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, updated_at TIMESTAMPTZ DEFAULT now() NOT NULL, CONSTRAINT menu_plans_name_check CHECK (TRIM(name) <> ''), 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".'; CREATE INDEX IF NOT EXISTS idx_menu_plans_user_id ON public.menu_plans(user_id); -- 19. Manage shared access to menu plans. CREATE TABLE IF NOT EXISTS public.shared_menu_plans ( shared_menu_plan_id BIGINT PRIMARY KEY GENERATED ALWAYS AS IDENTITY, menu_plan_id BIGINT NOT NULL REFERENCES public.menu_plans(menu_plan_id) ON DELETE CASCADE, shared_by_user_id UUID NOT NULL REFERENCES public.users(user_id) ON DELETE CASCADE, shared_with_user_id UUID NOT NULL REFERENCES public.users(user_id) ON DELETE CASCADE, permission_level TEXT NOT NULL CHECK (permission_level IN ('view', 'edit')), created_at TIMESTAMPTZ DEFAULT now() NOT NULL, updated_at TIMESTAMPTZ DEFAULT now() NOT NULL, UNIQUE(menu_plan_id, shared_with_user_id) ); COMMENT ON TABLE public.shared_menu_plans IS 'Allows users to share and collaborate on meal plans.'; CREATE INDEX IF NOT EXISTS idx_shared_menu_plans_menu_plan_id ON public.shared_menu_plans(menu_plan_id); CREATE INDEX IF NOT EXISTS idx_shared_menu_plans_shared_by_user_id ON public.shared_menu_plans(shared_by_user_id); CREATE INDEX IF NOT EXISTS idx_shared_menu_plans_shared_with_user_id ON public.shared_menu_plans(shared_with_user_id); -- 20. Store user-submitted corrections for flyer items. CREATE TABLE IF NOT EXISTS public.suggested_corrections ( suggested_correction_id BIGINT PRIMARY KEY GENERATED ALWAYS AS IDENTITY, flyer_item_id BIGINT NOT NULL REFERENCES public.flyer_items(flyer_item_id) ON DELETE CASCADE, user_id UUID NOT NULL REFERENCES public.users(user_id) ON DELETE CASCADE, correction_type TEXT NOT NULL, suggested_value TEXT NOT NULL, status TEXT DEFAULT 'pending' NOT NULL CHECK (status IN ('pending', 'approved', 'rejected')), created_at TIMESTAMPTZ DEFAULT now() NOT NULL, reviewed_notes TEXT, reviewed_at TIMESTAMPTZ, updated_at TIMESTAMPTZ DEFAULT now() NOT NULL, CONSTRAINT suggested_corrections_correction_type_check CHECK (TRIM(correction_type) <> ''), CONSTRAINT suggested_corrections_suggested_value_check CHECK (TRIM(suggested_value) <> '') ); 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.'; CREATE INDEX IF NOT EXISTS idx_suggested_corrections_flyer_item_id ON public.suggested_corrections(flyer_item_id); CREATE INDEX IF NOT EXISTS idx_suggested_corrections_user_id ON public.suggested_corrections(user_id); CREATE INDEX IF NOT EXISTS idx_suggested_corrections_pending ON public.suggested_corrections (created_at) WHERE status = 'pending'; -- 21. For prices submitted directly by users from in-store. CREATE TABLE IF NOT EXISTS public.user_submitted_prices ( user_submitted_price_id BIGINT PRIMARY KEY GENERATED ALWAYS AS IDENTITY, user_id UUID NOT NULL REFERENCES public.users(user_id) ON DELETE CASCADE, master_item_id BIGINT NOT NULL REFERENCES public.master_grocery_items(master_grocery_item_id) ON DELETE CASCADE, store_id BIGINT NOT NULL REFERENCES public.stores(store_id) ON DELETE CASCADE, price_in_cents INTEGER NOT NULL CHECK (price_in_cents > 0), photo_url TEXT, upvotes INTEGER DEFAULT 0 NOT NULL CHECK (upvotes >= 0), downvotes INTEGER DEFAULT 0 NOT NULL CHECK (downvotes >= 0), created_at TIMESTAMPTZ DEFAULT now() NOT NULL, updated_at TIMESTAMPTZ DEFAULT now() NOT NULL, CONSTRAINT user_submitted_prices_photo_url_check CHECK (photo_url IS NULL OR photo_url ~* '^https://?.*') ); 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.'; CREATE INDEX IF NOT EXISTS idx_user_submitted_prices_user_id ON public.user_submitted_prices(user_id); CREATE INDEX IF NOT EXISTS idx_user_submitted_prices_master_item_id ON public.user_submitted_prices(master_item_id); -- 22. Log flyer items that could not be automatically matched to a master item. CREATE TABLE IF NOT EXISTS public.unmatched_flyer_items ( unmatched_flyer_item_id BIGINT PRIMARY KEY GENERATED ALWAYS AS IDENTITY, flyer_item_id BIGINT NOT NULL REFERENCES public.flyer_items(flyer_item_id) ON DELETE CASCADE, status TEXT DEFAULT 'pending' NOT NULL CHECK (status IN ('pending', 'resolved', 'ignored')), created_at TIMESTAMPTZ DEFAULT now() NOT NULL, reviewed_at TIMESTAMPTZ, UNIQUE(flyer_item_id), updated_at TIMESTAMPTZ DEFAULT now() NOT NULL ); COMMENT ON TABLE public.unmatched_flyer_items IS 'A queue for reviewing flyer items that the system failed to automatically match.'; CREATE INDEX IF NOT EXISTS idx_unmatched_flyer_items_flyer_item_id ON public.unmatched_flyer_items(flyer_item_id); CREATE INDEX IF NOT EXISTS idx_unmatched_flyer_items_pending ON public.unmatched_flyer_items (created_at) WHERE status = 'pending'; -- 25. Linking table for when one flyer is valid for multiple locations. CREATE TABLE IF NOT EXISTS public.flyer_locations ( flyer_id BIGINT NOT NULL REFERENCES public.flyers(flyer_id) ON DELETE CASCADE, store_location_id BIGINT NOT NULL REFERENCES public.store_locations(store_location_id) ON DELETE CASCADE, PRIMARY KEY (flyer_id, store_location_id), created_at TIMESTAMPTZ DEFAULT now() NOT NULL, updated_at TIMESTAMPTZ DEFAULT now() NOT NULL ); COMMENT ON TABLE public.flyer_locations IS 'A linking table associating a single flyer with multiple store locations where its deals are valid.'; CREATE INDEX IF NOT EXISTS idx_flyer_locations_flyer_id ON public.flyer_locations(flyer_id); CREATE INDEX IF NOT EXISTS idx_flyer_locations_store_location_id ON public.flyer_locations(store_location_id); -- 26. Store recipes, which can be user-created or pre-populated. CREATE TABLE IF NOT EXISTS public.recipes ( recipe_id BIGINT PRIMARY KEY GENERATED ALWAYS AS IDENTITY, user_id UUID REFERENCES public.users(user_id) ON DELETE CASCADE, original_recipe_id BIGINT REFERENCES public.recipes(recipe_id) ON DELETE SET NULL, name TEXT NOT NULL, description TEXT, instructions TEXT, prep_time_minutes INTEGER CHECK (prep_time_minutes IS NULL OR prep_time_minutes >= 0), cook_time_minutes INTEGER CHECK (cook_time_minutes IS NULL OR cook_time_minutes >= 0), servings INTEGER CHECK (servings IS NULL OR servings > 0), 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 CHECK (avg_rating >= 0.0 AND avg_rating <= 5.0), status TEXT DEFAULT 'private' NOT NULL CHECK (status IN ('private', 'pending_review', 'public', 'rejected')), rating_count INTEGER DEFAULT 0 NOT NULL CHECK (rating_count >= 0), fork_count INTEGER DEFAULT 0 NOT NULL CHECK (fork_count >= 0), created_at TIMESTAMPTZ DEFAULT now() NOT NULL, updated_at TIMESTAMPTZ DEFAULT now() NOT NULL, CONSTRAINT recipes_name_check CHECK (TRIM(name) <> ''), CONSTRAINT recipes_photo_url_check CHECK (photo_url IS NULL OR photo_url ~* '^https://?.*') ); 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.'; COMMENT ON COLUMN public.recipes.original_recipe_id IS 'If this recipe is a variation of another, this points to the original.'; COMMENT ON COLUMN public.recipes.user_id IS 'Can be a system recipe (user_id is NULL) or user-submitted.'; COMMENT ON COLUMN public.recipes.avg_rating IS 'Aggregated rating data for fast sorting/display.'; COMMENT ON COLUMN public.recipes.calories_per_serving IS 'Optional nutritional information.'; COMMENT ON COLUMN public.recipes.protein_grams IS 'Optional nutritional information.'; COMMENT ON COLUMN public.recipes.fat_grams IS 'Optional nutritional information.'; COMMENT ON COLUMN public.recipes.carb_grams IS 'Optional nutritional information.'; CREATE INDEX IF NOT EXISTS idx_recipes_user_id ON public.recipes(user_id); CREATE INDEX IF NOT EXISTS idx_recipes_original_recipe_id ON public.recipes(original_recipe_id); -- Add a partial unique index to ensure system-wide recipes (user_id IS NULL) have unique names. -- This index helps speed up sorting for recipe recommendations. CREATE INDEX IF NOT EXISTS idx_recipes_rating_sort ON public.recipes (avg_rating DESC, rating_count DESC); CREATE UNIQUE INDEX IF NOT EXISTS idx_recipes_unique_system_recipe_name ON public.recipes(name) WHERE user_id IS NULL; -- 27. For ingredients required for each recipe. CREATE TABLE IF NOT EXISTS public.recipe_ingredients ( recipe_ingredient_id BIGINT PRIMARY KEY GENERATED ALWAYS AS IDENTITY, recipe_id BIGINT NOT NULL REFERENCES public.recipes(recipe_id) ON DELETE CASCADE, master_item_id BIGINT NOT NULL REFERENCES public.master_grocery_items(master_grocery_item_id) ON DELETE CASCADE, quantity NUMERIC NOT NULL CHECK (quantity > 0), unit TEXT NOT NULL, created_at TIMESTAMPTZ DEFAULT now() NOT NULL, updated_at TIMESTAMPTZ DEFAULT now() NOT NULL, CONSTRAINT recipe_ingredients_unit_check CHECK (TRIM(unit) <> '') ); COMMENT ON TABLE public.recipe_ingredients IS 'Defines the ingredients and quantities needed for a recipe.'; COMMENT ON COLUMN public.recipe_ingredients.unit IS 'e.g., "cups", "tbsp", "g", "each".'; CREATE INDEX IF NOT EXISTS idx_recipe_ingredients_recipe_id ON public.recipe_ingredients(recipe_id); CREATE INDEX IF NOT EXISTS idx_recipe_ingredients_master_item_id ON public.recipe_ingredients(master_item_id); -- 28. Suggest ingredient substitutions for a recipe. CREATE TABLE IF NOT EXISTS public.recipe_ingredient_substitutions ( recipe_ingredient_substitution_id BIGINT PRIMARY KEY GENERATED ALWAYS AS IDENTITY, recipe_ingredient_id BIGINT NOT NULL REFERENCES public.recipe_ingredients(recipe_ingredient_id) ON DELETE CASCADE, substitute_master_item_id BIGINT NOT NULL REFERENCES public.master_grocery_items(master_grocery_item_id) ON DELETE CASCADE, notes TEXT, UNIQUE(recipe_ingredient_id, substitute_master_item_id), created_at TIMESTAMPTZ DEFAULT now() NOT NULL, updated_at TIMESTAMPTZ DEFAULT now() NOT NULL ); COMMENT ON TABLE public.recipe_ingredient_substitutions IS 'Stores suggested alternative ingredients for a recipe item (e.g., "butter" for "olive oil").'; CREATE INDEX IF NOT EXISTS idx_recipe_ingredient_substitutions_recipe_ingredient_id ON public.recipe_ingredient_substitutions(recipe_ingredient_id); CREATE INDEX IF NOT EXISTS idx_recipe_ingredient_substitutions_substitute_master_item_id ON public.recipe_ingredient_substitutions(substitute_master_item_id); -- 29. Store a predefined list of tags for recipes. CREATE TABLE IF NOT EXISTS public.tags ( tag_id BIGINT PRIMARY KEY GENERATED ALWAYS AS IDENTITY, name TEXT NOT NULL UNIQUE, created_at TIMESTAMPTZ DEFAULT now() NOT NULL, updated_at TIMESTAMPTZ DEFAULT now() NOT NULL, CONSTRAINT tags_name_check CHECK (TRIM(name) <> '') ); COMMENT ON TABLE public.tags IS 'Stores tags for categorizing recipes, e.g., "Vegetarian", "Quick & Easy".'; -- 30. Associate multiple tags with a recipe. CREATE TABLE IF NOT EXISTS public.recipe_tags ( recipe_id BIGINT NOT NULL REFERENCES public.recipes(recipe_id) ON DELETE CASCADE, tag_id BIGINT NOT NULL REFERENCES public.tags(tag_id) ON DELETE CASCADE, PRIMARY KEY (recipe_id, tag_id), created_at TIMESTAMPTZ DEFAULT now() NOT NULL, updated_at TIMESTAMPTZ DEFAULT now() NOT NULL ); COMMENT ON TABLE public.recipe_tags IS 'A linking table to associate multiple tags with a single recipe.'; CREATE INDEX IF NOT EXISTS idx_recipe_tags_recipe_id ON public.recipe_tags(recipe_id); -- This index is crucial for functions that find recipes based on tags. CREATE INDEX IF NOT EXISTS idx_recipe_tags_tag_id ON public.recipe_tags(tag_id); -- 31. Store a predefined list of kitchen appliances. CREATE TABLE IF NOT EXISTS public.appliances ( appliance_id BIGINT PRIMARY KEY GENERATED ALWAYS AS IDENTITY, name TEXT NOT NULL UNIQUE, created_at TIMESTAMPTZ DEFAULT now() NOT NULL, updated_at TIMESTAMPTZ DEFAULT now() NOT NULL, CONSTRAINT appliances_name_check CHECK (TRIM(name) <> '') ); COMMENT ON TABLE public.appliances IS 'A predefined list of kitchen appliances (e.g., Air Fryer, Instant Pot).'; -- 32. Associate recipes with required appliances. CREATE TABLE IF NOT EXISTS public.recipe_appliances ( recipe_id BIGINT NOT NULL REFERENCES public.recipes(recipe_id) ON DELETE CASCADE, appliance_id BIGINT NOT NULL REFERENCES public.appliances(appliance_id) ON DELETE CASCADE, PRIMARY KEY (recipe_id, appliance_id), created_at TIMESTAMPTZ DEFAULT now() NOT NULL, updated_at TIMESTAMPTZ DEFAULT now() NOT NULL ); COMMENT ON TABLE public.recipe_appliances IS 'Links recipes to the specific kitchen appliances they require.'; CREATE INDEX IF NOT EXISTS idx_recipe_appliances_recipe_id ON public.recipe_appliances(recipe_id); CREATE INDEX IF NOT EXISTS idx_recipe_appliances_appliance_id ON public.recipe_appliances(appliance_id); -- 33. Store individual user ratings for recipes. CREATE TABLE IF NOT EXISTS public.recipe_ratings ( recipe_rating_id BIGINT PRIMARY KEY GENERATED ALWAYS AS IDENTITY, recipe_id BIGINT NOT NULL REFERENCES public.recipes(recipe_id) ON DELETE CASCADE, user_id UUID NOT NULL REFERENCES public.users(user_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), updated_at TIMESTAMPTZ DEFAULT now() NOT NULL ); COMMENT ON TABLE public.recipe_ratings IS 'Stores individual user ratings for recipes, ensuring a user can only rate a recipe once.'; CREATE INDEX IF NOT EXISTS idx_recipe_ratings_recipe_id ON public.recipe_ratings(recipe_id); CREATE INDEX IF NOT EXISTS idx_recipe_ratings_user_id ON public.recipe_ratings(user_id); -- 34. For user comments on recipes to enable discussion. CREATE TABLE IF NOT EXISTS public.recipe_comments ( recipe_comment_id BIGINT PRIMARY KEY GENERATED ALWAYS AS IDENTITY, recipe_id BIGINT NOT NULL REFERENCES public.recipes(recipe_id) ON DELETE CASCADE, user_id UUID NOT NULL REFERENCES public.users(user_id) ON DELETE CASCADE, parent_comment_id BIGINT REFERENCES public.recipe_comments(recipe_comment_id) ON DELETE CASCADE, content TEXT NOT NULL, status TEXT DEFAULT 'visible' NOT NULL CHECK (status IN ('visible', 'hidden', 'reported')), created_at TIMESTAMPTZ DEFAULT now() NOT NULL, updated_at TIMESTAMPTZ DEFAULT now() NOT NULL, CONSTRAINT recipe_comments_content_check CHECK (TRIM(content) <> '') ); COMMENT ON TABLE public.recipe_comments IS 'Allows for threaded discussions and comments on recipes.'; COMMENT ON COLUMN public.recipe_comments.parent_comment_id IS 'For threaded comments.'; CREATE INDEX IF NOT EXISTS idx_recipe_comments_recipe_id ON public.recipe_comments(recipe_id); CREATE INDEX IF NOT EXISTS idx_recipe_comments_user_id ON public.recipe_comments(user_id); CREATE INDEX IF NOT EXISTS idx_recipe_comments_parent_comment_id ON public.recipe_comments(parent_comment_id); -- 35. For users to define locations within their pantry. CREATE TABLE IF NOT EXISTS public.pantry_locations ( pantry_location_id BIGINT PRIMARY KEY GENERATED ALWAYS AS IDENTITY, user_id UUID NOT NULL REFERENCES public.users(user_id) ON DELETE CASCADE, name TEXT NOT NULL, created_at TIMESTAMPTZ DEFAULT now() NOT NULL, updated_at TIMESTAMPTZ DEFAULT now() NOT NULL, CONSTRAINT pantry_locations_name_check CHECK (TRIM(name) <> ''), UNIQUE(user_id, name) ); COMMENT ON TABLE public.pantry_locations IS 'User-defined locations for organizing pantry items (e.g., "Fridge", "Freezer", "Spice Rack").'; CREATE INDEX IF NOT EXISTS idx_pantry_locations_user_id ON public.pantry_locations(user_id); -- 36. Associate a recipe with a specific date and meal type within a menu plan. CREATE TABLE IF NOT EXISTS public.planned_meals ( planned_meal_id BIGINT PRIMARY KEY GENERATED ALWAYS AS IDENTITY, menu_plan_id BIGINT NOT NULL REFERENCES public.menu_plans(menu_plan_id) ON DELETE CASCADE, recipe_id BIGINT NOT NULL REFERENCES public.recipes(recipe_id) ON DELETE CASCADE, plan_date DATE NOT NULL, meal_type TEXT NOT NULL, servings_to_cook INTEGER, created_at TIMESTAMPTZ DEFAULT now() NOT NULL, updated_at TIMESTAMPTZ DEFAULT now() NOT NULL, CONSTRAINT planned_meals_meal_type_check CHECK (TRIM(meal_type) <> '') ); 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''.'; CREATE INDEX IF NOT EXISTS idx_planned_meals_menu_plan_id ON public.planned_meals(menu_plan_id); CREATE INDEX IF NOT EXISTS idx_planned_meals_recipe_id ON public.planned_meals(recipe_id); -- 37. Track the grocery items a user currently has in their pantry. CREATE TABLE IF NOT EXISTS public.pantry_items ( pantry_item_id BIGINT PRIMARY KEY GENERATED ALWAYS AS IDENTITY, user_id UUID NOT NULL REFERENCES public.users(user_id) ON DELETE CASCADE, master_item_id BIGINT NOT NULL REFERENCES public.master_grocery_items(master_grocery_item_id) ON DELETE CASCADE, quantity NUMERIC NOT NULL CHECK (quantity >= 0), unit TEXT, best_before_date DATE, pantry_location_id BIGINT REFERENCES public.pantry_locations(pantry_location_id) ON DELETE SET NULL, notification_sent_at TIMESTAMPTZ, 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.pantry_location_id IS 'Links the item to a user-defined location like "Fridge" or "Freezer".'; COMMENT ON COLUMN public.pantry_items.unit IS 'e.g., ''g'', ''ml'', ''items''. Should align with recipe_ingredients.unit and quantity convention.'; CREATE INDEX IF NOT EXISTS idx_pantry_items_user_id ON public.pantry_items(user_id); CREATE INDEX IF NOT EXISTS idx_pantry_items_master_item_id ON public.pantry_items(master_item_id); CREATE INDEX IF NOT EXISTS idx_pantry_items_pantry_location_id ON public.pantry_items(pantry_location_id); -- 38. Store password reset tokens. CREATE TABLE IF NOT EXISTS public.password_reset_tokens ( password_reset_token_id BIGINT PRIMARY KEY GENERATED ALWAYS AS IDENTITY, user_id UUID NOT NULL REFERENCES public.users(user_id) ON DELETE CASCADE, token_hash TEXT NOT NULL UNIQUE, expires_at TIMESTAMPTZ NOT NULL, created_at TIMESTAMPTZ DEFAULT now() NOT NULL, updated_at TIMESTAMPTZ DEFAULT now() NOT NULL, CONSTRAINT password_reset_tokens_token_hash_check CHECK (TRIM(token_hash) <> '') ); COMMENT ON TABLE public.password_reset_tokens IS 'Stores secure, single-use tokens for password reset requests.'; COMMENT ON COLUMN public.password_reset_tokens.token_hash IS 'A bcrypt hash of the reset token sent to the user.'; COMMENT ON COLUMN public.password_reset_tokens.expires_at IS 'The timestamp when this token is no longer valid.'; CREATE INDEX IF NOT EXISTS idx_password_reset_tokens_user_id ON public.password_reset_tokens(user_id); CREATE INDEX IF NOT EXISTS idx_password_reset_tokens_token_hash ON public.password_reset_tokens(token_hash); CREATE INDEX IF NOT EXISTS idx_password_reset_tokens_expires_at ON public.password_reset_tokens (expires_at); -- 39. Store unit conversion factors for specific master grocery items. CREATE TABLE IF NOT EXISTS public.unit_conversions ( unit_conversion_id BIGINT PRIMARY KEY GENERATED ALWAYS AS IDENTITY, master_item_id BIGINT NOT NULL REFERENCES public.master_grocery_items(master_grocery_item_id) ON DELETE CASCADE, from_unit TEXT NOT NULL, to_unit TEXT NOT NULL, factor NUMERIC NOT NULL CHECK (factor > 0), UNIQUE(master_item_id, from_unit, to_unit), created_at TIMESTAMPTZ DEFAULT now() NOT NULL, updated_at TIMESTAMPTZ DEFAULT now() NOT NULL, CONSTRAINT unit_conversions_from_unit_check CHECK (TRIM(from_unit) <> ''), CONSTRAINT unit_conversions_to_unit_check CHECK (TRIM(to_unit) <> ''), CONSTRAINT unit_conversions_units_check CHECK (from_unit <> to_unit) ); COMMENT ON TABLE public.unit_conversions IS 'Stores item-specific unit conversion factors (e.g., grams of flour to cups).'; COMMENT ON COLUMN public.unit_conversions.factor IS 'The multiplication factor to convert from_unit to to_unit.'; CREATE INDEX IF NOT EXISTS idx_unit_conversions_master_item_id ON public.unit_conversions(master_item_id); -- 40. For users to create their own private aliases for items. CREATE TABLE IF NOT EXISTS public.user_item_aliases ( user_item_alias_id BIGINT PRIMARY KEY GENERATED ALWAYS AS IDENTITY, user_id UUID NOT NULL REFERENCES public.users(user_id) ON DELETE CASCADE, master_item_id BIGINT NOT NULL REFERENCES public.master_grocery_items(master_grocery_item_id) ON DELETE CASCADE, alias TEXT NOT NULL, UNIQUE(user_id, alias), created_at TIMESTAMPTZ DEFAULT now() NOT NULL, updated_at TIMESTAMPTZ DEFAULT now() NOT NULL, CONSTRAINT user_item_aliases_alias_check CHECK (TRIM(alias) <> '') ); COMMENT ON TABLE public.user_item_aliases IS 'Allows users to create personal aliases for grocery items (e.g., "Dad''s Cereal").'; CREATE INDEX IF NOT EXISTS idx_user_item_aliases_user_id ON public.user_item_aliases(user_id); CREATE INDEX IF NOT EXISTS idx_user_item_aliases_master_item_id ON public.user_item_aliases(master_item_id); -- 41. For users to mark their favorite recipes. CREATE TABLE IF NOT EXISTS public.favorite_recipes ( user_id UUID NOT NULL REFERENCES public.users(user_id) ON DELETE CASCADE, recipe_id BIGINT NOT NULL REFERENCES public.recipes(recipe_id) ON DELETE CASCADE, created_at TIMESTAMPTZ DEFAULT now() NOT NULL, PRIMARY KEY (user_id, recipe_id), updated_at TIMESTAMPTZ DEFAULT now() NOT NULL ); COMMENT ON TABLE public.favorite_recipes IS 'A simple linking table for users to mark their favorite recipes.'; CREATE INDEX IF NOT EXISTS idx_favorite_recipes_user_id ON public.favorite_recipes(user_id); CREATE INDEX IF NOT EXISTS idx_favorite_recipes_recipe_id ON public.favorite_recipes(recipe_id); -- 42. For users to mark their favorite stores. CREATE TABLE IF NOT EXISTS public.favorite_stores ( user_id UUID NOT NULL REFERENCES public.users(user_id) ON DELETE CASCADE, store_id BIGINT NOT NULL REFERENCES public.stores(store_id) ON DELETE CASCADE, created_at TIMESTAMPTZ DEFAULT now() NOT NULL, PRIMARY KEY (user_id, store_id), updated_at TIMESTAMPTZ DEFAULT now() NOT NULL ); COMMENT ON TABLE public.favorite_stores IS 'A simple linking table for users to mark their favorite stores.'; CREATE INDEX IF NOT EXISTS idx_favorite_stores_user_id ON public.favorite_stores(user_id); CREATE INDEX IF NOT EXISTS idx_favorite_stores_store_id ON public.favorite_stores(store_id); -- 43. For users to group recipes into collections. CREATE TABLE IF NOT EXISTS public.recipe_collections ( recipe_collection_id BIGINT PRIMARY KEY GENERATED ALWAYS AS IDENTITY, user_id UUID NOT NULL REFERENCES public.users(user_id) ON DELETE CASCADE, name TEXT NOT NULL, description TEXT, created_at TIMESTAMPTZ DEFAULT now() NOT NULL, updated_at TIMESTAMPTZ DEFAULT now() NOT NULL, CONSTRAINT recipe_collections_name_check CHECK (TRIM(name) <> '') ); COMMENT ON TABLE public.recipe_collections IS 'Allows users to create personal collections of recipes (e.g., "Holiday Baking").'; CREATE INDEX IF NOT EXISTS idx_recipe_collections_user_id ON public.recipe_collections(user_id); -- 44. Associate recipes with a user's collection. CREATE TABLE IF NOT EXISTS public.recipe_collection_items ( collection_id BIGINT NOT NULL REFERENCES public.recipe_collections(recipe_collection_id) ON DELETE CASCADE, recipe_id BIGINT NOT NULL REFERENCES public.recipes(recipe_id) ON DELETE CASCADE, added_at TIMESTAMPTZ DEFAULT now() NOT NULL, PRIMARY KEY (collection_id, recipe_id), updated_at TIMESTAMPTZ DEFAULT now() NOT NULL ); COMMENT ON TABLE public.recipe_collection_items IS 'Links recipes to a user-defined collection.'; CREATE INDEX IF NOT EXISTS idx_recipe_collection_items_collection_id ON public.recipe_collection_items(collection_id); CREATE INDEX IF NOT EXISTS idx_recipe_collection_items_recipe_id ON public.recipe_collection_items(recipe_id); -- 44a. Manage shared access to recipe collections. CREATE TABLE IF NOT EXISTS public.shared_recipe_collections ( shared_collection_id BIGINT PRIMARY KEY GENERATED ALWAYS AS IDENTITY, recipe_collection_id BIGINT NOT NULL REFERENCES public.recipe_collections(recipe_collection_id) ON DELETE CASCADE, shared_by_user_id UUID NOT NULL REFERENCES public.users(user_id) ON DELETE CASCADE, shared_with_user_id UUID NOT NULL REFERENCES public.users(user_id) ON DELETE CASCADE, permission_level TEXT NOT NULL CHECK (permission_level IN ('view', 'edit')), created_at TIMESTAMPTZ DEFAULT now() NOT NULL, updated_at TIMESTAMPTZ DEFAULT now() NOT NULL, UNIQUE(recipe_collection_id, shared_with_user_id) ); -- This index is crucial for efficiently finding all collections shared with a specific user. CREATE INDEX IF NOT EXISTS idx_shared_recipe_collections_shared_with ON public.shared_recipe_collections(shared_with_user_id); -- 45. Log user search queries for analysis. CREATE TABLE IF NOT EXISTS public.search_queries ( search_query_id BIGINT PRIMARY KEY GENERATED ALWAYS AS IDENTITY, user_id UUID REFERENCES public.users(user_id) ON DELETE SET NULL, query_text TEXT NOT NULL, result_count INTEGER, was_successful BOOLEAN, created_at TIMESTAMPTZ DEFAULT now() NOT NULL, updated_at TIMESTAMPTZ DEFAULT now() NOT NULL, CONSTRAINT search_queries_query_text_check CHECK (TRIM(query_text) <> '') ); COMMENT ON TABLE public.search_queries IS 'Logs user search queries to analyze search effectiveness and identify gaps in data.'; COMMENT ON COLUMN public.search_queries.was_successful IS 'Indicates if the user interacted with a search result.'; CREATE INDEX IF NOT EXISTS idx_search_queries_user_id ON public.search_queries(user_id); -- 46. Store historical records of completed shopping trips. CREATE TABLE IF NOT EXISTS public.shopping_trips ( shopping_trip_id BIGINT PRIMARY KEY GENERATED ALWAYS AS IDENTITY, user_id UUID NOT NULL REFERENCES public.users(user_id) ON DELETE CASCADE, shopping_list_id BIGINT REFERENCES public.shopping_lists(shopping_list_id) ON DELETE SET NULL, completed_at TIMESTAMPTZ DEFAULT now() NOT NULL, total_spent_cents INTEGER, updated_at TIMESTAMPTZ DEFAULT now() NOT NULL ); COMMENT ON TABLE public.shopping_trips IS 'A historical record of a completed shopping trip.'; COMMENT ON COLUMN public.shopping_trips.total_spent_cents IS 'The total amount spent on this shopping trip, if provided by the user.'; CREATE INDEX IF NOT EXISTS idx_shopping_trips_user_id ON public.shopping_trips(user_id); CREATE INDEX IF NOT EXISTS idx_shopping_trips_shopping_list_id ON public.shopping_trips(shopping_list_id); -- 47. Store the items purchased during a specific shopping trip. CREATE TABLE IF NOT EXISTS public.shopping_trip_items ( shopping_trip_item_id BIGINT PRIMARY KEY GENERATED ALWAYS AS IDENTITY, shopping_trip_id BIGINT NOT NULL REFERENCES public.shopping_trips(shopping_trip_id) ON DELETE CASCADE, master_item_id BIGINT REFERENCES public.master_grocery_items(master_grocery_item_id) ON DELETE SET NULL, custom_item_name TEXT, quantity NUMERIC NOT NULL CHECK (quantity > 0), price_paid_cents INTEGER, created_at TIMESTAMPTZ DEFAULT now() NOT NULL, updated_at TIMESTAMPTZ DEFAULT now() NOT NULL, CONSTRAINT shopping_trip_items_custom_item_name_check CHECK (custom_item_name IS NULL OR TRIM(custom_item_name) <> ''), CONSTRAINT trip_must_have_item_identifier CHECK (master_item_id IS NOT NULL OR custom_item_name IS NOT NULL) ); COMMENT ON TABLE public.shopping_trip_items IS 'A historical log of items purchased during a shopping trip.'; COMMENT ON COLUMN public.shopping_trip_items.price_paid_cents IS 'The actual price paid for the item during the trip, if provided.'; CREATE INDEX IF NOT EXISTS idx_shopping_trip_items_shopping_trip_id ON public.shopping_trip_items(shopping_trip_id); CREATE INDEX IF NOT EXISTS idx_shopping_trip_items_master_item_id ON public.shopping_trip_items(master_item_id); -- 48. Store predefined dietary restrictions (diets and allergies). CREATE TABLE IF NOT EXISTS public.dietary_restrictions ( dietary_restriction_id BIGINT PRIMARY KEY GENERATED ALWAYS AS IDENTITY, name TEXT NOT NULL UNIQUE, type TEXT NOT NULL CHECK (type IN ('diet', 'allergy')), created_at TIMESTAMPTZ DEFAULT now() NOT NULL, updated_at TIMESTAMPTZ DEFAULT now() NOT NULL, CONSTRAINT dietary_restrictions_name_check CHECK (TRIM(name) <> '') ); COMMENT ON TABLE public.dietary_restrictions IS 'A predefined list of common diets (e.g., Vegan) and allergies (e.g., Nut Allergy).'; -- 49. For a user's specific dietary restrictions. CREATE TABLE IF NOT EXISTS public.user_dietary_restrictions ( user_id UUID NOT NULL REFERENCES public.users(user_id) ON DELETE CASCADE, restriction_id BIGINT NOT NULL REFERENCES public.dietary_restrictions(dietary_restriction_id) ON DELETE CASCADE, PRIMARY KEY (user_id, restriction_id), created_at TIMESTAMPTZ DEFAULT now() NOT NULL, updated_at TIMESTAMPTZ DEFAULT now() NOT NULL ); COMMENT ON TABLE public.user_dietary_restrictions IS 'Connects users to their selected dietary needs and allergies.'; -- This index is crucial for functions that filter recipes based on user diets/allergies. CREATE INDEX IF NOT EXISTS idx_user_dietary_restrictions_user_id ON public.user_dietary_restrictions(user_id); CREATE INDEX IF NOT EXISTS idx_user_dietary_restrictions_restriction_id ON public.user_dietary_restrictions(restriction_id); -- 50. For a user's owned kitchen appliances. CREATE TABLE IF NOT EXISTS public.user_appliances ( user_id UUID NOT NULL REFERENCES public.users(user_id) ON DELETE CASCADE, appliance_id BIGINT NOT NULL REFERENCES public.appliances(appliance_id) ON DELETE CASCADE, PRIMARY KEY (user_id, appliance_id), created_at TIMESTAMPTZ DEFAULT now() NOT NULL, updated_at TIMESTAMPTZ DEFAULT now() NOT NULL ); COMMENT ON TABLE public.user_appliances IS 'Tracks the kitchen appliances a user owns to help with recipe recommendations.'; CREATE INDEX IF NOT EXISTS idx_user_appliances_user_id ON public.user_appliances(user_id); CREATE INDEX IF NOT EXISTS idx_user_appliances_appliance_id ON public.user_appliances(appliance_id); -- 51. Manage the social graph (following relationships). CREATE TABLE IF NOT EXISTS public.user_follows ( follower_id UUID NOT NULL REFERENCES public.users(user_id) ON DELETE CASCADE, following_id UUID NOT NULL REFERENCES public.users(user_id) ON DELETE CASCADE, created_at TIMESTAMPTZ DEFAULT now() NOT NULL, PRIMARY KEY (follower_id, following_id), updated_at TIMESTAMPTZ DEFAULT now() NOT NULL, CONSTRAINT cant_follow_self CHECK (follower_id <> following_id) ); COMMENT ON TABLE public.user_follows IS 'Stores user following relationships to build a social graph.'; -- This index is crucial for efficiently generating a user's activity feed. CREATE INDEX IF NOT EXISTS idx_user_follows_follower_id ON public.user_follows(follower_id); CREATE INDEX IF NOT EXISTS idx_user_follows_following_id ON public.user_follows(following_id); -- 52. Store uploaded user receipts for purchase tracking and analysis. CREATE TABLE IF NOT EXISTS public.receipts ( receipt_id BIGINT PRIMARY KEY GENERATED ALWAYS AS IDENTITY, user_id UUID NOT NULL REFERENCES public.users(user_id) ON DELETE CASCADE, store_id BIGINT REFERENCES public.stores(store_id) ON DELETE CASCADE, receipt_image_url TEXT NOT NULL, transaction_date TIMESTAMPTZ, total_amount_cents INTEGER CHECK (total_amount_cents IS NULL OR total_amount_cents >= 0), status TEXT DEFAULT 'pending' NOT NULL CHECK (status IN ('pending', 'processing', 'completed', 'failed')), raw_text TEXT, created_at TIMESTAMPTZ DEFAULT now() NOT NULL, processed_at TIMESTAMPTZ, updated_at TIMESTAMPTZ DEFAULT now() NOT NULL, CONSTRAINT receipts_receipt_image_url_check CHECK (receipt_image_url ~* '^https://?.*') ); COMMENT ON TABLE public.receipts IS 'Stores uploaded user receipts for purchase tracking and analysis.'; CREATE INDEX IF NOT EXISTS idx_receipts_user_id ON public.receipts(user_id); CREATE INDEX IF NOT EXISTS idx_receipts_store_id ON public.receipts(store_id); -- 53. Store individual line items extracted from a user receipt. CREATE TABLE IF NOT EXISTS public.receipt_items ( receipt_item_id BIGINT PRIMARY KEY GENERATED ALWAYS AS IDENTITY, receipt_id BIGINT NOT NULL REFERENCES public.receipts(receipt_id) ON DELETE CASCADE, raw_item_description TEXT NOT NULL, quantity NUMERIC DEFAULT 1 NOT NULL CHECK (quantity > 0), price_paid_cents INTEGER NOT NULL CHECK (price_paid_cents >= 0), master_item_id BIGINT REFERENCES public.master_grocery_items(master_grocery_item_id) ON DELETE SET NULL, product_id BIGINT REFERENCES public.products(product_id) ON DELETE SET NULL, status TEXT DEFAULT 'unmatched' NOT NULL CHECK (status IN ('unmatched', 'matched', 'needs_review', 'ignored')), created_at TIMESTAMPTZ DEFAULT now() NOT NULL, updated_at TIMESTAMPTZ DEFAULT now() NOT NULL, CONSTRAINT receipt_items_raw_item_description_check CHECK (TRIM(raw_item_description) <> '') ); COMMENT ON TABLE public.receipt_items IS 'Stores individual line items extracted from a user receipt.'; CREATE INDEX IF NOT EXISTS idx_receipt_items_receipt_id ON public.receipt_items(receipt_id); CREATE INDEX IF NOT EXISTS idx_receipt_items_master_item_id ON public.receipt_items(master_item_id); -- 54. Store schema metadata to detect changes during deployment. CREATE TABLE IF NOT EXISTS public.schema_info ( environment TEXT PRIMARY KEY, schema_hash TEXT NOT NULL, deployed_at TIMESTAMPTZ DEFAULT now() NOT NULL ); COMMENT ON TABLE public.schema_info IS 'Stores metadata about the deployed schema, such as a hash of the schema file, to detect changes.'; COMMENT ON COLUMN public.schema_info.schema_hash IS 'A SHA-256 hash of the master_schema_rollup.sql file at the time of deployment.'; -- 55. Store user reactions to various entities (e.g., recipes, comments). CREATE TABLE IF NOT EXISTS public.user_reactions ( reaction_id BIGINT PRIMARY KEY GENERATED ALWAYS AS IDENTITY, user_id UUID NOT NULL REFERENCES public.users(user_id) ON DELETE CASCADE, entity_type TEXT NOT NULL, entity_id TEXT NOT NULL, reaction_type TEXT NOT NULL, created_at TIMESTAMPTZ DEFAULT now() NOT NULL, updated_at TIMESTAMPTZ DEFAULT now() NOT NULL, UNIQUE(user_id, entity_type, entity_id, reaction_type) ); COMMENT ON TABLE public.user_reactions IS 'Stores user reactions (e.g., like, love) to different content types.'; COMMENT ON COLUMN public.user_reactions.entity_type IS 'The type of content being reacted to (e.g., ''recipe'', ''comment'').'; COMMENT ON COLUMN public.user_reactions.entity_id IS 'The ID of the specific content item (e.g., a recipe_id or recipe_comment_id).'; COMMENT ON COLUMN public.user_reactions.reaction_type IS 'The type of reaction (e.g., ''like'', ''love'', ''helpful'').'; CREATE INDEX IF NOT EXISTS idx_user_reactions_user_id ON public.user_reactions(user_id); CREATE INDEX IF NOT EXISTS idx_user_reactions_entity ON public.user_reactions(entity_type, entity_id); -- 57. Static table defining available achievements for gamification. CREATE TABLE IF NOT EXISTS public.achievements ( achievement_id BIGINT PRIMARY KEY GENERATED ALWAYS AS IDENTITY, name TEXT NOT NULL UNIQUE, description TEXT NOT NULL, icon TEXT, points_value INTEGER NOT NULL DEFAULT 0 CHECK (points_value >= 0), created_at TIMESTAMPTZ DEFAULT now() NOT NULL, CONSTRAINT achievements_name_check CHECK (TRIM(name) <> ''), CONSTRAINT achievements_description_check CHECK (TRIM(description) <> '') ); COMMENT ON TABLE public.achievements IS 'A static table defining the available achievements users can earn.'; -- 58. Linking table to award users achievements. CREATE TABLE IF NOT EXISTS public.user_achievements ( user_id UUID NOT NULL REFERENCES public.users(user_id) ON DELETE CASCADE, achievement_id BIGINT NOT NULL REFERENCES public.achievements(achievement_id) ON DELETE CASCADE, achieved_at TIMESTAMPTZ DEFAULT now() NOT NULL, PRIMARY KEY (user_id, achievement_id) ); COMMENT ON TABLE public.user_achievements IS 'A linking table to award users badges or points for completing certain actions.'; CREATE INDEX IF NOT EXISTS idx_user_achievements_user_id ON public.user_achievements(user_id); CREATE INDEX IF NOT EXISTS idx_user_achievements_achievement_id ON public.user_achievements(achievement_id); -- 56. Store user-defined budgets for spending analysis. CREATE TABLE IF NOT EXISTS public.budgets ( budget_id BIGINT PRIMARY KEY GENERATED ALWAYS AS IDENTITY, user_id UUID NOT NULL REFERENCES public.users(user_id) ON DELETE CASCADE, name TEXT NOT NULL, amount_cents INTEGER NOT NULL CHECK (amount_cents > 0), period TEXT NOT NULL CHECK (period IN ('weekly', 'monthly')), start_date DATE NOT NULL, created_at TIMESTAMPTZ DEFAULT now() NOT NULL, updated_at TIMESTAMPTZ DEFAULT now() NOT NULL, CONSTRAINT budgets_name_check CHECK (TRIM(name) <> '') ); COMMENT ON TABLE public.budgets IS 'Allows users to set weekly or monthly grocery budgets for spending tracking.'; CREATE INDEX IF NOT EXISTS idx_budgets_user_id ON public.budgets(user_id);