293 lines
13 KiB
JavaScript
293 lines
13 KiB
JavaScript
const { outputProgress, formatElapsedTime, estimateRemaining, calculateRate, logError } = require('./utils/progress');
|
|
const { getConnection } = require('./utils/db');
|
|
|
|
async function calculateVendorMetrics(startTime, totalProducts, processedCount = 0, isCancelled = false) {
|
|
const connection = await getConnection();
|
|
let success = false;
|
|
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 using EXISTS for better performance
|
|
const [vendorCount] = await connection.query(`
|
|
SELECT COUNT(DISTINCT v.vendor) as count
|
|
FROM vendor_details v
|
|
WHERE v.status = 'active'
|
|
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 > ?
|
|
)
|
|
)
|
|
`, [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: totalVendors,
|
|
elapsed: formatElapsedTime(startTime),
|
|
remaining: null,
|
|
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)
|
|
}
|
|
});
|
|
return {
|
|
processedProducts: processedCount,
|
|
processedOrders: 0,
|
|
processedPurchaseOrders: 0,
|
|
success
|
|
};
|
|
}
|
|
|
|
outputProgress({
|
|
status: 'running',
|
|
operation: 'Starting vendor metrics calculation',
|
|
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)
|
|
}
|
|
});
|
|
|
|
// Process in batches
|
|
let lastVendor = '';
|
|
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
|
|
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 (p.pid IS NOT NULL OR po.po_id IS NOT NULL)
|
|
ORDER BY v.vendor
|
|
LIMIT ?
|
|
`, [lastCalculationTime, lastCalculationTime, lastVendor, BATCH_SIZE]);
|
|
|
|
if (batch.length === 0) break;
|
|
|
|
// 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');
|
|
|
|
await connection.query(`
|
|
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,
|
|
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
|
|
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)
|
|
AND po.updated > ?
|
|
GROUP BY po.vendor
|
|
`, [batch.map(row => row.vendor), lastCalculationTime]);
|
|
|
|
// Populate product stats with optimized index usage
|
|
await connection.query(`
|
|
INSERT INTO temp_product_stats
|
|
SELECT
|
|
p.vendor,
|
|
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,
|
|
SUM(pm.total_revenue) as total_revenue
|
|
FROM products p
|
|
FORCE INDEX (idx_vendor)
|
|
LEFT JOIN product_metrics pm FORCE INDEX (PRIMARY) ON p.pid = pm.pid
|
|
WHERE p.vendor IN (?)
|
|
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, lastCalculationTime]);
|
|
|
|
// Update metrics using temp tables with optimized join order
|
|
await connection.query(`
|
|
INSERT INTO vendor_metrics (
|
|
vendor,
|
|
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
|
|
)
|
|
SELECT
|
|
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
|
|
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),
|
|
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)]);
|
|
|
|
// 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;
|
|
|
|
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;
|
|
|
|
// Update calculate_status
|
|
await connection.query(`
|
|
INSERT INTO calculate_status (module_name, last_calculation_timestamp)
|
|
VALUES ('vendor_metrics', NOW())
|
|
ON DUPLICATE KEY UPDATE last_calculation_timestamp = NOW()
|
|
`);
|
|
|
|
return {
|
|
processedProducts: processedCount,
|
|
processedOrders: 0,
|
|
processedPurchaseOrders: 0,
|
|
success
|
|
};
|
|
|
|
} catch (error) {
|
|
success = false;
|
|
logError(error, 'Error calculating vendor metrics');
|
|
throw error;
|
|
} finally {
|
|
if (connection) {
|
|
connection.release();
|
|
}
|
|
}
|
|
}
|
|
|
|
module.exports = calculateVendorMetrics; |