Files
inventory/inventory-server/scripts/metrics/vendor-metrics.js
2025-01-26 23:42:38 -05:00

174 lines
7.9 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: 'Calculating vendor metrics',
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)
SELECT DISTINCT vendor, 'active' as status
FROM products
WHERE vendor IS NOT NULL
AND vendor NOT IN (SELECT vendor FROM vendor_details)
`);
// Calculate vendor performance metrics
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
)
WITH vendor_orders AS (
SELECT
po.vendor,
AVG(DATEDIFF(po.received_date, po.date)) as avg_lead_time_days,
COUNT(*) as total_orders,
COUNT(CASE WHEN po.received_date > po.expected_date THEN 1 END) as total_late_orders,
SUM(po.cost_price * po.ordered) as total_purchase_value,
AVG(po.cost_price * po.ordered) as avg_order_value,
CASE
WHEN COUNT(*) > 0 THEN
(COUNT(CASE WHEN po.received = po.ordered THEN 1 END) * 100.0) / COUNT(*)
ELSE 0
END as order_fill_rate
FROM purchase_orders po
WHERE po.status = 'closed'
GROUP BY po.vendor
),
vendor_products AS (
SELECT
p.vendor,
COUNT(DISTINCT p.product_id) as total_products,
COUNT(DISTINCT CASE WHEN p.visible = true THEN p.product_id END) as active_products,
SUM(o.price * o.quantity) as total_revenue,
CASE
WHEN SUM(o.price * o.quantity) > 0 THEN
(SUM((o.price - p.cost_price) * o.quantity) * 100.0) / SUM(o.price * o.quantity)
ELSE 0
END as avg_margin_percent
FROM products p
LEFT JOIN orders o ON p.product_id = o.product_id AND o.canceled = false
GROUP BY p.vendor
)
SELECT
vd.vendor,
COALESCE(vo.avg_lead_time_days, 0) as avg_lead_time_days,
CASE
WHEN COALESCE(vo.total_orders, 0) > 0 THEN
((COALESCE(vo.total_orders, 0) - COALESCE(vo.total_late_orders, 0)) * 100.0) / COALESCE(vo.total_orders, 1)
ELSE 0
END as on_time_delivery_rate,
COALESCE(vo.order_fill_rate, 0) as order_fill_rate,
COALESCE(vo.total_orders, 0) as total_orders,
COALESCE(vo.total_late_orders, 0) as total_late_orders,
COALESCE(vo.total_purchase_value, 0) as total_purchase_value,
COALESCE(vo.avg_order_value, 0) as avg_order_value,
COALESCE(vp.active_products, 0) as active_products,
COALESCE(vp.total_products, 0) as total_products,
COALESCE(vp.total_revenue, 0) as total_revenue,
COALESCE(vp.avg_margin_percent, 0) as avg_margin_percent,
vd.status
FROM vendor_details vd
LEFT JOIN vendor_orders vo ON vd.vendor = vo.vendor
LEFT JOIN vendor_products vp ON vd.vendor = vp.vendor
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 = CURRENT_TIMESTAMP
`);
// Calculate vendor 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 vendor_time_data AS (
SELECT
vd.vendor,
YEAR(po.date) as year,
MONTH(po.date) as month,
COUNT(DISTINCT po.po_id) as total_orders,
COUNT(DISTINCT CASE WHEN po.received_date > po.expected_date THEN po.po_id END) as late_orders,
AVG(DATEDIFF(po.received_date, po.date)) as avg_lead_time_days,
SUM(po.cost_price * po.ordered) as total_purchase_value,
SUM(o.price * o.quantity) as total_revenue,
CASE
WHEN SUM(o.price * o.quantity) > 0 THEN
(SUM((o.price - p.cost_price) * o.quantity) * 100.0) / SUM(o.price * o.quantity)
ELSE 0
END as avg_margin_percent
FROM vendor_details vd
LEFT JOIN products p ON vd.vendor = p.vendor
LEFT JOIN purchase_orders po ON p.product_id = po.product_id
LEFT JOIN orders o ON p.product_id = o.product_id AND o.canceled = false
WHERE po.date >= DATE_SUB(CURRENT_DATE, INTERVAL 12 MONTH)
GROUP BY vd.vendor, YEAR(po.date), MONTH(po.date)
)
SELECT
vendor,
year,
month,
COALESCE(total_orders, 0) as total_orders,
COALESCE(late_orders, 0) as late_orders,
COALESCE(avg_lead_time_days, 0) as avg_lead_time_days,
COALESCE(total_purchase_value, 0) as total_purchase_value,
COALESCE(total_revenue, 0) as total_revenue,
COALESCE(avg_margin_percent, 0) as avg_margin_percent
FROM vendor_time_data
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)
`);
return Math.floor(totalProducts * 0.75);
} finally {
connection.release();
}
}
module.exports = calculateVendorMetrics;