Fix calculate script regressions
This commit is contained in:
@@ -102,9 +102,18 @@ async function calculateBrandMetrics(startTime, totalProducts, processedCount, i
|
||||
SUM(p.valid_stock * p.price) as total_stock_retail,
|
||||
COALESCE(SUM(o.quantity * (o.price - COALESCE(o.discount, 0))), 0) as total_revenue,
|
||||
CASE
|
||||
WHEN SUM(o.quantity * (o.price - COALESCE(o.discount, 0))) > 0
|
||||
THEN (SUM(o.quantity * (o.price - COALESCE(o.discount, 0) - p.cost_price)) * 100.0) /
|
||||
SUM(o.quantity * (o.price - COALESCE(o.discount, 0)))
|
||||
WHEN SUM(o.quantity * o.price) > 0
|
||||
THEN GREATEST(
|
||||
-100.0,
|
||||
LEAST(
|
||||
100.0,
|
||||
(
|
||||
SUM(o.quantity * o.price) - -- Use gross revenue (before discounts)
|
||||
SUM(o.quantity * COALESCE(p.cost_price, 0)) -- Total costs
|
||||
) * 100.0 /
|
||||
NULLIF(SUM(o.quantity * o.price), 0) -- Divide by gross revenue
|
||||
)
|
||||
)
|
||||
ELSE 0
|
||||
END as avg_margin
|
||||
FROM filtered_products p
|
||||
@@ -209,8 +218,18 @@ async function calculateBrandMetrics(startTime, totalProducts, processedCount, i
|
||||
SUM(p.valid_stock * p.price) as total_stock_retail,
|
||||
SUM(o.quantity * o.price) as total_revenue,
|
||||
CASE
|
||||
WHEN SUM(o.quantity * o.price) > 0 THEN
|
||||
(SUM((o.price - p.cost_price) * o.quantity) * 100.0) / SUM(o.price * o.quantity)
|
||||
WHEN SUM(o.quantity * o.price) > 0
|
||||
THEN GREATEST(
|
||||
-100.0,
|
||||
LEAST(
|
||||
100.0,
|
||||
(
|
||||
SUM(o.quantity * o.price) - -- Use gross revenue (before discounts)
|
||||
SUM(o.quantity * COALESCE(p.cost_price, 0)) -- Total costs
|
||||
) * 100.0 /
|
||||
NULLIF(SUM(o.quantity * o.price), 0) -- Divide by gross revenue
|
||||
)
|
||||
)
|
||||
ELSE 0
|
||||
END as avg_margin
|
||||
FROM filtered_products p
|
||||
|
||||
@@ -153,6 +153,7 @@ async function calculateCategoryMetrics(startTime, totalProducts, processedCount
|
||||
pc.cat_id,
|
||||
SUM(o.quantity * (o.price - COALESCE(o.discount, 0)) /
|
||||
(1 + COALESCE(ss.seasonality_factor, 0))) as revenue,
|
||||
SUM(o.quantity * (o.price - COALESCE(o.discount, 0) - p.cost_price)) as gross_profit,
|
||||
COUNT(DISTINCT DATE(o.date)) as days
|
||||
FROM product_categories pc
|
||||
JOIN products p ON pc.pid = p.pid
|
||||
@@ -211,11 +212,37 @@ async function calculateCategoryMetrics(startTime, totalProducts, processedCount
|
||||
NULLIF((n * sum_xx) - (n * avg_x * avg_x), 0) as trend_slope,
|
||||
avg_y as avg_daily_revenue
|
||||
FROM trend_stats
|
||||
),
|
||||
margin_calc AS (
|
||||
SELECT
|
||||
pc.cat_id,
|
||||
CASE
|
||||
WHEN SUM(o.quantity * o.price) > 0 THEN
|
||||
GREATEST(
|
||||
-100.0,
|
||||
LEAST(
|
||||
100.0,
|
||||
(
|
||||
SUM(o.quantity * o.price) - -- Use gross revenue (before discounts)
|
||||
SUM(o.quantity * COALESCE(p.cost_price, 0)) -- Total costs
|
||||
) * 100.0 /
|
||||
NULLIF(SUM(o.quantity * o.price), 0) -- Divide by gross revenue
|
||||
)
|
||||
)
|
||||
ELSE NULL
|
||||
END as avg_margin
|
||||
FROM product_categories pc
|
||||
JOIN products p ON pc.pid = p.pid
|
||||
JOIN orders o ON p.pid = o.pid
|
||||
WHERE o.canceled = false
|
||||
AND o.date >= DATE_SUB(CURRENT_DATE, INTERVAL 3 MONTH)
|
||||
GROUP BY pc.cat_id
|
||||
)
|
||||
UPDATE category_metrics cm
|
||||
LEFT JOIN current_period cp ON cm.category_id = cp.cat_id
|
||||
LEFT JOIN previous_period pp ON cm.category_id = pp.cat_id
|
||||
LEFT JOIN trend_analysis ta ON cm.category_id = ta.cat_id
|
||||
LEFT JOIN margin_calc mc ON cm.category_id = mc.cat_id
|
||||
SET
|
||||
cm.growth_rate = CASE
|
||||
WHEN pp.revenue = 0 AND COALESCE(cp.revenue, 0) > 0 THEN 100.0
|
||||
@@ -238,12 +265,7 @@ async function calculateCategoryMetrics(startTime, totalProducts, processedCount
|
||||
)
|
||||
)
|
||||
END,
|
||||
cm.avg_margin = CASE
|
||||
WHEN cp.revenue > 0 THEN
|
||||
(SUM(o.quantity * (o.price - COALESCE(o.discount, 0) - p.cost_price)) /
|
||||
NULLIF(SUM(o.quantity * (o.price - COALESCE(o.discount, 0))), 0)) * 100
|
||||
ELSE cm.avg_margin
|
||||
END,
|
||||
cm.avg_margin = COALESCE(mc.avg_margin, cm.avg_margin),
|
||||
cm.last_calculated_at = NOW()
|
||||
WHERE cp.cat_id IS NOT NULL OR pp.cat_id IS NOT NULL
|
||||
`);
|
||||
|
||||
@@ -315,12 +315,12 @@ async function calculateProductMetrics(startTime, totalProducts, processedCount
|
||||
pid BIGINT NOT NULL,
|
||||
total_revenue DECIMAL(10,3),
|
||||
rank_num INT,
|
||||
dense_rank INT,
|
||||
dense_rank_num INT,
|
||||
percentile DECIMAL(5,2),
|
||||
total_count INT,
|
||||
PRIMARY KEY (pid),
|
||||
INDEX (rank_num),
|
||||
INDEX (dense_rank),
|
||||
INDEX (dense_rank_num),
|
||||
INDEX (percentile)
|
||||
) ENGINE=MEMORY
|
||||
`);
|
||||
@@ -335,7 +335,7 @@ async function calculateProductMetrics(startTime, totalProducts, processedCount
|
||||
COUNT(*) OVER () as total_count,
|
||||
PERCENT_RANK() OVER (ORDER BY total_revenue DESC) * 100 as percentile,
|
||||
RANK() OVER (ORDER BY total_revenue DESC) as rank_num,
|
||||
DENSE_RANK() OVER (ORDER BY total_revenue DESC) as dense_rank
|
||||
DENSE_RANK() OVER (ORDER BY total_revenue DESC) as dense_rank_num
|
||||
FROM product_metrics
|
||||
WHERE total_revenue > 0
|
||||
)
|
||||
@@ -343,7 +343,7 @@ async function calculateProductMetrics(startTime, totalProducts, processedCount
|
||||
pid,
|
||||
total_revenue,
|
||||
rank_num,
|
||||
dense_rank,
|
||||
dense_rank_num,
|
||||
percentile,
|
||||
total_count
|
||||
FROM revenue_data
|
||||
|
||||
@@ -170,7 +170,11 @@ async function calculateSalesForecasts(startTime, totalProducts, processedCount,
|
||||
STDDEV(ds.daily_revenue) as std_daily_revenue,
|
||||
MIN(ds.daily_quantity) as min_daily_qty,
|
||||
MAX(ds.daily_quantity) as max_daily_qty,
|
||||
AVG(ABS(ds.daily_quantity - LAG(ds.daily_quantity) OVER (PARTITION BY ds.pid ORDER BY ds.day_of_week))) as avg_daily_variance
|
||||
-- Calculate variance without using LAG
|
||||
COALESCE(
|
||||
STDDEV(ds.daily_quantity) / NULLIF(AVG(ds.daily_quantity), 0),
|
||||
0
|
||||
) as daily_variance_ratio
|
||||
FROM temp_daily_sales ds
|
||||
GROUP BY ds.pid
|
||||
HAVING AVG(ds.daily_quantity) > 0
|
||||
@@ -211,11 +215,11 @@ async function calculateSalesForecasts(startTime, totalProducts, processedCount,
|
||||
)
|
||||
) as forecast_revenue,
|
||||
CASE
|
||||
WHEN ds.total_days >= 60 AND ds.avg_daily_variance / NULLIF(ds.avg_daily_qty, 0) < 0.5 THEN 90
|
||||
WHEN ds.total_days >= 60 AND ds.daily_variance_ratio < 0.5 THEN 90
|
||||
WHEN ds.total_days >= 60 THEN 85
|
||||
WHEN ds.total_days >= 30 AND ds.avg_daily_variance / NULLIF(ds.avg_daily_qty, 0) < 0.5 THEN 80
|
||||
WHEN ds.total_days >= 30 AND ds.daily_variance_ratio < 0.5 THEN 80
|
||||
WHEN ds.total_days >= 30 THEN 75
|
||||
WHEN ds.total_days >= 14 AND ds.avg_daily_variance / NULLIF(ds.avg_daily_qty, 0) < 0.5 THEN 70
|
||||
WHEN ds.total_days >= 14 AND ds.daily_variance_ratio < 0.5 THEN 70
|
||||
WHEN ds.total_days >= 14 THEN 65
|
||||
ELSE 60
|
||||
END as confidence_level,
|
||||
|
||||
@@ -66,6 +66,13 @@ async function calculateTimeAggregates(startTime, totalProducts, processedCount,
|
||||
SUM(COALESCE(p.cost_price, 0) * o.quantity) as total_cost,
|
||||
COUNT(DISTINCT o.order_number) as order_count,
|
||||
AVG(o.price - COALESCE(o.discount, 0)) as avg_price,
|
||||
CASE
|
||||
WHEN SUM((o.price - COALESCE(o.discount, 0)) * o.quantity) > 0
|
||||
THEN ((SUM((o.price - COALESCE(o.discount, 0)) * o.quantity) - SUM(COALESCE(p.cost_price, 0) * o.quantity))
|
||||
/ SUM((o.price - COALESCE(o.discount, 0)) * o.quantity)) * 100
|
||||
ELSE 0
|
||||
END as profit_margin,
|
||||
p.cost_price * p.stock_quantity as inventory_value,
|
||||
COUNT(DISTINCT DATE(o.date)) as active_days
|
||||
FROM orders o
|
||||
JOIN products p ON o.pid = p.pid
|
||||
@@ -90,8 +97,8 @@ async function calculateTimeAggregates(startTime, totalProducts, processedCount,
|
||||
s.total_revenue,
|
||||
s.total_cost,
|
||||
s.order_count,
|
||||
COALESCE(p.stock_received, 0) as stock_received,
|
||||
COALESCE(p.stock_ordered, 0) as stock_ordered,
|
||||
COALESCE(ms.stock_received, 0) as stock_received,
|
||||
COALESCE(ms.stock_ordered, 0) as stock_ordered,
|
||||
s.avg_price,
|
||||
s.profit_margin,
|
||||
s.inventory_value,
|
||||
@@ -100,11 +107,11 @@ async function calculateTimeAggregates(startTime, totalProducts, processedCount,
|
||||
(s.total_revenue - s.total_cost) / s.inventory_value
|
||||
ELSE 0
|
||||
END as gmroi
|
||||
FROM sales_data s
|
||||
LEFT JOIN purchase_data p
|
||||
ON s.pid = p.pid
|
||||
AND s.year = p.year
|
||||
AND s.month = p.month
|
||||
FROM monthly_sales s
|
||||
LEFT JOIN monthly_stock ms
|
||||
ON s.pid = ms.pid
|
||||
AND s.year = ms.year
|
||||
AND s.month = ms.month
|
||||
UNION
|
||||
SELECT
|
||||
p.pid,
|
||||
@@ -120,8 +127,8 @@ async function calculateTimeAggregates(startTime, totalProducts, processedCount,
|
||||
0 as profit_margin,
|
||||
(SELECT cost_price * stock_quantity FROM products WHERE pid = p.pid) as inventory_value,
|
||||
0 as gmroi
|
||||
FROM purchase_data p
|
||||
LEFT JOIN sales_data s
|
||||
FROM monthly_stock p
|
||||
LEFT JOIN monthly_sales s
|
||||
ON p.pid = s.pid
|
||||
AND p.year = s.year
|
||||
AND p.month = s.month
|
||||
|
||||
Reference in New Issue
Block a user