Fix calculate errors

This commit is contained in:
2025-02-01 23:38:13 -05:00
parent 0a51328da2
commit bd5bcdd548
6 changed files with 92 additions and 92 deletions

View File

@@ -151,7 +151,7 @@ async function calculateCategoryMetrics(startTime, totalProducts, processedCount
WITH current_period AS (
SELECT
pc.cat_id,
SUM(o.quantity * o.price) / (1 + COALESCE(ss.seasonality_factor, 0)) as revenue
SUM(o.quantity * o.price / (1 + COALESCE(ss.seasonality_factor, 0))) as revenue
FROM product_categories pc
JOIN products p ON pc.pid = p.pid
JOIN orders o ON p.pid = o.pid
@@ -163,7 +163,7 @@ async function calculateCategoryMetrics(startTime, totalProducts, processedCount
previous_period AS (
SELECT
pc.cat_id,
SUM(o.quantity * o.price) / (1 + COALESCE(ss.seasonality_factor, 0)) as revenue
SUM(o.quantity * o.price / (1 + COALESCE(ss.seasonality_factor, 0))) as revenue
FROM product_categories pc
JOIN products p ON pc.pid = p.pid
JOIN orders o ON p.pid = o.pid
@@ -177,7 +177,7 @@ async function calculateCategoryMetrics(startTime, totalProducts, processedCount
SELECT
pc.cat_id,
MONTH(o.date) as month,
SUM(o.quantity * o.price) / (1 + COALESCE(ss.seasonality_factor, 0)) as revenue,
SUM(o.quantity * o.price / (1 + COALESCE(ss.seasonality_factor, 0))) as revenue,
COUNT(DISTINCT DATE(o.date)) as days_in_month
FROM product_categories pc
JOIN products p ON pc.pid = p.pid
@@ -187,14 +187,24 @@ async function calculateCategoryMetrics(startTime, totalProducts, processedCount
AND o.date >= DATE_SUB(CURRENT_DATE, INTERVAL 15 MONTH)
GROUP BY pc.cat_id, MONTH(o.date)
),
trend_analysis AS (
trend_stats AS (
SELECT
cat_id,
REGR_SLOPE(revenue / days_in_month, MONTH) as trend_slope,
AVG(revenue / days_in_month) as avg_daily_revenue
COUNT(*) as n,
AVG(month) as avg_x,
AVG(revenue / days_in_month) as avg_y,
SUM(month * (revenue / days_in_month)) as sum_xy,
SUM(month * month) as sum_xx
FROM trend_data
GROUP BY cat_id
HAVING COUNT(*) >= 6
),
trend_analysis AS (
SELECT
cat_id,
((n * sum_xy) - (avg_x * n * avg_y)) / ((n * sum_xx) - (n * avg_x * avg_x)) as trend_slope,
avg_y as avg_daily_revenue
FROM trend_stats
)
UPDATE category_metrics cm
LEFT JOIN current_period cp ON cm.category_id = cp.cat_id
@@ -265,13 +275,23 @@ async function calculateCategoryMetrics(startTime, totalProducts, processedCount
COUNT(DISTINCT CASE WHEN p.visible = true THEN p.pid END) as active_products,
SUM(p.stock_quantity * p.cost_price) as total_value,
SUM(o.quantity * o.price) as total_revenue,
CASE
WHEN SUM(o.quantity * o.price) > 0 THEN
LEAST(
GREATEST(
SUM(o.quantity * (o.price - GREATEST(p.cost_price, 0))) * 100.0 /
SUM(o.quantity * o.price),
-100
),
100
)
ELSE 0
END as avg_margin,
COALESCE(
SUM(o.quantity * (o.price - p.cost_price)) * 100.0 /
NULLIF(SUM(o.quantity * o.price), 0),
0
) as avg_margin,
COALESCE(
SUM(o.quantity) / NULLIF(AVG(GREATEST(p.stock_quantity, 0)), 0),
LEAST(
SUM(o.quantity) / NULLIF(AVG(GREATEST(p.stock_quantity, 0)), 0),
999.99
),
0
) as turnover_rate
FROM product_categories pc
@@ -286,8 +306,7 @@ async function calculateCategoryMetrics(startTime, totalProducts, processedCount
total_value = VALUES(total_value),
total_revenue = VALUES(total_revenue),
avg_margin = VALUES(avg_margin),
turnover_rate = VALUES(turnover_rate),
last_calculated_at = CURRENT_TIMESTAMP
turnover_rate = VALUES(turnover_rate)
`);
processedCount = Math.floor(totalProducts * 0.99);
@@ -342,7 +361,7 @@ async function calculateCategoryMetrics(startTime, totalProducts, processedCount
sales_data AS (
SELECT
pc.cat_id,
p.brand,
COALESCE(p.brand, 'Unknown') as brand,
dr.period_start,
dr.period_end,
COUNT(DISTINCT p.pid) as num_products,