Add backend changes and update scripts

This commit is contained in:
2025-01-16 00:47:29 -05:00
parent 1ea02b8938
commit 7ec587595a
7 changed files with 589 additions and 174 deletions

View File

@@ -547,7 +547,194 @@ async function calculateCategorySalesMetrics(connection, startTime, totalProduct
`);
}
// Update the main calculation function to include category sales metrics
// Add new functions for vendor and category metrics
async function calculateVendorMetrics(connection) {
console.log('Calculating vendor metrics...');
// 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
)
SELECT
vd.vendor,
-- Lead time metrics
AVG(DATEDIFF(po.received_date, po.date)) as avg_lead_time_days,
-- On-time delivery rate
(COUNT(CASE WHEN po.received_date <= po.expected_date THEN 1 END) / COUNT(*)) * 100 as on_time_delivery_rate,
-- Order fill rate
(SUM(po.received) / SUM(po.ordered)) * 100 as order_fill_rate,
COUNT(DISTINCT po.po_id) as total_orders,
COUNT(DISTINCT CASE WHEN po.received_date > po.expected_date THEN po.po_id 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,
-- Product counts
COUNT(DISTINCT CASE WHEN p.visible = true THEN p.product_id END) as active_products,
COUNT(DISTINCT p.product_id) as total_products,
-- Financial metrics
SUM(o.price * o.quantity) as total_revenue,
AVG(((o.price - p.cost_price) / o.price) * 100) as avg_margin_percent,
vd.status
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
GROUP BY vd.vendor, vd.status
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
)
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,
AVG(((o.price - p.cost_price) / o.price) * 100) 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)
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)
`);
}
async function calculateCategoryMetrics(connection) {
console.log('Calculating category metrics...');
// Calculate category performance metrics
await connection.query(`
INSERT INTO category_metrics (
category_id,
product_count,
active_products,
total_value,
avg_margin,
turnover_rate,
growth_rate,
status
)
SELECT
c.id as category_id,
COUNT(DISTINCT p.product_id) as product_count,
COUNT(DISTINCT CASE WHEN p.visible = true THEN p.product_id END) as active_products,
SUM(p.stock_quantity * p.cost_price) as total_value,
AVG(((p.price - p.cost_price) / p.price) * 100) as avg_margin,
-- Turnover rate calculation
SUM(o.quantity) / NULLIF(AVG(p.stock_quantity), 0) as turnover_rate,
-- Growth rate calculation (comparing current month to previous month)
((
SUM(CASE WHEN o.date >= DATE_SUB(CURRENT_DATE, INTERVAL 1 MONTH) THEN o.quantity ELSE 0 END) -
SUM(CASE WHEN o.date BETWEEN DATE_SUB(CURRENT_DATE, INTERVAL 2 MONTH) AND DATE_SUB(CURRENT_DATE, INTERVAL 1 MONTH) THEN o.quantity ELSE 0 END)
) / NULLIF(
SUM(CASE WHEN o.date BETWEEN DATE_SUB(CURRENT_DATE, INTERVAL 2 MONTH) AND DATE_SUB(CURRENT_DATE, INTERVAL 1 MONTH) THEN o.quantity ELSE 0 END),
0
) * 100) as growth_rate,
c.status
FROM categories c
LEFT JOIN product_categories pc ON c.id = pc.category_id
LEFT JOIN products p ON pc.product_id = p.product_id
LEFT JOIN orders o ON p.product_id = o.product_id AND o.canceled = false
GROUP BY c.id, c.status
ON DUPLICATE KEY UPDATE
product_count = VALUES(product_count),
active_products = VALUES(active_products),
total_value = VALUES(total_value),
avg_margin = VALUES(avg_margin),
turnover_rate = VALUES(turnover_rate),
growth_rate = VALUES(growth_rate),
status = VALUES(status),
last_calculated_at = CURRENT_TIMESTAMP
`);
// Calculate category time-based metrics
await connection.query(`
INSERT INTO category_time_metrics (
category_id,
year,
month,
product_count,
active_products,
total_value,
total_revenue,
avg_margin,
turnover_rate
)
SELECT
c.id as category_id,
YEAR(o.date) as year,
MONTH(o.date) as month,
COUNT(DISTINCT p.product_id) as product_count,
COUNT(DISTINCT CASE WHEN p.visible = true THEN p.product_id END) as active_products,
SUM(p.stock_quantity * p.cost_price) as total_value,
SUM(o.price * o.quantity) as total_revenue,
AVG(((p.price - p.cost_price) / p.price) * 100) as avg_margin,
SUM(o.quantity) / NULLIF(AVG(p.stock_quantity), 0) as turnover_rate
FROM categories c
LEFT JOIN product_categories pc ON c.id = pc.category_id
LEFT JOIN products p ON pc.product_id = p.product_id
LEFT JOIN orders o ON p.product_id = o.product_id AND o.canceled = false
WHERE o.date >= DATE_SUB(CURRENT_DATE, INTERVAL 12 MONTH)
GROUP BY c.id, YEAR(o.date), MONTH(o.date)
ON DUPLICATE KEY UPDATE
product_count = VALUES(product_count),
active_products = VALUES(active_products),
total_value = VALUES(total_value),
total_revenue = VALUES(total_revenue),
avg_margin = VALUES(avg_margin),
turnover_rate = VALUES(turnover_rate)
`);
}
// Update the main calculation function to include the new metrics
async function calculateMetrics() {
let pool;
const startTime = Date.now();