Category calculation fixes

This commit is contained in:
2025-04-02 15:42:20 -04:00
parent 6051b849d6
commit 2601a04211
4 changed files with 304 additions and 122 deletions

View File

@@ -6,6 +6,7 @@ DO $$
DECLARE
_module_name VARCHAR := 'category_metrics';
_start_time TIMESTAMPTZ := clock_timestamp();
_min_revenue NUMERIC := 50.00; -- Minimum revenue threshold for margin calculation
BEGIN
RAISE NOTICE 'Running % calculation...', _module_name;
@@ -44,7 +45,8 @@ BEGIN
)
),
-- Calculate metrics only at the most specific category level for each product
CategoryAggregates AS (
-- These are the direct metrics (only products directly in this category)
DirectCategoryMetrics AS (
SELECT
pdc.cat_id,
-- Counts
@@ -72,95 +74,171 @@ BEGIN
JOIN ProductDeepestCategory pdc ON pm.pid = pdc.pid
GROUP BY pdc.cat_id
),
-- Use a flat approach to build the complete category tree with aggregate values
CategoryTree AS (
WITH RECURSIVE CategoryHierarchy AS (
-- Build a category lookup table for parent relationships
CategoryHierarchyPaths AS (
WITH RECURSIVE ParentPaths AS (
-- Base case: All categories with their immediate parents
SELECT
c.cat_id,
c.name,
c.parent_id,
c.cat_id as leaf_id, -- Track original leaf category
ARRAY[c.cat_id] as path
FROM public.categories c
cat_id,
cat_id as leaf_id, -- Every category is its own leaf initially
ARRAY[cat_id] as path
FROM public.categories
UNION ALL
-- Recursive step: Walk up the parent chain
SELECT
p.cat_id,
p.name,
p.parent_id,
ch.leaf_id, -- Keep track of the original leaf
p.cat_id || ch.path
FROM public.categories p
JOIN CategoryHierarchy ch ON p.cat_id = ch.parent_id
c.parent_id as cat_id,
pp.leaf_id, -- Keep the original leaf_id
c.parent_id || pp.path as path
FROM ParentPaths pp
JOIN public.categories c ON pp.cat_id = c.cat_id
WHERE c.parent_id IS NOT NULL -- Stop at root categories
)
SELECT
ch.cat_id,
ch.leaf_id
FROM CategoryHierarchy ch
-- Select distinct paths to avoid duplication
SELECT DISTINCT cat_id, leaf_id
FROM ParentPaths
),
-- Now aggregate by maintaining the link between leaf categories and ancestors
-- Aggregate metrics from leaf categories to their ancestors without duplication
-- These are the rolled-up metrics (including all child categories)
RollupMetrics AS (
SELECT
ct.cat_id,
SUM(ca.product_count) AS product_count,
SUM(ca.active_product_count) AS active_product_count,
SUM(ca.replenishable_product_count) AS replenishable_product_count,
SUM(ca.current_stock_units) AS current_stock_units,
SUM(ca.current_stock_cost) AS current_stock_cost,
SUM(ca.current_stock_retail) AS current_stock_retail,
SUM(ca.sales_7d) AS sales_7d,
SUM(ca.revenue_7d) AS revenue_7d,
SUM(ca.sales_30d) AS sales_30d,
SUM(ca.revenue_30d) AS revenue_30d,
SUM(ca.cogs_30d) AS cogs_30d,
SUM(ca.profit_30d) AS profit_30d,
SUM(ca.sales_365d) AS sales_365d,
SUM(ca.revenue_365d) AS revenue_365d,
SUM(ca.lifetime_sales) AS lifetime_sales,
SUM(ca.lifetime_revenue) AS lifetime_revenue,
SUM(ca.total_avg_stock_units_30d) AS total_avg_stock_units_30d
FROM CategoryTree ct
JOIN CategoryAggregates ca ON ct.leaf_id = ca.cat_id
GROUP BY ct.cat_id
chp.cat_id,
-- For each parent category, count distinct products to avoid duplication
COUNT(DISTINCT dcm.cat_id) AS child_categories_count,
SUM(dcm.product_count) AS rollup_product_count,
SUM(dcm.active_product_count) AS rollup_active_product_count,
SUM(dcm.replenishable_product_count) AS rollup_replenishable_product_count,
SUM(dcm.current_stock_units) AS rollup_current_stock_units,
SUM(dcm.current_stock_cost) AS rollup_current_stock_cost,
SUM(dcm.current_stock_retail) AS rollup_current_stock_retail,
SUM(dcm.sales_7d) AS rollup_sales_7d,
SUM(dcm.revenue_7d) AS rollup_revenue_7d,
SUM(dcm.sales_30d) AS rollup_sales_30d,
SUM(dcm.revenue_30d) AS rollup_revenue_30d,
SUM(dcm.cogs_30d) AS rollup_cogs_30d,
SUM(dcm.profit_30d) AS rollup_profit_30d,
SUM(dcm.sales_365d) AS rollup_sales_365d,
SUM(dcm.revenue_365d) AS rollup_revenue_365d,
SUM(dcm.lifetime_sales) AS rollup_lifetime_sales,
SUM(dcm.lifetime_revenue) AS rollup_lifetime_revenue,
SUM(dcm.total_avg_stock_units_30d) AS rollup_total_avg_stock_units_30d
FROM CategoryHierarchyPaths chp
JOIN DirectCategoryMetrics dcm ON chp.leaf_id = dcm.cat_id
GROUP BY chp.cat_id
),
-- Combine direct and rollup metrics
CombinedMetrics AS (
SELECT
c.cat_id,
c.name,
c.type,
c.parent_id,
-- Direct metrics (just this category)
COALESCE(dcm.product_count, 0) AS direct_product_count,
COALESCE(dcm.active_product_count, 0) AS direct_active_product_count,
COALESCE(dcm.replenishable_product_count, 0) AS direct_replenishable_product_count,
COALESCE(dcm.current_stock_units, 0) AS direct_current_stock_units,
COALESCE(dcm.current_stock_cost, 0) AS direct_current_stock_cost,
COALESCE(dcm.current_stock_retail, 0) AS direct_current_stock_retail,
COALESCE(dcm.sales_7d, 0) AS direct_sales_7d,
COALESCE(dcm.revenue_7d, 0) AS direct_revenue_7d,
COALESCE(dcm.sales_30d, 0) AS direct_sales_30d,
COALESCE(dcm.revenue_30d, 0) AS direct_revenue_30d,
COALESCE(dcm.cogs_30d, 0) AS direct_cogs_30d,
COALESCE(dcm.profit_30d, 0) AS direct_profit_30d,
COALESCE(dcm.sales_365d, 0) AS direct_sales_365d,
COALESCE(dcm.revenue_365d, 0) AS direct_revenue_365d,
COALESCE(dcm.lifetime_sales, 0) AS direct_lifetime_sales,
COALESCE(dcm.lifetime_revenue, 0) AS direct_lifetime_revenue,
COALESCE(dcm.total_avg_stock_units_30d, 0) AS direct_avg_stock_units_30d,
-- Rolled up metrics (this category + all children)
COALESCE(rm.rollup_product_count, 0) AS product_count,
COALESCE(rm.rollup_active_product_count, 0) AS active_product_count,
COALESCE(rm.rollup_replenishable_product_count, 0) AS replenishable_product_count,
COALESCE(rm.rollup_current_stock_units, 0) AS current_stock_units,
COALESCE(rm.rollup_current_stock_cost, 0) AS current_stock_cost,
COALESCE(rm.rollup_current_stock_retail, 0) AS current_stock_retail,
COALESCE(rm.rollup_sales_7d, 0) AS sales_7d,
COALESCE(rm.rollup_revenue_7d, 0) AS revenue_7d,
COALESCE(rm.rollup_sales_30d, 0) AS sales_30d,
COALESCE(rm.rollup_revenue_30d, 0) AS revenue_30d,
COALESCE(rm.rollup_cogs_30d, 0) AS cogs_30d,
COALESCE(rm.rollup_profit_30d, 0) AS profit_30d,
COALESCE(rm.rollup_sales_365d, 0) AS sales_365d,
COALESCE(rm.rollup_revenue_365d, 0) AS revenue_365d,
COALESCE(rm.rollup_lifetime_sales, 0) AS lifetime_sales,
COALESCE(rm.rollup_lifetime_revenue, 0) AS lifetime_revenue,
COALESCE(rm.rollup_total_avg_stock_units_30d, 0) AS total_avg_stock_units_30d
FROM public.categories c
LEFT JOIN DirectCategoryMetrics dcm ON c.cat_id = dcm.cat_id
LEFT JOIN RollupMetrics rm ON c.cat_id = rm.cat_id
)
INSERT INTO public.category_metrics (
category_id, category_name, category_type, parent_id, last_calculated,
-- Store all direct and rolled up metrics
product_count, active_product_count, replenishable_product_count,
current_stock_units, current_stock_cost, current_stock_retail,
sales_7d, revenue_7d, sales_30d, revenue_30d, profit_30d, cogs_30d,
sales_365d, revenue_365d, lifetime_sales, lifetime_revenue,
-- Also store direct metrics with direct_ prefix
direct_product_count, direct_active_product_count, direct_replenishable_product_count,
direct_current_stock_units, direct_stock_cost, direct_stock_retail,
direct_sales_7d, direct_revenue_7d, direct_sales_30d, direct_revenue_30d,
direct_profit_30d, direct_cogs_30d, direct_sales_365d, direct_revenue_365d,
direct_lifetime_sales, direct_lifetime_revenue,
-- KPIs
avg_margin_30d, stock_turn_30d
)
SELECT
c.cat_id,
c.name,
c.type,
c.parent_id,
cm.cat_id,
cm.name,
cm.type,
cm.parent_id,
_start_time,
-- Base Aggregates
COALESCE(rm.product_count, 0),
COALESCE(rm.active_product_count, 0),
COALESCE(rm.replenishable_product_count, 0),
COALESCE(rm.current_stock_units, 0),
COALESCE(rm.current_stock_cost, 0.00),
COALESCE(rm.current_stock_retail, 0.00),
COALESCE(rm.sales_7d, 0), COALESCE(rm.revenue_7d, 0.00),
COALESCE(rm.sales_30d, 0), COALESCE(rm.revenue_30d, 0.00),
COALESCE(rm.profit_30d, 0.00), COALESCE(rm.cogs_30d, 0.00),
COALESCE(rm.sales_365d, 0), COALESCE(rm.revenue_365d, 0.00),
COALESCE(rm.lifetime_sales, 0), COALESCE(rm.lifetime_revenue, 0.00),
-- KPIs
(rm.profit_30d / NULLIF(rm.revenue_30d, 0)) * 100.0,
rm.sales_30d / NULLIF(rm.total_avg_stock_units_30d, 0) -- Simple unit-based turnover
FROM public.categories c -- Start from categories to include those with no products yet
LEFT JOIN RollupMetrics rm ON c.cat_id = rm.cat_id
-- Rolled-up metrics (total including children)
cm.product_count,
cm.active_product_count,
cm.replenishable_product_count,
cm.current_stock_units,
cm.current_stock_cost,
cm.current_stock_retail,
cm.sales_7d, cm.revenue_7d,
cm.sales_30d, cm.revenue_30d, cm.profit_30d, cm.cogs_30d,
cm.sales_365d, cm.revenue_365d,
cm.lifetime_sales, cm.lifetime_revenue,
-- Direct metrics (just this category)
cm.direct_product_count,
cm.direct_active_product_count,
cm.direct_replenishable_product_count,
cm.direct_current_stock_units,
cm.direct_current_stock_cost,
cm.direct_current_stock_retail,
cm.direct_sales_7d, cm.direct_revenue_7d,
cm.direct_sales_30d, cm.direct_revenue_30d, cm.direct_profit_30d, cm.direct_cogs_30d,
cm.direct_sales_365d, cm.direct_revenue_365d,
cm.direct_lifetime_sales, cm.direct_lifetime_revenue,
-- KPIs - Calculate margin only for categories with significant revenue
CASE
WHEN cm.revenue_30d >= _min_revenue THEN
((cm.revenue_30d - cm.cogs_30d) / cm.revenue_30d) * 100.0
ELSE NULL -- No margin for low/no revenue categories
END,
-- Stock Turn calculation
CASE
WHEN cm.total_avg_stock_units_30d > 0 THEN
cm.sales_30d / cm.total_avg_stock_units_30d
ELSE NULL -- No stock turn if no average stock
END
FROM CombinedMetrics cm
ON CONFLICT (category_id) DO UPDATE SET
category_name = EXCLUDED.category_name,
category_type = EXCLUDED.category_type,
parent_id = EXCLUDED.parent_id,
last_calculated = EXCLUDED.last_calculated,
-- Update rolled-up metrics
product_count = EXCLUDED.product_count,
active_product_count = EXCLUDED.active_product_count,
replenishable_product_count = EXCLUDED.replenishable_product_count,
@@ -172,6 +250,19 @@ 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,
-- Update direct metrics
direct_product_count = EXCLUDED.direct_product_count,
direct_active_product_count = EXCLUDED.direct_active_product_count,
direct_replenishable_product_count = EXCLUDED.direct_replenishable_product_count,
direct_current_stock_units = EXCLUDED.direct_current_stock_units,
direct_stock_cost = EXCLUDED.direct_stock_cost,
direct_stock_retail = EXCLUDED.direct_stock_retail,
direct_sales_7d = EXCLUDED.direct_sales_7d, direct_revenue_7d = EXCLUDED.direct_revenue_7d,
direct_sales_30d = EXCLUDED.direct_sales_30d, direct_revenue_30d = EXCLUDED.direct_revenue_30d,
direct_profit_30d = EXCLUDED.direct_profit_30d, direct_cogs_30d = EXCLUDED.direct_cogs_30d,
direct_sales_365d = EXCLUDED.direct_sales_365d, direct_revenue_365d = EXCLUDED.direct_revenue_365d,
direct_lifetime_sales = EXCLUDED.direct_lifetime_sales, direct_lifetime_revenue = EXCLUDED.direct_lifetime_revenue,
-- Update KPIs
avg_margin_30d = EXCLUDED.avg_margin_30d,
stock_turn_30d = EXCLUDED.stock_turn_30d;