Calculate script fixes

This commit is contained in:
2025-02-09 15:40:57 -05:00
parent 843ce71506
commit 7ff757203f
4 changed files with 112 additions and 59 deletions

View File

@@ -123,6 +123,22 @@ async function calculateCategoryMetrics(startTime, totalProducts, processedCount
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,
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
ELSE LEAST(999.99, GREATEST(-100,
((SUM(CASE
WHEN o.date >= DATE_SUB(CURRENT_DATE, INTERVAL 30 DAY)
THEN o.quantity * o.price
@@ -131,7 +147,9 @@ async function calculateCategoryMetrics(startTime, totalProducts, processedCount
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) as growth_rate,
END), 0) - 1) * 100)
))
END as growth_rate,
c.status,
NOW() as last_calculated_at
FROM categories c

View File

@@ -85,15 +85,19 @@ async function calculateFinancialMetrics(startTime, totalProducts, processedCoun
const [batch] = await connection.query(`
SELECT DISTINCT p.pid
FROM products p
LEFT JOIN orders o ON p.pid = o.pid AND o.updated > ?
LEFT JOIN orders o ON p.pid = o.pid
WHERE p.pid > ?
AND (
p.updated > ?
OR o.pid IS NOT NULL
OR EXISTS (
SELECT 1 FROM orders o2
WHERE o2.pid = p.pid
AND o2.updated > ?
)
)
ORDER BY p.pid
LIMIT ?
`, [lastCalculationTime, lastPid, lastCalculationTime, BATCH_SIZE]);
`, [lastPid, lastCalculationTime, lastCalculationTime, BATCH_SIZE]);
if (batch.length === 0) break;

View File

@@ -85,15 +85,19 @@ 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 AND o.updated > ?
LEFT JOIN orders o ON p.pid = o.pid
WHERE p.pid > ?
AND (
p.updated > ?
OR o.id IS NOT NULL
OR EXISTS (
SELECT 1 FROM orders o2
WHERE o2.pid = p.pid
AND o2.updated > ?
)
)
ORDER BY p.pid
LIMIT ?
`, [lastCalculationTime, lastPid, lastCalculationTime, BATCH_SIZE]);
`, [lastPid, lastCalculationTime, lastCalculationTime, BATCH_SIZE]);
if (batch.length === 0) break;

View File

@@ -15,16 +15,22 @@ async function calculateVendorMetrics(startTime, totalProducts, processedCount =
`);
const lastCalculationTime = lastCalc[0]?.last_calculation_timestamp || '1970-01-01';
// Get total count of vendors needing updates
// Get total count of vendors needing updates using EXISTS for better performance
const [vendorCount] = await connection.query(`
SELECT COUNT(DISTINCT v.vendor) as count
FROM vendor_details v
LEFT JOIN products p ON v.vendor = p.vendor AND p.updated > ?
LEFT JOIN purchase_orders po ON v.vendor = po.vendor AND po.updated > ?
WHERE v.status = 'active'
AND (
p.pid IS NOT NULL
OR po.id IS NOT NULL
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 > ?
)
)
`, [lastCalculationTime, lastCalculationTime]);
const totalVendors = vendorCount[0].count;
@@ -84,24 +90,71 @@ async function calculateVendorMetrics(startTime, totalProducts, processedCount =
while (true) {
if (isCancelled) break;
// Get batch of vendors using EXISTS for better performance
const [batch] = await connection.query(`
SELECT DISTINCT v.vendor
FROM vendor_details v
LEFT JOIN products p ON v.vendor = p.vendor AND p.updated > ?
LEFT JOIN purchase_orders po ON v.vendor = po.vendor AND po.updated > ?
WHERE v.status = 'active'
AND v.vendor > ?
AND (
p.pid IS NOT NULL
OR po.id IS NOT NULL
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 > ?
)
)
ORDER BY v.vendor
LIMIT ?
`, [lastCalculationTime, lastCalculationTime, lastVendor, BATCH_SIZE]);
`, [lastVendor, lastCalculationTime, lastCalculationTime, BATCH_SIZE]);
if (batch.length === 0) break;
// Update vendor metrics for this batch
// Create temporary tables for better performance
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
SELECT
po.vendor,
AVG(DATEDIFF(po.received_date, po.date)) as avg_lead_time_days,
COUNT(DISTINCT po.po_id) as total_orders,
COUNT(CASE WHEN DATEDIFF(po.received_date, po.date) > 30 THEN 1 END) as total_late_orders,
SUM(po.ordered * po.po_cost_price) as total_purchase_value,
AVG(po.ordered * po.po_cost_price) as avg_order_value,
(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
WHERE po.vendor IN (?)
AND po.received_date IS NOT NULL
AND po.date >= DATE_SUB(CURRENT_DATE, INTERVAL 365 DAY)
AND po.updated > ?
GROUP BY po.vendor
`, [batch.map(row => row.vendor), lastCalculationTime]);
// Create and populate product_stats temp table
await connection.query(`
CREATE TEMPORARY TABLE temp_product_stats AS
SELECT
p.vendor,
COUNT(DISTINCT p.pid) as total_products,
COUNT(DISTINCT CASE WHEN p.visible = true THEN p.pid END) as active_products,
AVG(pm.avg_margin_percent) as avg_margin_percent,
SUM(pm.total_revenue) as total_revenue
FROM products p
LEFT JOIN product_metrics pm ON p.pid = pm.pid
WHERE p.vendor IN (?)
AND p.updated > ?
GROUP BY p.vendor
`, [batch.map(row => row.vendor), lastCalculationTime]);
// Update metrics using temp tables
await connection.query(`
INSERT INTO vendor_metrics (
vendor,
@@ -119,36 +172,6 @@ async function calculateVendorMetrics(startTime, totalProducts, processedCount =
status,
last_calculated_at
)
WITH purchase_stats AS (
SELECT
po.vendor,
AVG(DATEDIFF(po.received_date, po.date)) as avg_lead_time_days,
COUNT(DISTINCT po.po_id) as total_orders,
COUNT(CASE WHEN DATEDIFF(po.received_date, po.date) > 30 THEN 1 END) as total_late_orders,
SUM(po.ordered * po.po_cost_price) as total_purchase_value,
AVG(po.ordered * po.po_cost_price) as avg_order_value,
(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
WHERE po.vendor IN (?)
AND po.received_date IS NOT NULL
AND po.date >= DATE_SUB(CURRENT_DATE, INTERVAL 365 DAY)
AND po.updated > ?
GROUP BY po.vendor
),
product_stats AS (
SELECT
p.vendor,
COUNT(DISTINCT p.pid) as total_products,
COUNT(DISTINCT CASE WHEN p.visible = true THEN p.pid END) as active_products,
AVG(pm.avg_margin_percent) as avg_margin_percent,
SUM(pm.total_revenue) as total_revenue
FROM products p
LEFT JOIN product_metrics pm ON p.pid = pm.pid
WHERE p.vendor IN (?)
AND p.updated > ?
GROUP BY p.vendor
)
SELECT
v.vendor,
COALESCE(ps.avg_lead_time_days, 0) as avg_lead_time_days,
@@ -165,8 +188,8 @@ async function calculateVendorMetrics(startTime, totalProducts, processedCount =
v.status,
NOW() as last_calculated_at
FROM vendor_details v
LEFT JOIN purchase_stats ps ON v.vendor = ps.vendor
LEFT JOIN product_stats prs ON v.vendor = prs.vendor
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),
@@ -182,7 +205,11 @@ async function calculateVendorMetrics(startTime, totalProducts, processedCount =
avg_margin_percent = VALUES(avg_margin_percent),
status = VALUES(status),
last_calculated_at = NOW()
`, [batch.map(row => row.vendor), lastCalculationTime, batch.map(row => row.vendor), lastCalculationTime, batch.map(row => row.vendor)]);
`, [batch.map(row => row.vendor)]);
// Clean up temp tables
await connection.query('DROP TEMPORARY TABLE IF EXISTS temp_purchase_stats');
await connection.query('DROP TEMPORARY TABLE IF EXISTS temp_product_stats');
lastVendor = batch[batch.length - 1].vendor;
processedCount += batch.length;