Optimize and fix calculate scripts

This commit is contained in:
2025-01-27 13:16:21 -05:00
parent 5781b45f37
commit 8323ae7703
10 changed files with 748 additions and 962 deletions

View File

@@ -6,7 +6,7 @@ async function calculateVendorMetrics(startTime, totalProducts, processedCount)
try {
outputProgress({
status: 'running',
operation: 'Calculating vendor metrics',
operation: 'Ensuring vendors exist in vendor_details',
current: Math.floor(totalProducts * 0.7),
total: totalProducts,
elapsed: formatElapsedTime(startTime),
@@ -15,160 +15,125 @@ async function calculateVendorMetrics(startTime, totalProducts, processedCount)
percentage: '70'
});
// First, ensure all vendors exist in vendor_details
// First ensure all vendors exist in vendor_details
await connection.query(`
INSERT IGNORE INTO vendor_details (vendor, status)
SELECT DISTINCT vendor, 'active' as status
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
AND vendor NOT IN (SELECT vendor FROM vendor_details)
`);
// Calculate vendor performance metrics
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,
total_orders,
total_late_orders,
total_purchase_value,
avg_order_value,
active_products,
total_products,
total_revenue,
avg_margin_percent,
status
status,
last_calculated_at
)
WITH vendor_orders AS (
WITH vendor_sales 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.receiving_status >= 30 -- Partial or fully received
GROUP BY po.vendor
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
p.vendor,
COUNT(DISTINCT p.pid) as total_products,
COUNT(DISTINCT CASE WHEN p.visible = true THEN p.pid 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.pid = o.pid AND o.canceled = false
GROUP BY p.vendor
vendor,
COUNT(DISTINCT pid) as total_products
FROM products
GROUP BY vendor
)
SELECT
vd.vendor,
COALESCE(vo.avg_lead_time_days, 0) as avg_lead_time_days,
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 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)
WHEN vp.total_orders > 0
THEN (vp.received_orders / vp.total_orders) * 100
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
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),
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
last_calculated_at = VALUES(last_calculated_at)
`);
// 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.pid = po.pid
LEFT JOIN orders o ON p.pid = o.pid 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);
return Math.floor(totalProducts * 0.9);
} finally {
connection.release();
}
}
module.exports = calculateVendorMetrics;
module.exports = calculateVendorMetrics;