Try to speed up calculate script + fixes
This commit is contained in:
@@ -86,23 +86,104 @@ async function calculateBrandMetrics(startTime, totalProducts, processedCount =
|
||||
const [batch] = await connection.query(`
|
||||
SELECT DISTINCT p.brand
|
||||
FROM products p
|
||||
FORCE INDEX (idx_brand)
|
||||
LEFT JOIN orders o FORCE INDEX (idx_orders_metrics) ON p.pid = o.pid AND o.updated > ?
|
||||
WHERE p.brand IS NOT NULL
|
||||
AND p.brand > ?
|
||||
AND (
|
||||
p.updated > ?
|
||||
OR EXISTS (
|
||||
SELECT 1 FROM orders o
|
||||
WHERE o.pid = p.pid
|
||||
AND o.updated > ?
|
||||
)
|
||||
OR o.id IS NOT NULL
|
||||
)
|
||||
ORDER BY p.brand
|
||||
LIMIT ?
|
||||
`, [lastBrand, lastCalculationTime, lastCalculationTime, BATCH_SIZE]);
|
||||
`, [lastCalculationTime, lastBrand, lastCalculationTime, BATCH_SIZE]);
|
||||
|
||||
if (batch.length === 0) break;
|
||||
|
||||
// Update brand 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 (
|
||||
brand VARCHAR(100) NOT NULL,
|
||||
product_count INT,
|
||||
active_products INT,
|
||||
total_stock_units INT,
|
||||
total_stock_cost DECIMAL(15,2),
|
||||
total_stock_retail DECIMAL(15,2),
|
||||
total_revenue DECIMAL(15,2),
|
||||
avg_margin DECIMAL(5,2),
|
||||
PRIMARY KEY (brand),
|
||||
INDEX (total_revenue),
|
||||
INDEX (product_count)
|
||||
) ENGINE=MEMORY
|
||||
`);
|
||||
|
||||
await connection.query(`
|
||||
CREATE TEMPORARY TABLE temp_sales_stats (
|
||||
brand VARCHAR(100) NOT NULL,
|
||||
current_period_sales DECIMAL(15,2),
|
||||
previous_period_sales DECIMAL(15,2),
|
||||
PRIMARY KEY (brand),
|
||||
INDEX (current_period_sales),
|
||||
INDEX (previous_period_sales)
|
||||
) ENGINE=MEMORY
|
||||
`);
|
||||
|
||||
// Populate product stats with optimized index usage
|
||||
await connection.query(`
|
||||
INSERT INTO temp_product_stats
|
||||
SELECT
|
||||
p.brand,
|
||||
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) as total_stock_units,
|
||||
SUM(p.stock_quantity * p.cost_price) as total_stock_cost,
|
||||
SUM(p.stock_quantity * p.price) as total_stock_retail,
|
||||
SUM(pm.total_revenue) as total_revenue,
|
||||
AVG(pm.avg_margin_percent) as avg_margin
|
||||
FROM products p
|
||||
FORCE INDEX (idx_brand)
|
||||
LEFT JOIN product_metrics pm FORCE INDEX (PRIMARY) ON p.pid = pm.pid
|
||||
WHERE p.brand IN (?)
|
||||
AND (
|
||||
p.updated > ?
|
||||
OR EXISTS (
|
||||
SELECT 1 FROM orders o FORCE INDEX (idx_orders_metrics)
|
||||
WHERE o.pid = p.pid
|
||||
AND o.updated > ?
|
||||
)
|
||||
)
|
||||
GROUP BY p.brand
|
||||
`, [batch.map(row => row.brand), lastCalculationTime, lastCalculationTime]);
|
||||
|
||||
// Populate sales stats with optimized index usage
|
||||
await connection.query(`
|
||||
INSERT INTO temp_sales_stats
|
||||
SELECT
|
||||
p.brand,
|
||||
SUM(CASE
|
||||
WHEN o.date >= DATE_SUB(CURRENT_DATE, INTERVAL 30 DAY)
|
||||
THEN o.quantity * o.price
|
||||
ELSE 0
|
||||
END) as current_period_sales,
|
||||
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) as previous_period_sales
|
||||
FROM products p
|
||||
FORCE INDEX (idx_brand)
|
||||
INNER 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)
|
||||
AND o.updated > ?
|
||||
WHERE p.brand IN (?)
|
||||
GROUP BY p.brand
|
||||
`, [lastCalculationTime, batch.map(row => row.brand)]);
|
||||
|
||||
// Update metrics using temp tables
|
||||
await connection.query(`
|
||||
INSERT INTO brand_metrics (
|
||||
brand,
|
||||
@@ -116,50 +197,6 @@ async function calculateBrandMetrics(startTime, totalProducts, processedCount =
|
||||
growth_rate,
|
||||
last_calculated_at
|
||||
)
|
||||
WITH product_stats AS (
|
||||
SELECT
|
||||
p.brand,
|
||||
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) as total_stock_units,
|
||||
SUM(p.stock_quantity * p.cost_price) as total_stock_cost,
|
||||
SUM(p.stock_quantity * p.price) as total_stock_retail,
|
||||
SUM(pm.total_revenue) as total_revenue,
|
||||
AVG(pm.avg_margin_percent) as avg_margin
|
||||
FROM products p
|
||||
LEFT JOIN product_metrics pm ON p.pid = pm.pid
|
||||
WHERE p.brand IN (?)
|
||||
AND (
|
||||
p.updated > ?
|
||||
OR EXISTS (
|
||||
SELECT 1 FROM orders o
|
||||
WHERE o.pid = p.pid
|
||||
AND o.updated > ?
|
||||
)
|
||||
)
|
||||
GROUP BY p.brand
|
||||
),
|
||||
sales_periods AS (
|
||||
SELECT
|
||||
p.brand,
|
||||
SUM(CASE
|
||||
WHEN o.date >= DATE_SUB(CURRENT_DATE, INTERVAL 30 DAY)
|
||||
THEN o.quantity * o.price
|
||||
ELSE 0
|
||||
END) as current_period_sales,
|
||||
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) as previous_period_sales
|
||||
FROM products p
|
||||
INNER JOIN orders o ON p.pid = o.pid
|
||||
AND o.canceled = false
|
||||
AND o.date >= DATE_SUB(CURRENT_DATE, INTERVAL 60 DAY)
|
||||
AND o.updated > ?
|
||||
WHERE p.brand IN (?)
|
||||
GROUP BY p.brand
|
||||
)
|
||||
SELECT
|
||||
ps.brand,
|
||||
COALESCE(ps.product_count, 0) as product_count,
|
||||
@@ -170,15 +207,15 @@ async function calculateBrandMetrics(startTime, totalProducts, processedCount =
|
||||
COALESCE(ps.total_revenue, 0) as total_revenue,
|
||||
COALESCE(ps.avg_margin, 0) as avg_margin,
|
||||
CASE
|
||||
WHEN COALESCE(sp.previous_period_sales, 0) = 0 AND COALESCE(sp.current_period_sales, 0) > 0 THEN 100
|
||||
WHEN COALESCE(sp.previous_period_sales, 0) = 0 THEN 0
|
||||
WHEN COALESCE(ss.previous_period_sales, 0) = 0 AND COALESCE(ss.current_period_sales, 0) > 0 THEN 100
|
||||
WHEN COALESCE(ss.previous_period_sales, 0) = 0 THEN 0
|
||||
ELSE LEAST(999.99, GREATEST(-100,
|
||||
((COALESCE(sp.current_period_sales, 0) / sp.previous_period_sales) - 1) * 100
|
||||
((COALESCE(ss.current_period_sales, 0) / ss.previous_period_sales) - 1) * 100
|
||||
))
|
||||
END as growth_rate,
|
||||
NOW() as last_calculated_at
|
||||
FROM product_stats ps
|
||||
LEFT JOIN sales_periods sp ON ps.brand = sp.brand
|
||||
FROM temp_product_stats ps
|
||||
LEFT JOIN temp_sales_stats ss ON ps.brand = ss.brand
|
||||
ON DUPLICATE KEY UPDATE
|
||||
product_count = VALUES(product_count),
|
||||
active_products = VALUES(active_products),
|
||||
@@ -189,13 +226,11 @@ async function calculateBrandMetrics(startTime, totalProducts, processedCount =
|
||||
avg_margin = VALUES(avg_margin),
|
||||
growth_rate = VALUES(growth_rate),
|
||||
last_calculated_at = NOW()
|
||||
`, [
|
||||
batch.map(row => row.brand), // For first IN clause
|
||||
lastCalculationTime, // For p.updated > ?
|
||||
lastCalculationTime, // For o.updated > ? in EXISTS
|
||||
lastCalculationTime, // For o.updated > ? in sales_periods
|
||||
batch.map(row => row.brand) // For second IN clause
|
||||
]);
|
||||
`);
|
||||
|
||||
// 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');
|
||||
|
||||
lastBrand = batch[batch.length - 1].brand;
|
||||
processedCount += batch.length;
|
||||
|
||||
Reference in New Issue
Block a user