378 lines
16 KiB
JavaScript
378 lines
16 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;
|
|
let processedOrders = 0;
|
|
let processedPurchaseOrders = 0;
|
|
|
|
try {
|
|
if (isCancelled) {
|
|
outputProgress({
|
|
status: 'cancelled',
|
|
operation: 'Vendor metrics calculation cancelled',
|
|
current: processedCount,
|
|
total: totalProducts,
|
|
elapsed: formatElapsedTime(startTime),
|
|
remaining: null,
|
|
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 {
|
|
processedProducts: processedCount,
|
|
processedOrders,
|
|
processedPurchaseOrders,
|
|
success
|
|
};
|
|
}
|
|
|
|
// Get counts of records that will be processed
|
|
const [orderCountResult, poCountResult] = await Promise.all([
|
|
connection.query(`
|
|
SELECT COUNT(*) as count
|
|
FROM orders o
|
|
WHERE o.canceled = false
|
|
`),
|
|
connection.query(`
|
|
SELECT COUNT(*) as count
|
|
FROM purchase_orders po
|
|
WHERE po.status != 0
|
|
`)
|
|
]);
|
|
processedOrders = parseInt(orderCountResult.rows[0].count);
|
|
processedPurchaseOrders = parseInt(poCountResult.rows[0].count);
|
|
|
|
outputProgress({
|
|
status: 'running',
|
|
operation: 'Starting vendor metrics calculation',
|
|
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)
|
|
}
|
|
});
|
|
|
|
// First ensure all vendors exist in vendor_details
|
|
await connection.query(`
|
|
INSERT 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
|
|
ON CONFLICT (vendor) DO NOTHING
|
|
`);
|
|
|
|
processedCount = Math.floor(totalProducts * 0.8);
|
|
outputProgress({
|
|
status: 'running',
|
|
operation: 'Vendor details updated, calculating metrics',
|
|
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)
|
|
}
|
|
});
|
|
|
|
if (isCancelled) return {
|
|
processedProducts: processedCount,
|
|
processedOrders,
|
|
processedPurchaseOrders,
|
|
success
|
|
};
|
|
|
|
// 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,
|
|
total_purchase_value,
|
|
avg_margin_percent,
|
|
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,
|
|
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 >= CURRENT_DATE - INTERVAL '12 months'
|
|
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
|
|
AND po.received_date IS NOT NULL
|
|
AND po.date IS NOT NULL
|
|
THEN EXTRACT(EPOCH FROM (po.received_date::timestamp with time zone - po.date::timestamp with time zone)) / 86400.0
|
|
ELSE NULL
|
|
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 >= CURRENT_DATE - INTERVAL '12 months'
|
|
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,
|
|
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
|
|
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 CONFLICT (vendor) DO UPDATE
|
|
SET
|
|
total_revenue = EXCLUDED.total_revenue,
|
|
total_orders = EXCLUDED.total_orders,
|
|
total_late_orders = EXCLUDED.total_late_orders,
|
|
avg_lead_time_days = EXCLUDED.avg_lead_time_days,
|
|
on_time_delivery_rate = EXCLUDED.on_time_delivery_rate,
|
|
order_fill_rate = EXCLUDED.order_fill_rate,
|
|
avg_order_value = EXCLUDED.avg_order_value,
|
|
active_products = EXCLUDED.active_products,
|
|
total_products = EXCLUDED.total_products,
|
|
total_purchase_value = EXCLUDED.total_purchase_value,
|
|
avg_margin_percent = EXCLUDED.avg_margin_percent,
|
|
status = EXCLUDED.status,
|
|
last_calculated_at = EXCLUDED.last_calculated_at
|
|
`);
|
|
|
|
processedCount = Math.floor(totalProducts * 0.9);
|
|
outputProgress({
|
|
status: 'running',
|
|
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),
|
|
timing: {
|
|
start_time: new Date(startTime).toISOString(),
|
|
end_time: new Date().toISOString(),
|
|
elapsed_seconds: Math.round((Date.now() - startTime) / 1000)
|
|
}
|
|
});
|
|
|
|
if (isCancelled) return {
|
|
processedProducts: processedCount,
|
|
processedOrders,
|
|
processedPurchaseOrders,
|
|
success
|
|
};
|
|
|
|
// 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,
|
|
EXTRACT(YEAR FROM o.date::timestamp with time zone) as year,
|
|
EXTRACT(MONTH FROM o.date::timestamp with time zone) 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 >= CURRENT_DATE - INTERVAL '12 months'
|
|
AND p.vendor IS NOT NULL
|
|
GROUP BY p.vendor, EXTRACT(YEAR FROM o.date::timestamp with time zone), EXTRACT(MONTH FROM o.date::timestamp with time zone)
|
|
),
|
|
monthly_po AS (
|
|
SELECT
|
|
p.vendor,
|
|
EXTRACT(YEAR FROM po.date::timestamp with time zone) as year,
|
|
EXTRACT(MONTH FROM po.date::timestamp with time zone) 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
|
|
AND po.received_date IS NOT NULL
|
|
AND po.date IS NOT NULL
|
|
THEN EXTRACT(EPOCH FROM (po.received_date::timestamp with time zone - po.date::timestamp with time zone)) / 86400.0
|
|
ELSE NULL
|
|
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 >= CURRENT_DATE - INTERVAL '12 months'
|
|
AND p.vendor IS NOT NULL
|
|
GROUP BY p.vendor, EXTRACT(YEAR FROM po.date::timestamp with time zone), EXTRACT(MONTH FROM po.date::timestamp with time zone)
|
|
)
|
|
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,
|
|
mo.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
|
|
UNION
|
|
SELECT
|
|
mp.vendor,
|
|
mp.year,
|
|
mp.month,
|
|
mp.total_po as total_orders,
|
|
mp.late_orders,
|
|
mp.avg_lead_time_days,
|
|
mp.total_purchase_value,
|
|
0 as total_revenue,
|
|
0 as avg_margin_percent
|
|
FROM monthly_po mp
|
|
LEFT JOIN monthly_orders mo ON mp.vendor = mo.vendor
|
|
AND mp.year = mo.year
|
|
AND mp.month = mo.month
|
|
WHERE mo.vendor IS NULL
|
|
ON CONFLICT (vendor, year, month) DO UPDATE
|
|
SET
|
|
total_orders = EXCLUDED.total_orders,
|
|
late_orders = EXCLUDED.late_orders,
|
|
avg_lead_time_days = EXCLUDED.avg_lead_time_days,
|
|
total_purchase_value = EXCLUDED.total_purchase_value,
|
|
total_revenue = EXCLUDED.total_revenue,
|
|
avg_margin_percent = EXCLUDED.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)
|
|
}
|
|
});
|
|
|
|
// 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 CONFLICT (module_name) DO UPDATE
|
|
SET last_calculation_timestamp = NOW()
|
|
`);
|
|
|
|
return {
|
|
processedProducts: processedCount,
|
|
processedOrders,
|
|
processedPurchaseOrders,
|
|
success
|
|
};
|
|
|
|
} catch (error) {
|
|
success = false;
|
|
logError(error, 'Error calculating vendor metrics');
|
|
throw error;
|
|
} finally {
|
|
if (connection) {
|
|
connection.release();
|
|
}
|
|
}
|
|
}
|
|
|
|
module.exports = calculateVendorMetrics; |