Flatten calculate file structure a bit

This commit is contained in:
2025-01-21 22:07:46 -05:00
parent fa8e2fa33b
commit 9c1bcba1a3
8 changed files with 7 additions and 7 deletions

View File

@@ -0,0 +1,498 @@
const { outputProgress, logError } = require('../utils/progress');
const { getConnection } = require('../utils/db');
async function calculateProductMetrics(startTime, totalProducts, processedCount = 0) {
const connection = await getConnection();
try {
// Process in batches of 250
const batchSize = 250;
for (let offset = 0; offset < totalProducts; offset += batchSize) {
const [products] = await connection.query('SELECT product_id, vendor FROM products LIMIT ? OFFSET ?', [batchSize, offset])
.catch(err => {
logError(err, `Failed to fetch products batch at offset ${offset}`);
throw err;
});
processedCount += products.length;
// Update progress after each batch
outputProgress({
status: 'running',
operation: 'Processing products',
current: processedCount,
total: totalProducts,
elapsed: formatElapsedTime(startTime),
remaining: estimateRemaining(startTime, processedCount, totalProducts),
rate: calculateRate(startTime, processedCount),
percentage: ((processedCount / totalProducts) * 100).toFixed(1)
});
// Process the batch
const metricsUpdates = [];
for (const product of products) {
try {
// Get configuration values for this product
const [configs] = await connection.query(`
WITH product_info AS (
SELECT
p.product_id,
p.vendor,
pc.category_id
FROM products p
LEFT JOIN product_categories pc ON p.product_id = pc.product_id
WHERE p.product_id = ?
),
threshold_options AS (
SELECT
st.*,
CASE
WHEN st.category_id = pi.category_id AND st.vendor = pi.vendor THEN 1
WHEN st.category_id = pi.category_id AND st.vendor IS NULL THEN 2
WHEN st.category_id IS NULL AND st.vendor = pi.vendor THEN 3
WHEN st.category_id IS NULL AND st.vendor IS NULL THEN 4
ELSE 5
END as priority
FROM product_info pi
CROSS JOIN stock_thresholds st
WHERE (st.category_id = pi.category_id OR st.category_id IS NULL)
AND (st.vendor = pi.vendor OR st.vendor IS NULL)
),
velocity_options AS (
SELECT
sv.*,
CASE
WHEN sv.category_id = pi.category_id AND sv.vendor = pi.vendor THEN 1
WHEN sv.category_id = pi.category_id AND sv.vendor IS NULL THEN 2
WHEN sv.category_id IS NULL AND sv.vendor = pi.vendor THEN 3
WHEN sv.category_id IS NULL AND sv.vendor IS NULL THEN 4
ELSE 5
END as priority
FROM product_info pi
CROSS JOIN sales_velocity_config sv
WHERE (sv.category_id = pi.category_id OR sv.category_id IS NULL)
AND (sv.vendor = pi.vendor OR sv.vendor IS NULL)
),
safety_options AS (
SELECT
ss.*,
CASE
WHEN ss.category_id = pi.category_id AND ss.vendor = pi.vendor THEN 1
WHEN ss.category_id = pi.category_id AND ss.vendor IS NULL THEN 2
WHEN ss.category_id IS NULL AND ss.vendor = pi.vendor THEN 3
WHEN ss.category_id IS NULL AND ss.vendor IS NULL THEN 4
ELSE 5
END as priority
FROM product_info pi
CROSS JOIN safety_stock_config ss
WHERE (ss.category_id = pi.category_id OR ss.category_id IS NULL)
AND (ss.vendor = pi.vendor OR ss.vendor IS NULL)
)
SELECT
COALESCE(
(SELECT critical_days
FROM threshold_options
ORDER BY priority LIMIT 1),
7
) as critical_days,
COALESCE(
(SELECT reorder_days
FROM threshold_options
ORDER BY priority LIMIT 1),
14
) as reorder_days,
COALESCE(
(SELECT overstock_days
FROM threshold_options
ORDER BY priority LIMIT 1),
90
) as overstock_days,
COALESCE(
(SELECT low_stock_threshold
FROM threshold_options
ORDER BY priority LIMIT 1),
5
) as low_stock_threshold,
COALESCE(
(SELECT daily_window_days
FROM velocity_options
ORDER BY priority LIMIT 1),
30
) as daily_window_days,
COALESCE(
(SELECT weekly_window_days
FROM velocity_options
ORDER BY priority LIMIT 1),
7
) as weekly_window_days,
COALESCE(
(SELECT monthly_window_days
FROM velocity_options
ORDER BY priority LIMIT 1),
90
) as monthly_window_days,
COALESCE(
(SELECT coverage_days
FROM safety_options
ORDER BY priority LIMIT 1),
14
) as safety_stock_days,
COALESCE(
(SELECT service_level
FROM safety_options
ORDER BY priority LIMIT 1),
95.0
) as service_level
`, [product.product_id]);
const config = configs[0];
// Calculate sales metrics
const [salesMetrics] = await connection.query(`
WITH sales_summary AS (
SELECT
SUM(o.quantity) as total_quantity_sold,
SUM((o.price - COALESCE(o.discount, 0)) * o.quantity) as total_revenue,
SUM(COALESCE(p.cost_price, 0) * o.quantity) as total_cost,
MAX(o.date) as last_sale_date,
MIN(o.date) as first_sale_date,
COUNT(DISTINCT o.order_number) as number_of_orders,
AVG(o.quantity) as avg_quantity_per_order,
SUM(CASE WHEN o.date >= DATE_SUB(CURDATE(), INTERVAL ? DAY) THEN o.quantity ELSE 0 END) as last_30_days_qty,
CASE
WHEN SUM(CASE WHEN o.date >= DATE_SUB(CURDATE(), INTERVAL ? DAY) THEN o.quantity ELSE 0 END) IS NULL THEN 0
ELSE SUM(CASE WHEN o.date >= DATE_SUB(CURDATE(), INTERVAL ? DAY) THEN o.quantity ELSE 0 END)
END as rolling_weekly_avg,
SUM(CASE WHEN o.date >= DATE_SUB(CURDATE(), INTERVAL ? DAY) THEN o.quantity ELSE 0 END) as last_month_qty
FROM orders o
JOIN products p ON o.product_id = p.product_id
WHERE o.canceled = 0 AND o.product_id = ?
GROUP BY o.product_id
)
SELECT
total_quantity_sold,
total_revenue,
total_cost,
last_sale_date,
first_sale_date,
number_of_orders,
avg_quantity_per_order,
last_30_days_qty / ? as rolling_daily_avg,
rolling_weekly_avg / ? as rolling_weekly_avg,
last_month_qty / ? as rolling_monthly_avg
FROM sales_summary
`, [
config.daily_window_days,
config.weekly_window_days,
config.weekly_window_days,
config.monthly_window_days,
product.product_id,
config.daily_window_days,
config.weekly_window_days,
config.monthly_window_days
]);
// Calculate purchase metrics
const [purchaseMetrics] = await connection.query(`
WITH recent_orders AS (
SELECT
date,
received_date,
received,
cost_price,
DATEDIFF(received_date, date) as lead_time_days,
ROW_NUMBER() OVER (ORDER BY date DESC) as order_rank
FROM purchase_orders
WHERE status = 'closed'
AND product_id = ?
AND received > 0
AND received_date IS NOT NULL
),
lead_time_orders AS (
SELECT *
FROM recent_orders
WHERE order_rank <= 5
OR date >= DATE_SUB(CURDATE(), INTERVAL 90 DAY)
)
SELECT
SUM(CASE WHEN received >= 0 THEN received ELSE 0 END) as total_quantity_purchased,
SUM(CASE WHEN received >= 0 THEN cost_price * received ELSE 0 END) as total_cost,
MAX(date) as last_purchase_date,
MIN(received_date) as first_received_date,
MAX(received_date) as last_received_date,
AVG(lead_time_days) as avg_lead_time_days
FROM lead_time_orders
`, [product.product_id]);
// Get stock info
const [stockInfo] = await connection.query(`
SELECT
p.stock_quantity,
p.cost_price,
p.created_at,
p.replenishable,
p.moq,
DATEDIFF(CURDATE(), MIN(po.received_date)) as days_since_first_stock,
DATEDIFF(CURDATE(), COALESCE(
(SELECT MAX(o2.date)
FROM orders o2
WHERE o2.product_id = p.product_id
AND o2.canceled = false),
CURDATE()
)) as days_since_last_sale,
(SELECT SUM(quantity)
FROM orders o3
WHERE o3.product_id = p.product_id
AND o3.canceled = false) as total_quantity_sold,
CASE
WHEN EXISTS (
SELECT 1 FROM orders o
WHERE o.product_id = p.product_id
AND o.date >= DATE_SUB(CURDATE(), INTERVAL 30 DAY)
AND o.canceled = false
AND (SELECT SUM(quantity) FROM orders o2
WHERE o2.product_id = p.product_id
AND o2.date >= o.date
AND o2.canceled = false) = 0
) THEN true
ELSE false
END as had_recent_stockout
FROM products p
LEFT JOIN purchase_orders po ON p.product_id = po.product_id
AND po.status = 'closed'
AND po.received > 0
WHERE p.product_id = ?
GROUP BY p.product_id
`, [product.product_id]);
// Calculate metrics
const metrics = salesMetrics[0] || {};
const purchases = purchaseMetrics[0] || {};
const stock = stockInfo[0] || {};
const daily_sales_avg = metrics.rolling_daily_avg || 0;
const weekly_sales_avg = metrics.rolling_weekly_avg || 0;
const monthly_sales_avg = metrics.total_quantity_sold ? metrics.total_quantity_sold / 30 : 0;
// Calculate days of inventory
const days_of_inventory = daily_sales_avg > 0 ?
Math.ceil(
(stock.stock_quantity / daily_sales_avg) +
(purchases.avg_lead_time_days || config.reorder_days) *
(1 + (config.service_level / 100))
) : null;
const weeks_of_inventory = days_of_inventory ? Math.ceil(days_of_inventory / 7) : null;
// Calculate margin percent
const margin_percent = metrics.total_revenue > 0 ?
((metrics.total_revenue - metrics.total_cost) / metrics.total_revenue) * 100 :
null;
// Calculate inventory value
const inventory_value = (stock.stock_quantity || 0) * (stock.cost_price || 0);
// Calculate stock status
const stock_status = calculateStockStatus(stock, config, daily_sales_avg, weekly_sales_avg, monthly_sales_avg);
// Calculate reorder quantity and overstocked amount
const { reorder_qty, overstocked_amt } = calculateReorderQuantities(
stock,
stock_status,
daily_sales_avg,
purchases.avg_lead_time_days,
config
);
// Add to batch update
metricsUpdates.push([
product.product_id,
daily_sales_avg || null,
weekly_sales_avg || null,
monthly_sales_avg || null,
metrics.avg_quantity_per_order || null,
metrics.number_of_orders || 0,
metrics.first_sale_date || null,
metrics.last_sale_date || null,
days_of_inventory,
weeks_of_inventory,
daily_sales_avg > 0 ? Math.max(1, Math.ceil(daily_sales_avg * config.reorder_days)) : null,
margin_percent,
metrics.total_revenue || 0,
inventory_value || 0,
purchases.avg_lead_time_days || null,
purchases.last_purchase_date || null,
purchases.first_received_date || null,
purchases.last_received_date || null,
stock_status,
reorder_qty,
overstocked_amt
]);
} catch (err) {
logError(err, `Failed processing product ${product.product_id}`);
continue;
}
}
// Batch update metrics
if (metricsUpdates.length > 0) {
await connection.query(`
INSERT INTO product_metrics (
product_id,
daily_sales_avg,
weekly_sales_avg,
monthly_sales_avg,
avg_quantity_per_order,
number_of_orders,
first_sale_date,
last_sale_date,
days_of_inventory,
weeks_of_inventory,
reorder_point,
avg_margin_percent,
total_revenue,
inventory_value,
avg_lead_time_days,
last_purchase_date,
first_received_date,
last_received_date,
stock_status,
reorder_qty,
overstocked_amt
) VALUES ?
ON DUPLICATE KEY UPDATE
last_calculated_at = NOW(),
daily_sales_avg = VALUES(daily_sales_avg),
weekly_sales_avg = VALUES(weekly_sales_avg),
monthly_sales_avg = VALUES(monthly_sales_avg),
avg_quantity_per_order = VALUES(avg_quantity_per_order),
number_of_orders = VALUES(number_of_orders),
first_sale_date = VALUES(first_sale_date),
last_sale_date = VALUES(last_sale_date),
days_of_inventory = VALUES(days_of_inventory),
weeks_of_inventory = VALUES(weeks_of_inventory),
reorder_point = VALUES(reorder_point),
avg_margin_percent = VALUES(avg_margin_percent),
total_revenue = VALUES(total_revenue),
inventory_value = VALUES(inventory_value),
avg_lead_time_days = VALUES(avg_lead_time_days),
last_purchase_date = VALUES(last_purchase_date),
first_received_date = VALUES(first_received_date),
last_received_date = VALUES(last_received_date),
stock_status = VALUES(stock_status),
reorder_qty = VALUES(reorder_qty),
overstocked_amt = VALUES(overstocked_amt)
`, [metricsUpdates]);
}
}
return processedCount;
} finally {
connection.release();
}
}
function calculateStockStatus(stock, config, daily_sales_avg, weekly_sales_avg, monthly_sales_avg) {
const days_since_first_stock = stock.days_since_first_stock || 0;
const days_since_last_sale = stock.days_since_last_sale || 9999;
const total_quantity_sold = stock.total_quantity_sold || 0;
const had_recent_stockout = stock.had_recent_stockout || false;
const dq = stock.stock_quantity || 0;
const ds = daily_sales_avg || 0;
const ws = weekly_sales_avg || 0;
const ms = monthly_sales_avg || 0;
// If no stock, return immediately
if (dq === 0) {
return had_recent_stockout ? 'Critical' : 'Out of Stock';
}
// 1. Check if truly "New" (≤30 days and no sales)
if (days_since_first_stock <= 30 && total_quantity_sold === 0) {
return 'New';
}
// 2. Handle zero or very low sales velocity cases
if (ds === 0 || (ds < 0.1 && ws < 0.5)) {
if (days_since_first_stock > config.overstock_days) {
return 'Overstocked';
}
if (days_since_first_stock > 30) {
return 'At Risk';
}
}
// 3. Calculate days of supply and check velocity trends
const days_of_supply = ds > 0 ? dq / ds : 999;
const velocity_trend = ds > 0 ? (ds / (ms || ds) - 1) * 100 : 0;
// Critical stock level
if (days_of_supply <= config.critical_days) {
return 'Critical';
}
// Reorder cases
if (days_of_supply <= config.reorder_days ||
(had_recent_stockout && days_of_supply <= config.reorder_days * 1.5)) {
return 'Reorder';
}
// At Risk cases
if (
(days_of_supply >= config.overstock_days * 0.8) ||
(velocity_trend <= -50 && days_of_supply > config.reorder_days * 2) ||
(days_since_last_sale > 45 && dq > 0) ||
(ds > 0 && ds < 0.2 && dq > ds * config.overstock_days * 0.5)
) {
return 'At Risk';
}
// Overstock cases
if (days_of_supply >= config.overstock_days) {
return 'Overstocked';
}
// If none of the above conditions are met
return 'Healthy';
}
function calculateReorderQuantities(stock, stock_status, daily_sales_avg, avg_lead_time, config) {
let reorder_qty = 0;
let overstocked_amt = 0;
// Only calculate reorder quantity for replenishable products
if (stock.replenishable && (stock_status === 'Critical' || stock_status === 'Reorder')) {
const ds = daily_sales_avg || 0;
const lt = avg_lead_time || 14;
const sc = config.safety_stock_days || 14;
const ss = config.safety_stock_days || 14;
const dq = stock.stock_quantity || 0;
const moq = stock.moq || 1;
// Calculate desired stock level
const desired_stock = (ds * (lt + sc)) + ss;
// Calculate raw reorder amount
const raw_reorder = Math.max(0, desired_stock - dq);
// Round up to nearest MOQ
reorder_qty = Math.ceil(raw_reorder / moq) * moq;
}
// Calculate overstocked amount for overstocked products
if (stock_status === 'Overstocked') {
const ds = daily_sales_avg || 0;
const dq = stock.stock_quantity || 0;
const lt = avg_lead_time || 14;
const sc = config.safety_stock_days || 14;
const ss = config.safety_stock_days || 14;
// Calculate maximum desired stock
const max_desired_stock = (ds * config.overstock_days) + ss;
// Calculate excess inventory
overstocked_amt = Math.max(0, dq - max_desired_stock);
}
return { reorder_qty, overstocked_amt };
}
module.exports = calculateProductMetrics;