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

@@ -178,6 +178,7 @@ CREATE TABLE public.category_metrics (
parent_id INT8, -- Denormalized for convenience parent_id INT8, -- Denormalized for convenience
last_calculated TIMESTAMPTZ NOT NULL DEFAULT NOW(), last_calculated TIMESTAMPTZ NOT NULL DEFAULT NOW(),
-- ROLLED-UP METRICS (includes this category + all descendants)
-- Counts & Basic Info -- Counts & Basic Info
product_count INT NOT NULL DEFAULT 0, -- Total products linked product_count INT NOT NULL DEFAULT 0, -- Total products linked
active_product_count INT NOT NULL DEFAULT 0, -- Visible products linked active_product_count INT NOT NULL DEFAULT 0, -- Visible products linked
@@ -195,7 +196,24 @@ CREATE TABLE public.category_metrics (
sales_365d INT NOT NULL DEFAULT 0, revenue_365d NUMERIC(16, 4) NOT NULL DEFAULT 0.00, sales_365d INT NOT NULL DEFAULT 0, revenue_365d NUMERIC(16, 4) NOT NULL DEFAULT 0.00,
lifetime_sales INT NOT NULL DEFAULT 0, lifetime_revenue NUMERIC(18, 4) NOT NULL DEFAULT 0.00, lifetime_sales INT NOT NULL DEFAULT 0, lifetime_revenue NUMERIC(18, 4) NOT NULL DEFAULT 0.00,
-- Calculated KPIs (Based on 30d aggregates) -- DIRECT METRICS (only products directly in this category)
direct_product_count INT NOT NULL DEFAULT 0, -- Products directly in this category
direct_active_product_count INT NOT NULL DEFAULT 0, -- Visible products directly in this category
direct_replenishable_product_count INT NOT NULL DEFAULT 0,-- Replenishable products directly in this category
-- Direct Current Stock Value
direct_current_stock_units INT NOT NULL DEFAULT 0,
direct_stock_cost NUMERIC(16, 4) NOT NULL DEFAULT 0.00,
direct_stock_retail NUMERIC(16, 4) NOT NULL DEFAULT 0.00,
-- Direct Rolling Period Aggregates
direct_sales_7d INT NOT NULL DEFAULT 0, direct_revenue_7d NUMERIC(16, 4) NOT NULL DEFAULT 0.00,
direct_sales_30d INT NOT NULL DEFAULT 0, direct_revenue_30d NUMERIC(16, 4) NOT NULL DEFAULT 0.00,
direct_profit_30d NUMERIC(16, 4) NOT NULL DEFAULT 0.00, direct_cogs_30d NUMERIC(16, 4) NOT NULL DEFAULT 0.00,
direct_sales_365d INT NOT NULL DEFAULT 0, direct_revenue_365d NUMERIC(16, 4) NOT NULL DEFAULT 0.00,
direct_lifetime_sales INT NOT NULL DEFAULT 0, direct_lifetime_revenue NUMERIC(18, 4) NOT NULL DEFAULT 0.00,
-- Calculated KPIs (Based on 30d aggregates) - Apply to rolled-up metrics
avg_margin_30d NUMERIC(7, 3), -- (profit / revenue) * 100 avg_margin_30d NUMERIC(7, 3), -- (profit / revenue) * 100
stock_turn_30d NUMERIC(10, 3), -- sales_units / avg_stock_units (Needs avg stock calc) stock_turn_30d NUMERIC(10, 3), -- sales_units / avg_stock_units (Needs avg stock calc)
-- growth_rate_30d NUMERIC(7, 3), -- (current 30d rev - prev 30d rev) / prev 30d rev -- growth_rate_30d NUMERIC(7, 3), -- (current 30d rev - prev 30d rev) / prev 30d rev

View File

@@ -8,8 +8,8 @@ const { Pool } = require('pg'); // Assuming you use 'pg'
const RUN_DAILY_SNAPSHOTS = false; const RUN_DAILY_SNAPSHOTS = false;
const RUN_PRODUCT_METRICS = false; const RUN_PRODUCT_METRICS = false;
const RUN_PERIODIC_METRICS = false; const RUN_PERIODIC_METRICS = false;
const RUN_BRAND_METRICS = true; const RUN_BRAND_METRICS = false;
const RUN_VENDOR_METRICS = true; const RUN_VENDOR_METRICS = false;
const RUN_CATEGORY_METRICS = true; const RUN_CATEGORY_METRICS = true;
// Maximum execution time for the entire sequence (e.g., 90 minutes) // Maximum execution time for the entire sequence (e.g., 90 minutes)

View File

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

View File

@@ -106,6 +106,11 @@ interface CategoryMetric {
lifetimeRevenue: string | number; lifetimeRevenue: string | number;
avgMargin_30d: string | number | null; avgMargin_30d: string | number | null;
stockTurn_30d: string | number | null; stockTurn_30d: string | number | null;
direct_active_product_count: number;
direct_current_stock_units: number;
direct_stock_cost: string | number;
direct_revenue_30d: string | number;
direct_profit_30d: string | number;
} }
// Define response type to avoid type errors // Define response type to avoid type errors
@@ -456,6 +461,83 @@ export function Categories() {
const hierarchicalCategories = useMemo(() => { const hierarchicalCategories = useMemo(() => {
if (!categories || categories.length === 0) return []; if (!categories || categories.length === 0) return [];
// DIRECT CALCULATION: Create a map to directly calculate accurate totals
// This approach doesn't rely on the tree structure for calculations
const directTotalsMap = new Map<string | number, {
revenue30d: number,
profit30d: number,
activeProductCount: number,
currentStockUnits: number,
currentStockCost: number
}>();
// First, identify all parent-child relationships
const childToParentMap = new Map<string | number, string | number>();
categories.forEach(cat => {
if (cat.parent_id) {
childToParentMap.set(cat.category_id, cat.parent_id);
}
});
// Build sets of all descendants for each category
const allDescendantsMap = new Map<string | number, Set<string | number>>();
// Helper to get all descendants recursively
const getAllDescendants = (categoryId: string | number): Set<string | number> => {
if (allDescendantsMap.has(categoryId)) {
return allDescendantsMap.get(categoryId)!;
}
const descendants = new Set<string | number>();
// Find direct children
categories.forEach(cat => {
if (cat.parent_id === categoryId) {
descendants.add(cat.category_id);
// Add their descendants recursively
const childDescendants = getAllDescendants(cat.category_id);
childDescendants.forEach(id => descendants.add(id));
}
});
// Cache and return
allDescendantsMap.set(categoryId, descendants);
return descendants;
};
// Calculate descendants for all categories
categories.forEach(cat => {
if (!allDescendantsMap.has(cat.category_id)) {
getAllDescendants(cat.category_id);
}
});
// Now use pre-calculated database values instead of calculating totals directly
categories.forEach(cat => {
// Use the pre-calculated values from the database
const totalRevenue = parseFloat(cat.revenue_30d?.toString() || '0');
const totalProfit = parseFloat(cat.profit_30d?.toString() || '0');
const totalActiveProducts = cat.active_product_count || 0;
const totalStockUnits = cat.current_stock_units || 0;
const totalStockCost = parseFloat(cat.current_stock_cost?.toString() || '0');
// Direct values (for display in tooltips)
const directRevenue = parseFloat(cat.direct_revenue_30d?.toString() || '0');
const directProfit = parseFloat(cat.direct_profit_30d?.toString() || '0');
const directActiveProducts = cat.direct_active_product_count || 0;
const directStockUnits = cat.direct_current_stock_units || 0;
const directStockCost = parseFloat(cat.direct_stock_cost?.toString() || '0');
// Set the pre-calculated totals
directTotalsMap.set(cat.category_id, {
revenue30d: totalRevenue,
profit30d: totalProfit,
activeProductCount: totalActiveProducts,
currentStockUnits: totalStockUnits,
currentStockCost: totalStockCost
});
});
// First, create a lookup map by category ID // First, create a lookup map by category ID
const categoryMap = new Map<string | number, CategoryWithChildren>(); const categoryMap = new Map<string | number, CategoryWithChildren>();
categories.forEach((cat) => { categories.forEach((cat) => {
@@ -476,14 +558,16 @@ export function Categories() {
if (parent) { if (parent) {
parent.children.push(processedCat); parent.children.push(processedCat);
} }
} else if (cat.parent_id) {
// This is an orphaned category
} else { } else {
// This is a root category // This is a root category
rootCategories.push(processedCat); rootCategories.push(processedCat);
} }
}); });
// Compute hierarchy levels and aggregate stats // Set hierarchy levels and use the direct aggregates we calculated
const computeHierarchyAndStats = ( const computeHierarchyAndLevels = (
categories: CategoryWithChildren[], categories: CategoryWithChildren[],
level = 0 level = 0
) => { ) => {
@@ -493,60 +577,49 @@ export function Categories() {
cat.isLast = index === arr.length - 1; cat.isLast = index === arr.length - 1;
cat.isExpanded = expandedCategories.has(cat.category_id); cat.isExpanded = expandedCategories.has(cat.category_id);
// Process children first to ensure we have their aggregated values // Process children to set their hierarchy levels
const children = const children =
cat.children.length > 0 cat.children.length > 0
? computeHierarchyAndStats(cat.children, level + 1) ? computeHierarchyAndLevels(cat.children, level + 1)
: []; : [];
// Calculate this category's own direct stats for clarity // Make sure we set aggregatedStats for ALL categories, not just those with children
const ownStats = { // First check if we have pre-calculated values
activeProductCount: cat.active_product_count || 0, const totals = directTotalsMap.get(cat.category_id);
currentStockUnits: cat.current_stock_units || 0,
currentStockCost: parseFloat(
cat.current_stock_cost?.toString() || "0"
),
revenue30d: parseFloat(cat.revenue_30d?.toString() || "0"),
profit30d: parseFloat(cat.profit_30d?.toString() || "0"),
avg_margin_30d: parseFloat(cat.avg_margin_30d?.toString() || "0"),
};
// For leaf nodes (no children), aggregated stats = own stats if (totals) {
if (children.length === 0) { // Use our pre-calculated totals for all metrics
cat.aggregatedStats = { ...ownStats }; cat.aggregatedStats = {
return cat; activeProductCount: totals.activeProductCount,
currentStockUnits: totals.currentStockUnits,
currentStockCost: totals.currentStockCost,
revenue30d: totals.revenue30d,
profit30d: totals.profit30d,
avg_margin_30d: totals.revenue30d > 0
? (totals.profit30d / totals.revenue30d) * 100
: 0
};
} else {
// If we don't have pre-calculated values (shouldn't happen with our algorithm)
// Ensure every category still has aggregatedStats set with its direct values
cat.aggregatedStats = {
activeProductCount: cat.direct_active_product_count || 0,
currentStockUnits: cat.direct_current_stock_units || 0,
currentStockCost: parseFloat(cat.direct_stock_cost?.toString() || "0"),
revenue30d: parseFloat(cat.direct_revenue_30d?.toString() || "0"),
profit30d: parseFloat(cat.direct_profit_30d?.toString() || "0"),
avg_margin_30d: parseFloat(cat.avg_margin_30d?.toString() || "0")
};
} }
// For parents, calculate aggregated stats = own stats + sum of all children's aggregated stats
const aggregatedStats = { ...ownStats }; // Start with own stats
// Add all children's AGGREGATED stats (not direct stats)
children.forEach((child) => {
if (child.aggregatedStats) {
aggregatedStats.activeProductCount +=
child.aggregatedStats.activeProductCount;
aggregatedStats.currentStockUnits +=
child.aggregatedStats.currentStockUnits;
aggregatedStats.currentStockCost +=
child.aggregatedStats.currentStockCost;
aggregatedStats.revenue30d += child.aggregatedStats.revenue30d;
aggregatedStats.profit30d += child.aggregatedStats.profit30d;
}
});
// Recalculate margin based on total profit and revenue
if (aggregatedStats.revenue30d > 0) {
aggregatedStats.avg_margin_30d =
(aggregatedStats.profit30d / aggregatedStats.revenue30d) * 100;
}
cat.aggregatedStats = aggregatedStats;
return cat; return cat;
}); });
}; };
// Compute hierarchy levels and aggregate stats for all categories // Apply hierarchy levels and use our pre-calculated totals
return computeHierarchyAndStats(rootCategories); const result = computeHierarchyAndLevels(rootCategories);
return result;
}, [categories, expandedCategories]); }, [categories, expandedCategories]);
// Recursive function to render category rows with streamlined stat display // Recursive function to render category rows with streamlined stat display
@@ -636,7 +709,7 @@ export function Categories() {
</p> </p>
<p> <p>
Directly in '{category.category_name}':{" "} Directly in '{category.category_name}':{" "}
{formatNumber(category.active_product_count)} {formatNumber(category.direct_active_product_count)}
</p> </p>
</TooltipContent> </TooltipContent>
</Tooltip> </Tooltip>
@@ -662,7 +735,7 @@ export function Categories() {
</p> </p>
<p> <p>
Directly in '{category.category_name}':{" "} Directly in '{category.category_name}':{" "}
{formatNumber(category.current_stock_units)} {formatNumber(category.direct_current_stock_units)}
</p> </p>
</TooltipContent> </TooltipContent>
</Tooltip> </Tooltip>
@@ -687,7 +760,7 @@ export function Categories() {
</p> </p>
<p> <p>
Directly in '{category.category_name}':{" "} Directly in '{category.category_name}':{" "}
{formatCurrency(category.current_stock_cost)} {formatCurrency(category.direct_stock_cost)}
</p> </p>
</TooltipContent> </TooltipContent>
</Tooltip> </Tooltip>
@@ -712,12 +785,12 @@ export function Categories() {
</p> </p>
<p> <p>
Directly from '{category.category_name}':{" "} Directly from '{category.category_name}':{" "}
{formatCurrency(category.revenue_30d)} {formatCurrency(category.direct_revenue_30d)}
</p> </p>
</TooltipContent> </TooltipContent>
</Tooltip> </Tooltip>
) : ( ) : (
formatCurrency(category.revenue_30d) formatCurrency(category.aggregatedStats ? category.aggregatedStats.revenue30d : category.revenue_30d)
)} )}
</TableCell> </TableCell>
@@ -737,12 +810,12 @@ export function Categories() {
</p> </p>
<p> <p>
Directly from '{category.category_name}':{" "} Directly from '{category.category_name}':{" "}
{formatCurrency(category.profit_30d)} {formatCurrency(category.direct_profit_30d)}
</p> </p>
</TooltipContent> </TooltipContent>
</Tooltip> </Tooltip>
) : ( ) : (
formatCurrency(category.profit_30d) formatCurrency(category.aggregatedStats ? category.aggregatedStats.profit30d : category.profit_30d)
)} )}
</TableCell> </TableCell>