775 lines
25 KiB
JavaScript
775 lines
25 KiB
JavaScript
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 {
|
|
const pool = req.app.locals.pool;
|
|
|
|
const { rows: [results] } = await pool.query(`
|
|
WITH vendor_count AS (
|
|
SELECT COUNT(DISTINCT vendor_name) AS count
|
|
FROM vendor_metrics
|
|
),
|
|
category_count AS (
|
|
SELECT COUNT(DISTINCT category_id) AS count
|
|
FROM category_metrics
|
|
),
|
|
metrics_summary AS (
|
|
SELECT
|
|
AVG(margin_30d) AS avg_profit_margin,
|
|
AVG(markup_30d) AS avg_markup,
|
|
AVG(stockturn_30d) AS avg_stock_turnover,
|
|
AVG(asp_30d) AS avg_order_value
|
|
FROM product_metrics
|
|
WHERE sales_30d > 0
|
|
)
|
|
SELECT
|
|
COALESCE(ms.avg_profit_margin, 0) AS profitMargin,
|
|
COALESCE(ms.avg_markup, 0) AS averageMarkup,
|
|
COALESCE(ms.avg_stock_turnover, 0) AS stockTurnoverRate,
|
|
COALESCE(vc.count, 0) AS vendorCount,
|
|
COALESCE(cc.count, 0) AS categoryCount,
|
|
COALESCE(ms.avg_order_value, 0) AS averageOrderValue
|
|
FROM metrics_summary ms
|
|
CROSS JOIN vendor_count vc
|
|
CROSS JOIN category_count cc
|
|
`);
|
|
|
|
// Ensure all values are numbers
|
|
const stats = {
|
|
profitMargin: Number(results.profitmargin) || 0,
|
|
averageMarkup: Number(results.averagemarkup) || 0,
|
|
stockTurnoverRate: Number(results.stockturnoverrate) || 0,
|
|
vendorCount: Number(results.vendorcount) || 0,
|
|
categoryCount: Number(results.categorycount) || 0,
|
|
averageOrderValue: Number(results.averageordervalue) || 0
|
|
};
|
|
|
|
res.json(stats);
|
|
} catch (error) {
|
|
console.error('Error fetching analytics stats:', error);
|
|
res.status(500).json({ error: 'Failed to fetch analytics stats' });
|
|
}
|
|
});
|
|
|
|
// Get profit analysis data
|
|
router.get('/profit', async (req, res) => {
|
|
try {
|
|
const pool = req.app.locals.pool;
|
|
|
|
// Get profit margins by category with full path
|
|
const { rows: byCategory } = await pool.query(`
|
|
WITH RECURSIVE category_path 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 category_path cp ON c.parent_id = cp.cat_id
|
|
)
|
|
SELECT
|
|
cm.category_name as category,
|
|
COALESCE(cp.path, cm.category_name) as categorypath,
|
|
cm.avg_margin_30d as profitmargin,
|
|
cm.revenue_30d as revenue,
|
|
cm.cogs_30d as cost
|
|
FROM category_metrics cm
|
|
LEFT JOIN category_path cp ON cm.category_id = cp.cat_id
|
|
WHERE cm.revenue_30d > 0
|
|
ORDER BY cm.revenue_30d DESC
|
|
LIMIT 10
|
|
`);
|
|
|
|
// Get profit margin over time
|
|
const { rows: overTime } = await pool.query(`
|
|
WITH time_series AS (
|
|
SELECT
|
|
date_trunc('day', generate_series(
|
|
CURRENT_DATE - INTERVAL '30 days',
|
|
CURRENT_DATE,
|
|
'1 day'::interval
|
|
))::date AS date
|
|
),
|
|
daily_profits AS (
|
|
SELECT
|
|
snapshot_date as date,
|
|
SUM(net_revenue) as revenue,
|
|
SUM(cogs) as cost,
|
|
CASE
|
|
WHEN SUM(net_revenue) > 0
|
|
THEN (SUM(net_revenue - cogs) / SUM(net_revenue)) * 100
|
|
ELSE 0
|
|
END as profit_margin
|
|
FROM daily_product_snapshots
|
|
WHERE snapshot_date >= CURRENT_DATE - INTERVAL '30 days'
|
|
GROUP BY snapshot_date
|
|
)
|
|
SELECT
|
|
to_char(ts.date, 'YYYY-MM-DD') as date,
|
|
COALESCE(dp.profit_margin, 0) as profitmargin,
|
|
COALESCE(dp.revenue, 0) as revenue,
|
|
COALESCE(dp.cost, 0) as cost
|
|
FROM time_series ts
|
|
LEFT JOIN daily_profits dp ON ts.date = dp.date
|
|
ORDER BY ts.date
|
|
`);
|
|
|
|
// Get top performing products by profit margin
|
|
const { rows: topProducts } = await pool.query(`
|
|
WITH RECURSIVE category_path 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 category_path cp ON c.parent_id = cp.cat_id
|
|
),
|
|
product_categories AS (
|
|
SELECT
|
|
pc.pid,
|
|
c.name as category,
|
|
COALESCE(cp.path, c.name) as categorypath
|
|
FROM product_categories pc
|
|
JOIN categories c ON pc.cat_id = c.cat_id
|
|
LEFT JOIN category_path cp ON c.cat_id = cp.cat_id
|
|
)
|
|
SELECT
|
|
pm.title as product,
|
|
COALESCE(pc.category, 'Uncategorized') as category,
|
|
COALESCE(pc.categorypath, 'Uncategorized') as categorypath,
|
|
pm.margin_30d as profitmargin,
|
|
pm.revenue_30d as revenue,
|
|
pm.cogs_30d as cost
|
|
FROM product_metrics pm
|
|
LEFT JOIN product_categories pc ON pm.pid = pc.pid
|
|
WHERE pm.revenue_30d > 100
|
|
AND pm.margin_30d > 0
|
|
ORDER BY pm.margin_30d DESC
|
|
LIMIT 10
|
|
`);
|
|
|
|
res.json({ byCategory, overTime, topProducts });
|
|
} catch (error) {
|
|
console.error('Error fetching profit analysis:', error);
|
|
res.status(500).json({ error: 'Failed to fetch profit analysis' });
|
|
}
|
|
});
|
|
|
|
// Get vendor performance data
|
|
router.get('/vendors', async (req, res) => {
|
|
try {
|
|
const pool = req.app.locals.pool;
|
|
|
|
// Set cache control headers to prevent 304
|
|
res.set({
|
|
'Cache-Control': 'no-cache, no-store, must-revalidate',
|
|
'Pragma': 'no-cache',
|
|
'Expires': '0'
|
|
});
|
|
|
|
console.log('Fetching vendor performance data...');
|
|
|
|
// Get vendor performance metrics from the vendor_metrics table
|
|
const { rows: rawPerformance } = await pool.query(`
|
|
SELECT
|
|
vendor_name as vendor,
|
|
revenue_30d as sales_volume,
|
|
avg_margin_30d as profit_margin,
|
|
COALESCE(
|
|
sales_30d / NULLIF(current_stock_units, 0),
|
|
0
|
|
) as stock_turnover,
|
|
product_count,
|
|
-- Use actual growth metrics from the vendor_metrics table
|
|
sales_growth_30d_vs_prev as growth
|
|
FROM vendor_metrics
|
|
WHERE revenue_30d > 0
|
|
ORDER BY revenue_30d DESC
|
|
LIMIT 20
|
|
`);
|
|
|
|
// Format the performance data
|
|
const performance = rawPerformance.map(vendor => ({
|
|
vendor: vendor.vendor,
|
|
salesVolume: Number(vendor.sales_volume) || 0,
|
|
profitMargin: Number(vendor.profit_margin) || 0,
|
|
stockTurnover: Number(vendor.stock_turnover) || 0,
|
|
productCount: Number(vendor.product_count) || 0,
|
|
growth: Number(vendor.growth) || 0
|
|
}));
|
|
|
|
// Get vendor comparison metrics (sales per product vs margin)
|
|
const { rows: rawComparison } = await pool.query(`
|
|
SELECT
|
|
vendor_name as vendor,
|
|
CASE
|
|
WHEN active_product_count > 0
|
|
THEN revenue_30d / active_product_count
|
|
ELSE 0
|
|
END as sales_per_product,
|
|
avg_margin_30d as average_margin,
|
|
product_count as size
|
|
FROM vendor_metrics
|
|
WHERE active_product_count > 0
|
|
ORDER BY sales_per_product DESC
|
|
LIMIT 10
|
|
`);
|
|
|
|
// Transform comparison data
|
|
const comparison = rawComparison.map(item => ({
|
|
vendor: item.vendor,
|
|
salesPerProduct: Number(item.sales_per_product) || 0,
|
|
averageMargin: Number(item.average_margin) || 0,
|
|
size: Number(item.size) || 0
|
|
}));
|
|
|
|
console.log('Performance data ready. Sending response...');
|
|
|
|
// Return complete structure that the front-end expects
|
|
res.json({
|
|
performance,
|
|
comparison,
|
|
// Add empty trends array to complete the structure
|
|
trends: []
|
|
});
|
|
} catch (error) {
|
|
console.error('Error fetching vendor performance:', error);
|
|
res.status(500).json({ error: 'Failed to fetch vendor performance data' });
|
|
}
|
|
});
|
|
|
|
// Get stock analysis data
|
|
router.get('/stock', async (req, res) => {
|
|
try {
|
|
const pool = req.app.locals.pool;
|
|
console.log('Fetching stock analysis data...');
|
|
|
|
// Use the new metrics tables to get data
|
|
|
|
// Get turnover by category
|
|
const { rows: turnoverByCategory } = await pool.query(`
|
|
WITH category_metrics_with_path AS (
|
|
WITH RECURSIVE category_path 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 category_path cp ON c.parent_id = cp.cat_id
|
|
)
|
|
SELECT
|
|
cm.category_id,
|
|
cm.category_name,
|
|
cp.path as category_path,
|
|
cm.current_stock_units,
|
|
cm.sales_30d,
|
|
cm.stock_turn_30d
|
|
FROM category_metrics cm
|
|
LEFT JOIN category_path cp ON cm.category_id = cp.cat_id
|
|
WHERE cm.sales_30d > 0
|
|
)
|
|
SELECT
|
|
category_name as category,
|
|
COALESCE(stock_turn_30d, 0) as turnoverRate,
|
|
current_stock_units as averageStock,
|
|
sales_30d as totalSales
|
|
FROM category_metrics_with_path
|
|
ORDER BY stock_turn_30d DESC NULLS LAST
|
|
LIMIT 10
|
|
`);
|
|
|
|
// Get stock levels over time (last 30 days)
|
|
const { rows: stockLevels } = await pool.query(`
|
|
WITH date_range AS (
|
|
SELECT generate_series(
|
|
CURRENT_DATE - INTERVAL '30 days',
|
|
CURRENT_DATE,
|
|
'1 day'::interval
|
|
)::date AS date
|
|
),
|
|
daily_stock_counts AS (
|
|
SELECT
|
|
snapshot_date,
|
|
COUNT(DISTINCT pid) as total_products,
|
|
COUNT(DISTINCT CASE WHEN eod_stock_quantity > 5 THEN pid END) as in_stock,
|
|
COUNT(DISTINCT CASE WHEN eod_stock_quantity <= 5 AND eod_stock_quantity > 0 THEN pid END) as low_stock,
|
|
COUNT(DISTINCT CASE WHEN eod_stock_quantity = 0 THEN pid END) as out_of_stock
|
|
FROM daily_product_snapshots
|
|
WHERE snapshot_date >= CURRENT_DATE - INTERVAL '30 days'
|
|
GROUP BY snapshot_date
|
|
)
|
|
SELECT
|
|
to_char(dr.date, 'YYYY-MM-DD') as date,
|
|
COALESCE(dsc.in_stock, 0) as inStock,
|
|
COALESCE(dsc.low_stock, 0) as lowStock,
|
|
COALESCE(dsc.out_of_stock, 0) as outOfStock
|
|
FROM date_range dr
|
|
LEFT JOIN daily_stock_counts dsc ON dr.date = dsc.snapshot_date
|
|
ORDER BY dr.date
|
|
`);
|
|
|
|
// Get critical items (products that need reordering)
|
|
const { rows: criticalItems } = await pool.query(`
|
|
SELECT
|
|
pm.title as product,
|
|
pm.sku as sku,
|
|
pm.current_stock as stockQuantity,
|
|
COALESCE(pm.config_safety_stock, 0) as reorderPoint,
|
|
COALESCE(pm.stockturn_30d, 0) as turnoverRate,
|
|
CASE
|
|
WHEN pm.sales_velocity_daily > 0
|
|
THEN ROUND(pm.current_stock / pm.sales_velocity_daily)
|
|
ELSE 999
|
|
END as daysUntilStockout
|
|
FROM product_metrics pm
|
|
WHERE pm.is_visible = true
|
|
AND pm.is_replenishable = true
|
|
AND pm.sales_30d > 0
|
|
AND pm.current_stock <= pm.config_safety_stock * 2
|
|
ORDER BY
|
|
CASE
|
|
WHEN pm.sales_velocity_daily > 0
|
|
THEN pm.current_stock / pm.sales_velocity_daily
|
|
ELSE 999
|
|
END ASC,
|
|
pm.revenue_30d DESC
|
|
LIMIT 10
|
|
`);
|
|
|
|
res.json({
|
|
turnoverByCategory,
|
|
stockLevels,
|
|
criticalItems
|
|
});
|
|
} catch (error) {
|
|
console.error('Error fetching stock analysis:', error);
|
|
res.status(500).json({ error: 'Failed to fetch stock analysis', details: error.message });
|
|
}
|
|
});
|
|
|
|
// Get price analysis data
|
|
router.get('/pricing', async (req, res) => {
|
|
try {
|
|
const pool = req.app.locals.pool;
|
|
|
|
// Get price points analysis
|
|
const { rows: pricePoints } = await pool.query(`
|
|
SELECT
|
|
CAST(p.price AS DECIMAL(15,3)) as price,
|
|
CAST(SUM(o.quantity) AS DECIMAL(15,3)) as salesVolume,
|
|
CAST(SUM(o.price * o.quantity) AS DECIMAL(15,3)) as revenue,
|
|
c.name as category
|
|
FROM products p
|
|
LEFT JOIN orders o ON p.pid = o.pid
|
|
JOIN product_categories pc ON p.pid = pc.pid
|
|
JOIN categories c ON pc.cat_id = c.cat_id
|
|
WHERE o.date >= CURRENT_DATE - INTERVAL '30 days'
|
|
GROUP BY p.price, c.name
|
|
HAVING SUM(o.quantity) > 0
|
|
ORDER BY revenue DESC
|
|
LIMIT 50
|
|
`);
|
|
|
|
// Get price elasticity data (price changes vs demand)
|
|
const { rows: elasticity } = await pool.query(`
|
|
SELECT
|
|
to_char(o.date, 'YYYY-MM-DD') as date,
|
|
CAST(AVG(o.price) AS DECIMAL(15,3)) as price,
|
|
CAST(SUM(o.quantity) AS DECIMAL(15,3)) as demand
|
|
FROM orders o
|
|
WHERE o.date >= CURRENT_DATE - INTERVAL '30 days'
|
|
GROUP BY to_char(o.date, 'YYYY-MM-DD')
|
|
ORDER BY date
|
|
`);
|
|
|
|
// Get price optimization recommendations
|
|
const { rows: recommendations } = await pool.query(`
|
|
SELECT
|
|
p.title as product,
|
|
CAST(p.price AS DECIMAL(15,3)) as currentPrice,
|
|
CAST(
|
|
ROUND(
|
|
CASE
|
|
WHEN AVG(o.quantity) > 10 THEN p.price * 1.1
|
|
WHEN AVG(o.quantity) < 2 THEN p.price * 0.9
|
|
ELSE p.price
|
|
END, 2
|
|
) AS DECIMAL(15,3)
|
|
) as recommendedPrice,
|
|
CAST(
|
|
ROUND(
|
|
SUM(o.price * o.quantity) *
|
|
CASE
|
|
WHEN AVG(o.quantity) > 10 THEN 1.15
|
|
WHEN AVG(o.quantity) < 2 THEN 0.95
|
|
ELSE 1
|
|
END, 2
|
|
) AS DECIMAL(15,3)
|
|
) as potentialRevenue,
|
|
CASE
|
|
WHEN AVG(o.quantity) > 10 THEN 85
|
|
WHEN AVG(o.quantity) < 2 THEN 75
|
|
ELSE 65
|
|
END as confidence
|
|
FROM products p
|
|
LEFT JOIN orders o ON p.pid = o.pid
|
|
WHERE o.date >= CURRENT_DATE - INTERVAL '30 days'
|
|
GROUP BY p.pid, p.price, p.title
|
|
HAVING ABS(
|
|
CAST(
|
|
ROUND(
|
|
CASE
|
|
WHEN AVG(o.quantity) > 10 THEN p.price * 1.1
|
|
WHEN AVG(o.quantity) < 2 THEN p.price * 0.9
|
|
ELSE p.price
|
|
END, 2
|
|
) AS DECIMAL(15,3)
|
|
) - CAST(p.price AS DECIMAL(15,3))
|
|
) > 0
|
|
ORDER BY
|
|
CAST(
|
|
ROUND(
|
|
SUM(o.price * o.quantity) *
|
|
CASE
|
|
WHEN AVG(o.quantity) > 10 THEN 1.15
|
|
WHEN AVG(o.quantity) < 2 THEN 0.95
|
|
ELSE 1
|
|
END, 2
|
|
) AS DECIMAL(15,3)
|
|
) - CAST(SUM(o.price * o.quantity) AS DECIMAL(15,3)) DESC
|
|
LIMIT 10
|
|
`);
|
|
|
|
res.json({ pricePoints, elasticity, recommendations });
|
|
} catch (error) {
|
|
console.error('Error fetching price analysis:', error);
|
|
res.status(500).json({ error: 'Failed to fetch price analysis' });
|
|
}
|
|
});
|
|
|
|
// Get category performance data
|
|
router.get('/categories', async (req, res) => {
|
|
try {
|
|
const pool = req.app.locals.pool;
|
|
|
|
// Common CTE for category paths
|
|
const categoryPathCTE = `
|
|
WITH RECURSIVE category_path 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 category_path cp ON c.parent_id = cp.cat_id
|
|
)
|
|
`;
|
|
|
|
// Get category performance metrics with full path
|
|
const { rows: performance } = await pool.query(`
|
|
${categoryPathCTE},
|
|
monthly_sales AS (
|
|
SELECT
|
|
c.name,
|
|
cp.path,
|
|
SUM(CASE
|
|
WHEN o.date >= CURRENT_DATE - INTERVAL '30 days'
|
|
THEN o.price * o.quantity
|
|
ELSE 0
|
|
END) as current_month,
|
|
SUM(CASE
|
|
WHEN o.date >= CURRENT_DATE - INTERVAL '60 days'
|
|
AND o.date < CURRENT_DATE - INTERVAL '30 days'
|
|
THEN o.price * o.quantity
|
|
ELSE 0
|
|
END) as previous_month
|
|
FROM products p
|
|
LEFT JOIN orders o ON p.pid = o.pid
|
|
JOIN product_categories pc ON p.pid = pc.pid
|
|
JOIN categories c ON pc.cat_id = c.cat_id
|
|
JOIN category_path cp ON c.cat_id = cp.cat_id
|
|
WHERE o.date >= CURRENT_DATE - INTERVAL '60 days'
|
|
GROUP BY c.name, cp.path
|
|
)
|
|
SELECT
|
|
c.name as category,
|
|
cp.path as categoryPath,
|
|
SUM(o.price * o.quantity) as revenue,
|
|
SUM(o.price * o.quantity - p.cost_price * o.quantity) as profit,
|
|
ROUND(
|
|
((ms.current_month / NULLIF(ms.previous_month, 0)) - 1) * 100,
|
|
1
|
|
) as growth,
|
|
COUNT(DISTINCT p.pid) as productCount
|
|
FROM products p
|
|
LEFT JOIN orders o ON p.pid = o.pid
|
|
JOIN product_categories pc ON p.pid = pc.pid
|
|
JOIN categories c ON pc.cat_id = c.cat_id
|
|
JOIN category_path cp ON c.cat_id = cp.cat_id
|
|
LEFT JOIN monthly_sales ms ON c.name = ms.name AND cp.path = ms.path
|
|
WHERE o.date >= CURRENT_DATE - INTERVAL '60 days'
|
|
GROUP BY c.name, cp.path, ms.current_month, ms.previous_month
|
|
HAVING SUM(o.price * o.quantity) > 0
|
|
ORDER BY revenue DESC
|
|
LIMIT 10
|
|
`);
|
|
|
|
// Get category revenue distribution with full path
|
|
const { rows: distribution } = await pool.query(`
|
|
${categoryPathCTE}
|
|
SELECT
|
|
c.name as category,
|
|
cp.path as categoryPath,
|
|
SUM(o.price * o.quantity) as value
|
|
FROM products p
|
|
LEFT JOIN orders o ON p.pid = o.pid
|
|
JOIN product_categories pc ON p.pid = pc.pid
|
|
JOIN categories c ON pc.cat_id = c.cat_id
|
|
JOIN category_path cp ON c.cat_id = cp.cat_id
|
|
WHERE o.date >= CURRENT_DATE - INTERVAL '30 days'
|
|
GROUP BY c.name, cp.path
|
|
HAVING SUM(o.price * o.quantity) > 0
|
|
ORDER BY value DESC
|
|
LIMIT 6
|
|
`);
|
|
|
|
// Get category sales trends with full path
|
|
const { rows: trends } = await pool.query(`
|
|
${categoryPathCTE}
|
|
SELECT
|
|
c.name as category,
|
|
cp.path as categoryPath,
|
|
to_char(o.date, 'Mon YYYY') as month,
|
|
SUM(o.price * o.quantity) as sales
|
|
FROM products p
|
|
LEFT JOIN orders o ON p.pid = o.pid
|
|
JOIN product_categories pc ON p.pid = pc.pid
|
|
JOIN categories c ON pc.cat_id = c.cat_id
|
|
JOIN category_path cp ON c.cat_id = cp.cat_id
|
|
WHERE o.date >= CURRENT_DATE - INTERVAL '6 months'
|
|
GROUP BY
|
|
c.name,
|
|
cp.path,
|
|
to_char(o.date, 'Mon YYYY'),
|
|
to_char(o.date, 'YYYY-MM')
|
|
ORDER BY
|
|
c.name,
|
|
to_char(o.date, 'YYYY-MM')
|
|
`);
|
|
|
|
res.json({ performance, distribution, trends });
|
|
} catch (error) {
|
|
console.error('Error fetching category performance:', error);
|
|
res.status(500).json({ error: 'Failed to fetch category performance' });
|
|
}
|
|
});
|
|
|
|
module.exports = router;
|