-- Description: Calculates metrics that don't need hourly updates, like ABC class -- and average lead time. -- Dependencies: product_metrics, purchase_orders, settings_global, calculate_status. -- Frequency: Daily or Weekly (e.g., run via cron job overnight). DO $$ DECLARE _module_name TEXT := 'periodic_metrics'; _start_time TIMESTAMPTZ := clock_timestamp(); _last_calc_time TIMESTAMPTZ; _abc_basis VARCHAR; _abc_period INT; _threshold_a NUMERIC; _threshold_b NUMERIC; 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 % module. Start Time: %', _module_name, _start_time; -- 1. Calculate Average Lead Time RAISE NOTICE 'Calculating Average Lead Time...'; WITH LeadTimes AS ( SELECT pid, AVG(GREATEST(1, (last_received_date::date - date::date))) AS avg_days -- Use GREATEST(1,...) to avoid 0 or negative days FROM public.purchase_orders WHERE status = 'received' -- Or potentially 'full_received' if using that status AND last_received_date IS NOT NULL AND date IS NOT NULL AND last_received_date >= date -- Ensure received date is not before order date GROUP BY pid ) UPDATE public.product_metrics pm SET avg_lead_time_days = lt.avg_days::int FROM LeadTimes lt WHERE pm.pid = lt.pid AND pm.avg_lead_time_days IS DISTINCT FROM lt.avg_days::int; -- Only update if changed RAISE NOTICE 'Finished Average Lead Time calculation.'; -- 2. Calculate ABC Classification RAISE NOTICE 'Calculating ABC Classification...'; -- Get ABC settings SELECT setting_value INTO _abc_basis FROM public.settings_global WHERE setting_key = 'abc_calculation_basis' LIMIT 1; SELECT setting_value::numeric INTO _threshold_a FROM public.settings_global WHERE setting_key = 'abc_revenue_threshold_a' LIMIT 1; SELECT setting_value::numeric INTO _threshold_b FROM public.settings_global WHERE setting_key = 'abc_revenue_threshold_b' LIMIT 1; _abc_basis := COALESCE(_abc_basis, 'revenue_30d'); -- Default basis _threshold_a := COALESCE(_threshold_a, 0.80); _threshold_b := COALESCE(_threshold_b, 0.95); RAISE NOTICE 'Using ABC Basis: %, Threshold A: %, Threshold B: %', _abc_basis, _threshold_a, _threshold_b; WITH RankedProducts AS ( SELECT pid, -- Dynamically select the metric based on setting CASE _abc_basis WHEN 'sales_30d' THEN COALESCE(sales_30d, 0) WHEN 'lifetime_revenue' THEN COALESCE(lifetime_revenue, 0)::numeric -- Cast needed if different type ELSE COALESCE(revenue_30d, 0) -- Default to revenue_30d END AS metric_value FROM public.product_metrics WHERE is_replenishable = TRUE -- Typically only classify replenishable items ), Cumulative AS ( SELECT pid, metric_value, SUM(metric_value) OVER (ORDER BY metric_value DESC NULLS LAST ROWS BETWEEN UNBOUNDED PRECEDING AND CURRENT ROW) as cumulative_metric, SUM(metric_value) OVER () as total_metric FROM RankedProducts WHERE metric_value > 0 -- Exclude items with no contribution ) UPDATE public.product_metrics pm SET abc_class = CASE WHEN c.cumulative_metric / NULLIF(c.total_metric, 0) <= _threshold_a THEN 'A' WHEN c.cumulative_metric / NULLIF(c.total_metric, 0) <= _threshold_b THEN 'B' ELSE 'C' END FROM Cumulative c WHERE pm.pid = c.pid AND pm.abc_class IS DISTINCT FROM ( -- Only update if changed CASE WHEN c.cumulative_metric / NULLIF(c.total_metric, 0) <= _threshold_a THEN 'A' WHEN c.cumulative_metric / NULLIF(c.total_metric, 0) <= _threshold_b THEN 'B' ELSE 'C' END); -- Set non-contributing or non-replenishable to 'C' or NULL if preferred UPDATE public.product_metrics SET abc_class = 'C' -- Or NULL WHERE abc_class IS NULL AND is_replenishable = TRUE; -- Catch those with 0 metric value UPDATE public.product_metrics SET abc_class = NULL -- Or 'N/A'? WHERE is_replenishable = FALSE AND abc_class IS NOT NULL; -- Unclassify non-replenishable items RAISE NOTICE 'Finished ABC Classification calculation.'; -- Add other periodic calculations here if needed (e.g., recalculating first/last dates) -- 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 % module. Duration: %', _module_name, clock_timestamp() - _start_time; END $$;