Add a bunch of untested calculations enhancements based on import script changes
This commit is contained in:
@@ -13,7 +13,12 @@ async function calculateVendorMetrics(startTime, totalProducts, processedCount,
|
||||
elapsed: formatElapsedTime(startTime),
|
||||
remaining: null,
|
||||
rate: calculateRate(startTime, processedCount),
|
||||
percentage: ((processedCount / totalProducts) * 100).toFixed(1)
|
||||
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)
|
||||
}
|
||||
});
|
||||
return processedCount;
|
||||
}
|
||||
@@ -26,7 +31,12 @@ async function calculateVendorMetrics(startTime, totalProducts, processedCount,
|
||||
elapsed: formatElapsedTime(startTime),
|
||||
remaining: estimateRemaining(startTime, processedCount, totalProducts),
|
||||
rate: calculateRate(startTime, processedCount),
|
||||
percentage: ((processedCount / totalProducts) * 100).toFixed(1)
|
||||
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)
|
||||
}
|
||||
});
|
||||
|
||||
// First ensure all vendors exist in vendor_details
|
||||
@@ -50,7 +60,12 @@ async function calculateVendorMetrics(startTime, totalProducts, processedCount,
|
||||
elapsed: formatElapsedTime(startTime),
|
||||
remaining: estimateRemaining(startTime, processedCount, totalProducts),
|
||||
rate: calculateRate(startTime, processedCount),
|
||||
percentage: ((processedCount / totalProducts) * 100).toFixed(1)
|
||||
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 processedCount;
|
||||
@@ -68,6 +83,8 @@ async function calculateVendorMetrics(startTime, totalProducts, processedCount,
|
||||
avg_order_value,
|
||||
active_products,
|
||||
total_products,
|
||||
total_purchase_value,
|
||||
avg_margin_percent,
|
||||
status,
|
||||
last_calculated_at
|
||||
)
|
||||
@@ -76,7 +93,8 @@ async function calculateVendorMetrics(startTime, totalProducts, processedCount,
|
||||
p.vendor,
|
||||
SUM(o.quantity * o.price) as total_revenue,
|
||||
COUNT(DISTINCT o.id) as total_orders,
|
||||
COUNT(DISTINCT p.pid) as active_products
|
||||
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
|
||||
@@ -91,7 +109,8 @@ async function calculateVendorMetrics(startTime, totalProducts, processedCount,
|
||||
AVG(CASE
|
||||
WHEN po.receiving_status = 40
|
||||
THEN DATEDIFF(po.received_date, po.date)
|
||||
END) as avg_lead_time_days
|
||||
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)
|
||||
@@ -127,6 +146,12 @@ async function calculateVendorMetrics(startTime, totalProducts, processedCount,
|
||||
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
|
||||
@@ -143,6 +168,8 @@ async function calculateVendorMetrics(startTime, totalProducts, processedCount,
|
||||
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)
|
||||
`);
|
||||
@@ -150,13 +177,111 @@ async function calculateVendorMetrics(startTime, totalProducts, processedCount,
|
||||
processedCount = Math.floor(totalProducts * 0.9);
|
||||
outputProgress({
|
||||
status: 'running',
|
||||
operation: 'Vendor metrics calculated',
|
||||
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)
|
||||
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 processedCount;
|
||||
|
||||
// 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 (
|
||||
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)
|
||||
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)
|
||||
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,
|
||||
COALESCE(mo.total_revenue, 0) as 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
|
||||
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)
|
||||
`);
|
||||
|
||||
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)
|
||||
}
|
||||
});
|
||||
|
||||
return processedCount;
|
||||
|
||||
Reference in New Issue
Block a user