sql fixes

This commit is contained in:
2026-01-02 17:55:22 -08:00
parent 2e01ad5bc9
commit 6e6fe80c7f
6 changed files with 559 additions and 528 deletions

View File

@@ -20,6 +20,9 @@ Create a new test file for `StatCard.tsx` to verify its props and rendering.
while assuming that master_schema_rollup.sql is the "ultimate source of truth", issues can happen and it may not have been properly
updated - look for differences between these files
UPC SCANNING ! UPC SCANNING !

View File

@@ -1,477 +1,8 @@
-- sql/Initial_triggers_and_functions.sql -- sql/Initial_triggers_and_functions.sql
-- This file contains all trigger functions and trigger definitions for the database. -- This file contains all trigger functions and trigger definitions for the database.
-- 1. Set up the trigger to automatically create a profile when a new user signs up.
-- This function is called by a trigger on the `public.users` table.
DROP FUNCTION IF EXISTS public.handle_new_user();
-- It creates a corresponding profile and a default shopping list for the new user.
-- It now accepts full_name and avatar_url from the user's metadata.
CREATE OR REPLACE FUNCTION public.handle_new_user()
RETURNS TRIGGER AS $$
DECLARE
new_profile_id UUID;
user_meta_data JSONB;
BEGIN
-- The user's metadata (full_name, avatar_url) is passed via a temporary session variable.
user_meta_data := current_setting('my_app.user_metadata', true)::JSONB;
INSERT INTO public.profiles (user_id, role, full_name, avatar_url)
VALUES (new.user_id, 'user', user_meta_data->>'full_name', user_meta_data->>'avatar_url')
RETURNING user_id INTO new_profile_id;
-- Also create a default shopping list for the new user.
INSERT INTO public.shopping_lists (user_id, name)
VALUES (new.user_id, 'Main Shopping List');
-- 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',
jsonb_build_object('email', new.email)
);
RETURN new;
END;
$$ LANGUAGE plpgsql;
-- 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
AFTER INSERT ON public.users
FOR EACH ROW EXECUTE FUNCTION public.handle_new_user();
-- 2. Create a reusable function to automatically update 'updated_at' columns.
DROP FUNCTION IF EXISTS public.handle_updated_at();
CREATE OR REPLACE FUNCTION public.handle_updated_at()
RETURNS TRIGGER AS $$
BEGIN
NEW.updated_at = now();
RETURN NEW;
END;
$$ LANGUAGE plpgsql;
-- Dynamically apply the 'handle_updated_at' trigger to all tables in the public schema
-- that have an 'updated_at' column. This is more maintainable than creating a separate
-- trigger for each table.
DO $$
DECLARE
t_name TEXT;
BEGIN
FOR t_name IN
SELECT table_name
FROM information_schema.columns
WHERE table_schema = 'public' AND column_name = 'updated_at'
LOOP
EXECUTE format('DROP TRIGGER IF EXISTS on_%s_updated ON public.%I;
CREATE TRIGGER on_%s_updated
BEFORE UPDATE ON public.%I
FOR EACH ROW EXECUTE FUNCTION public.handle_updated_at();',
t_name, t_name, t_name, t_name);
END LOOP;
END;
$$;
-- 3. Create a trigger function to populate the item_price_history table on insert.
DROP FUNCTION IF EXISTS public.update_price_history_on_flyer_item_insert();
CREATE OR REPLACE FUNCTION public.update_price_history_on_flyer_item_insert()
RETURNS TRIGGER AS $$
DECLARE
flyer_valid_from DATE;
flyer_valid_to DATE;
current_summary_date DATE;
flyer_location_id BIGINT;
BEGIN
-- If the item could not be matched, add it to the unmatched queue for review.
IF NEW.master_item_id IS NULL THEN
INSERT INTO public.unmatched_flyer_items (flyer_item_id)
VALUES (NEW.flyer_item_id)
ON CONFLICT (flyer_item_id) DO NOTHING;
END IF;
-- Only run if the new flyer item is linked to a master item and has a price.
IF NEW.master_item_id IS NULL OR NEW.price_in_cents IS NULL THEN
RETURN NEW;
END IF;
-- Get the validity dates of the flyer and the store_id.
SELECT valid_from, valid_to INTO flyer_valid_from, flyer_valid_to
FROM public.flyers
WHERE flyer_id = NEW.flyer_id;
-- This single, set-based query is much more performant than looping.
-- It generates all date/location pairs and inserts/updates them in one operation.
INSERT INTO public.item_price_history (master_item_id, summary_date, store_location_id, min_price_in_cents, max_price_in_cents, avg_price_in_cents, data_points_count)
SELECT
NEW.master_item_id,
d.day,
fl.store_location_id,
NEW.price_in_cents,
NEW.price_in_cents,
NEW.price_in_cents,
1
FROM public.flyer_locations fl
CROSS JOIN generate_series(flyer_valid_from, flyer_valid_to, '1 day'::interval) AS d(day)
WHERE fl.flyer_id = NEW.flyer_id
ON CONFLICT (master_item_id, summary_date, store_location_id)
DO UPDATE SET
min_price_in_cents = LEAST(item_price_history.min_price_in_cents, EXCLUDED.min_price_in_cents),
max_price_in_cents = GREATEST(item_price_history.max_price_in_cents, EXCLUDED.max_price_in_cents),
avg_price_in_cents = ROUND(((item_price_history.avg_price_in_cents * item_price_history.data_points_count) + EXCLUDED.avg_price_in_cents) / (item_price_history.data_points_count + 1.0)),
data_points_count = item_price_history.data_points_count + 1;
RETURN NEW;
END;
$$ LANGUAGE plpgsql;
-- Create the trigger on the flyer_items table for insert.
DROP TRIGGER IF EXISTS trigger_update_price_history ON public.flyer_items;
CREATE TRIGGER trigger_update_price_history
AFTER INSERT ON public.flyer_items
FOR EACH ROW EXECUTE FUNCTION public.update_price_history_on_flyer_item_insert();
-- 4. Create a trigger function to recalculate price history when a flyer item is deleted.
DROP FUNCTION IF EXISTS public.recalculate_price_history_on_flyer_item_delete();
CREATE OR REPLACE FUNCTION public.recalculate_price_history_on_flyer_item_delete()
RETURNS TRIGGER AS $$
DECLARE
affected_dates RECORD;
BEGIN
-- Only run if the deleted item was linked to a master item and had a price.
IF OLD.master_item_id IS NULL OR OLD.price_in_cents IS NULL THEN
RETURN OLD;
END IF;
-- This single, set-based query is much more performant than looping.
-- It recalculates aggregates for all affected dates and locations at once.
WITH affected_days_and_locations AS (
-- 1. Get all date/location pairs affected by the deleted item's flyer.
SELECT DISTINCT
generate_series(f.valid_from, f.valid_to, '1 day'::interval)::date AS summary_date,
fl.store_location_id
FROM public.flyers f
JOIN public.flyer_locations fl ON f.flyer_id = fl.flyer_id
WHERE f.flyer_id = OLD.flyer_id
),
new_aggregates AS (
-- 2. For each affected date/location, recalculate the aggregates from all other relevant flyer items.
SELECT
adl.summary_date,
adl.store_location_id,
MIN(fi.price_in_cents) AS min_price,
MAX(fi.price_in_cents) AS max_price,
ROUND(AVG(fi.price_in_cents))::int AS avg_price,
COUNT(fi.flyer_item_id)::int AS data_points
FROM affected_days_and_locations adl
LEFT JOIN public.flyer_items fi ON fi.master_item_id = OLD.master_item_id AND fi.price_in_cents IS NOT NULL
LEFT JOIN public.flyers f ON fi.flyer_id = f.flyer_id AND adl.summary_date BETWEEN f.valid_from AND f.valid_to
LEFT JOIN public.flyer_locations fl ON fi.flyer_id = fl.flyer_id AND adl.store_location_id = fl.store_location_id
WHERE fl.flyer_id IS NOT NULL -- Ensure the join was successful
GROUP BY adl.summary_date, adl.store_location_id
)
-- 3. Update the history table with the new aggregates.
UPDATE public.item_price_history iph
SET
min_price_in_cents = na.min_price,
max_price_in_cents = na.max_price,
avg_price_in_cents = na.avg_price,
data_points_count = na.data_points
FROM new_aggregates na
WHERE iph.master_item_id = OLD.master_item_id
AND iph.summary_date = na.summary_date
AND iph.store_location_id = na.store_location_id;
-- 4. Delete any history records that no longer have any data points.
DELETE FROM public.item_price_history iph
WHERE iph.master_item_id = OLD.master_item_id
AND NOT EXISTS (
SELECT 1 FROM new_aggregates na
WHERE na.summary_date = iph.summary_date AND na.store_location_id = iph.store_location_id
);
RETURN OLD;
END;
$$ LANGUAGE plpgsql;
-- Create the trigger on the flyer_items table for DELETE operations.
DROP TRIGGER IF EXISTS trigger_recalculate_price_history_on_delete ON public.flyer_items;
CREATE TRIGGER trigger_recalculate_price_history_on_delete
AFTER DELETE ON public.flyer_items
FOR EACH ROW EXECUTE FUNCTION public.recalculate_price_history_on_flyer_item_delete();
-- 5. Trigger function to update the average rating on the recipes table.
DROP FUNCTION IF EXISTS public.update_recipe_rating_aggregates();
CREATE OR REPLACE FUNCTION public.update_recipe_rating_aggregates()
RETURNS TRIGGER AS $$
BEGIN
UPDATE public.recipes
SET
avg_rating = (
SELECT AVG(rating)
FROM public.recipe_ratings
WHERE recipe_id = COALESCE(NEW.recipe_id, OLD.recipe_id) -- This is correct, no change needed
),
rating_count = (
SELECT COUNT(*)
FROM public.recipe_ratings
WHERE recipe_id = COALESCE(NEW.recipe_id, OLD.recipe_id) -- This is correct, no change needed
)
WHERE recipe_id = COALESCE(NEW.recipe_id, OLD.recipe_id);
RETURN NULL; -- The result is ignored since this is an AFTER trigger.
END;
$$ LANGUAGE plpgsql;
-- Trigger to call the function after any change to recipe_ratings.
DROP TRIGGER IF EXISTS on_recipe_rating_change ON public.recipe_ratings;
CREATE TRIGGER on_recipe_rating_change
AFTER INSERT OR UPDATE OR DELETE ON public.recipe_ratings
FOR EACH ROW EXECUTE FUNCTION public.update_recipe_rating_aggregates();
-- 6. Trigger function to log the creation of a new recipe.
DROP FUNCTION IF EXISTS public.log_new_recipe();
CREATE OR REPLACE FUNCTION public.log_new_recipe()
RETURNS TRIGGER AS $$
BEGIN
INSERT INTO public.activity_log (user_id, action, display_text, icon, details)
VALUES (
NEW.user_id,
'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_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;
-- Trigger to call the function after a new recipe is inserted.
DROP TRIGGER IF EXISTS on_new_recipe_created ON public.recipes;
CREATE TRIGGER on_new_recipe_created
AFTER INSERT ON public.recipes
FOR EACH ROW
WHEN (NEW.user_id IS NOT NULL) -- Only log activity for user-created recipes.
EXECUTE FUNCTION public.log_new_recipe();
-- 7a. Trigger function to update the item_count on the flyers table.
DROP FUNCTION IF EXISTS public.update_flyer_item_count();
CREATE OR REPLACE FUNCTION public.update_flyer_item_count()
RETURNS TRIGGER AS $$
BEGIN
IF (TG_OP = 'INSERT') THEN
UPDATE public.flyers SET item_count = item_count + 1 WHERE flyer_id = NEW.flyer_id;
ELSIF (TG_OP = 'DELETE') THEN
UPDATE public.flyers SET item_count = item_count - 1 WHERE flyer_id = OLD.flyer_id;
END IF;
RETURN NULL; -- The result is ignored since this is an AFTER trigger.
END;
$$ LANGUAGE plpgsql;
-- Trigger to call the function after any change to flyer_items.
-- This ensures the item_count on the parent flyer is always accurate.
DROP TRIGGER IF EXISTS on_flyer_item_change ON public.flyer_items;
CREATE TRIGGER on_flyer_item_change
AFTER INSERT OR DELETE ON public.flyer_items
FOR EACH ROW EXECUTE FUNCTION public.update_flyer_item_count();
-- 7. Trigger function to log the creation of a new flyer.
DROP FUNCTION IF EXISTS public.log_new_flyer();
CREATE OR REPLACE FUNCTION public.log_new_flyer()
RETURNS TRIGGER AS $$
BEGIN
INSERT INTO public.activity_log (action, display_text, icon, details)
VALUES (
'flyer_uploaded',
'A new flyer for ' || (SELECT name FROM public.stores WHERE store_id = NEW.store_id) || ' has been uploaded.',
'file-text',
jsonb_build_object(
'flyer_id', NEW.flyer_id,
'store_name', (SELECT name FROM public.stores WHERE store_id = NEW.store_id),
'valid_from', to_char(NEW.valid_from, 'YYYY-MM-DD'),
'valid_to', to_char(NEW.valid_to, 'YYYY-MM-DD')
)
);
RETURN NEW;
END;
$$ LANGUAGE plpgsql;
-- Trigger to call the function after a new flyer is inserted.
DROP TRIGGER IF EXISTS on_new_flyer_created ON public.flyers;
CREATE TRIGGER on_new_flyer_created
AFTER INSERT ON public.flyers
FOR EACH ROW EXECUTE FUNCTION public.log_new_flyer();
-- 8. Trigger function to log when a user favorites a recipe.
DROP FUNCTION IF EXISTS public.log_new_favorite_recipe();
CREATE OR REPLACE FUNCTION public.log_new_favorite_recipe()
RETURNS TRIGGER AS $$
BEGIN
INSERT INTO public.activity_log (user_id, action, display_text, icon, details)
VALUES (
NEW.user_id,
'recipe_favorited',
(SELECT full_name FROM public.profiles WHERE user_id = NEW.user_id) || ' favorited the recipe: ' || (SELECT name FROM public.recipes WHERE recipe_id = NEW.recipe_id),
'heart',
jsonb_build_object(
'recipe_id', NEW.recipe_id
)
);
-- Award 'First Favorite' achievement.
PERFORM public.award_achievement(NEW.user_id, 'First Favorite');
RETURN NEW;
END;
$$ LANGUAGE plpgsql;
-- Trigger to call the function after a recipe is favorited.
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 function to log when a user shares a shopping list.
DROP FUNCTION IF EXISTS public.log_new_list_share();
CREATE OR REPLACE FUNCTION public.log_new_list_share()
RETURNS TRIGGER AS $$
BEGIN
INSERT INTO public.activity_log (user_id, action, display_text, icon, details)
VALUES (
NEW.shared_by_user_id,
'list_shared',
(SELECT full_name FROM public.profiles WHERE user_id = NEW.shared_by_user_id) || ' shared a shopping list.',
'share-2',
jsonb_build_object(
'shopping_list_id', NEW.shopping_list_id,
'list_name', (SELECT name FROM public.shopping_lists WHERE shopping_list_id = NEW.shopping_list_id),
'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;
-- Trigger to call the function after a shopping list is shared.
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();
-- 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;
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();
-- 10. Trigger function to geocode a store location's address.
-- This function is designed to be extensible. In a production environment,
-- you would replace the placeholder with a call to an external geocoding service
-- (e.g., using the `http` extension or a `plpythonu` function) to convert
-- the address into geographic coordinates.
DROP FUNCTION IF EXISTS public.geocode_store_location();
CREATE OR REPLACE FUNCTION public.geocode_store_location()
RETURNS TRIGGER AS $$
DECLARE
full_address TEXT;
BEGIN
-- Only proceed if the address has actually changed.
IF TG_OP = 'INSERT' OR (TG_OP = 'UPDATE' AND NEW.address IS DISTINCT FROM OLD.address) THEN
-- Concatenate address parts into a single string for the geocoder.
full_address := CONCAT_WS(', ', NEW.address, NEW.city, NEW.province_state, NEW.postal_code);
-- ======================================================================
-- Placeholder for Geocoding API Call
-- ======================================================================
-- In a real application, you would call a geocoding service here.
-- For example, using the `http` extension:
--
-- DECLARE
-- response http_get;
-- lat NUMERIC;
-- lon NUMERIC;
-- BEGIN
-- SELECT * INTO response FROM http_get('https://api.geocodingservice.com/geocode?address=' || url_encode(full_address));
-- lat := (response.content::jsonb)->'results'->0->'geometry'->'location'->'lat';
-- lon := (response.content::jsonb)->'results'->0->'geometry'->'location'->'lng';
-- NEW.location := ST_SetSRID(ST_MakePoint(lon, lat), 4326)::geography;
-- END;
--
-- For now, this function does nothing, but the trigger is in place.
-- If you manually provide lat/lon, you could parse them here.
-- For this example, we will assume the `location` might be set manually
-- or by a separate batch process.
-- ======================================================================
END IF;
RETURN NEW;
END;
$$ LANGUAGE plpgsql;
-- Trigger to call the geocoding function.
DROP TRIGGER IF EXISTS on_store_location_address_change ON public.store_locations;
CREATE TRIGGER on_store_location_address_change
BEFORE INSERT OR UPDATE ON public.store_locations
FOR EACH ROW EXECUTE FUNCTION public.geocode_store_location();
-- 11. Trigger function to increment the fork_count on the original recipe.
DROP FUNCTION IF EXISTS public.increment_recipe_fork_count();
CREATE OR REPLACE FUNCTION public.increment_recipe_fork_count()
RETURNS TRIGGER AS $$
BEGIN
-- Only run if the recipe is a fork (original_recipe_id is not null).
IF NEW.original_recipe_id IS NOT NULL THEN
UPDATE public.recipes SET fork_count = fork_count + 1 WHERE recipe_id = NEW.original_recipe_id;
-- Award 'First Fork' achievement.
PERFORM public.award_achievement(NEW.user_id, 'First Fork');
END IF;
RETURN NEW;
END;
$$ LANGUAGE plpgsql;
DROP TRIGGER IF EXISTS on_recipe_fork ON public.recipes;
CREATE TRIGGER on_recipe_fork
AFTER INSERT ON public.recipes
FOR EACH ROW EXECUTE FUNCTION public.increment_recipe_fork_count();
-- ============================================================================ -- ============================================================================
-- PART 6: DATABASE FUNCTIONS -- PART 3: DATABASE FUNCTIONS
-- ============================================================================ -- ============================================================================
-- Function to find the best current sale price for a user's watched items. -- Function to find the best current sale price for a user's watched items.
DROP FUNCTION IF EXISTS public.get_best_sale_prices_for_user(UUID); DROP FUNCTION IF EXISTS public.get_best_sale_prices_for_user(UUID);
@@ -1336,8 +867,7 @@ AS $$
'list_shared' 'list_shared'
-- 'new_recipe_rating' could be added here later -- 'new_recipe_rating' could be added here later
) )
ORDER BY ORDER BY al.created_at DESC, al.display_text, al.icon
al.created_at DESC
LIMIT p_limit LIMIT p_limit
OFFSET p_offset; OFFSET p_offset;
$$; $$;
@@ -1554,11 +1084,11 @@ RETURNS TABLE(
user_id uuid, user_id uuid,
email text, email text,
full_name text, full_name text,
master_item_id integer, master_item_id bigint,
item_name text, item_name text,
best_price_in_cents integer, best_price_in_cents integer,
store_name text, store_name text,
flyer_id integer, flyer_id bigint,
valid_to date valid_to date
) AS $$ ) AS $$
BEGIN BEGIN
@@ -1569,11 +1099,12 @@ BEGIN
SELECT SELECT
fi.master_item_id, fi.master_item_id,
fi.price_in_cents, fi.price_in_cents,
f.store_name, s.name as store_name,
f.flyer_id, f.flyer_id,
f.valid_to f.valid_to
FROM public.flyer_items fi FROM public.flyer_items fi
JOIN public.flyers f ON fi.flyer_id = f.flyer_id JOIN public.flyers f ON fi.flyer_id = f.flyer_id
JOIN public.stores s ON f.store_id = s.store_id
WHERE WHERE
fi.master_item_id IS NOT NULL fi.master_item_id IS NOT NULL
AND fi.price_in_cents IS NOT NULL AND fi.price_in_cents IS NOT NULL
@@ -1616,3 +1147,472 @@ BEGIN
bp.price_rank = 1; bp.price_rank = 1;
END; END;
$$ LANGUAGE plpgsql; $$ LANGUAGE plpgsql;
-- ============================================================================
-- PART 4: TRIGGERS
-- ============================================================================
-- 1. Trigger to automatically create a profile when a new user signs up.
-- This function is called by a trigger on the `public.users` table.
DROP FUNCTION IF EXISTS public.handle_new_user();
-- It creates a corresponding profile and a default shopping list for the new user.
-- It now accepts full_name and avatar_url from the user's metadata.
CREATE OR REPLACE FUNCTION public.handle_new_user()
RETURNS TRIGGER AS $$
DECLARE
new_profile_id UUID;
user_meta_data JSONB;
BEGIN
-- The user's metadata (full_name, avatar_url) is passed via a temporary session variable.
user_meta_data := current_setting('my_app.user_metadata', true)::JSONB;
INSERT INTO public.profiles (user_id, role, full_name, avatar_url)
VALUES (new.user_id, 'user', user_meta_data->>'full_name', user_meta_data->>'avatar_url')
RETURNING user_id INTO new_profile_id;
-- Also create a default shopping list for the new user.
INSERT INTO public.shopping_lists (user_id, name)
VALUES (new.user_id, 'Main Shopping List');
-- 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',
jsonb_build_object('email', new.email)
);
RETURN new;
END;
$$ LANGUAGE plpgsql;
-- 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
AFTER INSERT ON public.users
FOR EACH ROW EXECUTE FUNCTION public.handle_new_user();
-- 2. Create a reusable function to automatically update 'updated_at' columns.
DROP FUNCTION IF EXISTS public.handle_updated_at();
CREATE OR REPLACE FUNCTION public.handle_updated_at()
RETURNS TRIGGER AS $$
BEGIN
NEW.updated_at = now();
RETURN NEW;
END;
$$ LANGUAGE plpgsql;
-- Dynamically apply the 'handle_updated_at' trigger to all tables in the public schema
-- that have an 'updated_at' column. This is more maintainable than creating a separate
-- trigger for each table.
DO $$
DECLARE
t_name TEXT;
BEGIN
FOR t_name IN
SELECT table_name
FROM information_schema.columns
WHERE table_schema = 'public' AND column_name = 'updated_at'
LOOP
EXECUTE format('DROP TRIGGER IF EXISTS on_%s_updated ON public.%I;
CREATE TRIGGER on_%s_updated
BEFORE UPDATE ON public.%I
FOR EACH ROW EXECUTE FUNCTION public.handle_updated_at();',
t_name, t_name, t_name, t_name);
END LOOP;
END;
$$;
-- 3. Create a trigger function to populate the item_price_history table on insert.
DROP FUNCTION IF EXISTS public.update_price_history_on_flyer_item_insert();
CREATE OR REPLACE FUNCTION public.update_price_history_on_flyer_item_insert()
RETURNS TRIGGER AS $$
DECLARE
flyer_valid_from DATE;
flyer_valid_to DATE;
current_summary_date DATE;
flyer_location_id BIGINT;
BEGIN
-- If the item could not be matched, add it to the unmatched queue for review.
IF NEW.master_item_id IS NULL THEN
INSERT INTO public.unmatched_flyer_items (flyer_item_id)
VALUES (NEW.flyer_item_id)
ON CONFLICT (flyer_item_id) DO NOTHING;
END IF;
-- Only run if the new flyer item is linked to a master item and has a price.
IF NEW.master_item_id IS NULL OR NEW.price_in_cents IS NULL THEN
RETURN NEW;
END IF;
-- Get the validity dates of the flyer and the store_id.
SELECT valid_from, valid_to INTO flyer_valid_from, flyer_valid_to
FROM public.flyers
WHERE flyer_id = NEW.flyer_id;
-- This single, set-based query is much more performant than looping.
-- It generates all date/location pairs and inserts/updates them in one operation.
INSERT INTO public.item_price_history (master_item_id, summary_date, store_location_id, min_price_in_cents, max_price_in_cents, avg_price_in_cents, data_points_count)
SELECT
NEW.master_item_id,
d.day,
fl.store_location_id,
NEW.price_in_cents,
NEW.price_in_cents,
NEW.price_in_cents,
1
FROM public.flyer_locations fl
CROSS JOIN generate_series(flyer_valid_from, flyer_valid_to, '1 day'::interval) AS d(day)
WHERE fl.flyer_id = NEW.flyer_id
ON CONFLICT (master_item_id, summary_date, store_location_id)
DO UPDATE SET
min_price_in_cents = LEAST(item_price_history.min_price_in_cents, EXCLUDED.min_price_in_cents),
max_price_in_cents = GREATEST(item_price_history.max_price_in_cents, EXCLUDED.max_price_in_cents),
avg_price_in_cents = ROUND(((item_price_history.avg_price_in_cents * item_price_history.data_points_count) + EXCLUDED.avg_price_in_cents) / (item_price_history.data_points_count + 1.0)),
data_points_count = item_price_history.data_points_count + 1;
RETURN NEW;
END;
$$ LANGUAGE plpgsql;
-- Create the trigger on the flyer_items table for insert.
DROP TRIGGER IF EXISTS trigger_update_price_history ON public.flyer_items;
CREATE TRIGGER trigger_update_price_history
AFTER INSERT ON public.flyer_items
FOR EACH ROW EXECUTE FUNCTION public.update_price_history_on_flyer_item_insert();
-- 4. Create a trigger function to recalculate price history when a flyer item is deleted.
DROP FUNCTION IF EXISTS public.recalculate_price_history_on_flyer_item_delete();
CREATE OR REPLACE FUNCTION public.recalculate_price_history_on_flyer_item_delete()
RETURNS TRIGGER AS $$
DECLARE
affected_dates RECORD;
BEGIN
-- Only run if the deleted item was linked to a master item and had a price.
IF OLD.master_item_id IS NULL OR OLD.price_in_cents IS NULL THEN
RETURN OLD;
END IF;
-- This single, set-based query is much more performant than looping.
-- It recalculates aggregates for all affected dates and locations at once.
WITH affected_days_and_locations AS (
-- 1. Get all date/location pairs affected by the deleted item's flyer.
SELECT DISTINCT
generate_series(f.valid_from, f.valid_to, '1 day'::interval)::date AS summary_date,
fl.store_location_id
FROM public.flyers f
JOIN public.flyer_locations fl ON f.flyer_id = fl.flyer_id
WHERE f.flyer_id = OLD.flyer_id
),
new_aggregates AS (
-- 2. For each affected date/location, recalculate the aggregates from all other relevant flyer items.
SELECT
adl.summary_date,
adl.store_location_id,
MIN(fi.price_in_cents) AS min_price,
MAX(fi.price_in_cents) AS max_price,
ROUND(AVG(fi.price_in_cents))::int AS avg_price,
COUNT(fi.flyer_item_id)::int AS data_points
FROM affected_days_and_locations adl
LEFT JOIN public.flyer_items fi ON fi.master_item_id = OLD.master_item_id AND fi.price_in_cents IS NOT NULL
LEFT JOIN public.flyers f ON fi.flyer_id = f.flyer_id AND adl.summary_date BETWEEN f.valid_from AND f.valid_to
LEFT JOIN public.flyer_locations fl ON fi.flyer_id = fl.flyer_id AND adl.store_location_id = fl.store_location_id
WHERE fl.flyer_id IS NOT NULL -- Ensure the join was successful
GROUP BY adl.summary_date, adl.store_location_id
)
-- 3. Update the history table with the new aggregates.
UPDATE public.item_price_history iph
SET
min_price_in_cents = na.min_price,
max_price_in_cents = na.max_price,
avg_price_in_cents = na.avg_price,
data_points_count = na.data_points
FROM new_aggregates na
WHERE iph.master_item_id = OLD.master_item_id
AND iph.summary_date = na.summary_date
AND iph.store_location_id = na.store_location_id;
-- 4. Delete any history records that no longer have any data points.
DELETE FROM public.item_price_history iph
WHERE iph.master_item_id = OLD.master_item_id
AND NOT EXISTS (
SELECT 1 FROM new_aggregates na
WHERE na.summary_date = iph.summary_date AND na.store_location_id = iph.store_location_id
);
RETURN OLD;
END;
$$ LANGUAGE plpgsql;
-- Create the trigger on the flyer_items table for DELETE operations.
DROP TRIGGER IF EXISTS trigger_recalculate_price_history_on_delete ON public.flyer_items;
CREATE TRIGGER trigger_recalculate_price_history_on_delete
AFTER DELETE ON public.flyer_items
FOR EACH ROW EXECUTE FUNCTION public.recalculate_price_history_on_flyer_item_delete();
-- 5. Trigger function to update the average rating on the recipes table.
DROP FUNCTION IF EXISTS public.update_recipe_rating_aggregates();
CREATE OR REPLACE FUNCTION public.update_recipe_rating_aggregates()
RETURNS TRIGGER AS $$
BEGIN
UPDATE public.recipes
SET
avg_rating = (
SELECT AVG(rating)
FROM public.recipe_ratings
WHERE recipe_id = COALESCE(NEW.recipe_id, OLD.recipe_id) -- This is correct, no change needed
),
rating_count = (
SELECT COUNT(*)
FROM public.recipe_ratings
WHERE recipe_id = COALESCE(NEW.recipe_id, OLD.recipe_id) -- This is correct, no change needed
)
WHERE recipe_id = COALESCE(NEW.recipe_id, OLD.recipe_id);
RETURN NULL; -- The result is ignored since this is an AFTER trigger.
END;
$$ LANGUAGE plpgsql;
-- Trigger to call the function after any change to recipe_ratings.
DROP TRIGGER IF EXISTS on_recipe_rating_change ON public.recipe_ratings;
CREATE TRIGGER on_recipe_rating_change
AFTER INSERT OR UPDATE OR DELETE ON public.recipe_ratings
FOR EACH ROW EXECUTE FUNCTION public.update_recipe_rating_aggregates();
-- 6. Trigger function to log the creation of a new recipe.
DROP FUNCTION IF EXISTS public.log_new_recipe();
CREATE OR REPLACE FUNCTION public.log_new_recipe()
RETURNS TRIGGER AS $$
BEGIN
INSERT INTO public.activity_log (user_id, action, display_text, icon, details)
VALUES (
NEW.user_id,
'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_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;
-- Trigger to call the function after a new recipe is inserted.
DROP TRIGGER IF EXISTS on_new_recipe_created ON public.recipes;
CREATE TRIGGER on_new_recipe_created
AFTER INSERT ON public.recipes
FOR EACH ROW
WHEN (NEW.user_id IS NOT NULL) -- Only log activity for user-created recipes.
EXECUTE FUNCTION public.log_new_recipe();
-- 7a. Trigger function to update the item_count on the flyers table.
DROP FUNCTION IF EXISTS public.update_flyer_item_count();
CREATE OR REPLACE FUNCTION public.update_flyer_item_count()
RETURNS TRIGGER AS $$
BEGIN
IF (TG_OP = 'INSERT') THEN
UPDATE public.flyers SET item_count = item_count + 1 WHERE flyer_id = NEW.flyer_id;
ELSIF (TG_OP = 'DELETE') THEN
UPDATE public.flyers SET item_count = item_count - 1 WHERE flyer_id = OLD.flyer_id;
END IF;
RETURN NULL; -- The result is ignored since this is an AFTER trigger.
END;
$$ LANGUAGE plpgsql;
-- Trigger to call the function after any change to flyer_items.
-- This ensures the item_count on the parent flyer is always accurate.
DROP TRIGGER IF EXISTS on_flyer_item_change ON public.flyer_items;
CREATE TRIGGER on_flyer_item_change
AFTER INSERT OR DELETE ON public.flyer_items
FOR EACH ROW EXECUTE FUNCTION public.update_flyer_item_count();
-- 7. Trigger function to log the creation of a new flyer.
DROP FUNCTION IF EXISTS public.log_new_flyer();
CREATE OR REPLACE FUNCTION public.log_new_flyer()
RETURNS TRIGGER AS $$
BEGIN
-- If the flyer was uploaded by a registered user, award the 'First-Upload' achievement.
-- The award_achievement function handles checking if the user already has it.
IF NEW.uploaded_by IS NOT NULL THEN
PERFORM public.award_achievement(NEW.uploaded_by, 'First-Upload');
END IF;
INSERT INTO public.activity_log (user_id, action, display_text, icon, details)
VALUES (
NEW.uploaded_by, -- Log the user who uploaded it
'flyer_uploaded',
'A new flyer for ' || (SELECT name FROM public.stores WHERE store_id = NEW.store_id) || ' has been uploaded.',
'file-text',
jsonb_build_object(
'flyer_id', NEW.flyer_id,
'store_name', (SELECT name FROM public.stores WHERE store_id = NEW.store_id),
'valid_from', to_char(NEW.valid_from, 'YYYY-MM-DD'),
'valid_to', to_char(NEW.valid_to, 'YYYY-MM-DD')
)
);
RETURN NEW;
END;
$$ LANGUAGE plpgsql;
-- Trigger to call the function after a new flyer is inserted.
DROP TRIGGER IF EXISTS on_new_flyer_created ON public.flyers;
CREATE TRIGGER on_new_flyer_created
AFTER INSERT ON public.flyers
FOR EACH ROW EXECUTE FUNCTION public.log_new_flyer();
-- 8. Trigger function to log when a user favorites a recipe.
DROP FUNCTION IF EXISTS public.log_new_favorite_recipe();
CREATE OR REPLACE FUNCTION public.log_new_favorite_recipe()
RETURNS TRIGGER AS $$
BEGIN
INSERT INTO public.activity_log (user_id, action, display_text, icon, details)
VALUES (
NEW.user_id,
'recipe_favorited',
(SELECT full_name FROM public.profiles WHERE user_id = NEW.user_id) || ' favorited the recipe: ' || (SELECT name FROM public.recipes WHERE recipe_id = NEW.recipe_id),
'heart',
jsonb_build_object(
'recipe_id', NEW.recipe_id
)
);
-- Award 'First Favorite' achievement.
PERFORM public.award_achievement(NEW.user_id, 'First Favorite');
RETURN NEW;
END;
$$ LANGUAGE plpgsql;
-- Trigger to call the function after a recipe is favorited.
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 function to log when a user shares a shopping list.
DROP FUNCTION IF EXISTS public.log_new_list_share();
CREATE OR REPLACE FUNCTION public.log_new_list_share()
RETURNS TRIGGER AS $$
BEGIN
INSERT INTO public.activity_log (user_id, action, display_text, icon, details)
VALUES (
NEW.shared_by_user_id,
'list_shared',
(SELECT full_name FROM public.profiles WHERE user_id = NEW.shared_by_user_id) || ' shared a shopping list.',
'share-2',
jsonb_build_object(
'shopping_list_id', NEW.shopping_list_id,
'list_name', (SELECT name FROM public.shopping_lists WHERE shopping_list_id = NEW.shopping_list_id),
'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;
-- Trigger to call the function after a shopping list is shared.
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();
-- 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;
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();
-- 10. Trigger function to geocode a store location's address.
-- This function is triggered when an address is inserted or updated, and is
-- designed to be extensible for external geocoding services to populate the
-- latitude, longitude, and location fields.
DROP FUNCTION IF EXISTS public.geocode_address();
CREATE OR REPLACE FUNCTION public.geocode_address()
RETURNS TRIGGER AS $$
DECLARE
full_address TEXT;
BEGIN
-- Only proceed if an address component has actually changed.
IF TG_OP = 'INSERT' OR (TG_OP = 'UPDATE' AND (
NEW.address_line_1 IS DISTINCT FROM OLD.address_line_1 OR
NEW.address_line_2 IS DISTINCT FROM OLD.address_line_2 OR
NEW.city IS DISTINCT FROM OLD.city OR
NEW.province_state IS DISTINCT FROM OLD.province_state OR
NEW.postal_code IS DISTINCT FROM OLD.postal_code OR
NEW.country IS DISTINCT FROM OLD.country
)) THEN
-- Concatenate address parts into a single string for the geocoder.
full_address := CONCAT_WS(', ', NEW.address_line_1, NEW.address_line_2, NEW.city, NEW.province_state, NEW.postal_code, NEW.country);
-- Placeholder for Geocoding API Call
-- In a real application, you would call a service here and update NEW.latitude, NEW.longitude, and NEW.location.
-- e.g., NEW.latitude := result.lat; NEW.longitude := result.lon;
-- NEW.location := ST_SetSRID(ST_MakePoint(NEW.longitude, NEW.latitude), 4326);
END IF;
RETURN NEW;
END;
$$ LANGUAGE plpgsql;
-- This trigger calls the geocoding function when an address changes.
DROP TRIGGER IF EXISTS on_address_change_geocode ON public.addresses;
CREATE TRIGGER on_address_change_geocode
BEFORE INSERT OR UPDATE ON public.addresses
FOR EACH ROW EXECUTE FUNCTION public.geocode_address();
-- 11. Trigger function to increment the fork_count on the original recipe.
DROP FUNCTION IF EXISTS public.increment_recipe_fork_count();
CREATE OR REPLACE FUNCTION public.increment_recipe_fork_count()
RETURNS TRIGGER AS $$
BEGIN
-- Only run if the recipe is a fork (original_recipe_id is not null).
IF NEW.original_recipe_id IS NOT NULL THEN
UPDATE public.recipes SET fork_count = fork_count + 1 WHERE recipe_id = NEW.original_recipe_id;
-- Award 'First Fork' achievement.
PERFORM public.award_achievement(NEW.user_id, 'First Fork');
END IF;
RETURN NEW;
END;
$$ LANGUAGE plpgsql;
DROP TRIGGER IF EXISTS on_recipe_fork ON public.recipes;
CREATE TRIGGER on_recipe_fork
AFTER INSERT ON public.recipes
FOR EACH ROW EXECUTE FUNCTION public.increment_recipe_fork_count();

View File

@@ -265,5 +265,6 @@ INSERT INTO public.achievements (name, description, icon, points_value) VALUES
('List Sharer', 'Share a shopping list with another user for the first time.', 'list', 20), ('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 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 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) ('First Budget Created', 'Create your first budget to track spending.', 'piggy-bank', 15),
('First-Upload', 'Upload your first flyer.', 'upload-cloud', 25)
ON CONFLICT (name) DO NOTHING; ON CONFLICT (name) DO NOTHING;

View File

@@ -162,7 +162,6 @@ COMMENT ON COLUMN public.flyers.uploaded_by IS 'The user who uploaded the flyer.
CREATE INDEX IF NOT EXISTS idx_flyers_status ON public.flyers(status); 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_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_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. -- 7. The 'master_grocery_items' table. This is the master dictionary.
CREATE TABLE IF NOT EXISTS public.master_grocery_items ( CREATE TABLE IF NOT EXISTS public.master_grocery_items (
master_grocery_item_id BIGINT PRIMARY KEY GENERATED ALWAYS AS IDENTITY, master_grocery_item_id BIGINT PRIMARY KEY GENERATED ALWAYS AS IDENTITY,
@@ -973,6 +972,21 @@ 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_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); 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 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);
-- 57. Static table defining available achievements for gamification. -- 57. Static table defining available achievements for gamification.
CREATE TABLE IF NOT EXISTS public.achievements ( CREATE TABLE IF NOT EXISTS public.achievements (
achievement_id BIGINT PRIMARY KEY GENERATED ALWAYS AS IDENTITY, achievement_id BIGINT PRIMARY KEY GENERATED ALWAYS AS IDENTITY,
@@ -998,17 +1012,3 @@ CREATE INDEX IF NOT EXISTS idx_user_achievements_user_id ON public.user_achievem
CREATE INDEX IF NOT EXISTS idx_user_achievements_achievement_id ON public.user_achievements(achievement_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);

View File

@@ -102,11 +102,11 @@ CREATE TABLE IF NOT EXISTS public.profiles (
address_id BIGINT REFERENCES public.addresses(address_id) ON DELETE SET NULL, address_id BIGINT REFERENCES public.addresses(address_id) ON DELETE SET NULL,
points INTEGER DEFAULT 0 NOT NULL CHECK (points >= 0), points INTEGER DEFAULT 0 NOT NULL CHECK (points >= 0),
preferences JSONB, preferences JSONB,
role TEXT CHECK (role IN ('admin', 'user')), role TEXT NOT NULL CHECK (role IN ('admin', 'user')),
created_at TIMESTAMPTZ DEFAULT now() NOT NULL, created_at TIMESTAMPTZ DEFAULT now() NOT NULL,
updated_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_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://?.*'), 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, created_by UUID REFERENCES public.users(user_id) ON DELETE SET NULL,
updated_by UUID REFERENCES public.users(user_id) ON DELETE SET NULL updated_by UUID REFERENCES public.users(user_id) ON DELETE SET NULL
); );
@@ -124,7 +124,7 @@ CREATE TABLE IF NOT EXISTS public.stores (
created_at TIMESTAMPTZ DEFAULT now() NOT NULL, created_at TIMESTAMPTZ DEFAULT now() NOT NULL,
updated_at TIMESTAMPTZ DEFAULT now() NOT NULL, updated_at TIMESTAMPTZ DEFAULT now() NOT NULL,
CONSTRAINT stores_name_check CHECK (TRIM(name) <> ''), CONSTRAINT stores_name_check CHECK (TRIM(name) <> ''),
CONSTRAINT stores_logo_url_check CHECK (logo_url IS NULL OR logo_url ~* '^https://?.*'), 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 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).'; COMMENT ON TABLE public.stores IS 'Stores metadata for grocery store chains (e.g., Safeway, Kroger).';
@@ -144,7 +144,7 @@ CREATE TABLE IF NOT EXISTS public.flyers (
flyer_id BIGINT PRIMARY KEY GENERATED ALWAYS AS IDENTITY, flyer_id BIGINT PRIMARY KEY GENERATED ALWAYS AS IDENTITY,
file_name TEXT NOT NULL, file_name TEXT NOT NULL,
image_url TEXT NOT NULL, image_url TEXT NOT NULL,
icon_url TEXT, icon_url TEXT NOT NULL,
checksum TEXT UNIQUE, checksum TEXT UNIQUE,
store_id BIGINT REFERENCES public.stores(store_id) ON DELETE CASCADE, store_id BIGINT REFERENCES public.stores(store_id) ON DELETE CASCADE,
valid_from DATE, valid_from DATE,
@@ -157,8 +157,8 @@ CREATE TABLE IF NOT EXISTS public.flyers (
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_valid_dates_check CHECK (valid_to >= valid_from),
CONSTRAINT flyers_file_name_check CHECK (TRIM(file_name) <> ''), CONSTRAINT flyers_file_name_check CHECK (TRIM(file_name) <> ''),
CONSTRAINT flyers_image_url_check CHECK (image_url ~* '^https://?.*'), 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_icon_url_check CHECK (icon_url ~* '^https?://.*'),
CONSTRAINT flyers_checksum_check CHECK (checksum IS NULL OR length(checksum) = 64) 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.'; COMMENT ON TABLE public.flyers IS 'Stores metadata for each processed flyer, linking it to a store and its validity period.';
@@ -215,7 +215,7 @@ CREATE TABLE IF NOT EXISTS public.brands (
created_at TIMESTAMPTZ DEFAULT now() NOT 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_name_check CHECK (TRIM(name) <> ''),
CONSTRAINT brands_logo_url_check CHECK (logo_url IS NULL OR logo_url ~* '^https://?.*') 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 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.'; 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.';
@@ -482,7 +482,7 @@ CREATE TABLE IF NOT EXISTS public.user_submitted_prices (
downvotes INTEGER DEFAULT 0 NOT NULL CHECK (downvotes >= 0), downvotes INTEGER DEFAULT 0 NOT NULL CHECK (downvotes >= 0),
created_at TIMESTAMPTZ DEFAULT now() NOT NULL, 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://?.*') 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 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.photo_url IS 'URL to user-submitted photo evidence of the price.';
@@ -539,7 +539,7 @@ CREATE TABLE IF NOT EXISTS public.recipes (
created_at TIMESTAMPTZ DEFAULT now() NOT NULL, 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_name_check CHECK (TRIM(name) <> ''),
CONSTRAINT recipes_photo_url_check CHECK (photo_url IS NULL OR photo_url ~* '^https://?.*') 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 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.servings IS 'The number of servings this recipe yields.';
@@ -689,8 +689,8 @@ CREATE TABLE IF NOT EXISTS public.planned_meals (
meal_type TEXT NOT NULL, meal_type TEXT NOT NULL,
servings_to_cook INTEGER, servings_to_cook INTEGER,
created_at TIMESTAMPTZ DEFAULT now() NOT NULL, created_at TIMESTAMPTZ DEFAULT now() NOT NULL,
CONSTRAINT planned_meals_meal_type_check CHECK (TRIM(meal_type) <> ''), updated_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 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''.'; COMMENT ON COLUMN public.planned_meals.meal_type IS 'The designated meal for the recipe, e.g., ''Breakfast'', ''Lunch'', ''Dinner''.';
@@ -940,7 +940,7 @@ CREATE TABLE IF NOT EXISTS public.receipts (
raw_text TEXT, raw_text TEXT,
created_at TIMESTAMPTZ DEFAULT now() NOT NULL, created_at TIMESTAMPTZ DEFAULT now() NOT NULL,
processed_at TIMESTAMPTZ, processed_at TIMESTAMPTZ,
CONSTRAINT receipts_receipt_image_url_check CHECK (receipt_image_url ~* '^https://?.*'), CONSTRAINT receipts_receipt_image_url_check CHECK (receipt_image_url ~* '^https?://.*'),
updated_at TIMESTAMPTZ DEFAULT now() NOT NULL updated_at TIMESTAMPTZ DEFAULT now() NOT NULL
); );
COMMENT ON TABLE public.receipts IS 'Stores uploaded user receipts for purchase tracking and analysis.'; COMMENT ON TABLE public.receipts IS 'Stores uploaded user receipts for purchase tracking and analysis.';
@@ -1113,6 +1113,7 @@ DECLARE
ground_beef_id BIGINT; pasta_item_id BIGINT; tomatoes_id BIGINT; onions_id BIGINT; garlic_id BIGINT; ground_beef_id BIGINT; pasta_item_id BIGINT; tomatoes_id BIGINT; onions_id BIGINT; garlic_id BIGINT;
bell_peppers_id BIGINT; carrots_id BIGINT; soy_sauce_id BIGINT; bell_peppers_id BIGINT; carrots_id BIGINT; soy_sauce_id BIGINT;
soda_item_id BIGINT; turkey_item_id BIGINT; bread_item_id BIGINT; cheese_item_id BIGINT; soda_item_id BIGINT; turkey_item_id BIGINT; bread_item_id BIGINT; cheese_item_id BIGINT;
chicken_thighs_id BIGINT; paper_towels_id BIGINT; toilet_paper_id BIGINT;
-- Tag IDs -- Tag IDs
quick_easy_tag BIGINT; healthy_tag BIGINT; chicken_tag BIGINT; quick_easy_tag BIGINT; healthy_tag BIGINT; chicken_tag BIGINT;
@@ -1164,6 +1165,9 @@ BEGIN
SELECT mgi.master_grocery_item_id INTO turkey_item_id FROM public.master_grocery_items mgi WHERE mgi.name = 'turkey'; SELECT mgi.master_grocery_item_id INTO turkey_item_id FROM public.master_grocery_items mgi WHERE mgi.name = 'turkey';
SELECT mgi.master_grocery_item_id INTO bread_item_id FROM public.master_grocery_items mgi WHERE mgi.name = 'bread'; SELECT mgi.master_grocery_item_id INTO bread_item_id FROM public.master_grocery_items mgi WHERE mgi.name = 'bread';
SELECT mgi.master_grocery_item_id INTO cheese_item_id FROM public.master_grocery_items mgi WHERE mgi.name = 'cheese'; SELECT mgi.master_grocery_item_id INTO cheese_item_id FROM public.master_grocery_items mgi WHERE mgi.name = 'cheese';
SELECT mgi.master_grocery_item_id INTO chicken_thighs_id FROM public.master_grocery_items mgi WHERE mgi.name = 'chicken thighs';
SELECT mgi.master_grocery_item_id INTO paper_towels_id FROM public.master_grocery_items mgi WHERE mgi.name = 'paper towels';
SELECT mgi.master_grocery_item_id INTO toilet_paper_id FROM public.master_grocery_items mgi WHERE mgi.name = 'toilet paper';
-- Insert ingredients for each recipe -- Insert ingredients for each recipe
INSERT INTO public.recipe_ingredients (recipe_id, master_item_id, quantity, unit) VALUES INSERT INTO public.recipe_ingredients (recipe_id, master_item_id, quantity, unit) VALUES
@@ -1200,6 +1204,17 @@ BEGIN
(bolognese_recipe_id, family_tag), (bolognese_recipe_id, beef_tag), (bolognese_recipe_id, weeknight_tag), (bolognese_recipe_id, family_tag), (bolognese_recipe_id, beef_tag), (bolognese_recipe_id, weeknight_tag),
(stir_fry_recipe_id, quick_easy_tag), (stir_fry_recipe_id, healthy_tag), (stir_fry_recipe_id, vegetarian_tag) (stir_fry_recipe_id, quick_easy_tag), (stir_fry_recipe_id, healthy_tag), (stir_fry_recipe_id, vegetarian_tag)
ON CONFLICT (recipe_id, tag_id) DO NOTHING; ON CONFLICT (recipe_id, tag_id) DO NOTHING;
INSERT INTO public.master_item_aliases (master_item_id, alias) VALUES
(ground_beef_id, 'ground chuck'), (ground_beef_id, 'lean ground beef'),
(ground_beef_id, 'extra lean ground beef'), (ground_beef_id, 'hamburger meat'),
(chicken_breast_id, 'boneless skinless chicken breast'), (chicken_breast_id, 'chicken cutlets'),
(chicken_thighs_id, 'boneless skinless chicken thighs'), (chicken_thighs_id, 'bone-in chicken thighs'),
(bell_peppers_id, 'red pepper'), (bell_peppers_id, 'green pepper'), (bell_peppers_id, 'yellow pepper'), (bell_peppers_id, 'orange pepper'),
(soda_item_id, 'pop'), (soda_item_id, 'soft drink'), (soda_item_id, 'coke'), (soda_item_id, 'pepsi'),
(paper_towels_id, 'paper towel'),
(toilet_paper_id, 'bathroom tissue'), (toilet_paper_id, 'toilet tissue')
ON CONFLICT (alias) DO NOTHING;
END $$; END $$;
-- Pre-populate the unit_conversions table with common cooking conversions. -- Pre-populate the unit_conversions table with common cooking conversions.
@@ -2627,7 +2642,9 @@ BEGIN
'file-text', 'file-text',
jsonb_build_object( jsonb_build_object(
'flyer_id', NEW.flyer_id, 'flyer_id', NEW.flyer_id,
'store_name', (SELECT name FROM public.stores WHERE store_id = NEW.store_id) 'store_name', (SELECT name FROM public.stores WHERE store_id = NEW.store_id),
'valid_from', to_char(NEW.valid_from, 'YYYY-MM-DD'),
'valid_to', to_char(NEW.valid_to, 'YYYY-MM-DD')
) )
); );
RETURN NEW; RETURN NEW;
@@ -2677,6 +2694,7 @@ BEGIN
(SELECT full_name FROM public.profiles WHERE user_id = NEW.shared_by_user_id) || ' shared a shopping list.', (SELECT full_name FROM public.profiles WHERE user_id = NEW.shared_by_user_id) || ' shared a shopping list.',
'share-2', 'share-2',
jsonb_build_object( jsonb_build_object(
'shopping_list_id', NEW.shopping_list_id,
'list_name', (SELECT name FROM public.shopping_lists WHERE shopping_list_id = NEW.shopping_list_id), 'list_name', (SELECT name FROM public.shopping_lists WHERE shopping_list_id = NEW.shopping_list_id),
'shared_with_user_id', NEW.shared_with_user_id 'shared_with_user_id', NEW.shared_with_user_id
) )
@@ -2725,35 +2743,43 @@ CREATE TRIGGER on_new_recipe_collection_share
FOR EACH ROW EXECUTE FUNCTION public.log_new_recipe_collection_share(); FOR EACH ROW EXECUTE FUNCTION public.log_new_recipe_collection_share();
-- 10. Trigger function to geocode a store location's address. -- 10. Trigger function to geocode a store location's address.
-- This function is designed to be extensible for external geocoding services. -- This function is triggered when an address is inserted or updated, and is
DROP FUNCTION IF EXISTS public.geocode_store_location(); -- designed to be extensible for external geocoding services to populate the
-- latitude, longitude, and location fields.
DROP FUNCTION IF EXISTS public.geocode_address();
CREATE OR REPLACE FUNCTION public.geocode_store_location() CREATE OR REPLACE FUNCTION public.geocode_address()
RETURNS TRIGGER AS $$ RETURNS TRIGGER AS $$
DECLARE DECLARE
full_address TEXT; full_address TEXT;
BEGIN BEGIN
-- Only proceed if the address has actually changed. -- Only proceed if an address component has actually changed.
-- Note: We check against the linked address fields via the NEW.address_id in a real scenario, IF TG_OP = 'INSERT' OR (TG_OP = 'UPDATE' AND (
-- but for this trigger to work effectively, it usually requires a direct update on the address table NEW.address_line_1 IS DISTINCT FROM OLD.address_line_1 OR
-- or this trigger should be moved to the 'addresses' table. NEW.address_line_2 IS DISTINCT FROM OLD.address_line_2 OR
-- However, based on the provided logic, we are keeping the placeholder structure. NEW.city IS DISTINCT FROM OLD.city OR
NEW.province_state IS DISTINCT FROM OLD.province_state OR
-- Placeholder logic: NEW.postal_code IS DISTINCT FROM OLD.postal_code OR
IF TG_OP = 'INSERT' THEN NEW.country IS DISTINCT FROM OLD.country
-- Logic to fetch address string based on NEW.address_id and geocode )) THEN
NULL; -- Concatenate address parts into a single string for the geocoder.
full_address := CONCAT_WS(', ', NEW.address_line_1, NEW.address_line_2, NEW.city, NEW.province_state, NEW.postal_code, NEW.country);
-- Placeholder for Geocoding API Call.
-- In a real application, you would call a service here and update NEW.latitude, NEW.longitude, and NEW.location.
-- e.g., NEW.latitude := result.lat; NEW.longitude := result.lon;
-- NEW.location := ST_SetSRID(ST_MakePoint(NEW.longitude, NEW.latitude), 4326);
END IF; END IF;
RETURN NEW; RETURN NEW;
END; END;
$$ LANGUAGE plpgsql; $$ LANGUAGE plpgsql;
-- Trigger to call the geocoding function. -- This trigger calls the geocoding function when an address changes.
DROP TRIGGER IF EXISTS on_store_location_address_change ON public.store_locations; DROP TRIGGER IF EXISTS on_address_change_geocode ON public.addresses;
CREATE TRIGGER on_store_location_address_change CREATE TRIGGER on_address_change_geocode
BEFORE INSERT OR UPDATE ON public.store_locations BEFORE INSERT OR UPDATE ON public.addresses
FOR EACH ROW EXECUTE FUNCTION public.geocode_store_location(); FOR EACH ROW EXECUTE FUNCTION public.geocode_address();
-- 11. Trigger function to increment the fork_count on the original recipe. -- 11. Trigger function to increment the fork_count on the original recipe.
DROP FUNCTION IF EXISTS public.increment_recipe_fork_count(); DROP FUNCTION IF EXISTS public.increment_recipe_fork_count();
@@ -2789,11 +2815,11 @@ RETURNS TABLE(
email text, email text,
full_name text, full_name text,
master_item_id integer, master_item_id bigint,
item_name text, item_name text,
best_price_in_cents integer, best_price_in_cents integer,
store_name text, store_name text,
flyer_id integer, flyer_id bigint,
valid_to date valid_to date
) AS $$ ) AS $$
BEGIN BEGIN
@@ -2805,7 +2831,7 @@ BEGIN
SELECT SELECT
fi.master_item_id, fi.master_item_id,
fi.price_in_cents, fi.price_in_cents,
f.store_name, s.name as store_name,
f.flyer_id, f.flyer_id,
f.valid_to f.valid_to
FROM public.flyer_items fi FROM public.flyer_items fi

View File

@@ -14,7 +14,7 @@ export interface Flyer {
readonly flyer_id: number; readonly flyer_id: number;
file_name: string; file_name: string;
image_url: string; image_url: string;
icon_url?: string | null; // URL for the 64x64 icon version of the flyer icon_url: string; // URL for the 64x64 icon version of the flyer
readonly checksum?: string; readonly checksum?: string;
readonly store_id?: number; readonly store_id?: number;
valid_from?: string | null; valid_from?: string | null;
@@ -72,7 +72,7 @@ export interface FlyerItem {
item: string; item: string;
price_display: string; price_display: string;
price_in_cents?: number | null; price_in_cents?: number | null;
quantity?: string; quantity: string;
quantity_num?: number | null; quantity_num?: number | null;
master_item_id?: number; // Can be updated by admin correction master_item_id?: number; // Can be updated by admin correction
master_item_name?: string | null; master_item_name?: string | null;
@@ -151,6 +151,7 @@ export interface User {
*/ */
export interface UserWithPasswordHash extends User { export interface UserWithPasswordHash extends User {
password_hash: string | null; password_hash: string | null;
refresh_token: string | null;
readonly failed_login_attempts: number; readonly failed_login_attempts: number;
readonly last_failed_login: string | null; // TIMESTAMPTZ readonly last_failed_login: string | null; // TIMESTAMPTZ
readonly last_login_at?: string | null; // TIMESTAMPTZ readonly last_login_at?: string | null; // TIMESTAMPTZ
@@ -536,7 +537,7 @@ export type ActivityLogAction =
interface ActivityLogItemBase { interface ActivityLogItemBase {
readonly activity_log_id: number; readonly activity_log_id: number;
readonly user_id: string | null; readonly user_id: string | null;
action: string; action: ActivityLogAction;
display_text: string; display_text: string;
icon?: string | null; icon?: string | null;
readonly created_at: string; readonly created_at: string;