Opus corrections/fixes/additions
This commit is contained in:
@@ -44,6 +44,21 @@ BEGIN
|
||||
WHERE p.vendor IS NOT NULL AND p.vendor <> ''
|
||||
GROUP BY p.vendor
|
||||
),
|
||||
PreviousPeriodVendorMetrics AS (
|
||||
-- Get previous period metrics for growth calculation
|
||||
SELECT
|
||||
p.vendor,
|
||||
SUM(CASE WHEN dps.snapshot_date >= CURRENT_DATE - INTERVAL '59 days'
|
||||
AND dps.snapshot_date < CURRENT_DATE - INTERVAL '29 days'
|
||||
THEN dps.units_sold ELSE 0 END) AS sales_prev_30d,
|
||||
SUM(CASE WHEN dps.snapshot_date >= CURRENT_DATE - INTERVAL '59 days'
|
||||
AND dps.snapshot_date < CURRENT_DATE - INTERVAL '29 days'
|
||||
THEN dps.net_revenue ELSE 0 END) AS revenue_prev_30d
|
||||
FROM public.daily_product_snapshots dps
|
||||
JOIN public.products p ON dps.pid = p.pid
|
||||
WHERE p.vendor IS NOT NULL AND p.vendor <> ''
|
||||
GROUP BY p.vendor
|
||||
),
|
||||
VendorPOAggregates AS (
|
||||
-- Aggregate PO related stats including lead time calculated from POs to receivings
|
||||
SELECT
|
||||
@@ -78,7 +93,8 @@ BEGIN
|
||||
po_count_365d, avg_lead_time_days,
|
||||
sales_7d, revenue_7d, sales_30d, revenue_30d, profit_30d, cogs_30d,
|
||||
sales_365d, revenue_365d, lifetime_sales, lifetime_revenue,
|
||||
avg_margin_30d
|
||||
avg_margin_30d,
|
||||
sales_growth_30d_vs_prev, revenue_growth_30d_vs_prev
|
||||
)
|
||||
SELECT
|
||||
v.vendor,
|
||||
@@ -102,10 +118,14 @@ BEGIN
|
||||
COALESCE(vpa.sales_365d, 0), COALESCE(vpa.revenue_365d, 0.00),
|
||||
COALESCE(vpa.lifetime_sales, 0), COALESCE(vpa.lifetime_revenue, 0.00),
|
||||
-- KPIs
|
||||
(vpa.profit_30d / NULLIF(vpa.revenue_30d, 0)) * 100.0
|
||||
(vpa.profit_30d / NULLIF(vpa.revenue_30d, 0)) * 100.0,
|
||||
-- Growth metrics
|
||||
std_numeric(safe_divide((vpa.sales_30d - ppvm.sales_prev_30d) * 100.0, ppvm.sales_prev_30d), 2),
|
||||
std_numeric(safe_divide((vpa.revenue_30d - ppvm.revenue_prev_30d) * 100.0, ppvm.revenue_prev_30d), 2)
|
||||
FROM AllVendors v
|
||||
LEFT JOIN VendorProductAggregates vpa ON v.vendor = vpa.vendor
|
||||
LEFT JOIN VendorPOAggregates vpoa ON v.vendor = vpoa.vendor
|
||||
LEFT JOIN PreviousPeriodVendorMetrics ppvm ON v.vendor = ppvm.vendor
|
||||
|
||||
ON CONFLICT (vendor_name) DO UPDATE SET
|
||||
last_calculated = EXCLUDED.last_calculated,
|
||||
@@ -124,7 +144,9 @@ BEGIN
|
||||
profit_30d = EXCLUDED.profit_30d, cogs_30d = EXCLUDED.cogs_30d,
|
||||
sales_365d = EXCLUDED.sales_365d, revenue_365d = EXCLUDED.revenue_365d,
|
||||
lifetime_sales = EXCLUDED.lifetime_sales, lifetime_revenue = EXCLUDED.lifetime_revenue,
|
||||
avg_margin_30d = EXCLUDED.avg_margin_30d
|
||||
avg_margin_30d = EXCLUDED.avg_margin_30d,
|
||||
sales_growth_30d_vs_prev = EXCLUDED.sales_growth_30d_vs_prev,
|
||||
revenue_growth_30d_vs_prev = EXCLUDED.revenue_growth_30d_vs_prev
|
||||
WHERE -- Only update if at least one value has changed
|
||||
vendor_metrics.product_count IS DISTINCT FROM EXCLUDED.product_count OR
|
||||
vendor_metrics.active_product_count IS DISTINCT FROM EXCLUDED.active_product_count OR
|
||||
|
||||
Reference in New Issue
Block a user