231 lines
11 KiB
JavaScript
231 lines
11 KiB
JavaScript
const { outputProgress } = require('./utils/progress');
|
|
const { getConnection } = require('./utils/db');
|
|
|
|
async function calculateSalesForecasts(startTime, totalProducts, processedCount) {
|
|
const connection = await getConnection();
|
|
try {
|
|
outputProgress({
|
|
status: 'running',
|
|
operation: 'Calculating sales forecasts',
|
|
current: Math.floor(totalProducts * 0.98),
|
|
total: totalProducts,
|
|
elapsed: formatElapsedTime(startTime),
|
|
remaining: estimateRemaining(startTime, Math.floor(totalProducts * 0.98), totalProducts),
|
|
rate: calculateRate(startTime, Math.floor(totalProducts * 0.98)),
|
|
percentage: '98'
|
|
});
|
|
|
|
// Calculate product-level forecasts
|
|
await connection.query(`
|
|
INSERT INTO sales_forecasts (
|
|
pid,
|
|
forecast_date,
|
|
forecast_units,
|
|
forecast_revenue,
|
|
confidence_level,
|
|
last_calculated_at
|
|
)
|
|
WITH daily_sales AS (
|
|
SELECT
|
|
o.pid,
|
|
DATE(o.date) as sale_date,
|
|
SUM(o.quantity) as daily_quantity,
|
|
SUM(o.price * o.quantity) as daily_revenue
|
|
FROM orders o
|
|
WHERE o.canceled = false
|
|
AND o.date >= DATE_SUB(CURRENT_DATE, INTERVAL 90 DAY)
|
|
GROUP BY o.pid, DATE(o.date)
|
|
),
|
|
forecast_dates AS (
|
|
SELECT
|
|
DATE_ADD(CURRENT_DATE, INTERVAL n DAY) as forecast_date
|
|
FROM (
|
|
SELECT 0 as n UNION SELECT 1 UNION SELECT 2 UNION SELECT 3 UNION SELECT 4 UNION
|
|
SELECT 5 UNION SELECT 6 UNION SELECT 7 UNION SELECT 8 UNION SELECT 9 UNION
|
|
SELECT 10 UNION SELECT 11 UNION SELECT 12 UNION SELECT 13 UNION SELECT 14 UNION
|
|
SELECT 15 UNION SELECT 16 UNION SELECT 17 UNION SELECT 18 UNION SELECT 19 UNION
|
|
SELECT 20 UNION SELECT 21 UNION SELECT 22 UNION SELECT 23 UNION SELECT 24 UNION
|
|
SELECT 25 UNION SELECT 26 UNION SELECT 27 UNION SELECT 28 UNION SELECT 29 UNION
|
|
SELECT 30
|
|
) numbers
|
|
),
|
|
product_stats AS (
|
|
SELECT
|
|
ds.pid,
|
|
AVG(ds.daily_quantity) as avg_daily_quantity,
|
|
STDDEV_SAMP(ds.daily_quantity) as std_daily_quantity,
|
|
AVG(ds.daily_revenue) as avg_daily_revenue,
|
|
STDDEV_SAMP(ds.daily_revenue) as std_daily_revenue,
|
|
COUNT(*) as data_points,
|
|
-- Calculate day-of-week averages
|
|
AVG(CASE WHEN DAYOFWEEK(ds.sale_date) = 1 THEN ds.daily_revenue END) as sunday_avg,
|
|
AVG(CASE WHEN DAYOFWEEK(ds.sale_date) = 2 THEN ds.daily_revenue END) as monday_avg,
|
|
AVG(CASE WHEN DAYOFWEEK(ds.sale_date) = 3 THEN ds.daily_revenue END) as tuesday_avg,
|
|
AVG(CASE WHEN DAYOFWEEK(ds.sale_date) = 4 THEN ds.daily_revenue END) as wednesday_avg,
|
|
AVG(CASE WHEN DAYOFWEEK(ds.sale_date) = 5 THEN ds.daily_revenue END) as thursday_avg,
|
|
AVG(CASE WHEN DAYOFWEEK(ds.sale_date) = 6 THEN ds.daily_revenue END) as friday_avg,
|
|
AVG(CASE WHEN DAYOFWEEK(ds.sale_date) = 7 THEN ds.daily_revenue END) as saturday_avg
|
|
FROM daily_sales ds
|
|
GROUP BY ds.pid
|
|
)
|
|
SELECT
|
|
ps.pid,
|
|
fd.forecast_date,
|
|
GREATEST(0,
|
|
ps.avg_daily_quantity *
|
|
(1 + COALESCE(
|
|
(SELECT seasonality_factor
|
|
FROM sales_seasonality
|
|
WHERE MONTH(fd.forecast_date) = month
|
|
LIMIT 1),
|
|
0
|
|
))
|
|
) as forecast_units,
|
|
GREATEST(0,
|
|
CASE DAYOFWEEK(fd.forecast_date)
|
|
WHEN 1 THEN COALESCE(ps.sunday_avg, ps.avg_daily_revenue)
|
|
WHEN 2 THEN COALESCE(ps.monday_avg, ps.avg_daily_revenue)
|
|
WHEN 3 THEN COALESCE(ps.tuesday_avg, ps.avg_daily_revenue)
|
|
WHEN 4 THEN COALESCE(ps.wednesday_avg, ps.avg_daily_revenue)
|
|
WHEN 5 THEN COALESCE(ps.thursday_avg, ps.avg_daily_revenue)
|
|
WHEN 6 THEN COALESCE(ps.friday_avg, ps.avg_daily_revenue)
|
|
WHEN 7 THEN COALESCE(ps.saturday_avg, ps.avg_daily_revenue)
|
|
END *
|
|
(1 + COALESCE(
|
|
(SELECT seasonality_factor
|
|
FROM sales_seasonality
|
|
WHERE MONTH(fd.forecast_date) = month
|
|
LIMIT 1),
|
|
0
|
|
)) *
|
|
-- Add some randomness within a small range (±5%)
|
|
(0.95 + (RAND() * 0.1))
|
|
) as forecast_revenue,
|
|
CASE
|
|
WHEN ps.data_points >= 60 THEN 90
|
|
WHEN ps.data_points >= 30 THEN 80
|
|
WHEN ps.data_points >= 14 THEN 70
|
|
ELSE 60
|
|
END as confidence_level,
|
|
NOW() as last_calculated_at
|
|
FROM product_stats ps
|
|
CROSS JOIN forecast_dates fd
|
|
WHERE ps.avg_daily_quantity > 0
|
|
ON DUPLICATE KEY UPDATE
|
|
forecast_units = VALUES(forecast_units),
|
|
forecast_revenue = VALUES(forecast_revenue),
|
|
confidence_level = VALUES(confidence_level),
|
|
last_calculated_at = NOW()
|
|
`);
|
|
|
|
// Calculate category-level forecasts
|
|
await connection.query(`
|
|
INSERT INTO category_forecasts (
|
|
category_id,
|
|
forecast_date,
|
|
forecast_units,
|
|
forecast_revenue,
|
|
confidence_level,
|
|
last_calculated_at
|
|
)
|
|
WITH category_daily_sales AS (
|
|
SELECT
|
|
pc.cat_id as category_id,
|
|
DATE(o.date) as sale_date,
|
|
SUM(o.quantity) as daily_quantity,
|
|
SUM(o.price * o.quantity) as daily_revenue
|
|
FROM orders o
|
|
JOIN product_categories pc ON o.pid = pc.pid
|
|
WHERE o.canceled = false
|
|
AND o.date >= DATE_SUB(CURRENT_DATE, INTERVAL 90 DAY)
|
|
GROUP BY pc.cat_id, DATE(o.date)
|
|
),
|
|
forecast_dates AS (
|
|
SELECT
|
|
DATE_ADD(CURRENT_DATE, INTERVAL n DAY) as forecast_date
|
|
FROM (
|
|
SELECT 0 as n UNION SELECT 1 UNION SELECT 2 UNION SELECT 3 UNION SELECT 4 UNION
|
|
SELECT 5 UNION SELECT 6 UNION SELECT 7 UNION SELECT 8 UNION SELECT 9 UNION
|
|
SELECT 10 UNION SELECT 11 UNION SELECT 12 UNION SELECT 13 UNION SELECT 14 UNION
|
|
SELECT 15 UNION SELECT 16 UNION SELECT 17 UNION SELECT 18 UNION SELECT 19 UNION
|
|
SELECT 20 UNION SELECT 21 UNION SELECT 22 UNION SELECT 23 UNION SELECT 24 UNION
|
|
SELECT 25 UNION SELECT 26 UNION SELECT 27 UNION SELECT 28 UNION SELECT 29 UNION
|
|
SELECT 30
|
|
) numbers
|
|
),
|
|
category_stats AS (
|
|
SELECT
|
|
cds.category_id,
|
|
AVG(cds.daily_quantity) as avg_daily_quantity,
|
|
STDDEV_SAMP(cds.daily_quantity) as std_daily_quantity,
|
|
AVG(cds.daily_revenue) as avg_daily_revenue,
|
|
STDDEV_SAMP(cds.daily_revenue) as std_daily_revenue,
|
|
COUNT(*) as data_points,
|
|
-- Calculate day-of-week averages
|
|
AVG(CASE WHEN DAYOFWEEK(cds.sale_date) = 1 THEN cds.daily_revenue END) as sunday_avg,
|
|
AVG(CASE WHEN DAYOFWEEK(cds.sale_date) = 2 THEN cds.daily_revenue END) as monday_avg,
|
|
AVG(CASE WHEN DAYOFWEEK(cds.sale_date) = 3 THEN cds.daily_revenue END) as tuesday_avg,
|
|
AVG(CASE WHEN DAYOFWEEK(cds.sale_date) = 4 THEN cds.daily_revenue END) as wednesday_avg,
|
|
AVG(CASE WHEN DAYOFWEEK(cds.sale_date) = 5 THEN cds.daily_revenue END) as thursday_avg,
|
|
AVG(CASE WHEN DAYOFWEEK(cds.sale_date) = 6 THEN cds.daily_revenue END) as friday_avg,
|
|
AVG(CASE WHEN DAYOFWEEK(cds.sale_date) = 7 THEN cds.daily_revenue END) as saturday_avg
|
|
FROM category_daily_sales cds
|
|
GROUP BY cds.category_id
|
|
)
|
|
SELECT
|
|
cs.category_id,
|
|
fd.forecast_date,
|
|
GREATEST(0,
|
|
cs.avg_daily_quantity *
|
|
(1 + COALESCE(
|
|
(SELECT seasonality_factor
|
|
FROM sales_seasonality
|
|
WHERE MONTH(fd.forecast_date) = month
|
|
LIMIT 1),
|
|
0
|
|
))
|
|
) as forecast_units,
|
|
GREATEST(0,
|
|
CASE DAYOFWEEK(fd.forecast_date)
|
|
WHEN 1 THEN COALESCE(cs.sunday_avg, cs.avg_daily_revenue)
|
|
WHEN 2 THEN COALESCE(cs.monday_avg, cs.avg_daily_revenue)
|
|
WHEN 3 THEN COALESCE(cs.tuesday_avg, cs.avg_daily_revenue)
|
|
WHEN 4 THEN COALESCE(cs.wednesday_avg, cs.avg_daily_revenue)
|
|
WHEN 5 THEN COALESCE(cs.thursday_avg, cs.avg_daily_revenue)
|
|
WHEN 6 THEN COALESCE(cs.friday_avg, cs.avg_daily_revenue)
|
|
WHEN 7 THEN COALESCE(cs.saturday_avg, cs.avg_daily_revenue)
|
|
END *
|
|
(1 + COALESCE(
|
|
(SELECT seasonality_factor
|
|
FROM sales_seasonality
|
|
WHERE MONTH(fd.forecast_date) = month
|
|
LIMIT 1),
|
|
0
|
|
)) *
|
|
-- Add some randomness within a small range (±5%)
|
|
(0.95 + (RAND() * 0.1))
|
|
) as forecast_revenue,
|
|
CASE
|
|
WHEN cs.data_points >= 60 THEN 90
|
|
WHEN cs.data_points >= 30 THEN 80
|
|
WHEN cs.data_points >= 14 THEN 70
|
|
ELSE 60
|
|
END as confidence_level,
|
|
NOW() as last_calculated_at
|
|
FROM category_stats cs
|
|
CROSS JOIN forecast_dates fd
|
|
WHERE cs.avg_daily_quantity > 0
|
|
ON DUPLICATE KEY UPDATE
|
|
forecast_units = VALUES(forecast_units),
|
|
forecast_revenue = VALUES(forecast_revenue),
|
|
confidence_level = VALUES(confidence_level),
|
|
last_calculated_at = NOW()
|
|
`);
|
|
|
|
return Math.floor(totalProducts * 1.0);
|
|
} finally {
|
|
connection.release();
|
|
}
|
|
}
|
|
|
|
module.exports = calculateSalesForecasts;
|