-- Description: Calculates and updates daily aggregated product data for the current day. -- Uses UPSERT (INSERT ON CONFLICT UPDATE) for idempotency. -- Dependencies: Core import tables (products, orders, purchase_orders), calculate_status table. -- Frequency: Hourly (Run ~5-10 minutes after hourly data import completes). DO $$ DECLARE _module_name TEXT := 'daily_snapshots'; _start_time TIMESTAMPTZ := clock_timestamp(); -- Time execution started _last_calc_time TIMESTAMPTZ; _target_date DATE := CURRENT_DATE; -- Always recalculate today for simplicity with hourly runs BEGIN -- Get the timestamp before the last successful run of this module SELECT last_calculation_timestamp INTO _last_calc_time FROM public.calculate_status WHERE module_name = _module_name; RAISE NOTICE 'Running % for date %. Start Time: %', _module_name, _target_date, _start_time; -- Use CTEs to aggregate data for the target date WITH SalesData AS ( SELECT p.pid, p.sku, -- Aggregate Sales (Quantity > 0, Status not Canceled/Returned) COALESCE(SUM(CASE WHEN o.quantity > 0 AND COALESCE(o.status, 'pending') NOT IN ('canceled', 'returned') THEN o.quantity ELSE 0 END), 0) AS units_sold, COALESCE(SUM(CASE WHEN o.quantity > 0 AND COALESCE(o.status, 'pending') NOT IN ('canceled', 'returned') THEN o.price * o.quantity ELSE 0 END), 0.00) AS gross_revenue_unadjusted, -- Before discount COALESCE(SUM(CASE WHEN o.quantity > 0 AND COALESCE(o.status, 'pending') NOT IN ('canceled', 'returned') THEN o.discount ELSE 0 END), 0.00) AS discounts, COALESCE(SUM(CASE WHEN o.quantity > 0 AND COALESCE(o.status, 'pending') NOT IN ('canceled', 'returned') THEN COALESCE(o.costeach, p.landing_cost_price, p.cost_price) * o.quantity ELSE 0 END), 0.00) AS cogs, COALESCE(SUM(CASE WHEN o.quantity > 0 AND COALESCE(o.status, 'pending') NOT IN ('canceled', 'returned') THEN p.regular_price * o.quantity ELSE 0 END), 0.00) AS gross_regular_revenue, -- Use current regular price for simplicity here -- Aggregate Returns (Quantity < 0 or Status = Returned) COALESCE(SUM(CASE WHEN o.quantity < 0 OR COALESCE(o.status, 'pending') = 'returned' THEN ABS(o.quantity) ELSE 0 END), 0) AS units_returned, COALESCE(SUM(CASE WHEN o.quantity < 0 OR COALESCE(o.status, 'pending') = 'returned' THEN o.price * ABS(o.quantity) ELSE 0 END), 0.00) AS returns_revenue FROM public.products p -- Start from products to include those with no orders today LEFT JOIN public.orders o ON p.pid = o.pid AND o.date::date = _target_date -- Cast to date to ensure compatibility regardless of original type GROUP BY p.pid, p.sku ), ReceivingData AS ( SELECT po.pid, -- Prioritize the actual table fields over the JSON data COALESCE( -- First try the received field from purchase_orders table SUM(CASE WHEN po.date::date = _target_date THEN po.received ELSE 0 END), -- Otherwise fall back to the receiving_history JSON as secondary source SUM( CASE WHEN (rh.item->>'date')::date = _target_date THEN (rh.item->>'qty')::numeric WHEN (rh.item->>'received_at')::date = _target_date THEN (rh.item->>'qty')::numeric WHEN (rh.item->>'receipt_date')::date = _target_date THEN (rh.item->>'qty')::numeric ELSE 0 END ), 0 ) AS units_received, COALESCE( -- First try the actual cost_price from purchase_orders SUM(CASE WHEN po.date::date = _target_date THEN po.received * po.cost_price ELSE 0 END), -- Otherwise fall back to receiving_history JSON SUM( CASE WHEN (rh.item->>'date')::date = _target_date THEN (rh.item->>'qty')::numeric WHEN (rh.item->>'received_at')::date = _target_date THEN (rh.item->>'qty')::numeric WHEN (rh.item->>'receipt_date')::date = _target_date THEN (rh.item->>'qty')::numeric ELSE 0 END * COALESCE((rh.item->>'cost')::numeric, po.cost_price) ), 0.00 ) AS cost_received FROM public.purchase_orders po LEFT JOIN LATERAL jsonb_array_elements(po.receiving_history) AS rh(item) ON jsonb_typeof(po.receiving_history) = 'array' AND jsonb_array_length(po.receiving_history) > 0 AND ( (rh.item->>'date')::date = _target_date OR (rh.item->>'received_at')::date = _target_date OR (rh.item->>'receipt_date')::date = _target_date ) -- Include POs with the current date or relevant receiving_history WHERE po.date::date = _target_date OR jsonb_typeof(po.receiving_history) = 'array' AND jsonb_array_length(po.receiving_history) > 0 GROUP BY po.pid ), CurrentStock AS ( -- Select current stock values directly from products table SELECT pid, stock_quantity, COALESCE(landing_cost_price, cost_price, 0.00) as effective_cost_price, COALESCE(price, 0.00) as current_price, COALESCE(regular_price, 0.00) as current_regular_price FROM public.products ) -- Upsert into the daily snapshots table INSERT INTO public.daily_product_snapshots ( snapshot_date, pid, sku, eod_stock_quantity, eod_stock_cost, eod_stock_retail, eod_stock_gross, stockout_flag, units_sold, units_returned, gross_revenue, discounts, returns_revenue, net_revenue, cogs, gross_regular_revenue, profit, units_received, cost_received, calculation_timestamp ) SELECT _target_date AS snapshot_date, p.pid, p.sku, -- Inventory Metrics (Using CurrentStock) cs.stock_quantity AS eod_stock_quantity, cs.stock_quantity * cs.effective_cost_price AS eod_stock_cost, cs.stock_quantity * cs.current_price AS eod_stock_retail, cs.stock_quantity * cs.current_regular_price AS eod_stock_gross, (cs.stock_quantity <= 0) AS stockout_flag, -- Sales Metrics (From SalesData) COALESCE(sd.units_sold, 0), COALESCE(sd.units_returned, 0), COALESCE(sd.gross_revenue_unadjusted, 0.00), COALESCE(sd.discounts, 0.00), COALESCE(sd.returns_revenue, 0.00), COALESCE(sd.gross_revenue_unadjusted, 0.00) - COALESCE(sd.discounts, 0.00) AS net_revenue, COALESCE(sd.cogs, 0.00), COALESCE(sd.gross_regular_revenue, 0.00), (COALESCE(sd.gross_revenue_unadjusted, 0.00) - COALESCE(sd.discounts, 0.00)) - COALESCE(sd.cogs, 0.00) AS profit, -- Basic profit: Net Revenue - COGS -- Receiving Metrics (From ReceivingData) COALESCE(rd.units_received, 0), COALESCE(rd.cost_received, 0.00), _start_time -- Timestamp of this calculation run FROM public.products p LEFT JOIN CurrentStock cs ON p.pid = cs.pid LEFT JOIN SalesData sd ON p.pid = sd.pid LEFT JOIN ReceivingData rd ON p.pid = rd.pid WHERE p.pid IS NOT NULL -- Ensure we only insert for existing products ON CONFLICT (snapshot_date, pid) DO UPDATE SET sku = EXCLUDED.sku, eod_stock_quantity = EXCLUDED.eod_stock_quantity, eod_stock_cost = EXCLUDED.eod_stock_cost, eod_stock_retail = EXCLUDED.eod_stock_retail, eod_stock_gross = EXCLUDED.eod_stock_gross, stockout_flag = EXCLUDED.stockout_flag, units_sold = EXCLUDED.units_sold, units_returned = EXCLUDED.units_returned, gross_revenue = EXCLUDED.gross_revenue, discounts = EXCLUDED.discounts, returns_revenue = EXCLUDED.returns_revenue, net_revenue = EXCLUDED.net_revenue, cogs = EXCLUDED.cogs, gross_regular_revenue = EXCLUDED.gross_regular_revenue, profit = EXCLUDED.profit, units_received = EXCLUDED.units_received, cost_received = EXCLUDED.cost_received, calculation_timestamp = EXCLUDED.calculation_timestamp; -- Use the timestamp from this run -- Update the status table with the timestamp from the START of this run UPDATE public.calculate_status SET last_calculation_timestamp = _start_time WHERE module_name = _module_name; RAISE NOTICE 'Finished % for date %. Duration: %', _module_name, _target_date, clock_timestamp() - _start_time; END $$;