Fix specific import calculations

This commit is contained in:
2025-04-07 22:07:21 -04:00
parent 92ff80fba2
commit 43f76e4ac0
4 changed files with 153 additions and 22 deletions

View File

@@ -31,7 +31,8 @@ BEGIN
p.stock_quantity as current_stock, -- Use actual current stock for forecast base
p.created_at, p.first_received, p.date_last_sold,
p.moq,
p.uom
p.uom,
p.total_sold as historical_total_sold -- Add historical total_sold from products table
FROM public.products p
),
OnOrderInfo AS (
@@ -99,9 +100,30 @@ BEGIN
AVG(CASE WHEN snapshot_date BETWEEN _calculation_date - INTERVAL '29 days' AND _calculation_date THEN eod_stock_retail END) AS avg_stock_retail_30d,
AVG(CASE WHEN snapshot_date BETWEEN _calculation_date - INTERVAL '29 days' AND _calculation_date THEN eod_stock_gross END) AS avg_stock_gross_30d,
-- Lifetime (Sum over ALL available snapshots up to calculation date)
SUM(units_sold) AS lifetime_sales,
SUM(net_revenue) AS lifetime_revenue,
-- Lifetime (Using product.total_sold instead of snapshot summation for historical accuracy)
p.historical_total_sold AS lifetime_sales,
COALESCE(
-- Option 1: Use 30-day average price if available
CASE WHEN SUM(CASE WHEN snapshot_date >= _calculation_date - INTERVAL '29 days' AND snapshot_date <= _calculation_date THEN units_sold ELSE 0 END) > 0 THEN
p.historical_total_sold * (
SUM(CASE WHEN snapshot_date >= _calculation_date - INTERVAL '29 days' AND snapshot_date <= _calculation_date THEN net_revenue ELSE 0 END) /
NULLIF(SUM(CASE WHEN snapshot_date >= _calculation_date - INTERVAL '29 days' AND snapshot_date <= _calculation_date THEN units_sold ELSE 0 END), 0)
)
ELSE NULL END,
-- Option 2: Try 365-day average price if available
CASE WHEN SUM(CASE WHEN snapshot_date >= _calculation_date - INTERVAL '364 days' AND snapshot_date <= _calculation_date THEN units_sold ELSE 0 END) > 0 THEN
p.historical_total_sold * (
SUM(CASE WHEN snapshot_date >= _calculation_date - INTERVAL '364 days' AND snapshot_date <= _calculation_date THEN net_revenue ELSE 0 END) /
NULLIF(SUM(CASE WHEN snapshot_date >= _calculation_date - INTERVAL '364 days' AND snapshot_date <= _calculation_date THEN units_sold ELSE 0 END), 0)
)
ELSE NULL END,
-- Option 3: Use current price from products table
p.historical_total_sold * p.current_price,
-- Option 4: Use regular price if current price might be zero
p.historical_total_sold * p.current_regular_price,
-- Final fallback: Use accumulated revenue (less accurate for old products)
SUM(net_revenue)
) AS lifetime_revenue,
-- Yesterday (Sales for the specific _calculation_date)
SUM(CASE WHEN snapshot_date = _calculation_date THEN units_sold ELSE 0 END) as yesterday_sales