Try to speed up calculate script + fixes

This commit is contained in:
2025-02-10 01:29:01 -05:00
parent 7ff757203f
commit 610e26689c
7 changed files with 520 additions and 260 deletions

View File

@@ -85,12 +85,14 @@ async function calculateTimeAggregates(startTime, totalProducts, processedCount
const [batch] = await connection.query(`
SELECT DISTINCT p.pid
FROM products p
LEFT JOIN orders o ON p.pid = o.pid
FORCE INDEX (PRIMARY)
LEFT JOIN orders o FORCE INDEX (idx_orders_metrics) ON p.pid = o.pid
WHERE p.pid > ?
AND (
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.updated > ?
)
@@ -101,21 +103,32 @@ async function calculateTimeAggregates(startTime, totalProducts, processedCount
if (batch.length === 0) break;
// Calculate and update time aggregates for this batch
// Calculate and update time aggregates for this batch using temporary table
await connection.query('DROP TEMPORARY TABLE IF EXISTS temp_time_aggregates');
await connection.query(`
INSERT INTO product_time_aggregates (
pid,
year,
month,
total_quantity_sold,
total_revenue,
total_cost,
order_count,
avg_price,
profit_margin,
inventory_value,
gmroi
)
CREATE TEMPORARY TABLE temp_time_aggregates (
pid BIGINT NOT NULL,
year INT NOT NULL,
month INT NOT NULL,
total_quantity_sold INT DEFAULT 0,
total_revenue DECIMAL(10,3) DEFAULT 0,
total_cost DECIMAL(10,3) DEFAULT 0,
order_count INT DEFAULT 0,
stock_received INT DEFAULT 0,
stock_ordered INT DEFAULT 0,
avg_price DECIMAL(10,3),
profit_margin DECIMAL(10,3),
inventory_value DECIMAL(10,3),
gmroi DECIMAL(10,3),
PRIMARY KEY (pid, year, month),
INDEX (pid),
INDEX (year, month)
) ENGINE=MEMORY
`);
// Populate temporary table
await connection.query(`
INSERT INTO temp_time_aggregates
SELECT
p.pid,
YEAR(o.date) as year,
@@ -124,6 +137,8 @@ async function calculateTimeAggregates(startTime, totalProducts, processedCount
SUM(o.quantity * o.price) as total_revenue,
SUM(o.quantity * p.cost_price) as total_cost,
COUNT(DISTINCT o.order_number) as order_count,
COALESCE(SUM(CASE WHEN po.received_date IS NOT NULL THEN po.received ELSE 0 END), 0) as stock_received,
COALESCE(SUM(po.ordered), 0) as stock_ordered,
AVG(o.price) as avg_price,
CASE
WHEN SUM(o.quantity * o.price) > 0
@@ -137,22 +152,45 @@ async function calculateTimeAggregates(startTime, totalProducts, processedCount
ELSE 0
END as gmroi
FROM products p
INNER JOIN orders o ON p.pid = o.pid
AND o.canceled = false
AND o.date >= DATE_SUB(CURRENT_DATE, INTERVAL 12 MONTH)
FORCE INDEX (PRIMARY)
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 12 MONTH)
LEFT JOIN purchase_orders po FORCE INDEX (idx_po_metrics) ON p.pid = po.pid
AND po.date >= DATE_SUB(CURRENT_DATE, INTERVAL 12 MONTH)
WHERE p.pid IN (?)
GROUP BY p.pid, YEAR(o.date), MONTH(o.date)
HAVING year IS NOT NULL AND month IS NOT NULL
`, [batch.map(row => row.pid)]);
// Update from temporary table
await connection.query(`
INSERT INTO product_time_aggregates (
pid, year, month,
total_quantity_sold, total_revenue, total_cost,
order_count, stock_received, stock_ordered,
avg_price, profit_margin, inventory_value, gmroi
)
SELECT
pid, year, month,
total_quantity_sold, total_revenue, total_cost,
order_count, stock_received, stock_ordered,
avg_price, profit_margin, inventory_value, gmroi
FROM temp_time_aggregates
ON DUPLICATE KEY UPDATE
total_quantity_sold = VALUES(total_quantity_sold),
total_revenue = VALUES(total_revenue),
total_cost = VALUES(total_cost),
order_count = VALUES(order_count),
stock_received = VALUES(stock_received),
stock_ordered = VALUES(stock_ordered),
avg_price = VALUES(avg_price),
profit_margin = VALUES(profit_margin),
inventory_value = VALUES(inventory_value),
gmroi = VALUES(gmroi)
`, [batch.map(row => row.pid)]);
`);
await connection.query('DROP TEMPORARY TABLE IF EXISTS temp_time_aggregates');
lastPid = batch[batch.length - 1].pid;
processedCount += batch.length;