More gemini suggested improvements for speed
This commit is contained in:
@@ -219,6 +219,28 @@ async function calculateProductMetrics(startTime, totalProducts, processedCount
|
||||
JOIN products p ON pm.pid = p.pid
|
||||
LEFT JOIN temp_sales_metrics sm ON pm.pid = sm.pid
|
||||
LEFT JOIN temp_purchase_metrics lm ON pm.pid = lm.pid
|
||||
LEFT JOIN (
|
||||
SELECT
|
||||
sf.pid,
|
||||
AVG(CASE
|
||||
WHEN o.quantity > 0
|
||||
THEN ABS(sf.forecast_units - o.quantity) / o.quantity * 100
|
||||
ELSE 100
|
||||
END) as avg_forecast_error,
|
||||
AVG(CASE
|
||||
WHEN o.quantity > 0
|
||||
THEN (sf.forecast_units - o.quantity) / o.quantity * 100
|
||||
ELSE 0
|
||||
END) as avg_forecast_bias,
|
||||
MAX(sf.forecast_date) as last_forecast_date
|
||||
FROM sales_forecasts sf
|
||||
JOIN orders o ON sf.pid = o.pid
|
||||
AND DATE(o.date) = sf.forecast_date
|
||||
WHERE o.canceled = false
|
||||
AND sf.forecast_date >= DATE_SUB(CURRENT_DATE, INTERVAL 90 DAY)
|
||||
AND sf.pid IN (?)
|
||||
GROUP BY sf.pid
|
||||
) fa ON pm.pid = fa.pid
|
||||
SET
|
||||
pm.inventory_value = p.stock_quantity * p.cost_price,
|
||||
pm.daily_sales_avg = COALESCE(sm.daily_sales_avg, 0),
|
||||
@@ -229,51 +251,12 @@ async function calculateProductMetrics(startTime, totalProducts, processedCount
|
||||
pm.first_sale_date = sm.first_sale_date,
|
||||
pm.last_sale_date = sm.last_sale_date,
|
||||
pm.avg_lead_time_days = COALESCE(lm.avg_lead_time_days, 30),
|
||||
pm.days_of_inventory = CASE
|
||||
WHEN COALESCE(sm.daily_sales_avg, 0) > 0
|
||||
THEN FLOOR(p.stock_quantity / sm.daily_sales_avg)
|
||||
ELSE NULL
|
||||
END,
|
||||
pm.weeks_of_inventory = CASE
|
||||
WHEN COALESCE(sm.weekly_sales_avg, 0) > 0
|
||||
THEN FLOOR(p.stock_quantity / sm.weekly_sales_avg)
|
||||
ELSE NULL
|
||||
END,
|
||||
pm.stock_status = CASE
|
||||
WHEN p.stock_quantity <= 0 THEN 'Out of Stock'
|
||||
WHEN COALESCE(sm.daily_sales_avg, 0) = 0 AND p.stock_quantity <= ? THEN 'Low Stock'
|
||||
WHEN COALESCE(sm.daily_sales_avg, 0) = 0 THEN 'In Stock'
|
||||
WHEN p.stock_quantity / NULLIF(sm.daily_sales_avg, 0) <= ? THEN 'Critical'
|
||||
WHEN p.stock_quantity / NULLIF(sm.daily_sales_avg, 0) <= ? THEN 'Reorder'
|
||||
WHEN p.stock_quantity / NULLIF(sm.daily_sales_avg, 0) > ? THEN 'Overstocked'
|
||||
ELSE 'Healthy'
|
||||
END,
|
||||
pm.reorder_qty = CASE
|
||||
WHEN COALESCE(sm.daily_sales_avg, 0) > 0 THEN
|
||||
GREATEST(
|
||||
CEIL(sm.daily_sales_avg * COALESCE(lm.avg_lead_time_days, 30) * 1.96),
|
||||
?
|
||||
)
|
||||
ELSE ?
|
||||
END,
|
||||
pm.overstocked_amt = CASE
|
||||
WHEN p.stock_quantity / NULLIF(sm.daily_sales_avg, 0) > ?
|
||||
THEN GREATEST(0, p.stock_quantity - CEIL(sm.daily_sales_avg * ?))
|
||||
ELSE 0
|
||||
END,
|
||||
pm.forecast_accuracy = GREATEST(0, 100 - LEAST(fa.avg_forecast_error, 100)),
|
||||
pm.forecast_bias = GREATEST(-100, LEAST(fa.avg_forecast_bias, 100)),
|
||||
pm.last_forecast_date = fa.last_forecast_date,
|
||||
pm.last_calculated_at = NOW()
|
||||
WHERE p.pid IN (?)
|
||||
`, [
|
||||
defaultThresholds.low_stock_threshold,
|
||||
defaultThresholds.critical_days,
|
||||
defaultThresholds.reorder_days,
|
||||
defaultThresholds.overstock_days,
|
||||
defaultThresholds.low_stock_threshold,
|
||||
defaultThresholds.low_stock_threshold,
|
||||
defaultThresholds.overstock_days,
|
||||
defaultThresholds.overstock_days,
|
||||
batch.map(row => row.pid)
|
||||
]);
|
||||
`, [batch.map(row => row.pid), batch.map(row => row.pid)]);
|
||||
|
||||
lastPid = batch[batch.length - 1].pid;
|
||||
myProcessedProducts += batch.length; // Increment the *module's* count
|
||||
|
||||
@@ -101,12 +101,6 @@ async function calculateSalesForecasts(startTime, totalProducts, processedCount
|
||||
|
||||
if (batch.length === 0) break;
|
||||
|
||||
// Create temporary tables for better performance
|
||||
await connection.query('DROP TEMPORARY TABLE IF EXISTS temp_historical_sales');
|
||||
await connection.query('DROP TEMPORARY TABLE IF EXISTS temp_sales_stats');
|
||||
await connection.query('DROP TEMPORARY TABLE IF EXISTS temp_recent_trend');
|
||||
await connection.query('DROP TEMPORARY TABLE IF EXISTS temp_confidence_calc');
|
||||
|
||||
// Create optimized temporary tables with indexes
|
||||
await connection.query(`
|
||||
CREATE TEMPORARY TABLE temp_historical_sales (
|
||||
@@ -128,25 +122,15 @@ async function calculateSalesForecasts(startTime, totalProducts, processedCount
|
||||
days_with_sales INT,
|
||||
first_sale DATE,
|
||||
last_sale DATE,
|
||||
PRIMARY KEY (pid),
|
||||
INDEX (days_with_sales),
|
||||
INDEX (last_sale)
|
||||
) ENGINE=MEMORY
|
||||
`);
|
||||
|
||||
await connection.query(`
|
||||
CREATE TEMPORARY TABLE temp_recent_trend (
|
||||
pid BIGINT NOT NULL,
|
||||
recent_avg_units DECIMAL(10,2),
|
||||
recent_avg_revenue DECIMAL(15,2),
|
||||
PRIMARY KEY (pid)
|
||||
) ENGINE=MEMORY
|
||||
`);
|
||||
|
||||
await connection.query(`
|
||||
CREATE TEMPORARY TABLE temp_confidence_calc (
|
||||
CREATE TEMPORARY TABLE temp_recent_stats (
|
||||
pid BIGINT NOT NULL,
|
||||
confidence_level TINYINT,
|
||||
recent_avg_units DECIMAL(10,2),
|
||||
recent_avg_revenue DECIMAL(15,2),
|
||||
PRIMARY KEY (pid)
|
||||
) ENGINE=MEMORY
|
||||
`);
|
||||
@@ -167,7 +151,7 @@ async function calculateSalesForecasts(startTime, totalProducts, processedCount
|
||||
GROUP BY o.pid, DATE(o.date)
|
||||
`, [batch.map(row => row.pid)]);
|
||||
|
||||
// Populate sales stats
|
||||
// Combine sales stats and recent trend calculations
|
||||
await connection.query(`
|
||||
INSERT INTO temp_sales_stats
|
||||
SELECT
|
||||
@@ -182,23 +166,40 @@ async function calculateSalesForecasts(startTime, totalProducts, processedCount
|
||||
GROUP BY pid
|
||||
`);
|
||||
|
||||
// Populate recent trend
|
||||
// Calculate recent averages
|
||||
await connection.query(`
|
||||
INSERT INTO temp_recent_trend
|
||||
INSERT INTO temp_recent_stats
|
||||
SELECT
|
||||
h.pid,
|
||||
AVG(h.daily_quantity) as recent_avg_units,
|
||||
AVG(h.daily_revenue) as recent_avg_revenue
|
||||
FROM temp_historical_sales h
|
||||
WHERE h.sale_date >= DATE_SUB(CURRENT_DATE, INTERVAL 30 DAY)
|
||||
GROUP BY h.pid
|
||||
pid,
|
||||
AVG(daily_quantity) as recent_avg_units,
|
||||
AVG(daily_revenue) as recent_avg_revenue
|
||||
FROM temp_historical_sales
|
||||
WHERE sale_date >= DATE_SUB(CURRENT_DATE, INTERVAL 30 DAY)
|
||||
GROUP BY pid
|
||||
`);
|
||||
|
||||
// Calculate confidence levels
|
||||
// Generate forecasts using temp tables - optimized version
|
||||
await connection.query(`
|
||||
INSERT INTO temp_confidence_calc
|
||||
REPLACE INTO sales_forecasts
|
||||
(pid, forecast_date, forecast_units, forecast_revenue, confidence_level, last_calculated_at)
|
||||
SELECT
|
||||
s.pid,
|
||||
s.pid,
|
||||
DATE_ADD(CURRENT_DATE, INTERVAL n.days DAY),
|
||||
GREATEST(0, ROUND(
|
||||
CASE
|
||||
WHEN s.days_with_sales >= n.days
|
||||
THEN COALESCE(r.recent_avg_units, s.avg_daily_units)
|
||||
ELSE s.avg_daily_units * (s.days_with_sales / n.days)
|
||||
END
|
||||
)),
|
||||
GREATEST(0, ROUND(
|
||||
CASE
|
||||
WHEN s.days_with_sales >= n.days
|
||||
THEN COALESCE(r.recent_avg_revenue, s.avg_daily_revenue)
|
||||
ELSE s.avg_daily_revenue * (s.days_with_sales / n.days)
|
||||
END,
|
||||
2
|
||||
)),
|
||||
LEAST(100, GREATEST(0, ROUND(
|
||||
(s.days_with_sales / 180.0 * 50) + -- Up to 50 points for history length
|
||||
(CASE
|
||||
@@ -213,47 +214,21 @@ async function calculateSalesForecasts(startTime, totalProducts, processedCount
|
||||
WHEN DATEDIFF(CURRENT_DATE, s.last_sale) <= 30 THEN 10
|
||||
ELSE 0
|
||||
END) -- Up to 20 points for recency
|
||||
))) as confidence_level
|
||||
FROM temp_sales_stats s
|
||||
`);
|
||||
|
||||
// Generate forecasts using temp tables
|
||||
await connection.query(`
|
||||
REPLACE INTO sales_forecasts
|
||||
(pid, forecast_date, forecast_units, forecast_revenue, confidence_level, last_calculated_at)
|
||||
SELECT
|
||||
s.pid,
|
||||
DATE_ADD(CURRENT_DATE, INTERVAL n.days DAY),
|
||||
GREATEST(0, ROUND(
|
||||
CASE
|
||||
WHEN s.days_with_sales >= n.days THEN COALESCE(t.recent_avg_units, s.avg_daily_units)
|
||||
ELSE s.avg_daily_units * (s.days_with_sales / n.days)
|
||||
END
|
||||
)),
|
||||
GREATEST(0, ROUND(
|
||||
CASE
|
||||
WHEN s.days_with_sales >= n.days THEN COALESCE(t.recent_avg_revenue, s.avg_daily_revenue)
|
||||
ELSE s.avg_daily_revenue * (s.days_with_sales / n.days)
|
||||
END,
|
||||
2
|
||||
)),
|
||||
c.confidence_level,
|
||||
))),
|
||||
NOW()
|
||||
FROM temp_sales_stats s
|
||||
LEFT JOIN temp_recent_stats r ON s.pid = r.pid
|
||||
CROSS JOIN (
|
||||
SELECT 30 as days
|
||||
UNION SELECT 60
|
||||
UNION SELECT 90
|
||||
) n
|
||||
LEFT JOIN temp_recent_trend t ON s.pid = t.pid
|
||||
LEFT JOIN temp_confidence_calc c ON s.pid = c.pid;
|
||||
`);
|
||||
|
||||
// Clean up temp tables
|
||||
await connection.query('DROP TEMPORARY TABLE IF EXISTS temp_historical_sales');
|
||||
await connection.query('DROP TEMPORARY TABLE IF EXISTS temp_sales_stats');
|
||||
await connection.query('DROP TEMPORARY TABLE IF EXISTS temp_recent_trend');
|
||||
await connection.query('DROP TEMPORARY TABLE IF EXISTS temp_confidence_calc');
|
||||
await connection.query('DROP TEMPORARY TABLE IF EXISTS temp_recent_stats');
|
||||
|
||||
lastPid = batch[batch.length - 1].pid;
|
||||
myProcessedProducts += batch.length;
|
||||
|
||||
Reference in New Issue
Block a user