Optimize and fix calculate scripts

This commit is contained in:
2025-01-27 13:16:21 -05:00
parent 5781b45f37
commit 8323ae7703
10 changed files with 748 additions and 962 deletions

View File

@@ -15,98 +15,104 @@ async function calculateCategoryMetrics(startTime, totalProducts, processedCount
percentage: '85'
});
// Calculate category performance metrics
// First, calculate base category metrics
await connection.query(`
INSERT INTO category_metrics (
category_id,
product_count,
active_products,
total_value,
avg_margin,
turnover_rate,
growth_rate,
status
)
WITH category_sales AS (
SELECT
c.cat_id as category_id,
COUNT(DISTINCT p.pid) as product_count,
COUNT(DISTINCT CASE WHEN p.visible = true THEN p.pid END) as active_products,
SUM(p.stock_quantity * p.cost_price) as total_value,
CASE
WHEN SUM(o.price * o.quantity) > 0
THEN (SUM((o.price - p.cost_price) * o.quantity) * 100.0) / SUM(o.price * o.quantity)
ELSE 0
END as avg_margin,
CASE
WHEN AVG(GREATEST(p.stock_quantity, 0)) >= 0.01
THEN LEAST(
SUM(CASE
WHEN o.date >= DATE_SUB(CURRENT_DATE, INTERVAL 1 YEAR)
THEN COALESCE(o.quantity, 0)
ELSE 0
END) /
GREATEST(
AVG(GREATEST(p.stock_quantity, 0)),
1.0
),
999.99
)
ELSE 0
END as turnover_rate,
-- Current period (last 3 months)
SUM(CASE
WHEN o.date >= DATE_SUB(CURRENT_DATE, INTERVAL 3 MONTH)
THEN COALESCE(o.quantity * o.price, 0)
ELSE 0
END) as current_period_sales,
-- Previous year same period
SUM(CASE
WHEN o.date BETWEEN DATE_SUB(CURRENT_DATE, INTERVAL 15 MONTH) AND DATE_SUB(CURRENT_DATE, INTERVAL 12 MONTH)
THEN COALESCE(o.quantity * o.price, 0)
ELSE 0
END) as previous_year_period_sales,
c.status
FROM categories c
LEFT JOIN product_categories pc ON c.cat_id = pc.cat_id
LEFT JOIN products p ON pc.pid = p.pid
LEFT JOIN orders o ON p.pid = o.pid AND o.canceled = false
GROUP BY c.cat_id, c.status
status,
last_calculated_at
)
SELECT
category_id,
product_count,
active_products,
total_value,
COALESCE(avg_margin, 0) as avg_margin,
COALESCE(turnover_rate, 0) as turnover_rate,
-- Enhanced YoY growth rate calculation
CASE
WHEN previous_year_period_sales = 0 AND current_period_sales > 0 THEN 100.0
WHEN previous_year_period_sales = 0 THEN 0.0
ELSE LEAST(
GREATEST(
((current_period_sales - previous_year_period_sales) /
NULLIF(previous_year_period_sales, 0)) * 100.0,
-100.0
),
999.99
)
END as growth_rate,
status
FROM category_sales
c.cat_id,
COUNT(DISTINCT p.pid) as product_count,
COUNT(DISTINCT CASE WHEN p.visible = true THEN p.pid END) as active_products,
COALESCE(SUM(p.stock_quantity * p.cost_price), 0) as total_value,
c.status,
NOW() as last_calculated_at
FROM categories c
LEFT JOIN product_categories pc ON c.cat_id = pc.cat_id
LEFT JOIN products p ON pc.pid = p.pid
GROUP BY c.cat_id, c.status
ON DUPLICATE KEY UPDATE
product_count = VALUES(product_count),
active_products = VALUES(active_products),
total_value = VALUES(total_value),
avg_margin = VALUES(avg_margin),
turnover_rate = VALUES(turnover_rate),
growth_rate = VALUES(growth_rate),
status = VALUES(status),
last_calculated_at = CURRENT_TIMESTAMP
last_calculated_at = VALUES(last_calculated_at)
`);
// Calculate category time-based metrics
// Then update with margin and turnover data
await connection.query(`
WITH category_sales AS (
SELECT
pc.cat_id,
SUM(o.quantity * o.price) as total_sales,
SUM(o.quantity * (o.price - p.cost_price)) as total_margin,
SUM(o.quantity) as units_sold,
AVG(GREATEST(p.stock_quantity, 0)) as avg_stock
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 1 YEAR)
GROUP BY pc.cat_id
)
UPDATE category_metrics cm
JOIN category_sales cs ON cm.category_id = cs.cat_id
SET
cm.avg_margin = COALESCE(cs.total_margin * 100.0 / NULLIF(cs.total_sales, 0), 0),
cm.turnover_rate = LEAST(COALESCE(cs.units_sold / NULLIF(cs.avg_stock, 0), 0), 999.99),
cm.last_calculated_at = NOW()
`);
// Finally update growth rates
await connection.query(`
WITH current_period AS (
SELECT
pc.cat_id,
SUM(o.quantity * o.price) as revenue
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
),
previous_period AS (
SELECT
pc.cat_id,
SUM(o.quantity * o.price) as revenue
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 BETWEEN DATE_SUB(CURRENT_DATE, INTERVAL 15 MONTH)
AND DATE_SUB(CURRENT_DATE, INTERVAL 12 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
SET
cm.growth_rate = CASE
WHEN pp.revenue = 0 AND COALESCE(cp.revenue, 0) > 0 THEN 100.0
WHEN pp.revenue = 0 THEN 0.0
ELSE LEAST(
GREATEST(
((COALESCE(cp.revenue, 0) - pp.revenue) / pp.revenue) * 100.0,
-100.0
),
999.99
)
END,
cm.last_calculated_at = NOW()
WHERE cp.cat_id IS NOT NULL OR pp.cat_id IS NOT NULL
`);
// Calculate time-based metrics
await connection.query(`
INSERT INTO category_time_metrics (
category_id,
@@ -120,29 +126,28 @@ async function calculateCategoryMetrics(startTime, totalProducts, processedCount
turnover_rate
)
SELECT
c.cat_id as category_id,
pc.cat_id,
YEAR(o.date) as year,
MONTH(o.date) as month,
COUNT(DISTINCT p.pid) as product_count,
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.price * o.quantity) as total_revenue,
CASE
WHEN SUM(o.price * o.quantity) > 0
THEN (SUM((o.price - p.cost_price) * o.quantity) * 100.0) / SUM(o.price * o.quantity)
ELSE 0
END as avg_margin,
CASE
WHEN AVG(p.stock_quantity) > 0
THEN SUM(o.quantity) / AVG(p.stock_quantity)
ELSE 0
END as turnover_rate
FROM categories c
LEFT JOIN product_categories pc ON c.cat_id = pc.cat_id
LEFT JOIN products p ON pc.pid = p.pid
LEFT JOIN orders o ON p.pid = o.pid AND o.canceled = false
WHERE o.date >= DATE_SUB(CURRENT_DATE, INTERVAL 12 MONTH)
GROUP BY c.cat_id, YEAR(o.date), MONTH(o.date)
SUM(o.quantity * o.price) as total_revenue,
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),
0
) as turnover_rate
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 12 MONTH)
GROUP BY pc.cat_id, YEAR(o.date), MONTH(o.date)
ON DUPLICATE KEY UPDATE
product_count = VALUES(product_count),
active_products = VALUES(active_products),
@@ -152,73 +157,45 @@ async function calculateCategoryMetrics(startTime, totalProducts, processedCount
turnover_rate = VALUES(turnover_rate)
`);
// Calculate category sales metrics with NULL brand handling
await connection.query(`
INSERT INTO category_sales_metrics (
category_id,
brand,
period_start,
period_end,
avg_daily_sales,
total_sold,
num_products,
avg_price,
last_calculated_at
)
WITH date_ranges AS (
// Calculate sales metrics for different time periods
const periods = [30, 90, 180, 365];
for (const days of periods) {
await connection.query(`
INSERT INTO category_sales_metrics (
category_id,
brand,
period_start,
period_end,
avg_daily_sales,
total_sold,
num_products,
avg_price,
last_calculated_at
)
SELECT
DATE_SUB(CURDATE(), INTERVAL 30 DAY) as period_start,
CURDATE() as period_end
UNION ALL
SELECT
DATE_SUB(CURDATE(), INTERVAL 90 DAY),
CURDATE()
UNION ALL
SELECT
DATE_SUB(CURDATE(), INTERVAL 180 DAY),
CURDATE()
UNION ALL
SELECT
DATE_SUB(CURDATE(), INTERVAL 365 DAY),
CURDATE()
),
category_metrics AS (
SELECT
c.cat_id as category_id,
pc.cat_id as category_id,
COALESCE(p.brand, 'Unbranded') as brand,
dr.period_start,
dr.period_end,
COUNT(DISTINCT p.pid) as num_products,
COALESCE(SUM(o.quantity), 0) / DATEDIFF(dr.period_end, dr.period_start) as avg_daily_sales,
DATE_SUB(CURDATE(), INTERVAL ? DAY) as period_start,
CURDATE() as period_end,
COALESCE(SUM(o.quantity), 0) / ? as avg_daily_sales,
COALESCE(SUM(o.quantity), 0) as total_sold,
COALESCE(AVG(o.price), 0) as avg_price
FROM categories c
JOIN product_categories pc ON c.cat_id = pc.cat_id
COUNT(DISTINCT p.pid) as num_products,
COALESCE(AVG(o.price), 0) as avg_price,
NOW() as last_calculated_at
FROM product_categories pc
JOIN products p ON pc.pid = p.pid
CROSS JOIN date_ranges dr
LEFT JOIN orders o ON p.pid = o.pid
AND o.date BETWEEN dr.period_start AND dr.period_end
AND o.date >= DATE_SUB(CURDATE(), INTERVAL ? DAY)
AND o.canceled = false
GROUP BY c.cat_id, COALESCE(p.brand, 'Unbranded'), dr.period_start, dr.period_end
)
SELECT
category_id,
brand,
period_start,
period_end,
avg_daily_sales,
total_sold,
num_products,
avg_price,
NOW() as last_calculated_at
FROM category_metrics
ON DUPLICATE KEY UPDATE
avg_daily_sales = VALUES(avg_daily_sales),
total_sold = VALUES(total_sold),
num_products = VALUES(num_products),
avg_price = VALUES(avg_price),
last_calculated_at = NOW()
`);
GROUP BY pc.cat_id, p.brand
ON DUPLICATE KEY UPDATE
avg_daily_sales = VALUES(avg_daily_sales),
total_sold = VALUES(total_sold),
num_products = VALUES(num_products),
avg_price = VALUES(avg_price),
last_calculated_at = NOW()
`, [days, days, days]);
}
return Math.floor(totalProducts * 0.9);
} finally {