Files
inventory/inventory-server/scripts/metrics-new/calculate_vendor_metrics.sql

143 lines
7.6 KiB
SQL

-- Description: Calculates and updates aggregated metrics per vendor.
-- Dependencies: product_metrics, products, purchase_orders, calculate_status table.
-- Frequency: Daily (after product_metrics update).
DO $$
DECLARE
_module_name VARCHAR := 'vendor_metrics';
_start_time TIMESTAMPTZ := clock_timestamp();
BEGIN
RAISE NOTICE 'Running % calculation...', _module_name;
WITH VendorProductAggregates AS (
-- Aggregate metrics from product_metrics table per vendor
SELECT
p.vendor,
COUNT(DISTINCT pm.pid) AS product_count,
COUNT(DISTINCT CASE WHEN pm.is_visible THEN pm.pid END) AS active_product_count,
COUNT(DISTINCT CASE WHEN pm.is_replenishable THEN pm.pid END) AS replenishable_product_count,
SUM(pm.current_stock) AS current_stock_units,
SUM(pm.current_stock_cost) AS current_stock_cost,
SUM(pm.current_stock_retail) AS current_stock_retail,
SUM(pm.on_order_qty) AS on_order_units,
SUM(pm.on_order_cost) AS on_order_cost,
-- Only include products with valid sales data in each time period
COUNT(DISTINCT CASE WHEN pm.sales_7d > 0 THEN pm.pid END) AS products_with_sales_7d,
SUM(CASE WHEN pm.sales_7d > 0 THEN pm.sales_7d ELSE 0 END) AS sales_7d,
SUM(CASE WHEN pm.revenue_7d > 0 THEN pm.revenue_7d ELSE 0 END) AS revenue_7d,
COUNT(DISTINCT CASE WHEN pm.sales_30d > 0 THEN pm.pid END) AS products_with_sales_30d,
SUM(CASE WHEN pm.sales_30d > 0 THEN pm.sales_30d ELSE 0 END) AS sales_30d,
SUM(CASE WHEN pm.revenue_30d > 0 THEN pm.revenue_30d ELSE 0 END) AS revenue_30d,
SUM(CASE WHEN pm.cogs_30d > 0 THEN pm.cogs_30d ELSE 0 END) AS cogs_30d,
SUM(CASE WHEN pm.profit_30d != 0 THEN pm.profit_30d ELSE 0 END) AS profit_30d,
COUNT(DISTINCT CASE WHEN pm.sales_365d > 0 THEN pm.pid END) AS products_with_sales_365d,
SUM(CASE WHEN pm.sales_365d > 0 THEN pm.sales_365d ELSE 0 END) AS sales_365d,
SUM(CASE WHEN pm.revenue_365d > 0 THEN pm.revenue_365d ELSE 0 END) AS revenue_365d,
COUNT(DISTINCT CASE WHEN pm.lifetime_sales > 0 THEN pm.pid END) AS products_with_lifetime_sales,
SUM(CASE WHEN pm.lifetime_sales > 0 THEN pm.lifetime_sales ELSE 0 END) AS lifetime_sales,
SUM(CASE WHEN pm.lifetime_revenue > 0 THEN pm.lifetime_revenue ELSE 0 END) AS lifetime_revenue
FROM public.product_metrics pm
JOIN public.products p ON pm.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
po.vendor,
COUNT(DISTINCT po.po_id) AS po_count_365d,
-- Calculate lead time by averaging the days between PO date and receiving date
AVG(GREATEST(1, CASE
WHEN r.received_date IS NOT NULL AND po.date IS NOT NULL
THEN (r.received_date::date - po.date::date)
ELSE NULL
END))::int AS avg_lead_time_days_hist -- Avg lead time from HISTORICAL received POs
FROM public.purchase_orders po
-- Join to receivings table to find when items were received
LEFT JOIN public.receivings r ON r.pid = po.pid
WHERE po.vendor IS NOT NULL AND po.vendor <> ''
AND po.date >= CURRENT_DATE - INTERVAL '1 year' -- Look at POs created in the last year
AND po.status = 'done' -- Only calculate lead time on completed POs
AND r.received_date IS NOT NULL
AND po.date IS NOT NULL
AND r.received_date >= po.date
GROUP BY po.vendor
),
AllVendors AS (
-- Ensure all vendors from products table are included
SELECT DISTINCT vendor FROM public.products WHERE vendor IS NOT NULL AND vendor <> ''
)
INSERT INTO public.vendor_metrics (
vendor_name, last_calculated,
product_count, active_product_count, replenishable_product_count,
current_stock_units, current_stock_cost, current_stock_retail,
on_order_units, on_order_cost,
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
)
SELECT
v.vendor,
_start_time,
-- Base Aggregates
COALESCE(vpa.product_count, 0),
COALESCE(vpa.active_product_count, 0),
COALESCE(vpa.replenishable_product_count, 0),
COALESCE(vpa.current_stock_units, 0),
COALESCE(vpa.current_stock_cost, 0.00),
COALESCE(vpa.current_stock_retail, 0.00),
COALESCE(vpa.on_order_units, 0),
COALESCE(vpa.on_order_cost, 0.00),
-- PO Aggregates
COALESCE(vpoa.po_count_365d, 0),
vpoa.avg_lead_time_days_hist, -- Can be NULL if no received POs
-- Sales Aggregates
COALESCE(vpa.sales_7d, 0), COALESCE(vpa.revenue_7d, 0.00),
COALESCE(vpa.sales_30d, 0), COALESCE(vpa.revenue_30d, 0.00),
COALESCE(vpa.profit_30d, 0.00), COALESCE(vpa.cogs_30d, 0.00),
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
FROM AllVendors v
LEFT JOIN VendorProductAggregates vpa ON v.vendor = vpa.vendor
LEFT JOIN VendorPOAggregates vpoa ON v.vendor = vpoa.vendor
ON CONFLICT (vendor_name) DO UPDATE SET
last_calculated = EXCLUDED.last_calculated,
product_count = EXCLUDED.product_count,
active_product_count = EXCLUDED.active_product_count,
replenishable_product_count = EXCLUDED.replenishable_product_count,
current_stock_units = EXCLUDED.current_stock_units,
current_stock_cost = EXCLUDED.current_stock_cost,
current_stock_retail = EXCLUDED.current_stock_retail,
on_order_units = EXCLUDED.on_order_units,
on_order_cost = EXCLUDED.on_order_cost,
po_count_365d = EXCLUDED.po_count_365d,
avg_lead_time_days = EXCLUDED.avg_lead_time_days,
sales_7d = EXCLUDED.sales_7d, revenue_7d = EXCLUDED.revenue_7d,
sales_30d = EXCLUDED.sales_30d, revenue_30d = EXCLUDED.revenue_30d,
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
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
vendor_metrics.current_stock_units IS DISTINCT FROM EXCLUDED.current_stock_units OR
vendor_metrics.on_order_units IS DISTINCT FROM EXCLUDED.on_order_units OR
vendor_metrics.sales_30d IS DISTINCT FROM EXCLUDED.sales_30d OR
vendor_metrics.revenue_30d IS DISTINCT FROM EXCLUDED.revenue_30d OR
vendor_metrics.lifetime_sales IS DISTINCT FROM EXCLUDED.lifetime_sales;
-- Update calculate_status
INSERT INTO public.calculate_status (module_name, last_calculation_timestamp)
VALUES (_module_name, _start_time)
ON CONFLICT (module_name) DO UPDATE SET last_calculation_timestamp = _start_time;
RAISE NOTICE 'Finished % calculation. Duration: %', _module_name, clock_timestamp() - _start_time;
END $$;