Make calculations incremental

This commit is contained in:
2025-02-09 13:35:44 -05:00
parent 2a6a0d0a87
commit 843ce71506
9 changed files with 935 additions and 1654 deletions

View File

@@ -4,20 +4,51 @@ const { getConnection } = require('./utils/db');
async function calculateVendorMetrics(startTime, totalProducts, processedCount = 0, isCancelled = false) {
const connection = await getConnection();
let success = false;
let processedOrders = 0;
let processedPurchaseOrders = 0;
const BATCH_SIZE = 5000;
try {
// Get last calculation timestamp
const [lastCalc] = await connection.query(`
SELECT last_calculation_timestamp
FROM calculate_status
WHERE module_name = 'vendor_metrics'
`);
const lastCalculationTime = lastCalc[0]?.last_calculation_timestamp || '1970-01-01';
// Get total count of vendors needing updates
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
)
`, [lastCalculationTime, lastCalculationTime]);
const totalVendors = vendorCount[0].count;
if (totalVendors === 0) {
console.log('No vendors need metric updates');
return {
processedProducts: 0,
processedOrders: 0,
processedPurchaseOrders: 0,
success: true
};
}
if (isCancelled) {
outputProgress({
status: 'cancelled',
operation: 'Vendor metrics calculation cancelled',
current: processedCount,
total: totalProducts,
total: totalVendors,
elapsed: formatElapsedTime(startTime),
remaining: null,
rate: calculateRate(startTime, processedCount),
percentage: ((processedCount / totalProducts) * 100).toFixed(1),
percentage: ((processedCount / totalVendors) * 100).toFixed(1),
timing: {
start_time: new Date(startTime).toISOString(),
end_time: new Date().toISOString(),
@@ -26,37 +57,21 @@ async function calculateVendorMetrics(startTime, totalProducts, processedCount =
});
return {
processedProducts: processedCount,
processedOrders,
processedPurchaseOrders,
processedOrders: 0,
processedPurchaseOrders: 0,
success
};
}
// Get counts of records that will be processed
const [[orderCount], [poCount]] = await Promise.all([
connection.query(`
SELECT COUNT(*) as count
FROM orders o
WHERE o.canceled = false
`),
connection.query(`
SELECT COUNT(*) as count
FROM purchase_orders po
WHERE po.status != 0
`)
]);
processedOrders = orderCount.count;
processedPurchaseOrders = poCount.count;
outputProgress({
status: 'running',
operation: 'Starting vendor metrics calculation',
current: processedCount,
total: totalProducts,
total: totalVendors,
elapsed: formatElapsedTime(startTime),
remaining: estimateRemaining(startTime, processedCount, totalProducts),
remaining: estimateRemaining(startTime, processedCount, totalVendors),
rate: calculateRate(startTime, processedCount),
percentage: ((processedCount / totalProducts) * 100).toFixed(1),
percentage: ((processedCount / totalVendors) * 100).toFixed(1),
timing: {
start_time: new Date(startTime).toISOString(),
end_time: new Date().toISOString(),
@@ -64,278 +79,130 @@ async function calculateVendorMetrics(startTime, totalProducts, processedCount =
}
});
// First ensure all vendors exist in vendor_details
await connection.query(`
INSERT IGNORE INTO vendor_details (vendor, status, created_at, updated_at)
SELECT DISTINCT
vendor,
'active' as status,
NOW() as created_at,
NOW() as updated_at
FROM products
WHERE vendor IS NOT NULL
`);
// Process in batches
let lastVendor = '';
while (true) {
if (isCancelled) break;
processedCount = Math.floor(totalProducts * 0.8);
outputProgress({
status: 'running',
operation: 'Vendor details updated, calculating metrics',
current: processedCount,
total: totalProducts,
elapsed: formatElapsedTime(startTime),
remaining: estimateRemaining(startTime, processedCount, totalProducts),
rate: calculateRate(startTime, processedCount),
percentage: ((processedCount / totalProducts) * 100).toFixed(1),
timing: {
start_time: new Date(startTime).toISOString(),
end_time: new Date().toISOString(),
elapsed_seconds: Math.round((Date.now() - startTime) / 1000)
}
});
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
)
ORDER BY v.vendor
LIMIT ?
`, [lastCalculationTime, lastCalculationTime, lastVendor, BATCH_SIZE]);
if (isCancelled) return {
processedProducts: processedCount,
processedOrders,
processedPurchaseOrders,
success
};
if (batch.length === 0) break;
// Now calculate vendor metrics
await connection.query(`
INSERT INTO vendor_metrics (
vendor,
total_revenue,
total_orders,
total_late_orders,
avg_lead_time_days,
on_time_delivery_rate,
order_fill_rate,
avg_order_value,
active_products,
total_products,
total_purchase_value,
avg_margin_percent,
status,
last_calculated_at
)
WITH vendor_sales AS (
SELECT
p.vendor,
SUM(o.quantity * o.price) as total_revenue,
COUNT(DISTINCT o.id) as total_orders,
COUNT(DISTINCT p.pid) as active_products,
SUM(o.quantity * (o.price - p.cost_price)) as total_margin
FROM products p
JOIN orders o ON p.pid = o.pid
WHERE o.canceled = false
AND o.date >= DATE_SUB(CURRENT_DATE, INTERVAL 12 MONTH)
GROUP BY p.vendor
),
vendor_po AS (
SELECT
p.vendor,
COUNT(DISTINCT CASE WHEN po.receiving_status = 40 THEN po.id END) as received_orders,
COUNT(DISTINCT po.id) as total_orders,
AVG(CASE
WHEN po.receiving_status = 40
THEN DATEDIFF(po.received_date, po.date)
END) as avg_lead_time_days,
SUM(po.ordered * po.po_cost_price) as total_purchase_value
FROM products p
JOIN purchase_orders po ON p.pid = po.pid
WHERE po.date >= DATE_SUB(CURRENT_DATE, INTERVAL 12 MONTH)
GROUP BY p.vendor
),
vendor_products AS (
SELECT
// Update vendor metrics for this batch
await connection.query(`
INSERT INTO vendor_metrics (
vendor,
COUNT(DISTINCT pid) as total_products
FROM products
GROUP BY vendor
)
SELECT
vs.vendor,
COALESCE(vs.total_revenue, 0) as total_revenue,
COALESCE(vp.total_orders, 0) as total_orders,
COALESCE(vp.total_orders - vp.received_orders, 0) as total_late_orders,
COALESCE(vp.avg_lead_time_days, 0) as avg_lead_time_days,
CASE
WHEN vp.total_orders > 0
THEN (vp.received_orders / vp.total_orders) * 100
ELSE 0
END as on_time_delivery_rate,
CASE
WHEN vp.total_orders > 0
THEN (vp.received_orders / vp.total_orders) * 100
ELSE 0
END as order_fill_rate,
CASE
WHEN vs.total_orders > 0
THEN vs.total_revenue / vs.total_orders
ELSE 0
END as avg_order_value,
COALESCE(vs.active_products, 0) as active_products,
COALESCE(vpr.total_products, 0) as total_products,
COALESCE(vp.total_purchase_value, 0) as total_purchase_value,
CASE
WHEN vs.total_revenue > 0
THEN (vs.total_margin / vs.total_revenue) * 100
ELSE 0
END as avg_margin_percent,
'active' as status,
NOW() as last_calculated_at
FROM vendor_sales vs
LEFT JOIN vendor_po vp ON vs.vendor = vp.vendor
LEFT JOIN vendor_products vpr ON vs.vendor = vpr.vendor
WHERE vs.vendor IS NOT NULL
ON DUPLICATE KEY UPDATE
total_revenue = VALUES(total_revenue),
total_orders = VALUES(total_orders),
total_late_orders = VALUES(total_late_orders),
avg_lead_time_days = VALUES(avg_lead_time_days),
on_time_delivery_rate = VALUES(on_time_delivery_rate),
order_fill_rate = VALUES(order_fill_rate),
avg_order_value = VALUES(avg_order_value),
active_products = VALUES(active_products),
total_products = VALUES(total_products),
total_purchase_value = VALUES(total_purchase_value),
avg_margin_percent = VALUES(avg_margin_percent),
status = VALUES(status),
last_calculated_at = VALUES(last_calculated_at)
`);
processedCount = Math.floor(totalProducts * 0.9);
outputProgress({
status: 'running',
operation: 'Vendor metrics calculated, updating time-based metrics',
current: processedCount,
total: totalProducts,
elapsed: formatElapsedTime(startTime),
remaining: estimateRemaining(startTime, processedCount, totalProducts),
rate: calculateRate(startTime, processedCount),
percentage: ((processedCount / totalProducts) * 100).toFixed(1),
timing: {
start_time: new Date(startTime).toISOString(),
end_time: new Date().toISOString(),
elapsed_seconds: Math.round((Date.now() - startTime) / 1000)
}
});
if (isCancelled) return {
processedProducts: processedCount,
processedOrders,
processedPurchaseOrders,
success
};
// Calculate time-based metrics
await connection.query(`
INSERT INTO vendor_time_metrics (
vendor,
year,
month,
total_orders,
late_orders,
avg_lead_time_days,
total_purchase_value,
total_revenue,
avg_margin_percent
)
WITH monthly_orders AS (
avg_lead_time_days,
on_time_delivery_rate,
order_fill_rate,
total_orders,
total_late_orders,
total_purchase_value,
avg_order_value,
active_products,
total_products,
total_revenue,
avg_margin_percent,
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
p.vendor,
YEAR(o.date) as year,
MONTH(o.date) as month,
COUNT(DISTINCT o.id) as total_orders,
SUM(o.quantity * o.price) as total_revenue,
SUM(o.quantity * (o.price - p.cost_price)) as total_margin
FROM products p
JOIN orders o ON p.pid = o.pid
WHERE o.canceled = false
AND o.date >= DATE_SUB(CURRENT_DATE, INTERVAL 12 MONTH)
AND p.vendor IS NOT NULL
GROUP BY p.vendor, YEAR(o.date), MONTH(o.date)
),
monthly_po AS (
SELECT
p.vendor,
YEAR(po.date) as year,
MONTH(po.date) as month,
COUNT(DISTINCT po.id) as total_po,
COUNT(DISTINCT CASE
WHEN po.receiving_status = 40 AND po.received_date > po.expected_date
THEN po.id
END) as late_orders,
AVG(CASE
WHEN po.receiving_status = 40
THEN DATEDIFF(po.received_date, po.date)
END) as avg_lead_time_days,
SUM(po.ordered * po.po_cost_price) as total_purchase_value
FROM products p
JOIN purchase_orders po ON p.pid = po.pid
WHERE po.date >= DATE_SUB(CURRENT_DATE, INTERVAL 12 MONTH)
AND p.vendor IS NOT NULL
GROUP BY p.vendor, YEAR(po.date), MONTH(po.date)
)
SELECT
mo.vendor,
mo.year,
mo.month,
COALESCE(mp.total_po, 0) as total_orders,
COALESCE(mp.late_orders, 0) as late_orders,
COALESCE(mp.avg_lead_time_days, 0) as avg_lead_time_days,
COALESCE(mp.total_purchase_value, 0) as total_purchase_value,
mo.total_revenue,
CASE
WHEN mo.total_revenue > 0
THEN (mo.total_margin / mo.total_revenue) * 100
ELSE 0
END as avg_margin_percent
FROM monthly_orders mo
LEFT JOIN monthly_po mp ON mo.vendor = mp.vendor
AND mo.year = mp.year
AND mo.month = mp.month
UNION
SELECT
mp.vendor,
mp.year,
mp.month,
mp.total_po as total_orders,
mp.late_orders,
mp.avg_lead_time_days,
mp.total_purchase_value,
0 as total_revenue,
0 as avg_margin_percent
FROM monthly_po mp
LEFT JOIN monthly_orders mo ON mp.vendor = mo.vendor
AND mp.year = mo.year
AND mp.month = mo.month
WHERE mo.vendor IS NULL
ON DUPLICATE KEY UPDATE
total_orders = VALUES(total_orders),
late_orders = VALUES(late_orders),
avg_lead_time_days = VALUES(avg_lead_time_days),
total_purchase_value = VALUES(total_purchase_value),
total_revenue = VALUES(total_revenue),
avg_margin_percent = VALUES(avg_margin_percent)
`);
v.vendor,
COALESCE(ps.avg_lead_time_days, 0) as avg_lead_time_days,
COALESCE(ps.on_time_delivery_rate, 0) as on_time_delivery_rate,
COALESCE(ps.order_fill_rate, 0) as order_fill_rate,
COALESCE(ps.total_orders, 0) as total_orders,
COALESCE(ps.total_late_orders, 0) as total_late_orders,
COALESCE(ps.total_purchase_value, 0) as total_purchase_value,
COALESCE(ps.avg_order_value, 0) as avg_order_value,
COALESCE(prs.active_products, 0) as active_products,
COALESCE(prs.total_products, 0) as total_products,
COALESCE(prs.total_revenue, 0) as total_revenue,
COALESCE(prs.avg_margin_percent, 0) as avg_margin_percent,
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
WHERE v.vendor IN (?)
ON DUPLICATE KEY UPDATE
avg_lead_time_days = VALUES(avg_lead_time_days),
on_time_delivery_rate = VALUES(on_time_delivery_rate),
order_fill_rate = VALUES(order_fill_rate),
total_orders = VALUES(total_orders),
total_late_orders = VALUES(total_late_orders),
total_purchase_value = VALUES(total_purchase_value),
avg_order_value = VALUES(avg_order_value),
active_products = VALUES(active_products),
total_products = VALUES(total_products),
total_revenue = VALUES(total_revenue),
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)]);
processedCount = Math.floor(totalProducts * 0.95);
outputProgress({
status: 'running',
operation: 'Time-based vendor metrics calculated',
current: processedCount,
total: totalProducts,
elapsed: formatElapsedTime(startTime),
remaining: estimateRemaining(startTime, processedCount, totalProducts),
rate: calculateRate(startTime, processedCount),
percentage: ((processedCount / totalProducts) * 100).toFixed(1),
timing: {
start_time: new Date(startTime).toISOString(),
end_time: new Date().toISOString(),
elapsed_seconds: Math.round((Date.now() - startTime) / 1000)
}
});
lastVendor = batch[batch.length - 1].vendor;
processedCount += batch.length;
outputProgress({
status: 'running',
operation: 'Processing vendor metrics batch',
current: processedCount,
total: totalVendors,
elapsed: formatElapsedTime(startTime),
remaining: estimateRemaining(startTime, processedCount, totalVendors),
rate: calculateRate(startTime, processedCount),
percentage: ((processedCount / totalVendors) * 100).toFixed(1),
timing: {
start_time: new Date(startTime).toISOString(),
end_time: new Date().toISOString(),
elapsed_seconds: Math.round((Date.now() - startTime) / 1000)
}
});
}
// If we get here, everything completed successfully
success = true;
@@ -349,8 +216,8 @@ async function calculateVendorMetrics(startTime, totalProducts, processedCount =
return {
processedProducts: processedCount,
processedOrders,
processedPurchaseOrders,
processedOrders: 0,
processedPurchaseOrders: 0,
success
};