-- Description: Backfills the daily_product_snapshots table using imported historical unit data -- (daily inventory/stats) and historical price data (current prices table). -- - Uses imported daily sales/receipt UNIT counts for accuracy. -- - ESTIMATES historical stock levels using a forward calculation. -- - APPROXIMATES historical REVENUE using looked-up historical base prices. -- - APPROXIMATES historical COGS, PROFIT, and STOCK VALUE using CURRENT product costs/prices. -- Run ONCE after importing historical data and before initial product_metrics population. -- Dependencies: Core import tables (products), imported history tables (imported_daily_inventory, -- imported_product_stat_history, imported_product_current_prices), -- daily_product_snapshots table must exist. -- Frequency: Run ONCE. CREATE OR REPLACE FUNCTION backfill_daily_snapshots_range_final( _start_date DATE, _end_date DATE ) RETURNS VOID AS $$ DECLARE _current_processing_date DATE := _start_date; _batch_start_time TIMESTAMPTZ; _row_count INTEGER; BEGIN RAISE NOTICE 'Starting FINAL historical snapshot backfill from % to %.', _start_date, _end_date; RAISE NOTICE 'Using historical units and historical prices (for revenue approximation).'; RAISE NOTICE 'WARNING: Historical COGS, Profit, and Stock Value use CURRENT product costs/prices.'; -- Ensure end date is not in the future IF _end_date >= CURRENT_DATE THEN _end_date := CURRENT_DATE - INTERVAL '1 day'; RAISE NOTICE 'Adjusted end date to % to avoid conflict with hourly script.', _end_date; END IF; -- Performance: Create temporary table with product info to avoid repeated lookups CREATE TEMP TABLE IF NOT EXISTS temp_product_info AS SELECT pid, sku, 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; -- Performance: Create index on temporary table CREATE INDEX IF NOT EXISTS temp_product_info_pid_idx ON temp_product_info(pid); ANALYZE temp_product_info; RAISE NOTICE 'Created temporary product info table with % products', (SELECT COUNT(*) FROM temp_product_info); WHILE _current_processing_date <= _end_date LOOP _batch_start_time := clock_timestamp(); RAISE NOTICE 'Processing date: %', _current_processing_date; -- Get Daily Transaction Unit Info from imported history WITH DailyHistoryUnits AS ( SELECT pids.pid, -- Prioritize daily_inventory, fallback to product_stat_history for sold qty COALESCE(di.amountsold, ps.qty_sold, 0)::integer as units_sold_today, COALESCE(di.qtyreceived, 0)::integer as units_received_today FROM (SELECT DISTINCT pid FROM temp_product_info) pids -- Ensure all products are considered LEFT JOIN public.imported_daily_inventory di ON pids.pid = di.pid AND di.date = _current_processing_date LEFT JOIN public.imported_product_stat_history ps ON pids.pid = ps.pid AND ps.date = _current_processing_date -- Removed WHERE clause to ensure snapshots are created even for days with 0 activity, -- allowing stock carry-over. The main query will handle products properly. ), HistoricalPrice AS ( -- Find the base price (qty_buy=1) active on the processing date SELECT DISTINCT ON (pid) pid, price_each FROM public.imported_product_current_prices WHERE qty_buy = 1 -- Use TIMESTAMPTZ comparison logic: AND date_active <= (_current_processing_date + interval '1 day' - interval '1 second') -- Active sometime on or before end of processing day AND (date_deactive IS NULL OR date_deactive > _current_processing_date) -- Not deactivated before start of processing day -- Assuming 'active' flag isn't needed if dates are correct; add 'AND active != 0' if necessary ORDER BY pid, date_active DESC -- Get the most recently activated price ), PreviousStock AS ( -- Get the estimated stock from the PREVIOUS day snapshot SELECT pid, eod_stock_quantity FROM public.daily_product_snapshots WHERE snapshot_date = _current_processing_date - INTERVAL '1 day' ) -- Insert 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 _current_processing_date AS snapshot_date, p.pid, p.sku, -- Estimated EOD Stock (using historical daily units) -- Handle potential NULL from joins with COALESCE 0 COALESCE(ps.eod_stock_quantity, 0) + COALESCE(dh.units_received_today, 0) - COALESCE(dh.units_sold_today, 0) AS estimated_eod_stock, -- Valued Stock (using estimated stock and CURRENT prices/costs - APPROXIMATION) GREATEST(0, COALESCE(ps.eod_stock_quantity, 0) + COALESCE(dh.units_received_today, 0) - COALESCE(dh.units_sold_today, 0)) * p.effective_cost_price AS eod_stock_cost, GREATEST(0, COALESCE(ps.eod_stock_quantity, 0) + COALESCE(dh.units_received_today, 0) - COALESCE(dh.units_sold_today, 0)) * p.current_price AS eod_stock_retail, -- Stock retail uses current price GREATEST(0, COALESCE(ps.eod_stock_quantity, 0) + COALESCE(dh.units_received_today, 0) - COALESCE(dh.units_sold_today, 0)) * p.current_regular_price AS eod_stock_gross, -- Stock gross uses current regular price -- Stockout Flag (based on estimated stock) (COALESCE(ps.eod_stock_quantity, 0) + COALESCE(dh.units_received_today, 0) - COALESCE(dh.units_sold_today, 0)) <= 0 AS stockout_flag, -- Today's Unit Aggregates from History COALESCE(dh.units_sold_today, 0) as units_sold, 0 AS units_returned, -- Placeholder: Cannot determine returns from daily summary -- Monetary Values using looked-up Historical Price and CURRENT Cost/RegPrice COALESCE(dh.units_sold_today, 0) * COALESCE(hp.price_each, p.current_price) AS gross_revenue, -- Approx Revenue 0 AS discounts, -- Placeholder 0 AS returns_revenue, -- Placeholder COALESCE(dh.units_sold_today, 0) * COALESCE(hp.price_each, p.current_price) AS net_revenue, -- Approx Net Revenue COALESCE(dh.units_sold_today, 0) * p.effective_cost_price AS cogs, -- Approx COGS (uses CURRENT cost) COALESCE(dh.units_sold_today, 0) * p.current_regular_price AS gross_regular_revenue, -- Approx Gross Regular Revenue -- Approx Profit (COALESCE(dh.units_sold_today, 0) * COALESCE(hp.price_each, p.current_price)) - (COALESCE(dh.units_sold_today, 0) * p.effective_cost_price) AS profit, COALESCE(dh.units_received_today, 0) as units_received, -- Estimate received cost using CURRENT product cost COALESCE(dh.units_received_today, 0) * p.effective_cost_price AS cost_received, -- Approx clock_timestamp() -- Timestamp of this specific calculation FROM temp_product_info p -- Use the temp table for better performance LEFT JOIN PreviousStock ps ON p.pid = ps.pid LEFT JOIN DailyHistoryUnits dh ON p.pid = dh.pid -- Join today's historical activity LEFT JOIN HistoricalPrice hp ON p.pid = hp.pid -- Join the looked-up historical price -- Optimization: Only process products with activity or previous stock WHERE (dh.units_sold_today > 0 OR dh.units_received_today > 0 OR COALESCE(ps.eod_stock_quantity, 0) > 0) ON CONFLICT (snapshot_date, pid) DO NOTHING; -- Avoid errors if rerunning parts, but prefer clean runs GET DIAGNOSTICS _row_count = ROW_COUNT; RAISE NOTICE 'Processed %: Inserted/Skipped % rows. Duration: %', _current_processing_date, _row_count, clock_timestamp() - _batch_start_time; _current_processing_date := _current_processing_date + INTERVAL '1 day'; END LOOP; -- Clean up temporary tables DROP TABLE IF EXISTS temp_product_info; RAISE NOTICE 'Finished FINAL historical snapshot backfill.'; END; $$ LANGUAGE plpgsql; -- Example usage: -- SELECT backfill_daily_snapshots_range_final('2023-01-01'::date, '2023-12-31'::date);