Try to speed up calculate script + fixes
This commit is contained in:
@@ -119,10 +119,39 @@ async function calculateProductMetrics(startTime, totalProducts, processedCount
|
||||
processedOrders = orderCount[0].count;
|
||||
|
||||
// Clear temporary tables
|
||||
await connection.query('TRUNCATE TABLE temp_sales_metrics');
|
||||
await connection.query('TRUNCATE TABLE temp_purchase_metrics');
|
||||
await connection.query('DROP TEMPORARY TABLE IF EXISTS temp_sales_metrics');
|
||||
await connection.query('DROP TEMPORARY TABLE IF EXISTS temp_purchase_metrics');
|
||||
|
||||
// Populate temp_sales_metrics with base stats and sales averages
|
||||
// Create optimized temporary tables with indexes
|
||||
await connection.query(`
|
||||
CREATE TEMPORARY TABLE temp_sales_metrics (
|
||||
pid BIGINT NOT NULL,
|
||||
daily_sales_avg DECIMAL(10,3),
|
||||
weekly_sales_avg DECIMAL(10,3),
|
||||
monthly_sales_avg DECIMAL(10,3),
|
||||
total_revenue DECIMAL(10,2),
|
||||
avg_margin_percent DECIMAL(5,2),
|
||||
first_sale_date DATE,
|
||||
last_sale_date DATE,
|
||||
PRIMARY KEY (pid),
|
||||
INDEX (daily_sales_avg),
|
||||
INDEX (total_revenue)
|
||||
) ENGINE=MEMORY
|
||||
`);
|
||||
|
||||
await connection.query(`
|
||||
CREATE TEMPORARY TABLE temp_purchase_metrics (
|
||||
pid BIGINT NOT NULL,
|
||||
avg_lead_time_days DECIMAL(5,1),
|
||||
last_purchase_date DATE,
|
||||
first_received_date DATE,
|
||||
last_received_date DATE,
|
||||
PRIMARY KEY (pid),
|
||||
INDEX (avg_lead_time_days)
|
||||
) ENGINE=MEMORY
|
||||
`);
|
||||
|
||||
// Populate temp_sales_metrics with base stats and sales averages using FORCE INDEX
|
||||
await connection.query(`
|
||||
INSERT INTO temp_sales_metrics
|
||||
SELECT
|
||||
@@ -139,12 +168,13 @@ async function calculateProductMetrics(startTime, totalProducts, processedCount
|
||||
MIN(o.date) as first_sale_date,
|
||||
MAX(o.date) as last_sale_date
|
||||
FROM products p
|
||||
LEFT JOIN orders o ON p.pid = o.pid
|
||||
AND o.canceled = false
|
||||
AND o.date >= DATE_SUB(CURDATE(), INTERVAL 90 DAY)
|
||||
FORCE INDEX (PRIMARY)
|
||||
LEFT JOIN orders o FORCE INDEX (idx_orders_metrics) ON p.pid = o.pid
|
||||
AND o.canceled = false
|
||||
AND o.date >= DATE_SUB(CURDATE(), INTERVAL 90 DAY)
|
||||
WHERE p.updated > ?
|
||||
OR EXISTS (
|
||||
SELECT 1 FROM orders o2
|
||||
SELECT 1 FROM orders o2 FORCE INDEX (idx_orders_metrics)
|
||||
WHERE o2.pid = p.pid
|
||||
AND o2.canceled = false
|
||||
AND o2.updated > ?
|
||||
@@ -152,7 +182,7 @@ async function calculateProductMetrics(startTime, totalProducts, processedCount
|
||||
GROUP BY p.pid
|
||||
`, [lastCalculationTime, lastCalculationTime]);
|
||||
|
||||
// Populate temp_purchase_metrics
|
||||
// Populate temp_purchase_metrics with optimized index usage
|
||||
await connection.query(`
|
||||
INSERT INTO temp_purchase_metrics
|
||||
SELECT
|
||||
@@ -162,12 +192,13 @@ async function calculateProductMetrics(startTime, totalProducts, processedCount
|
||||
MIN(po.received_date) as first_received_date,
|
||||
MAX(po.received_date) as last_received_date
|
||||
FROM products p
|
||||
LEFT JOIN purchase_orders po ON p.pid = po.pid
|
||||
AND po.received_date IS NOT NULL
|
||||
AND po.date >= DATE_SUB(CURDATE(), INTERVAL 365 DAY)
|
||||
FORCE INDEX (PRIMARY)
|
||||
LEFT JOIN purchase_orders po FORCE INDEX (idx_po_metrics) ON p.pid = po.pid
|
||||
AND po.received_date IS NOT NULL
|
||||
AND po.date >= DATE_SUB(CURDATE(), INTERVAL 365 DAY)
|
||||
WHERE p.updated > ?
|
||||
OR EXISTS (
|
||||
SELECT 1 FROM purchase_orders po2
|
||||
SELECT 1 FROM purchase_orders po2 FORCE INDEX (idx_po_metrics)
|
||||
WHERE po2.pid = p.pid
|
||||
AND po2.updated > ?
|
||||
)
|
||||
|
||||
Reference in New Issue
Block a user