206 lines
8.4 KiB
JavaScript
206 lines
8.4 KiB
JavaScript
const { outputProgress } = require('./utils/progress');
|
|
const { getConnection } = require('./utils/db');
|
|
|
|
async function calculateCategoryMetrics(startTime, totalProducts, processedCount) {
|
|
const connection = await getConnection();
|
|
try {
|
|
outputProgress({
|
|
status: 'running',
|
|
operation: 'Calculating category metrics',
|
|
current: Math.floor(totalProducts * 0.85),
|
|
total: totalProducts,
|
|
elapsed: formatElapsedTime(startTime),
|
|
remaining: estimateRemaining(startTime, Math.floor(totalProducts * 0.85), totalProducts),
|
|
rate: calculateRate(startTime, Math.floor(totalProducts * 0.85)),
|
|
percentage: '85'
|
|
});
|
|
|
|
// First, calculate base category metrics
|
|
await connection.query(`
|
|
INSERT INTO category_metrics (
|
|
category_id,
|
|
product_count,
|
|
active_products,
|
|
total_value,
|
|
status,
|
|
last_calculated_at
|
|
)
|
|
SELECT
|
|
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),
|
|
status = VALUES(status),
|
|
last_calculated_at = VALUES(last_calculated_at)
|
|
`);
|
|
|
|
// 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,
|
|
year,
|
|
month,
|
|
product_count,
|
|
active_products,
|
|
total_value,
|
|
total_revenue,
|
|
avg_margin,
|
|
turnover_rate
|
|
)
|
|
SELECT
|
|
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.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),
|
|
total_value = VALUES(total_value),
|
|
total_revenue = VALUES(total_revenue),
|
|
avg_margin = VALUES(avg_margin),
|
|
turnover_rate = VALUES(turnover_rate)
|
|
`);
|
|
|
|
// 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
|
|
pc.cat_id as category_id,
|
|
COALESCE(p.brand, 'Unbranded') as brand,
|
|
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,
|
|
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
|
|
LEFT JOIN orders o ON p.pid = o.pid
|
|
AND o.date >= DATE_SUB(CURDATE(), INTERVAL ? DAY)
|
|
AND o.canceled = false
|
|
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 {
|
|
connection.release();
|
|
}
|
|
}
|
|
|
|
module.exports = calculateCategoryMetrics;
|