database work !
Some checks failed
Deploy to Test Environment / deploy-to-test (push) Failing after 41s

This commit is contained in:
2025-12-31 17:01:35 -08:00
parent 7f1d74c047
commit 40580dbf15
22 changed files with 1372 additions and 612 deletions

View File

@@ -8,16 +8,23 @@
CREATE TABLE IF NOT EXISTS public.addresses (
address_id BIGINT PRIMARY KEY GENERATED ALWAYS AS IDENTITY,
address_line_1 TEXT NOT NULL UNIQUE,
address_line_2 TEXT,
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
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.';
@@ -31,12 +38,14 @@ CREATE TABLE IF NOT EXISTS public.users (
email TEXT NOT NULL UNIQUE,
password_hash TEXT,
refresh_token TEXT,
failed_login_attempts INTEGER DEFAULT 0,
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
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.';
@@ -59,10 +68,13 @@ CREATE TABLE IF NOT EXISTS public.activity_log (
icon TEXT,
details JSONB,
created_at TIMESTAMPTZ DEFAULT now() NOT NULL,
updated_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.';
CREATE INDEX IF NOT EXISTS idx_activity_log_user_id ON public.activity_log(user_id);
-- 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.
@@ -72,16 +84,20 @@ CREATE TABLE IF NOT EXISTS public.profiles (
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')),
points INTEGER DEFAULT 0 NOT NULL,
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.
@@ -91,6 +107,8 @@ CREATE TABLE IF NOT EXISTS public.stores (
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).';
@@ -100,7 +118,8 @@ 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
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'').';
@@ -116,10 +135,15 @@ CREATE TABLE IF NOT EXISTS public.flyers (
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,
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
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);
@@ -135,6 +159,7 @@ COMMENT ON COLUMN public.flyers.status IS 'The processing status of the flyer, e
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);
@@ -147,7 +172,8 @@ CREATE TABLE IF NOT EXISTS public.master_grocery_items (
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
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);
@@ -172,7 +198,9 @@ CREATE TABLE IF NOT EXISTS public.brands (
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
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.';
@@ -187,7 +215,9 @@ CREATE TABLE IF NOT EXISTS public.products (
size TEXT,
upc_code TEXT UNIQUE,
created_at TIMESTAMPTZ DEFAULT now() NOT NULL,
updated_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.';
@@ -203,18 +233,22 @@ CREATE TABLE IF NOT EXISTS public.flyer_items (
flyer_id BIGINT REFERENCES public.flyers(flyer_id) ON DELETE CASCADE,
item TEXT NOT NULL,
price_display TEXT NOT NULL,
price_in_cents INTEGER,
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,
click_count INTEGER DEFAULT 0 NOT NULL,
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
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.';
@@ -233,6 +267,8 @@ CREATE INDEX IF NOT EXISTS idx_flyer_items_master_item_id ON public.flyer_items(
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);
@@ -241,7 +277,7 @@ 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,
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
@@ -259,7 +295,8 @@ CREATE TABLE IF NOT EXISTS public.notifications (
link_url TEXT,
is_read BOOLEAN DEFAULT false NOT NULL,
created_at TIMESTAMPTZ DEFAULT now() NOT NULL,
updated_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.';
@@ -272,8 +309,8 @@ 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,
created_at TIMESTAMPTZ DEFAULT now() NOT NULL,
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.';
@@ -285,13 +322,14 @@ CREATE TABLE IF NOT EXISTS public.item_price_history (
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,
max_price_in_cents INTEGER,
avg_price_in_cents INTEGER,
data_points_count INTEGER DEFAULT 0 NOT NULL,
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
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.';
@@ -308,7 +346,8 @@ CREATE TABLE IF NOT EXISTS public.master_item_aliases (
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
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".';
@@ -320,7 +359,8 @@ CREATE TABLE IF NOT EXISTS public.shopping_lists (
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
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);
@@ -331,12 +371,13 @@ CREATE TABLE IF NOT EXISTS public.shopping_list_items (
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,
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 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".';
@@ -344,7 +385,6 @@ COMMENT ON COLUMN public.shopping_list_items.is_purchased IS 'Lets users check i
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);
-- 17. Manage shared access to shopping lists.
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,
@@ -369,6 +409,7 @@ CREATE TABLE IF NOT EXISTS public.menu_plans (
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".';
@@ -397,11 +438,13 @@ CREATE TABLE IF NOT EXISTS public.suggested_corrections (
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,
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
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.';
@@ -417,12 +460,13 @@ CREATE TABLE IF NOT EXISTS public.user_submitted_prices (
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,
price_in_cents INTEGER NOT NULL CHECK (price_in_cents > 0),
photo_url TEXT,
upvotes INTEGER DEFAULT 0 NOT NULL,
downvotes INTEGER DEFAULT 0 NOT NULL,
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
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.';
@@ -464,20 +508,22 @@ CREATE TABLE IF NOT EXISTS public.recipes (
name TEXT NOT NULL,
description TEXT,
instructions TEXT,
prep_time_minutes INTEGER,
cook_time_minutes INTEGER,
servings INTEGER,
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,
status TEXT DEFAULT 'private' NOT NULL CHECK (status IN ('private', 'pending_review', 'public', 'rejected')),
rating_count INTEGER DEFAULT 0 NOT NULL,
fork_count INTEGER DEFAULT 0 NOT NULL,
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
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.';
@@ -488,11 +534,11 @@ COMMENT ON COLUMN public.recipes.calories_per_serving IS 'Optional nutritional i
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.';
COMMENT ON COLUMN public.recipes.fork_count IS 'To track how many times a public recipe has been "forked" or copied by other users.';
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 allows different users to have recipes with the same name.
-- 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.
@@ -500,10 +546,11 @@ 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,
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
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".';
@@ -529,7 +576,8 @@ 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
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".';
@@ -543,6 +591,7 @@ CREATE TABLE IF NOT EXISTS public.recipe_tags (
);
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.
@@ -550,7 +599,8 @@ 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
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).';
@@ -590,7 +640,8 @@ CREATE TABLE IF NOT EXISTS public.recipe_comments (
content TEXT NOT NULL,
status TEXT DEFAULT 'visible' NOT NULL CHECK (status IN ('visible', 'hidden', 'reported')),
created_at TIMESTAMPTZ DEFAULT now() NOT NULL,
updated_at TIMESTAMPTZ 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.';
@@ -605,6 +656,7 @@ CREATE TABLE IF NOT EXISTS public.pantry_locations (
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").';
@@ -618,8 +670,9 @@ CREATE TABLE IF NOT EXISTS public.planned_meals (
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
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''.';
@@ -631,7 +684,7 @@ 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,
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,
@@ -640,7 +693,6 @@ CREATE TABLE IF NOT EXISTS public.pantry_items (
UNIQUE(user_id, master_item_id, unit)
);
COMMENT ON TABLE public.pantry_items IS 'Tracks a user''s personal inventory of grocery items to enable smart shopping lists.';
COMMENT ON COLUMN public.pantry_items.quantity IS 'The current amount of the item. Convention: use grams for weight, mL for volume where applicable.';
COMMENT ON COLUMN public.pantry_items.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);
@@ -654,7 +706,8 @@ CREATE TABLE IF NOT EXISTS public.password_reset_tokens (
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
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.';
@@ -669,10 +722,13 @@ CREATE TABLE IF NOT EXISTS public.unit_conversions (
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,
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
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.';
@@ -686,7 +742,8 @@ CREATE TABLE IF NOT EXISTS public.user_item_aliases (
alias TEXT NOT NULL,
UNIQUE(user_id, alias),
created_at TIMESTAMPTZ DEFAULT now() NOT NULL,
updated_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);
@@ -723,7 +780,8 @@ CREATE TABLE IF NOT EXISTS public.recipe_collections (
name TEXT NOT NULL,
description TEXT,
created_at TIMESTAMPTZ DEFAULT now() NOT NULL,
updated_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);
@@ -748,8 +806,11 @@ CREATE TABLE IF NOT EXISTS public.shared_recipe_collections (
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 (
@@ -759,7 +820,8 @@ CREATE TABLE IF NOT EXISTS public.search_queries (
result_count INTEGER,
was_successful BOOLEAN,
created_at TIMESTAMPTZ DEFAULT now() NOT NULL,
updated_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.';
@@ -785,10 +847,11 @@ CREATE TABLE IF NOT EXISTS public.shopping_trip_items (
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,
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.';
@@ -802,7 +865,8 @@ CREATE TABLE IF NOT EXISTS public.dietary_restrictions (
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
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).';
@@ -815,6 +879,7 @@ CREATE TABLE IF NOT EXISTS public.user_dietary_restrictions (
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);
@@ -840,6 +905,7 @@ CREATE TABLE IF NOT EXISTS public.user_follows (
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);
@@ -850,12 +916,13 @@ CREATE TABLE IF NOT EXISTS public.receipts (
store_id BIGINT REFERENCES public.stores(store_id) ON DELETE CASCADE,
receipt_image_url TEXT NOT NULL,
transaction_date TIMESTAMPTZ,
total_amount_cents INTEGER,
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
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);
@@ -866,13 +933,14 @@ 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,
price_paid_cents INTEGER 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
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);
@@ -885,7 +953,6 @@ CREATE TABLE IF NOT EXISTS public.schema_info (
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.environment IS 'The deployment environment (e.g., ''development'', ''test'', ''production'').';
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).
@@ -912,8 +979,10 @@ CREATE TABLE IF NOT EXISTS public.achievements (
name TEXT NOT NULL UNIQUE,
description TEXT NOT NULL,
icon TEXT,
points_value INTEGER NOT NULL DEFAULT 0,
created_at TIMESTAMPTZ DEFAULT now() NOT NULL
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.';
@@ -934,11 +1003,12 @@ 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,
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
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);