368 lines
14 KiB
PL/PgSQL
368 lines
14 KiB
PL/PgSQL
|
|
|
|
|
|
|
|
-- 19. Policies for the 'flyers' storage bucket
|
|
DROP POLICY IF EXISTS "Allow public access to flyers storage" ON storage.objects;
|
|
CREATE POLICY "Allow public access to flyers storage" ON storage.objects
|
|
-- Allow public read access to flyers
|
|
FOR SELECT TO public USING (bucket_id = 'flyers');
|
|
-- Allow authenticated users to upload/manage their own flyers (if applicable, needs user_id association)
|
|
-- For now, restricting write access to authenticated users. If specific roles are needed, adjust TO authenticated.
|
|
CREATE POLICY "Allow authenticated users to manage flyers" ON storage.objects
|
|
FOR INSERT, UPDATE, DELETE TO authenticated USING (bucket_id = 'flyers');
|
|
|
|
-- 20. Set up the trigger to automatically create a profile when a new user signs up.
|
|
-- NOTE: Trigger definitions have been moved to `triggers.sql`.
|
|
|
|
-- 21. Create a reusable function to automatically update 'updated_at' columns.
|
|
-- NOTE: Trigger definitions have been moved to `triggers.sql`.
|
|
|
|
-- 22. Function to find the best current sale price for a user's watched items.
|
|
CREATE OR REPLACE FUNCTION public.get_best_sale_prices_for_user(p_user_id UUID)
|
|
RETURNS TABLE (
|
|
master_item_id BIGINT,
|
|
item_name TEXT,
|
|
best_price_in_cents INTEGER,
|
|
store_name TEXT,
|
|
flyer_id BIGINT,
|
|
flyer_image_url TEXT,
|
|
flyer_valid_from DATE,
|
|
flyer_valid_to DATE
|
|
)
|
|
LANGUAGE plpgsql
|
|
SECURITY INVOKER -- Runs with the privileges of the calling user. RLS policies will apply.
|
|
AS $$
|
|
BEGIN
|
|
RETURN QUERY
|
|
WITH UserWatchedSales AS (
|
|
SELECT
|
|
uwi.master_item_id,
|
|
mgi.name AS item_name,
|
|
fi.price_in_cents,
|
|
s.name AS store_name,
|
|
f.id AS flyer_id,
|
|
f.image_url AS flyer_image_url,
|
|
f.valid_from AS flyer_valid_from,
|
|
f.valid_to AS flyer_valid_to,
|
|
ROW_NUMBER() OVER (PARTITION BY uwi.master_item_id ORDER BY fi.price_in_cents ASC, f.valid_to DESC, s.name ASC) as rn
|
|
FROM
|
|
public.user_watched_items uwi
|
|
JOIN public.master_grocery_items mgi ON uwi.master_item_id = mgi.id
|
|
JOIN public.flyer_items fi ON uwi.master_item_id = fi.master_item_id
|
|
JOIN public.flyers f ON fi.flyer_id = f.id
|
|
JOIN public.stores s ON f.store_id = s.id
|
|
WHERE uwi.user_id = p_user_id
|
|
AND f.valid_from <= CURRENT_DATE
|
|
AND f.valid_to >= CURRENT_DATE
|
|
AND fi.price_in_cents IS NOT NULL
|
|
)
|
|
SELECT uws.master_item_id, uws.item_name, uws.price_in_cents, uws.store_name, uws.flyer_id, uws.flyer_image_url, uws.flyer_valid_from, uws.flyer_valid_to
|
|
FROM UserWatchedSales uws
|
|
WHERE uws.rn = 1;
|
|
END;
|
|
$$;
|
|
|
|
-- 23. Create a trigger function to populate the item_price_history table.
|
|
-- NOTE: Trigger definitions have been moved to `triggers.sql`.
|
|
|
|
-- 24. Create a trigger function to recalculate price history when a flyer item is deleted.
|
|
-- NOTE: Trigger definitions have been moved to `triggers.sql`.
|
|
|
|
-- 25. Function to generate a smart shopping list from a menu plan, subtracting pantry items.
|
|
CREATE OR REPLACE FUNCTION public.generate_shopping_list_for_menu_plan(p_menu_plan_id BIGINT, p_user_id UUID)
|
|
RETURNS TABLE (
|
|
master_item_id BIGINT,
|
|
item_name TEXT,
|
|
required_quantity NUMERIC,
|
|
pantry_quantity NUMERIC,
|
|
shopping_list_quantity NUMERIC,
|
|
unit TEXT
|
|
)
|
|
LANGUAGE plpgsql
|
|
SECURITY INVOKER -- Runs with the privileges of the calling user. RLS policies will apply.
|
|
AS $$
|
|
BEGIN
|
|
RETURN QUERY
|
|
WITH RequiredIngredients AS (
|
|
-- First, calculate the total quantity of each ingredient needed for the menu plan.
|
|
-- This now accounts for scaling the recipe based on desired servings.
|
|
SELECT
|
|
ri.master_item_id,
|
|
ri.unit,
|
|
SUM(
|
|
ri.quantity * -- The base ingredient quantity
|
|
-- Calculate the scaling factor. Default to 1 if servings_to_cook is not set.
|
|
(COALESCE(pm.servings_to_cook, r.servings)::NUMERIC / NULLIF(r.servings, 0)::NUMERIC)
|
|
) AS total_required
|
|
FROM public.menu_plans mp
|
|
JOIN public.planned_meals pm ON mp.id = pm.menu_plan_id
|
|
JOIN public.recipe_ingredients ri ON pm.recipe_id = ri.recipe_id
|
|
JOIN public.recipes r ON pm.recipe_id = r.id -- Join to get the recipe's base servings
|
|
WHERE mp.id = p_menu_plan_id AND mp.user_id = p_user_id
|
|
GROUP BY ri.master_item_id, ri.unit
|
|
)
|
|
-- Now, compare the required ingredients with the user's pantry.
|
|
SELECT
|
|
req.master_item_id,
|
|
mgi.name AS item_name,
|
|
req.total_required AS required_quantity,
|
|
COALESCE(pi.quantity, 0) AS pantry_quantity,
|
|
-- Calculate the amount to buy. If pantry has enough, this will be 0.
|
|
GREATEST(0, req.total_required - COALESCE(pi.quantity, 0)) AS shopping_list_quantity,
|
|
req.unit
|
|
FROM RequiredIngredients req
|
|
JOIN public.master_grocery_items mgi ON req.master_item_id = mgi.id
|
|
LEFT JOIN public.pantry_items pi
|
|
ON req.master_item_id = pi.master_item_id
|
|
AND req.unit = pi.unit -- Critical: only subtract if units match
|
|
AND pi.user_id = p_user_id
|
|
WHERE
|
|
-- Only include items that need to be purchased.
|
|
GREATEST(0, req.total_required - COALESCE(pi.quantity, 0)) > 0;
|
|
END;
|
|
$$;
|
|
|
|
-- 26. Function to find all recipes that can be made entirely from items currently on sale.
|
|
CREATE OR REPLACE FUNCTION public.get_recipes_by_sale_percentage(p_min_sale_percentage NUMERIC DEFAULT 100.0)
|
|
RETURNS TABLE (recipe_details JSONB) -- The return type remains the same (JSONB object per recipe)
|
|
LANGUAGE sql
|
|
STABLE -- Indicates the function cannot modify the database and is safe for read-only queries.
|
|
SECURITY INVOKER
|
|
AS $$
|
|
WITH BestCurrentPrices AS (
|
|
-- 1. For every item on sale, find its single best price and the store offering it.
|
|
SELECT
|
|
bcp.master_item_id,
|
|
bcp.price_in_cents,
|
|
bcp.store_name
|
|
FROM (
|
|
SELECT
|
|
fi.master_item_id,
|
|
fi.price_in_cents,
|
|
s.name as store_name,
|
|
ROW_NUMBER() OVER(PARTITION BY fi.master_item_id ORDER BY fi.price_in_cents ASC, f.valid_to DESC) as rn
|
|
FROM public.flyer_items fi
|
|
JOIN public.flyers f ON fi.flyer_id = f.id
|
|
JOIN public.stores s ON f.store_id = s.id
|
|
WHERE fi.master_item_id IS NOT NULL
|
|
AND fi.price_in_cents IS NOT NULL
|
|
AND CURRENT_DATE BETWEEN f.valid_from AND f.valid_to
|
|
) bcp
|
|
WHERE bcp.rn = 1
|
|
),
|
|
RecipeIngredientStats AS (
|
|
-- 2. For each recipe, count its total ingredients and how many of them are on sale.
|
|
SELECT
|
|
ri.recipe_id,
|
|
COUNT(ri.master_item_id) AS total_ingredients,
|
|
COUNT(bcp.master_item_id) AS sale_ingredients
|
|
FROM public.recipe_ingredients ri
|
|
LEFT JOIN BestCurrentPrices bcp ON ri.master_item_id = bcp.master_item_id -- Join to count how many ingredients are on sale
|
|
GROUP BY ri.recipe_id
|
|
),
|
|
EligibleRecipes AS (
|
|
-- 3. Filter recipes based on the minimum sale percentage.
|
|
SELECT
|
|
ris.recipe_id,
|
|
ris.total_ingredients,
|
|
ris.sale_ingredients
|
|
FROM RecipeIngredientStats ris
|
|
WHERE ris.total_ingredients > 0 -- Avoid division by zero and recipes with no ingredients
|
|
AND (ris.sale_ingredients * 100.0 / ris.total_ingredients) >= p_min_sale_percentage
|
|
),
|
|
RecipeSaleDetails AS (
|
|
-- 4. Gather details for the eligible recipes and ALL their ingredients, noting which are on sale.
|
|
SELECT
|
|
r.id AS recipe_id,
|
|
r.name AS recipe_name,
|
|
mgi.name AS item_name,
|
|
bcp.price_in_cents AS best_price_in_cents, -- This will be NULL if not on sale
|
|
bcp.store_name -- This will be NULL if not on sale
|
|
FROM public.recipes r
|
|
JOIN EligibleRecipes er ON r.id = er.recipe_id -- Join with the filtered eligible recipes
|
|
JOIN public.recipe_ingredients ri ON r.id = ri.recipe_id
|
|
JOIN public.master_grocery_items mgi ON ri.master_item_id = mgi.id
|
|
LEFT JOIN BestCurrentPrices bcp ON ri.master_item_id = bcp.master_item_id -- LEFT JOIN to include all ingredients
|
|
)
|
|
-- 5. Aggregate the details into a JSON object for each recipe.
|
|
SELECT
|
|
jsonb_build_object(
|
|
'id', rsd.recipe_id,
|
|
'name', rsd.recipe_name,
|
|
-- Aggregate all ingredients for the recipe into a JSON array.
|
|
'ingredients', jsonb_agg(
|
|
jsonb_build_object(
|
|
'item_name', rsd.item_name,
|
|
'on_sale', (rsd.best_price_in_cents IS NOT NULL), -- Mark if the item is on sale
|
|
'best_price_in_cents', rsd.best_price_in_cents,
|
|
'store_name', rsd.store_name
|
|
)
|
|
ORDER BY (rsd.best_price_in_cents IS NOT NULL) DESC, rsd.item_name ASC -- Show sale items first
|
|
)
|
|
)
|
|
FROM RecipeSaleDetails rsd
|
|
GROUP BY rsd.recipe_id, rsd.recipe_name;
|
|
$$;
|
|
|
|
-- 27. Function to add items from a menu plan to a user's shopping list.
|
|
CREATE OR REPLACE FUNCTION public.add_menu_plan_to_shopping_list(
|
|
p_menu_plan_id BIGINT,
|
|
p_shopping_list_id BIGINT,
|
|
p_user_id UUID
|
|
)
|
|
RETURNS TABLE (
|
|
master_item_id BIGINT,
|
|
item_name TEXT,
|
|
quantity_added NUMERIC
|
|
)
|
|
LANGUAGE plpgsql
|
|
-- SECURITY DEFINER is used here to chain functions and perform checks before modification.
|
|
-- The function internally ensures the calling user has the correct permissions.
|
|
SECURITY DEFINER
|
|
AS $$
|
|
DECLARE
|
|
list_owner_id UUID;
|
|
item_to_add RECORD;
|
|
BEGIN
|
|
-- Security Check: Ensure the user owns the target shopping list.
|
|
SELECT user_id INTO list_owner_id
|
|
FROM public.shopping_lists
|
|
WHERE id = p_shopping_list_id;
|
|
|
|
IF list_owner_id IS NULL OR list_owner_id <> p_user_id THEN
|
|
RAISE EXCEPTION 'Permission denied: You do not own shopping list %', p_shopping_list_id;
|
|
END IF;
|
|
|
|
-- Loop through the items generated by the smart shopping list function.
|
|
FOR item_to_add IN
|
|
SELECT * FROM public.generate_shopping_list_for_menu_plan(p_menu_plan_id, p_user_id)
|
|
LOOP
|
|
-- Insert the item into the shopping list. If it already exists, update the quantity.
|
|
INSERT INTO public.shopping_list_items (shopping_list_id, master_item_id, quantity)
|
|
VALUES (p_shopping_list_id, item_to_add.master_item_id, item_to_add.shopping_list_quantity)
|
|
ON CONFLICT (shopping_list_id, master_item_id)
|
|
DO UPDATE SET
|
|
quantity = shopping_list_items.quantity + EXCLUDED.quantity;
|
|
|
|
-- Return the details of the item that was added/updated.
|
|
RETURN QUERY SELECT item_to_add.master_item_id, item_to_add.item_name, item_to_add.shopping_list_quantity;
|
|
END LOOP;
|
|
END;
|
|
$$;
|
|
|
|
-- 28. Trigger function to update the average rating on the recipes table.
|
|
-- NOTE: Trigger definitions have been moved to `triggers.sql`.
|
|
|
|
-- 29. Function to find recipes that have at least 'x' ingredients currently on sale.
|
|
CREATE OR REPLACE FUNCTION public.get_recipes_by_min_sale_ingredients(p_min_sale_ingredients INTEGER)
|
|
RETURNS TABLE (
|
|
recipe_id BIGINT,
|
|
recipe_name TEXT,
|
|
description TEXT,
|
|
sale_ingredients_count BIGINT
|
|
)
|
|
LANGUAGE sql
|
|
STABLE
|
|
SECURITY INVOKER
|
|
AS $$
|
|
WITH CurrentSaleItems AS (
|
|
-- 1. Get a distinct list of all master item IDs that are currently on sale.
|
|
SELECT DISTINCT fi.master_item_id
|
|
FROM public.flyer_items fi
|
|
JOIN public.flyers f ON fi.flyer_id = f.id
|
|
WHERE fi.master_item_id IS NOT NULL
|
|
AND fi.price_in_cents IS NOT NULL
|
|
AND CURRENT_DATE BETWEEN f.valid_from AND f.valid_to
|
|
),
|
|
RecipeIngredientStats AS (
|
|
-- 2. For each recipe, count how many of its ingredients are on sale.
|
|
SELECT
|
|
ri.recipe_id,
|
|
COUNT(csi.master_item_id) AS sale_ingredients_count
|
|
FROM public.recipe_ingredients ri
|
|
LEFT JOIN CurrentSaleItems csi ON ri.master_item_id = csi.master_item_id
|
|
GROUP BY ri.recipe_id
|
|
)
|
|
-- 3. Select recipes that meet the minimum sale ingredient count.
|
|
SELECT
|
|
r.id,
|
|
r.name,
|
|
r.description,
|
|
ris.sale_ingredients_count
|
|
FROM public.recipes r
|
|
JOIN RecipeIngredientStats ris ON r.id = ris.recipe_id
|
|
WHERE ris.sale_ingredients_count >= p_min_sale_ingredients
|
|
ORDER BY
|
|
ris.sale_ingredients_count DESC,
|
|
r.avg_rating DESC;
|
|
$$;
|
|
|
|
-- 30. Function to find the most frequently advertised items in a given period.
|
|
CREATE OR REPLACE FUNCTION public.get_most_frequent_sale_items(days_interval INTEGER, result_limit INTEGER)
|
|
RETURNS TABLE (
|
|
item_name TEXT,
|
|
sale_occurrence_count BIGINT
|
|
)
|
|
LANGUAGE sql
|
|
STABLE
|
|
SECURITY INVOKER
|
|
AS $$
|
|
SELECT
|
|
mgi.name AS item_name,
|
|
COUNT(DISTINCT fi.flyer_id) AS sale_occurrence_count
|
|
FROM
|
|
public.flyer_items fi
|
|
JOIN
|
|
public.flyers f ON fi.flyer_id = f.id
|
|
JOIN
|
|
public.master_grocery_items mgi ON fi.master_item_id = mgi.id
|
|
WHERE
|
|
-- Only consider items linked to our master list
|
|
fi.master_item_id IS NOT NULL
|
|
-- Filter for flyers that have been active in the last X days
|
|
AND f.valid_to >= (CURRENT_DATE - (days_interval || ' days')::INTERVAL)
|
|
AND f.valid_from <= CURRENT_DATE
|
|
GROUP BY
|
|
mgi.id, mgi.name
|
|
ORDER BY
|
|
sale_occurrence_count DESC
|
|
LIMIT result_limit;
|
|
$$;
|
|
|
|
-- 31. Function to find recipes by a specific ingredient and tag.
|
|
CREATE OR REPLACE FUNCTION public.find_recipes_by_ingredient_and_tag(p_ingredient_name TEXT, p_tag_name TEXT)
|
|
RETURNS TABLE (
|
|
id BIGINT,
|
|
name TEXT,
|
|
description TEXT,
|
|
prep_time_minutes INTEGER,
|
|
cook_time_minutes INTEGER,
|
|
avg_rating NUMERIC
|
|
)
|
|
LANGUAGE sql
|
|
STABLE
|
|
SECURITY INVOKER
|
|
AS $$
|
|
SELECT
|
|
r.id, r.name, r.description, r.prep_time_minutes, r.cook_time_minutes, r.avg_rating
|
|
FROM
|
|
public.recipes r
|
|
WHERE
|
|
-- Check that the recipe has the required ingredient
|
|
EXISTS (
|
|
SELECT 1 FROM public.recipe_ingredients ri
|
|
JOIN public.master_grocery_items mgi ON ri.master_item_id = mgi.id
|
|
WHERE ri.recipe_id = r.id AND mgi.name = p_ingredient_name
|
|
)
|
|
AND
|
|
-- Check that the recipe has the required tag
|
|
EXISTS (
|
|
SELECT 1 FROM public.recipe_tags rt
|
|
JOIN public.tags t ON rt.tag_id = t.id
|
|
WHERE rt.recipe_id = r.id AND t.name = p_tag_name
|
|
)
|
|
ORDER BY
|
|
r.avg_rating DESC, r.name ASC;
|
|
$$;
|