more testing and queue work
Some checks failed
Deploy to Web Server flyer-crawler.projectium.com / deploy (push) Failing after 5m39s
Some checks failed
Deploy to Web Server flyer-crawler.projectium.com / deploy (push) Failing after 5m39s
This commit is contained in:
@@ -2535,3 +2535,79 @@ DROP TRIGGER IF EXISTS on_new_recipe_collection_share ON public.shared_recipe_co
|
||||
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();
|
||||
|
||||
-- =================================================================
|
||||
-- Function: get_best_sale_prices_for_all_users()
|
||||
-- Description: Retrieves the best sale price for every item on every user's watchlist.
|
||||
-- This is a highly efficient function designed for the daily deal check background job.
|
||||
-- It replaces the need to call get_best_sale_prices_for_user for each user individually.
|
||||
-- Returns: TABLE(...) - A set of records including user details and deal information.
|
||||
-- =================================================================
|
||||
CREATE OR REPLACE FUNCTION public.get_best_sale_prices_for_all_users()
|
||||
RETURNS TABLE(
|
||||
user_id uuid,
|
||||
email text,
|
||||
full_name text,
|
||||
master_item_id integer,
|
||||
item_name text,
|
||||
best_price_in_cents integer,
|
||||
store_name text,
|
||||
flyer_id integer,
|
||||
valid_to date
|
||||
) AS $$
|
||||
BEGIN
|
||||
RETURN QUERY
|
||||
WITH
|
||||
-- Step 1: Find all flyer items that are currently on sale and have a valid price.
|
||||
current_sales AS (
|
||||
SELECT
|
||||
fi.master_item_id,
|
||||
fi.price_in_cents,
|
||||
f.store_name,
|
||||
f.flyer_id,
|
||||
f.valid_to
|
||||
FROM public.flyer_items fi
|
||||
JOIN public.flyers f ON fi.flyer_id = f.flyer_id
|
||||
WHERE
|
||||
fi.master_item_id IS NOT NULL
|
||||
AND fi.price_in_cents IS NOT NULL
|
||||
AND f.valid_to >= CURRENT_DATE
|
||||
),
|
||||
-- Step 2: For each master item, find its absolute best (lowest) price across all current sales.
|
||||
-- We use a window function to rank the sales for each item by price.
|
||||
best_prices AS (
|
||||
SELECT
|
||||
cs.master_item_id,
|
||||
cs.price_in_cents AS best_price_in_cents,
|
||||
cs.store_name,
|
||||
cs.flyer_id,
|
||||
cs.valid_to,
|
||||
-- Rank items by price, ascending. The best price will have a rank of 1.
|
||||
ROW_NUMBER() OVER(PARTITION BY cs.master_item_id ORDER BY cs.price_in_cents ASC) as price_rank
|
||||
FROM current_sales cs
|
||||
)
|
||||
-- Step 3: Join the best-priced items with the user watchlist and user details.
|
||||
SELECT
|
||||
u.user_id,
|
||||
u.email,
|
||||
p.full_name,
|
||||
bp.master_item_id,
|
||||
mgi.name AS item_name,
|
||||
bp.best_price_in_cents,
|
||||
bp.store_name,
|
||||
bp.flyer_id,
|
||||
bp.valid_to
|
||||
FROM public.user_watched_items uwi
|
||||
-- Join with users and profiles to get user details for notifications.
|
||||
JOIN public.users u ON uwi.user_id = u.user_id
|
||||
JOIN public.profiles p ON u.user_id = p.user_id
|
||||
-- Join with the best-priced items.
|
||||
JOIN best_prices bp ON uwi.master_item_id = bp.master_item_id
|
||||
-- Join with master items to get the item name.
|
||||
JOIN public.master_grocery_items mgi ON bp.master_item_id = mgi.master_grocery_item_id
|
||||
WHERE
|
||||
-- Only include the items that are at their absolute best price (rank = 1).
|
||||
bp.price_rank = 1;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
|
||||
Reference in New Issue
Block a user