Add forecasting page

This commit is contained in:
2025-01-15 22:08:52 -05:00
parent e5f97ab836
commit c8c3d323a4
15 changed files with 893 additions and 94 deletions

View File

@@ -466,7 +466,88 @@ async function calculateLeadTimeMetrics(connection, startTime, totalProducts) {
`);
}
// Update the main calculation function to include our new calculations
// Add new function for category sales metrics
async function calculateCategorySalesMetrics(connection, startTime, totalProducts) {
outputProgress({
status: 'running',
operation: 'Calculating category sales metrics',
current: Math.floor(totalProducts * 0.9),
total: totalProducts,
elapsed: formatElapsedTime(startTime),
remaining: estimateRemaining(startTime, Math.floor(totalProducts * 0.9), totalProducts),
rate: calculateRate(startTime, Math.floor(totalProducts * 0.9)),
percentage: '90'
});
await connection.query(`
INSERT INTO category_sales_metrics (
category_id,
brand,
period_start,
period_end,
avg_daily_sales,
total_sold,
num_products,
avg_price,
last_calculated_at
)
WITH date_ranges AS (
SELECT
DATE_SUB(CURDATE(), INTERVAL 30 DAY) as period_start,
CURDATE() as period_end
UNION ALL
SELECT
DATE_SUB(CURDATE(), INTERVAL 90 DAY),
CURDATE()
UNION ALL
SELECT
DATE_SUB(CURDATE(), INTERVAL 180 DAY),
CURDATE()
UNION ALL
SELECT
DATE_SUB(CURDATE(), INTERVAL 365 DAY),
CURDATE()
),
category_metrics AS (
SELECT
c.id as category_id,
p.brand,
dr.period_start,
dr.period_end,
COUNT(DISTINCT p.product_id) as num_products,
COALESCE(SUM(o.quantity), 0) / DATEDIFF(dr.period_end, dr.period_start) as avg_daily_sales,
COALESCE(SUM(o.quantity), 0) as total_sold,
COALESCE(AVG(o.price), 0) as avg_price
FROM categories c
JOIN product_categories pc ON c.id = pc.category_id
JOIN products p ON pc.product_id = p.product_id
CROSS JOIN date_ranges dr
LEFT JOIN orders o ON p.product_id = o.product_id
AND o.date BETWEEN dr.period_start AND dr.period_end
AND o.canceled = false
GROUP BY c.id, p.brand, dr.period_start, dr.period_end
)
SELECT
category_id,
brand,
period_start,
period_end,
avg_daily_sales,
total_sold,
num_products,
avg_price,
NOW() as last_calculated_at
FROM category_metrics
ON DUPLICATE KEY UPDATE
avg_daily_sales = VALUES(avg_daily_sales),
total_sold = VALUES(total_sold),
num_products = VALUES(num_products),
avg_price = VALUES(avg_price),
last_calculated_at = NOW()
`);
}
// Update the main calculation function to include category sales metrics
async function calculateMetrics() {
let pool;
const startTime = Date.now();
@@ -751,6 +832,7 @@ async function calculateMetrics() {
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,
COUNT(*) as orders_analyzed
@@ -952,6 +1034,7 @@ async function calculateMetrics() {
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,
@@ -985,6 +1068,7 @@ async function calculateMetrics() {
inventory_value,
avg_lead_time_days,
last_purchase_date,
first_received_date,
last_received_date,
stock_status,
reorder_qty,
@@ -1008,6 +1092,7 @@ async function calculateMetrics() {
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),
@@ -1067,6 +1152,12 @@ async function calculateMetrics() {
});
await calculateLeadTimeMetrics(connection, startTime, totalProducts);
// Add category sales metrics calculation
if (isCancelled) {
throw new Error('Operation cancelled');
}
await calculateCategorySalesMetrics(connection, startTime, totalProducts);
// Calculate ABC classification
if (isCancelled) {
throw new Error('Operation cancelled');