Try to speed up calculate script + fixes
This commit is contained in:
@@ -94,33 +94,54 @@ async function calculateVendorMetrics(startTime, totalProducts, processedCount =
|
||||
const [batch] = await connection.query(`
|
||||
SELECT DISTINCT v.vendor
|
||||
FROM vendor_details v
|
||||
FORCE INDEX (PRIMARY)
|
||||
LEFT JOIN products p FORCE INDEX (idx_vendor) ON p.vendor = v.vendor AND p.updated > ?
|
||||
LEFT JOIN purchase_orders po FORCE INDEX (idx_vendor) ON po.vendor = v.vendor AND po.updated > ?
|
||||
WHERE v.status = 'active'
|
||||
AND v.vendor > ?
|
||||
AND (
|
||||
EXISTS (
|
||||
SELECT 1 FROM products p
|
||||
WHERE p.vendor = v.vendor
|
||||
AND p.updated > ?
|
||||
)
|
||||
OR EXISTS (
|
||||
SELECT 1 FROM purchase_orders po
|
||||
WHERE po.vendor = v.vendor
|
||||
AND po.updated > ?
|
||||
)
|
||||
)
|
||||
AND (p.pid IS NOT NULL OR po.po_id IS NOT NULL)
|
||||
ORDER BY v.vendor
|
||||
LIMIT ?
|
||||
`, [lastVendor, lastCalculationTime, lastCalculationTime, BATCH_SIZE]);
|
||||
`, [lastCalculationTime, lastCalculationTime, lastVendor, BATCH_SIZE]);
|
||||
|
||||
if (batch.length === 0) break;
|
||||
|
||||
// Create temporary tables for better performance
|
||||
// Create temporary tables with optimized structure and indexes
|
||||
await connection.query('DROP TEMPORARY TABLE IF EXISTS temp_purchase_stats');
|
||||
await connection.query('DROP TEMPORARY TABLE IF EXISTS temp_product_stats');
|
||||
|
||||
// Create and populate purchase_stats temp table
|
||||
await connection.query(`
|
||||
CREATE TEMPORARY TABLE temp_purchase_stats AS
|
||||
CREATE TEMPORARY TABLE temp_purchase_stats (
|
||||
vendor VARCHAR(100) NOT NULL,
|
||||
avg_lead_time_days DECIMAL(10,2),
|
||||
total_orders INT,
|
||||
total_late_orders INT,
|
||||
total_purchase_value DECIMAL(15,2),
|
||||
avg_order_value DECIMAL(15,2),
|
||||
on_time_delivery_rate DECIMAL(5,2),
|
||||
order_fill_rate DECIMAL(5,2),
|
||||
PRIMARY KEY (vendor),
|
||||
INDEX (total_orders),
|
||||
INDEX (total_purchase_value)
|
||||
) ENGINE=MEMORY
|
||||
`);
|
||||
|
||||
await connection.query(`
|
||||
CREATE TEMPORARY TABLE temp_product_stats (
|
||||
vendor VARCHAR(100) NOT NULL,
|
||||
total_products INT,
|
||||
active_products INT,
|
||||
avg_margin_percent DECIMAL(5,2),
|
||||
total_revenue DECIMAL(15,2),
|
||||
PRIMARY KEY (vendor),
|
||||
INDEX (total_products),
|
||||
INDEX (total_revenue)
|
||||
) ENGINE=MEMORY
|
||||
`);
|
||||
|
||||
// Populate purchase_stats temp table with optimized index usage
|
||||
await connection.query(`
|
||||
INSERT INTO temp_purchase_stats
|
||||
SELECT
|
||||
po.vendor,
|
||||
AVG(DATEDIFF(po.received_date, po.date)) as avg_lead_time_days,
|
||||
@@ -131,6 +152,7 @@ async function calculateVendorMetrics(startTime, totalProducts, processedCount =
|
||||
(COUNT(CASE WHEN DATEDIFF(po.received_date, po.date) <= 30 THEN 1 END) / COUNT(*)) * 100 as on_time_delivery_rate,
|
||||
(SUM(LEAST(po.received, po.ordered)) / NULLIF(SUM(po.ordered), 0)) * 100 as order_fill_rate
|
||||
FROM purchase_orders po
|
||||
FORCE INDEX (idx_vendor)
|
||||
WHERE po.vendor IN (?)
|
||||
AND po.received_date IS NOT NULL
|
||||
AND po.date >= DATE_SUB(CURRENT_DATE, INTERVAL 365 DAY)
|
||||
@@ -138,23 +160,31 @@ async function calculateVendorMetrics(startTime, totalProducts, processedCount =
|
||||
GROUP BY po.vendor
|
||||
`, [batch.map(row => row.vendor), lastCalculationTime]);
|
||||
|
||||
// Create and populate product_stats temp table
|
||||
// Populate product stats with optimized index usage
|
||||
await connection.query(`
|
||||
CREATE TEMPORARY TABLE temp_product_stats AS
|
||||
INSERT INTO temp_product_stats
|
||||
SELECT
|
||||
p.vendor,
|
||||
COUNT(DISTINCT p.pid) as total_products,
|
||||
COUNT(DISTINCT p.pid) as product_count,
|
||||
COUNT(DISTINCT CASE WHEN p.visible = true THEN p.pid END) as active_products,
|
||||
AVG(pm.avg_margin_percent) as avg_margin_percent,
|
||||
AVG(pm.avg_margin_percent) as avg_margin,
|
||||
SUM(pm.total_revenue) as total_revenue
|
||||
FROM products p
|
||||
LEFT JOIN product_metrics pm ON p.pid = pm.pid
|
||||
FORCE INDEX (idx_vendor)
|
||||
LEFT JOIN product_metrics pm FORCE INDEX (PRIMARY) ON p.pid = pm.pid
|
||||
WHERE p.vendor IN (?)
|
||||
AND p.updated > ?
|
||||
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.vendor
|
||||
`, [batch.map(row => row.vendor), lastCalculationTime]);
|
||||
`, [batch.map(row => row.vendor), lastCalculationTime, lastCalculationTime]);
|
||||
|
||||
// Update metrics using temp tables
|
||||
// Update metrics using temp tables with optimized join order
|
||||
await connection.query(`
|
||||
INSERT INTO vendor_metrics (
|
||||
vendor,
|
||||
@@ -188,8 +218,9 @@ async function calculateVendorMetrics(startTime, totalProducts, processedCount =
|
||||
v.status,
|
||||
NOW() as last_calculated_at
|
||||
FROM vendor_details v
|
||||
LEFT JOIN temp_purchase_stats ps ON v.vendor = ps.vendor
|
||||
LEFT JOIN temp_product_stats prs ON v.vendor = prs.vendor
|
||||
FORCE INDEX (PRIMARY)
|
||||
LEFT JOIN temp_purchase_stats ps ON v.vendor = ps.vendor
|
||||
LEFT JOIN temp_product_stats prs ON v.vendor = prs.vendor
|
||||
WHERE v.vendor IN (?)
|
||||
ON DUPLICATE KEY UPDATE
|
||||
avg_lead_time_days = VALUES(avg_lead_time_days),
|
||||
|
||||
Reference in New Issue
Block a user