504 lines
25 KiB
JavaScript
504 lines
25 KiB
JavaScript
const { outputProgress, logError } = require('./utils/progress');
|
|
const { getConnection } = require('./utils/db');
|
|
|
|
// Helper function to handle NaN and undefined values
|
|
function sanitizeValue(value) {
|
|
if (value === undefined || value === null || Number.isNaN(value)) {
|
|
return null;
|
|
}
|
|
return value;
|
|
}
|
|
|
|
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 pid, 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.pid,
|
|
p.vendor,
|
|
pc.cat_id as category_id
|
|
FROM products p
|
|
LEFT JOIN product_categories pc ON p.pid = pc.pid
|
|
WHERE p.pid = ?
|
|
),
|
|
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.pid]);
|
|
|
|
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.pid = p.pid
|
|
WHERE o.canceled = 0 AND o.pid = ?
|
|
GROUP BY o.pid
|
|
)
|
|
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.pid,
|
|
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 receiving_status >= 30 -- Partial or fully received
|
|
AND pid = ?
|
|
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.pid]);
|
|
|
|
// Get stock info
|
|
const [stockInfo] = await connection.query(`
|
|
SELECT
|
|
p.stock_quantity,
|
|
p.cost_price,
|
|
p.created_at,
|
|
p.replenishable,
|
|
p.moq,
|
|
p.notions_inv_count,
|
|
p.date_last_sold,
|
|
p.total_sold,
|
|
DATEDIFF(CURDATE(), MIN(po.received_date)) as days_since_first_stock,
|
|
DATEDIFF(CURDATE(), COALESCE(p.date_last_sold, CURDATE())) as days_since_last_sale,
|
|
CASE
|
|
WHEN EXISTS (
|
|
SELECT 1 FROM orders o
|
|
WHERE o.pid = p.pid
|
|
AND o.date >= DATE_SUB(CURDATE(), INTERVAL 30 DAY)
|
|
AND o.canceled = false
|
|
AND (SELECT SUM(quantity) FROM orders o2
|
|
WHERE o2.pid = p.pid
|
|
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.pid = po.pid
|
|
AND po.receiving_status >= 30 -- Partial or fully received
|
|
AND po.received > 0
|
|
WHERE p.pid = ?
|
|
GROUP BY p.pid
|
|
`, [product.pid]);
|
|
|
|
// Calculate metrics
|
|
const salesData = salesMetrics[0] || {};
|
|
const purchaseData = purchaseMetrics[0] || {};
|
|
const stockData = stockInfo[0] || {};
|
|
|
|
// Sales velocity metrics
|
|
const daily_sales_avg = sanitizeValue(salesData.rolling_daily_avg) || 0;
|
|
const weekly_sales_avg = sanitizeValue(salesData.rolling_weekly_avg) || 0;
|
|
const monthly_sales_avg = sanitizeValue(salesData.rolling_monthly_avg) || 0;
|
|
|
|
// Stock metrics
|
|
const stock_quantity = sanitizeValue(stockData.stock_quantity) || 0;
|
|
const days_of_inventory = daily_sales_avg > 0 ? Math.floor(stock_quantity / daily_sales_avg) : 999;
|
|
const weeks_of_inventory = Math.floor(days_of_inventory / 7);
|
|
|
|
// Calculate stock status
|
|
const stock_status = calculateStockStatus(
|
|
stock_quantity,
|
|
config,
|
|
daily_sales_avg,
|
|
weekly_sales_avg,
|
|
monthly_sales_avg
|
|
);
|
|
|
|
// Calculate reorder quantities
|
|
const reorder_quantities = calculateReorderQuantities(
|
|
stock_quantity,
|
|
stock_status,
|
|
daily_sales_avg,
|
|
sanitizeValue(purchaseData.avg_lead_time_days) || 0,
|
|
config
|
|
);
|
|
|
|
// Financial metrics
|
|
const cost_price = sanitizeValue(stockData.cost_price) || 0;
|
|
const inventory_value = stock_quantity * cost_price;
|
|
const total_revenue = sanitizeValue(salesData.total_revenue) || 0;
|
|
const total_cost = sanitizeValue(salesData.total_cost) || 0;
|
|
const gross_profit = total_revenue - total_cost;
|
|
const avg_margin_percent = total_revenue > 0 ? ((gross_profit / total_revenue) * 100) : 0;
|
|
const gmroi = inventory_value > 0 ? (gross_profit / inventory_value) : 0;
|
|
|
|
// Add to batch update with sanitized values
|
|
metricsUpdates.push([
|
|
product.pid,
|
|
sanitizeValue(daily_sales_avg),
|
|
sanitizeValue(weekly_sales_avg),
|
|
sanitizeValue(monthly_sales_avg),
|
|
sanitizeValue(salesData.avg_quantity_per_order),
|
|
sanitizeValue(salesData.number_of_orders),
|
|
salesData.first_sale_date || null,
|
|
salesData.last_sale_date || null,
|
|
sanitizeValue(days_of_inventory),
|
|
sanitizeValue(weeks_of_inventory),
|
|
sanitizeValue(reorder_quantities.reorder_point),
|
|
sanitizeValue(reorder_quantities.safety_stock),
|
|
sanitizeValue(reorder_quantities.reorder_qty),
|
|
sanitizeValue(reorder_quantities.overstocked_amt),
|
|
sanitizeValue(avg_margin_percent),
|
|
sanitizeValue(total_revenue),
|
|
sanitizeValue(inventory_value),
|
|
sanitizeValue(total_cost),
|
|
sanitizeValue(gross_profit),
|
|
sanitizeValue(gmroi),
|
|
sanitizeValue(purchaseData.avg_lead_time_days),
|
|
purchaseData.last_purchase_date || null,
|
|
purchaseData.first_received_date || null,
|
|
purchaseData.last_received_date || null,
|
|
null, // abc_class - calculated separately
|
|
stock_status,
|
|
sanitizeValue(0), // turnover_rate - calculated separately
|
|
sanitizeValue(purchaseData.avg_lead_time_days),
|
|
sanitizeValue(config.target_days),
|
|
stock_status === 'Critical' ? 'Warning' : 'Normal',
|
|
null, // forecast_accuracy
|
|
null, // forecast_bias
|
|
null // last_forecast_date
|
|
]);
|
|
} catch (err) {
|
|
logError(err, `Failed processing product ${product.pid}`);
|
|
continue;
|
|
}
|
|
}
|
|
|
|
// Batch update metrics
|
|
if (metricsUpdates.length > 0) {
|
|
try {
|
|
await connection.query(`
|
|
INSERT INTO product_metrics (
|
|
pid,
|
|
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,
|
|
safety_stock,
|
|
reorder_qty,
|
|
overstocked_amt,
|
|
avg_margin_percent,
|
|
total_revenue,
|
|
inventory_value,
|
|
cost_of_goods_sold,
|
|
gross_profit,
|
|
gmroi,
|
|
avg_lead_time_days,
|
|
last_purchase_date,
|
|
first_received_date,
|
|
last_received_date,
|
|
abc_class,
|
|
stock_status,
|
|
turnover_rate,
|
|
current_lead_time,
|
|
target_lead_time,
|
|
lead_time_status,
|
|
forecast_accuracy,
|
|
forecast_bias,
|
|
last_forecast_date
|
|
)
|
|
VALUES ?
|
|
ON DUPLICATE KEY UPDATE
|
|
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),
|
|
safety_stock = VALUES(safety_stock),
|
|
reorder_qty = VALUES(reorder_qty),
|
|
overstocked_amt = VALUES(overstocked_amt),
|
|
avg_margin_percent = VALUES(avg_margin_percent),
|
|
total_revenue = VALUES(total_revenue),
|
|
inventory_value = VALUES(inventory_value),
|
|
cost_of_goods_sold = VALUES(cost_of_goods_sold),
|
|
gross_profit = VALUES(gross_profit),
|
|
gmroi = VALUES(gmroi),
|
|
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),
|
|
turnover_rate = VALUES(turnover_rate),
|
|
current_lead_time = VALUES(current_lead_time),
|
|
target_lead_time = VALUES(target_lead_time),
|
|
lead_time_status = VALUES(lead_time_status),
|
|
last_calculated_at = CURRENT_TIMESTAMP
|
|
`, [metricsUpdates]);
|
|
} catch (err) {
|
|
logError(err, 'Failed to update metrics batch');
|
|
throw err;
|
|
}
|
|
}
|
|
}
|
|
|
|
return processedCount;
|
|
} finally {
|
|
if (connection) {
|
|
connection.release();
|
|
}
|
|
}
|
|
}
|
|
|
|
function calculateStockStatus(stock, config, daily_sales_avg, weekly_sales_avg, monthly_sales_avg) {
|
|
if (stock <= 0) {
|
|
return 'Out of Stock';
|
|
}
|
|
|
|
// Use the most appropriate sales average based on data quality
|
|
let sales_avg = daily_sales_avg;
|
|
if (sales_avg === 0) {
|
|
sales_avg = weekly_sales_avg / 7;
|
|
}
|
|
if (sales_avg === 0) {
|
|
sales_avg = monthly_sales_avg / 30;
|
|
}
|
|
|
|
if (sales_avg === 0) {
|
|
return stock <= config.low_stock_threshold ? 'Low Stock' : 'In Stock';
|
|
}
|
|
|
|
const days_of_stock = stock / sales_avg;
|
|
|
|
if (days_of_stock <= config.critical_days) {
|
|
return 'Critical';
|
|
} else if (days_of_stock <= config.reorder_days) {
|
|
return 'Reorder';
|
|
} else if (days_of_stock > config.overstock_days) {
|
|
return 'Overstocked';
|
|
}
|
|
|
|
return 'Healthy';
|
|
}
|
|
|
|
function calculateReorderQuantities(stock, stock_status, daily_sales_avg, avg_lead_time, config) {
|
|
// Calculate safety stock based on service level and lead time
|
|
const z_score = 1.96; // 95% service level
|
|
const lead_time = avg_lead_time || config.target_days;
|
|
const safety_stock = Math.ceil(daily_sales_avg * Math.sqrt(lead_time) * z_score);
|
|
|
|
// Calculate reorder point
|
|
const lead_time_demand = daily_sales_avg * lead_time;
|
|
const reorder_point = Math.ceil(lead_time_demand + safety_stock);
|
|
|
|
// Calculate reorder quantity using EOQ formula if we have the necessary data
|
|
let reorder_qty = 0;
|
|
if (daily_sales_avg > 0) {
|
|
const annual_demand = daily_sales_avg * 365;
|
|
const order_cost = 25; // Fixed cost per order
|
|
const holding_cost_percent = 0.25; // 25% annual holding cost
|
|
|
|
reorder_qty = Math.ceil(Math.sqrt((2 * annual_demand * order_cost) / holding_cost_percent));
|
|
} else {
|
|
// If no sales data, use a basic calculation
|
|
reorder_qty = Math.max(safety_stock, config.low_stock_threshold);
|
|
}
|
|
|
|
// Calculate overstocked amount
|
|
const overstocked_amt = stock_status === 'Overstocked' ?
|
|
stock - Math.ceil(daily_sales_avg * config.overstock_days) :
|
|
0;
|
|
|
|
return {
|
|
safety_stock,
|
|
reorder_point,
|
|
reorder_qty,
|
|
overstocked_amt
|
|
};
|
|
}
|
|
|
|
module.exports = calculateProductMetrics;
|