Try to speed up calculate script + fixes
This commit is contained in:
@@ -88,9 +88,10 @@ async function calculateCategoryMetrics(startTime, totalProducts, processedCount
|
||||
const [batch] = await connection.query(`
|
||||
SELECT DISTINCT c.cat_id
|
||||
FROM categories c
|
||||
JOIN product_categories pc ON c.cat_id = pc.cat_id
|
||||
LEFT JOIN products p ON pc.pid = p.pid AND p.updated > ?
|
||||
LEFT JOIN orders o ON p.pid = o.pid AND o.updated > ?
|
||||
FORCE INDEX (PRIMARY)
|
||||
JOIN product_categories pc FORCE INDEX (idx_category) ON c.cat_id = pc.cat_id
|
||||
LEFT JOIN products p FORCE INDEX (PRIMARY) ON pc.pid = p.pid AND p.updated > ?
|
||||
LEFT JOIN orders o FORCE INDEX (idx_orders_metrics) ON p.pid = o.pid AND o.updated > ?
|
||||
WHERE c.status = 'active'
|
||||
AND c.cat_id > ?
|
||||
AND (
|
||||
@@ -103,7 +104,81 @@ async function calculateCategoryMetrics(startTime, totalProducts, processedCount
|
||||
|
||||
if (batch.length === 0) break;
|
||||
|
||||
// Update category metrics for this batch
|
||||
// Create temporary tables for better performance
|
||||
await connection.query('DROP TEMPORARY TABLE IF EXISTS temp_product_stats');
|
||||
await connection.query('DROP TEMPORARY TABLE IF EXISTS temp_sales_stats');
|
||||
|
||||
await connection.query(`
|
||||
CREATE TEMPORARY TABLE temp_product_stats (
|
||||
cat_id BIGINT NOT NULL,
|
||||
product_count INT,
|
||||
active_products INT,
|
||||
total_value DECIMAL(15,2),
|
||||
avg_margin DECIMAL(5,2),
|
||||
turnover_rate DECIMAL(10,2),
|
||||
PRIMARY KEY (cat_id),
|
||||
INDEX (product_count),
|
||||
INDEX (total_value)
|
||||
) ENGINE=MEMORY
|
||||
`);
|
||||
|
||||
await connection.query(`
|
||||
CREATE TEMPORARY TABLE temp_sales_stats (
|
||||
cat_id BIGINT NOT NULL,
|
||||
recent_revenue DECIMAL(15,2),
|
||||
previous_revenue DECIMAL(15,2),
|
||||
PRIMARY KEY (cat_id),
|
||||
INDEX (recent_revenue),
|
||||
INDEX (previous_revenue)
|
||||
) ENGINE=MEMORY
|
||||
`);
|
||||
|
||||
// Populate product stats
|
||||
await connection.query(`
|
||||
INSERT INTO temp_product_stats
|
||||
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,
|
||||
SUM(p.stock_quantity * p.cost_price) as total_value,
|
||||
AVG(pm.avg_margin_percent) as avg_margin,
|
||||
AVG(pm.turnover_rate) as turnover_rate
|
||||
FROM categories c
|
||||
FORCE INDEX (PRIMARY)
|
||||
JOIN product_categories pc FORCE INDEX (idx_category) ON c.cat_id = pc.cat_id
|
||||
LEFT JOIN products p FORCE INDEX (PRIMARY) ON pc.pid = p.pid
|
||||
LEFT JOIN product_metrics pm FORCE INDEX (PRIMARY) ON p.pid = pm.pid
|
||||
WHERE c.cat_id IN (?)
|
||||
GROUP BY c.cat_id
|
||||
`, [batch.map(row => row.cat_id)]);
|
||||
|
||||
// Populate sales stats
|
||||
await connection.query(`
|
||||
INSERT INTO temp_sales_stats
|
||||
SELECT
|
||||
c.cat_id,
|
||||
COALESCE(SUM(CASE
|
||||
WHEN o.date >= DATE_SUB(CURRENT_DATE, INTERVAL 30 DAY)
|
||||
THEN o.quantity * o.price
|
||||
ELSE 0
|
||||
END), 0) as recent_revenue,
|
||||
COALESCE(SUM(CASE
|
||||
WHEN o.date BETWEEN DATE_SUB(CURRENT_DATE, INTERVAL 60 DAY) AND DATE_SUB(CURRENT_DATE, INTERVAL 30 DAY)
|
||||
THEN o.quantity * o.price
|
||||
ELSE 0
|
||||
END), 0) as previous_revenue
|
||||
FROM categories c
|
||||
FORCE INDEX (PRIMARY)
|
||||
JOIN product_categories pc FORCE INDEX (idx_category) ON c.cat_id = pc.cat_id
|
||||
LEFT JOIN products p FORCE INDEX (PRIMARY) ON pc.pid = p.pid
|
||||
LEFT JOIN orders o FORCE INDEX (idx_orders_metrics) ON p.pid = o.pid
|
||||
AND o.canceled = false
|
||||
AND o.date >= DATE_SUB(CURRENT_DATE, INTERVAL 60 DAY)
|
||||
WHERE c.cat_id IN (?)
|
||||
GROUP BY c.cat_id
|
||||
`, [batch.map(row => row.cat_id)]);
|
||||
|
||||
// Update metrics using temp tables
|
||||
await connection.query(`
|
||||
INSERT INTO category_metrics (
|
||||
category_id,
|
||||
@@ -118,49 +193,25 @@ async function calculateCategoryMetrics(startTime, totalProducts, processedCount
|
||||
)
|
||||
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,
|
||||
SUM(p.stock_quantity * p.cost_price) as total_value,
|
||||
AVG(pm.avg_margin_percent) as avg_margin,
|
||||
AVG(pm.turnover_rate) as turnover_rate,
|
||||
COALESCE(ps.product_count, 0) as product_count,
|
||||
COALESCE(ps.active_products, 0) as active_products,
|
||||
COALESCE(ps.total_value, 0) as total_value,
|
||||
COALESCE(ps.avg_margin, 0) as avg_margin,
|
||||
COALESCE(ps.turnover_rate, 0) as turnover_rate,
|
||||
CASE
|
||||
WHEN COALESCE(SUM(CASE
|
||||
WHEN o.date BETWEEN DATE_SUB(CURRENT_DATE, INTERVAL 60 DAY) AND DATE_SUB(CURRENT_DATE, INTERVAL 30 DAY)
|
||||
THEN o.quantity * o.price
|
||||
ELSE 0
|
||||
END), 0) = 0 AND COALESCE(SUM(CASE
|
||||
WHEN o.date >= DATE_SUB(CURRENT_DATE, INTERVAL 30 DAY)
|
||||
THEN o.quantity * o.price
|
||||
ELSE 0
|
||||
END), 0) > 0 THEN 100
|
||||
WHEN COALESCE(SUM(CASE
|
||||
WHEN o.date BETWEEN DATE_SUB(CURRENT_DATE, INTERVAL 60 DAY) AND DATE_SUB(CURRENT_DATE, INTERVAL 30 DAY)
|
||||
THEN o.quantity * o.price
|
||||
ELSE 0
|
||||
END), 0) = 0 THEN 0
|
||||
WHEN ss.previous_revenue = 0 AND ss.recent_revenue > 0 THEN 100
|
||||
WHEN ss.previous_revenue = 0 THEN 0
|
||||
ELSE LEAST(999.99, GREATEST(-100,
|
||||
((SUM(CASE
|
||||
WHEN o.date >= DATE_SUB(CURRENT_DATE, INTERVAL 30 DAY)
|
||||
THEN o.quantity * o.price
|
||||
ELSE 0
|
||||
END) / NULLIF(SUM(CASE
|
||||
WHEN o.date BETWEEN DATE_SUB(CURRENT_DATE, INTERVAL 60 DAY) AND DATE_SUB(CURRENT_DATE, INTERVAL 30 DAY)
|
||||
THEN o.quantity * o.price
|
||||
ELSE 0
|
||||
END), 0) - 1) * 100)
|
||||
((ss.recent_revenue / NULLIF(ss.previous_revenue, 0) - 1) * 100)
|
||||
))
|
||||
END as growth_rate,
|
||||
c.status,
|
||||
NOW() as last_calculated_at
|
||||
FROM categories c
|
||||
JOIN product_categories pc ON c.cat_id = pc.cat_id
|
||||
LEFT JOIN products p ON pc.pid = p.pid
|
||||
LEFT JOIN product_metrics pm ON p.pid = pm.pid
|
||||
LEFT JOIN orders o ON p.pid = o.pid
|
||||
AND o.canceled = false
|
||||
AND o.date >= DATE_SUB(CURRENT_DATE, INTERVAL 60 DAY)
|
||||
FORCE INDEX (PRIMARY)
|
||||
LEFT JOIN temp_product_stats ps ON c.cat_id = ps.cat_id
|
||||
LEFT JOIN temp_sales_stats ss ON c.cat_id = ss.cat_id
|
||||
WHERE c.cat_id IN (?)
|
||||
GROUP BY c.cat_id, c.status
|
||||
ON DUPLICATE KEY UPDATE
|
||||
product_count = VALUES(product_count),
|
||||
active_products = VALUES(active_products),
|
||||
@@ -172,6 +223,10 @@ async function calculateCategoryMetrics(startTime, totalProducts, processedCount
|
||||
last_calculated_at = NOW()
|
||||
`, [batch.map(row => row.cat_id)]);
|
||||
|
||||
// Clean up temp tables
|
||||
await connection.query('DROP TEMPORARY TABLE IF EXISTS temp_product_stats');
|
||||
await connection.query('DROP TEMPORARY TABLE IF EXISTS temp_sales_stats');
|
||||
|
||||
lastCatId = batch[batch.length - 1].cat_id;
|
||||
processedCount += batch.length;
|
||||
|
||||
|
||||
Reference in New Issue
Block a user