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

@@ -18,6 +18,7 @@ CREATE TABLE IF NOT EXISTS temp_purchase_metrics (
product_id BIGINT NOT NULL,
avg_lead_time_days INT,
last_purchase_date DATE,
first_received_date DATE,
last_received_date DATE,
PRIMARY KEY (product_id)
);
@@ -51,6 +52,7 @@ CREATE TABLE IF NOT EXISTS product_metrics (
-- Purchase metrics
avg_lead_time_days INT,
last_purchase_date DATE,
first_received_date DATE,
last_received_date DATE,
-- Classification
abc_class CHAR(1),
@@ -107,6 +109,23 @@ CREATE TABLE IF NOT EXISTS vendor_metrics (
INDEX idx_vendor_performance (on_time_delivery_rate)
);
-- New table for category-based sales metrics
CREATE TABLE IF NOT EXISTS category_sales_metrics (
category_id BIGINT NOT NULL,
brand VARCHAR(100) NOT NULL,
period_start DATE NOT NULL,
period_end DATE NOT NULL,
avg_daily_sales DECIMAL(10,3) DEFAULT 0,
total_sold INT DEFAULT 0,
num_products INT DEFAULT 0,
avg_price DECIMAL(10,3) DEFAULT 0,
last_calculated_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
PRIMARY KEY (category_id, brand, period_start, period_end),
FOREIGN KEY (category_id) REFERENCES categories(id) ON DELETE CASCADE,
INDEX idx_category_brand (category_id, brand),
INDEX idx_period (period_start, period_end)
);
-- Re-enable foreign key checks
SET FOREIGN_KEY_CHECKS = 1;
@@ -223,4 +242,27 @@ LEFT JOIN
WHERE
o.canceled = false
GROUP BY
p.product_id, p.SKU, p.title;
p.product_id, p.SKU, p.title;
-- Create view for category sales trends
CREATE OR REPLACE VIEW category_sales_trends AS
SELECT
c.id as category_id,
c.name as category_name,
p.brand,
COUNT(DISTINCT p.product_id) as num_products,
COALESCE(AVG(o.quantity), 0) as avg_daily_sales,
COALESCE(SUM(o.quantity), 0) as total_sold,
COALESCE(AVG(o.price), 0) as avg_price,
MIN(o.date) as first_sale_date,
MAX(o.date) as last_sale_date
FROM
categories c
JOIN
product_categories pc ON c.id = pc.category_id
JOIN
products p ON pc.product_id = p.product_id
LEFT JOIN
orders o ON p.product_id = o.product_id AND o.canceled = false
GROUP BY
c.id, c.name, p.brand;

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');

View File

@@ -21,7 +21,8 @@ const METRICS_TABLES = [
'temp_purchase_metrics',
'product_metrics',
'product_time_aggregates',
'vendor_metrics'
'vendor_metrics',
'category_sales_metrics'
];
// Config tables that must exist

View File

@@ -527,4 +527,72 @@ router.get('/categories', async (req, res) => {
}
});
// Forecast endpoint
router.get('/forecast', async (req, res) => {
try {
const { brand, startDate, endDate } = req.query;
const pool = req.app.locals.pool;
const [results] = await pool.query(`
WITH category_metrics AS (
SELECT
c.id as category_id,
c.name as category_name,
p.brand,
COUNT(DISTINCT p.product_id) as num_products,
COALESCE(ROUND(SUM(o.quantity) / DATEDIFF(?, ?), 2), 0) as avg_daily_sales,
COALESCE(SUM(o.quantity), 0) as total_sold,
COALESCE(ROUND(SUM(o.quantity) / COUNT(DISTINCT p.product_id), 2), 0) as avgTotalSold,
COALESCE(ROUND(AVG(o.price), 2), 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
LEFT JOIN orders o ON p.product_id = o.product_id
AND o.date BETWEEN ? AND ?
AND o.canceled = false
WHERE p.brand = ?
GROUP BY c.id, c.name, p.brand
),
product_metrics AS (
SELECT
p.product_id,
p.title,
p.sku,
p.stock_quantity,
pc.category_id,
COALESCE(SUM(o.quantity), 0) as total_sold,
COALESCE(ROUND(AVG(o.price), 2), 0) as avg_price
FROM products p
JOIN product_categories pc ON p.product_id = pc.product_id
LEFT JOIN orders o ON p.product_id = o.product_id
AND o.date BETWEEN ? AND ?
AND o.canceled = false
WHERE p.brand = ?
GROUP BY p.product_id, p.title, p.sku, p.stock_quantity, pc.category_id
)
SELECT
cm.*,
JSON_ARRAYAGG(
JSON_OBJECT(
'product_id', pm.product_id,
'name', pm.title,
'sku', pm.sku,
'stock_quantity', pm.stock_quantity,
'total_sold', pm.total_sold,
'avg_price', pm.avg_price
)
) as products
FROM category_metrics cm
JOIN product_metrics pm ON cm.category_id = pm.category_id
GROUP BY cm.category_id, cm.category_name, cm.brand, cm.num_products, cm.avg_daily_sales, cm.total_sold, cm.avgTotalSold, cm.avg_price
ORDER BY cm.total_sold DESC
`, [startDate, endDate, startDate, endDate, brand, startDate, endDate, brand]);
res.json(results);
} catch (error) {
console.error('Error fetching forecast data:', error);
res.status(500).json({ error: 'Failed to fetch forecast data' });
}
});
module.exports = router;

View File

@@ -6,6 +6,36 @@ const { importProductsFromCSV } = require('../utils/csvImporter');
// Configure multer for file uploads
const upload = multer({ dest: 'uploads/' });
// Get unique brands
router.get('/brands', async (req, res) => {
console.log('Brands endpoint hit:', {
url: req.url,
method: req.method,
headers: req.headers,
path: req.path
});
try {
const pool = req.app.locals.pool;
console.log('Fetching brands from database...');
const [results] = await pool.query(`
SELECT DISTINCT brand
FROM products
WHERE brand IS NOT NULL
AND brand != ''
AND visible = true
ORDER BY brand
`);
console.log(`Found ${results.length} brands:`, results.slice(0, 3));
res.json(results.map(r => r.brand));
} catch (error) {
console.error('Error fetching brands:', error);
res.status(500).json({ error: 'Failed to fetch brands' });
}
});
// Get all products with pagination, filtering, and sorting
router.get('/', async (req, res) => {
const pool = req.app.locals.pool;