139 lines
5.6 KiB
JavaScript
139 lines
5.6 KiB
JavaScript
const { outputProgress } = require('./utils/progress');
|
|
const { getConnection } = require('./utils/db');
|
|
|
|
async function calculateVendorMetrics(startTime, totalProducts, processedCount) {
|
|
const connection = await getConnection();
|
|
try {
|
|
outputProgress({
|
|
status: 'running',
|
|
operation: 'Ensuring vendors exist in vendor_details',
|
|
current: Math.floor(totalProducts * 0.7),
|
|
total: totalProducts,
|
|
elapsed: formatElapsedTime(startTime),
|
|
remaining: estimateRemaining(startTime, Math.floor(totalProducts * 0.7), totalProducts),
|
|
rate: calculateRate(startTime, Math.floor(totalProducts * 0.7)),
|
|
percentage: '70'
|
|
});
|
|
|
|
// 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
|
|
`);
|
|
|
|
outputProgress({
|
|
status: 'running',
|
|
operation: 'Calculating vendor metrics',
|
|
current: Math.floor(totalProducts * 0.8),
|
|
total: totalProducts,
|
|
elapsed: formatElapsedTime(startTime),
|
|
remaining: estimateRemaining(startTime, Math.floor(totalProducts * 0.8), totalProducts),
|
|
rate: calculateRate(startTime, Math.floor(totalProducts * 0.8)),
|
|
percentage: '80'
|
|
});
|
|
|
|
// 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,
|
|
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
|
|
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
|
|
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
|
|
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,
|
|
'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),
|
|
status = VALUES(status),
|
|
last_calculated_at = VALUES(last_calculated_at)
|
|
`);
|
|
|
|
return Math.floor(totalProducts * 0.9);
|
|
} finally {
|
|
connection.release();
|
|
}
|
|
}
|
|
|
|
module.exports = calculateVendorMetrics; |