db fixin
Some checks failed
Deploy to Web Server flyer-crawler.projectium.com / deploy (push) Failing after 1m7s

This commit is contained in:
2025-11-30 09:37:42 -08:00
parent 949e0dc062
commit 361e064bd0
6 changed files with 160 additions and 60 deletions

View File

@@ -67,6 +67,7 @@ CREATE TABLE IF NOT EXISTS public.profiles (
postal_code VARCHAR(10),
country VARCHAR(2),
preferences JSONB,
points INTEGER DEFAULT 0 NOT NULL,
role TEXT CHECK (role IN ('admin', 'user')),
created_at TIMESTAMPTZ DEFAULT now() NOT NULL,
updated_at TIMESTAMPTZ DEFAULT now() NOT NULL,
@@ -80,6 +81,7 @@ COMMENT ON COLUMN public.profiles.city IS 'Optional. The user''s city for region
COMMENT ON COLUMN public.profiles.province_state IS 'Optional. The user''s province or state.';
COMMENT ON COLUMN public.profiles.postal_code IS 'Optional. The user''s postal or ZIP code.';
COMMENT ON COLUMN public.profiles.country IS 'Optional. The user''s two-letter ISO 3166-1 alpha-2 country code (e.g., CA, US).';
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 (
@@ -105,8 +107,8 @@ COMMENT ON TABLE public.categories IS 'Stores a predefined list of grocery item
CREATE TABLE IF NOT EXISTS public.flyers (
flyer_id BIGINT PRIMARY KEY GENERATED ALWAYS AS IDENTITY,
file_name TEXT NOT NULL,
icon_url TEXT,
image_url TEXT NOT NULL,
icon_url TEXT,
checksum TEXT UNIQUE,
store_id BIGINT REFERENCES public.stores(store_id),
valid_from DATE,
@@ -118,12 +120,9 @@ CREATE TABLE IF NOT EXISTS public.flyers (
);
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);
-- Add a composite index to optimize queries that filter by active date ranges and store.
-- This is particularly useful for the recalculate_price_history_on_flyer_item_delete trigger.
CREATE INDEX IF NOT EXISTS idx_flyers_valid_dates_store ON public.flyers(valid_from, valid_to, 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.image_url IS 'The public URL of the primary flyer image stored on server Storage.';
COMMENT ON COLUMN public.flyers.checksum IS 'A SHA-256 hash of the original file content to prevent duplicate processing.';
COMMENT ON COLUMN public.flyers.store_id IS 'Foreign key linking this flyer to a specific store in the `stores` table.';
COMMENT ON COLUMN public.flyers.valid_from IS 'The start date of the sale period for this flyer, extracted by the AI.';
@@ -132,7 +131,7 @@ COMMENT ON COLUMN public.flyers.store_address IS 'The physical store address if
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_created_at ON public.flyers (created_at DESC);
CREATE INDEX IF NOT EXISTS idx_flyers_valid_to_name ON public.flyers (valid_to DESC, name ASC);
CREATE INDEX IF NOT EXISTS idx_flyers_valid_to_file_name ON public.flyers (valid_to DESC, file_name ASC);
-- 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,
@@ -176,7 +175,8 @@ CREATE TABLE IF NOT EXISTS public.flyer_items (
click_count INTEGER DEFAULT 0 NOT NULL,
master_item_id BIGINT REFERENCES public.master_grocery_items(master_grocery_item_id),
product_id BIGINT,
created_at TIMESTAMPTZ DEFAULT now() NOT NULL
created_at TIMESTAMPTZ DEFAULT now() NOT NULL,
updated_at TIMESTAMPTZ DEFAULT now() NOT NULL
);
COMMENT ON TABLE public.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.';
@@ -402,8 +402,7 @@ CREATE INDEX IF NOT EXISTS idx_user_submitted_prices_master_item_id ON public.us
-- 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', 'reviewed', 'ignored')),
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),
@@ -473,9 +472,10 @@ CREATE TABLE IF NOT EXISTS public.recipes (
protein_grams NUMERIC,
fat_grams NUMERIC,
carb_grams NUMERIC,
avg_rating NUMERIC(2,1) DEFAULT 0.0,
status TEXT DEFAULT 'private' NOT NULL CHECK (status IN ('private', 'pending_review', 'public')),
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,
created_at TIMESTAMPTZ DEFAULT now() NOT NULL,
updated_at TIMESTAMPTZ DEFAULT now() NOT NULL
);
@@ -898,6 +898,42 @@ COMMENT ON COLUMN public.user_reactions.reaction_type IS 'The type of reaction (
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);
-- 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,
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
);
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);
-- 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,
created_at TIMESTAMPTZ DEFAULT now() NOT NULL
);
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);
-- ============================================================================
@@ -1107,6 +1143,16 @@ INSERT INTO public.dietary_restrictions (name, type) VALUES
('Tree Nuts', 'allergy'), ('Peanuts', 'allergy'), ('Soy', 'allergy'), ('Wheat', 'allergy')
ON CONFLICT (name) DO NOTHING;
-- Pre-populate the achievements table.
INSERT INTO public.achievements (name, description, icon, points_value) VALUES
('First Recipe', 'Create your very first recipe.', 'chef-hat', 10),
('Recipe Sharer', 'Share a recipe with another user for the first time.', 'share-2', 15),
('List Sharer', 'Share a shopping list with another user for the first time.', 'list', 20),
('First Favorite', 'Mark a recipe as one of your favorites.', 'heart', 5),
('First Fork', 'Make a personal copy of a public recipe.', 'git-fork', 10),
('First Budget Created', 'Create your first budget to track spending.', 'piggy-bank', 15)
ON CONFLICT (name) DO NOTHING;
-- ============================================================================
-- PART 3: DATABASE FUNCTIONS
-- ============================================================================
@@ -1730,9 +1776,9 @@ CREATE OR REPLACE FUNCTION public.get_activity_log(p_limit INTEGER DEFAULT 20, p
RETURNS TABLE (
activity_log_id BIGINT,
user_id UUID,
action TEXT, -- Changed from activity_type
display_text TEXT, -- Added
icon TEXT, -- Added
action TEXT,
display_text TEXT,
icon TEXT,
details JSONB,
created_at TIMESTAMPTZ,
user_full_name TEXT, -- Added
@@ -1843,7 +1889,7 @@ AS $$
)
-- Final Selection: Get activities from the log where the user_id is in the followed list.
SELECT
al.activity_log_id, al.user_id, al.action, al.display_text, al.icon, al.details, al.created_at,
al.activity_log_id, al.user_id, al.action, al.display_text, al.icon, al.details, al.created_at, al.display_text, al.icon,
p.full_name, p.avatar_url
FROM public.activity_log al
JOIN public.profiles p ON al.user_id = p.user_id
@@ -2011,6 +2057,42 @@ BEGIN
END;
$$;
-- Function to award an achievement to a user if they don't already have it.
DROP FUNCTION IF EXISTS public.award_achievement(UUID, TEXT);
CREATE OR REPLACE FUNCTION public.award_achievement(p_user_id UUID, p_achievement_name TEXT)
RETURNS void
LANGUAGE plpgsql
SECURITY DEFINER -- Allows updating points on the profile table.
AS $$
DECLARE
v_achievement_id BIGINT;
v_points_value INTEGER;
BEGIN
-- Find the achievement by name to get its ID and point value.
SELECT achievement_id, points_value INTO v_achievement_id, v_points_value
FROM public.achievements WHERE name = p_achievement_name;
-- If the achievement doesn't exist, do nothing.
IF v_achievement_id IS NULL THEN
RETURN;
END IF;
-- Insert the achievement for the user.
-- ON CONFLICT DO NOTHING ensures that if the user already has the achievement,
-- we don't try to insert it again, and the rest of the function is skipped.
INSERT INTO public.user_achievements (user_id, achievement_id)
VALUES (p_user_id, v_achievement_id)
ON CONFLICT (user_id, achievement_id) DO NOTHING;
-- If the insert was successful (i.e., the user didn't have the achievement),
-- update their total points. The `GET DIAGNOSTICS` command checks the row count of the last query.
IF FOUND THEN
UPDATE public.profiles SET points = points + v_points_value WHERE user_id = p_user_id;
END IF;
END;
$$;
/**
* Creates a personal, editable copy (a "fork") of a public recipe for a user.
* @param p_user_id The ID of the user forking the recipe.
@@ -2060,15 +2142,19 @@ BEGIN
-- Log the new user event
INSERT INTO public.activity_log (user_id, action, display_text, icon, details)
VALUES (new.user_id, 'user_registered',
COALESCE(user_meta_data->>'full_name', new.email) || ' has registered.',
'user-plus',
VALUES (new.user_id, 'user_registered',
COALESCE(user_meta_data->>'full_name', new.email) || ' has registered.',
'user-plus',
jsonb_build_object('email', new.email)
);
RETURN new;
END;
$$ LANGUAGE plpgsql;
-- ============================================================================
-- PART 4: TRIGGERS
-- ============================================================================
-- This trigger calls the function after a new user is created.
DROP TRIGGER IF EXISTS on_auth_user_created ON public.users;
CREATE TRIGGER on_auth_user_created
@@ -2278,8 +2364,12 @@ BEGIN
'recipe_created',
(SELECT full_name FROM public.profiles WHERE user_id = NEW.user_id) || ' created a new recipe: ' || NEW.name,
'chef-hat',
jsonb_build_object('recipe_name', NEW.name)
jsonb_build_object('recipe_id', NEW.recipe_id, 'recipe_name', NEW.name)
);
-- Award 'First Recipe' achievement if it's their first one.
PERFORM public.award_achievement(NEW.user_id, 'First Recipe');
RETURN NEW;
END;
$$ LANGUAGE plpgsql;
@@ -2335,10 +2425,14 @@ BEGIN
'recipe_id', NEW.recipe_id
)
);
-- Award 'First Favorite' achievement.
PERFORM public.award_achievement(NEW.user_id, 'First Favorite');
RETURN NEW;
END;
$$ LANGUAGE plpgsql;
-- 8. Trigger to log when a user favorites a recipe.
-- 9. Trigger function to log when a user shares a shopping list.
DROP FUNCTION IF EXISTS public.log_new_list_share();
@@ -2356,18 +2450,45 @@ BEGIN
'shared_with_user_id', NEW.shared_with_user_id
)
);
-- Award 'List Sharer' achievement.
PERFORM public.award_achievement(NEW.shared_by_user_id, 'List Sharer');
RETURN NEW;
END;
$$ LANGUAGE plpgsql;
-- 9a. Trigger function to log when a user shares a recipe collection.
DROP FUNCTION IF EXISTS public.log_new_recipe_collection_share();
CREATE OR REPLACE FUNCTION public.log_new_recipe_collection_share()
RETURNS TRIGGER AS $$
BEGIN
-- Log the activity
INSERT INTO public.activity_log (user_id, action, display_text, icon, details)
VALUES (
NEW.shared_by_user_id, 'recipe_collection_shared',
(SELECT full_name FROM public.profiles WHERE user_id = NEW.shared_by_user_id) || ' shared a recipe collection.',
'book',
jsonb_build_object('collection_id', NEW.recipe_collection_id, 'shared_with_user_id', NEW.shared_with_user_id)
);
-- Award 'Recipe Sharer' achievement.
PERFORM public.award_achievement(NEW.shared_by_user_id, 'Recipe Sharer');
RETURN NEW;
END;
$$ LANGUAGE plpgsql;
-- 8. Trigger to log when a user favorites a recipe.
DROP TRIGGER IF EXISTS on_new_favorite_recipe ON public.favorite_recipes;
CREATE TRIGGER on_new_favorite_recipe
AFTER INSERT ON public.favorite_recipes
FOR EACH ROW EXECUTE FUNCTION public.log_new_favorite_recipe();
-- 9. Trigger to log when a user shares a shopping list.
DROP TRIGGER IF EXISTS on_new_list_share ON public.shared_shopping_lists;
CREATE TRIGGER on_new_list_share
AFTER INSERT ON public.shared_shopping_lists
FOR EACH ROW EXECUTE FUNCTION public.log_new_list_share();
DROP TRIGGER IF EXISTS on_new_recipe_collection_share ON public.shared_recipe_collections;
CREATE TRIGGER on_new_recipe_collection_share
AFTER INSERT ON public.shared_recipe_collections
FOR EACH ROW EXECUTE FUNCTION public.log_new_recipe_collection_share();