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

@@ -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;