Fix/enhance forecasting page
This commit is contained in:
@@ -1,6 +1,169 @@
|
||||
const express = require('express');
|
||||
const router = express.Router();
|
||||
|
||||
// Forecasting: summarize sales for products received in a period by brand
|
||||
router.get('/forecast', async (req, res) => {
|
||||
try {
|
||||
const pool = req.app.locals.pool;
|
||||
|
||||
const brand = (req.query.brand || '').toString();
|
||||
const titleSearch = (req.query.search || req.query.q || '').toString().trim() || null;
|
||||
const startDateStr = req.query.startDate;
|
||||
const endDateStr = req.query.endDate;
|
||||
|
||||
if (!brand) {
|
||||
return res.status(400).json({ error: 'Missing required parameter: brand' });
|
||||
}
|
||||
|
||||
// Default to last 30 days if no dates provided
|
||||
const endDate = endDateStr ? new Date(endDateStr) : new Date();
|
||||
const startDate = startDateStr ? new Date(startDateStr) : new Date(endDate.getTime() - 29 * 24 * 60 * 60 * 1000);
|
||||
|
||||
// Normalize to date boundaries for consistency
|
||||
const startISO = new Date(Date.UTC(startDate.getUTCFullYear(), startDate.getUTCMonth(), startDate.getUTCDate())).toISOString();
|
||||
const endISO = new Date(Date.UTC(endDate.getUTCFullYear(), endDate.getUTCMonth(), endDate.getUTCDate())).toISOString();
|
||||
|
||||
const sql = `
|
||||
WITH params AS (
|
||||
SELECT
|
||||
$1::date AS start_date,
|
||||
$2::date AS end_date,
|
||||
$3::text AS brand,
|
||||
$4::text AS title_search,
|
||||
(($2::date - $1::date) + 1)::int AS days
|
||||
),
|
||||
category_path AS (
|
||||
WITH RECURSIVE cp AS (
|
||||
SELECT c.cat_id, c.name, c.parent_id, c.name::text AS path
|
||||
FROM categories c WHERE c.parent_id IS NULL
|
||||
UNION ALL
|
||||
SELECT c.cat_id, c.name, c.parent_id, (cp.path || ' > ' || c.name)::text
|
||||
FROM categories c
|
||||
JOIN cp ON c.parent_id = cp.cat_id
|
||||
)
|
||||
SELECT * FROM cp
|
||||
),
|
||||
product_first_received AS (
|
||||
SELECT
|
||||
p.pid,
|
||||
COALESCE(p.first_received::date, MIN(r.received_date)::date) AS first_received_date
|
||||
FROM products p
|
||||
LEFT JOIN receivings r ON r.pid = p.pid
|
||||
GROUP BY p.pid, p.first_received
|
||||
),
|
||||
recent_products AS (
|
||||
SELECT p.pid
|
||||
FROM products p
|
||||
JOIN product_first_received fr ON fr.pid = p.pid
|
||||
JOIN params pr ON 1=1
|
||||
WHERE p.visible = true
|
||||
AND COALESCE(p.brand,'Unbranded') = pr.brand
|
||||
AND fr.first_received_date BETWEEN pr.start_date AND pr.end_date
|
||||
AND (pr.title_search IS NULL OR p.title ILIKE '%' || pr.title_search || '%')
|
||||
),
|
||||
product_pick_category AS (
|
||||
(
|
||||
SELECT DISTINCT ON (pc.pid)
|
||||
pc.pid,
|
||||
c.name AS category_name,
|
||||
COALESCE(cp.path, c.name) AS path
|
||||
FROM product_categories pc
|
||||
JOIN categories c ON c.cat_id = pc.cat_id AND (c.type IS NULL OR c.type NOT IN (20,21))
|
||||
LEFT JOIN category_path cp ON cp.cat_id = c.cat_id
|
||||
WHERE pc.pid IN (SELECT pid FROM recent_products)
|
||||
AND (cp.path IS NULL OR (
|
||||
cp.path NOT ILIKE '%Black Friday%'
|
||||
AND cp.path NOT ILIKE '%Deals%'
|
||||
))
|
||||
AND COALESCE(c.name, '') NOT IN ('Black Friday', 'Deals')
|
||||
ORDER BY pc.pid, length(COALESCE(cp.path,'')) DESC
|
||||
)
|
||||
UNION ALL
|
||||
(
|
||||
SELECT
|
||||
rp.pid,
|
||||
'Uncategorized'::text AS category_name,
|
||||
'Uncategorized'::text AS path
|
||||
FROM recent_products rp
|
||||
WHERE NOT EXISTS (
|
||||
SELECT 1
|
||||
FROM product_categories pc
|
||||
JOIN categories c ON c.cat_id = pc.cat_id AND (c.type IS NULL OR c.type NOT IN (20,21))
|
||||
LEFT JOIN category_path cp ON cp.cat_id = c.cat_id
|
||||
WHERE pc.pid = rp.pid
|
||||
AND (cp.path IS NULL OR (
|
||||
cp.path NOT ILIKE '%Black Friday%'
|
||||
AND cp.path NOT ILIKE '%Deals%'
|
||||
))
|
||||
AND COALESCE(c.name, '') NOT IN ('Black Friday', 'Deals')
|
||||
)
|
||||
)
|
||||
),
|
||||
product_sales AS (
|
||||
SELECT
|
||||
p.pid,
|
||||
p.title,
|
||||
p.sku,
|
||||
COALESCE(p.stock_quantity, 0) AS stock_quantity,
|
||||
COALESCE(p.price, 0) AS price,
|
||||
COALESCE(SUM(o.quantity), 0) AS total_sold
|
||||
FROM recent_products rp
|
||||
JOIN products p ON p.pid = rp.pid
|
||||
LEFT JOIN params pr ON true
|
||||
LEFT JOIN orders o ON o.pid = p.pid
|
||||
AND o.date::date BETWEEN pr.start_date AND pr.end_date
|
||||
AND (o.canceled IS DISTINCT FROM TRUE)
|
||||
GROUP BY p.pid, p.title, p.sku, p.stock_quantity, p.price
|
||||
)
|
||||
SELECT
|
||||
ppc.category_name,
|
||||
ppc.path,
|
||||
COUNT(ps.pid) AS num_products,
|
||||
SUM(ps.total_sold) AS total_sold,
|
||||
ROUND(AVG(COALESCE(ps.total_sold,0) / NULLIF(pr.days,0)), 2) AS avg_daily_sales,
|
||||
ROUND(AVG(COALESCE(ps.total_sold,0)), 2) AS avg_total_sold,
|
||||
MIN(ps.total_sold) AS min_total_sold,
|
||||
MAX(ps.total_sold) AS max_total_sold,
|
||||
JSON_AGG(
|
||||
JSON_BUILD_OBJECT(
|
||||
'pid', ps.pid,
|
||||
'title', ps.title,
|
||||
'sku', ps.sku,
|
||||
'total_sold', ps.total_sold,
|
||||
'categoryPath', ppc.path
|
||||
)
|
||||
) AS products
|
||||
FROM product_sales ps
|
||||
JOIN product_pick_category ppc ON ppc.pid = ps.pid
|
||||
JOIN params pr ON true
|
||||
GROUP BY ppc.category_name, ppc.path
|
||||
HAVING SUM(ps.total_sold) >= 0
|
||||
ORDER BY (ppc.category_name = 'Uncategorized') ASC, avg_total_sold DESC NULLS LAST
|
||||
LIMIT 200;
|
||||
`;
|
||||
|
||||
const { rows } = await pool.query(sql, [startISO, endISO, brand, titleSearch]);
|
||||
|
||||
// Normalize/shape response keys to match front-end expectations
|
||||
const shaped = rows.map(r => ({
|
||||
category_name: r.category_name,
|
||||
path: r.path,
|
||||
avg_daily_sales: Number(r.avg_daily_sales) || 0,
|
||||
total_sold: Number(r.total_sold) || 0,
|
||||
num_products: Number(r.num_products) || 0,
|
||||
avgTotalSold: Number(r.avg_total_sold) || 0,
|
||||
minSold: Number(r.min_total_sold) || 0,
|
||||
maxSold: Number(r.max_total_sold) || 0,
|
||||
products: Array.isArray(r.products) ? r.products : []
|
||||
}));
|
||||
|
||||
res.json(shaped);
|
||||
} catch (error) {
|
||||
console.error('Error fetching forecast data:', error);
|
||||
res.status(500).json({ error: 'Failed to fetch forecast data' });
|
||||
}
|
||||
});
|
||||
|
||||
// Get overall analytics stats
|
||||
router.get('/stats', async (req, res) => {
|
||||
try {
|
||||
@@ -608,4 +771,4 @@ router.get('/categories', async (req, res) => {
|
||||
}
|
||||
});
|
||||
|
||||
module.exports = router;
|
||||
module.exports = router;
|
||||
|
||||
Reference in New Issue
Block a user