Get frontend dashboard/analytics mostly loading data again
This commit is contained in:
@@ -7,37 +7,33 @@ router.get('/stats', async (req, res) => {
|
||||
const pool = req.app.locals.pool;
|
||||
|
||||
const { rows: [results] } = await pool.query(`
|
||||
SELECT
|
||||
COALESCE(
|
||||
ROUND(
|
||||
(SUM(o.price * o.quantity - p.cost_price * o.quantity) /
|
||||
NULLIF(SUM(o.price * o.quantity), 0) * 100)::numeric, 1
|
||||
),
|
||||
0
|
||||
) as profitMargin,
|
||||
COALESCE(
|
||||
ROUND(
|
||||
(AVG(p.price / NULLIF(p.cost_price, 0) - 1) * 100)::numeric, 1
|
||||
),
|
||||
0
|
||||
) as averageMarkup,
|
||||
COALESCE(
|
||||
ROUND(
|
||||
(SUM(o.quantity) / NULLIF(AVG(p.stock_quantity), 0))::numeric, 2
|
||||
),
|
||||
0
|
||||
) as stockTurnoverRate,
|
||||
COALESCE(COUNT(DISTINCT p.vendor), 0) as vendorCount,
|
||||
COALESCE(COUNT(DISTINCT p.categories), 0) as categoryCount,
|
||||
COALESCE(
|
||||
ROUND(
|
||||
AVG(o.price * o.quantity)::numeric, 2
|
||||
),
|
||||
0
|
||||
) as averageOrderValue
|
||||
FROM products p
|
||||
LEFT JOIN orders o ON p.pid = o.pid
|
||||
WHERE o.date >= CURRENT_DATE - INTERVAL '30 days'
|
||||
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
|
||||
@@ -84,43 +80,53 @@ router.get('/profit', async (req, res) => {
|
||||
JOIN category_path cp ON c.parent_id = cp.cat_id
|
||||
)
|
||||
SELECT
|
||||
c.name as category,
|
||||
cp.path as categoryPath,
|
||||
ROUND(
|
||||
(SUM(o.price * o.quantity - p.cost_price * o.quantity) /
|
||||
NULLIF(SUM(o.price * o.quantity), 0) * 100)::numeric, 1
|
||||
) as profitMargin,
|
||||
ROUND(SUM(o.price * o.quantity)::numeric, 3) as revenue,
|
||||
ROUND(SUM(p.cost_price * o.quantity)::numeric, 3) as cost
|
||||
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
|
||||
ORDER BY profitMargin DESC
|
||||
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 trend over time
|
||||
// Get profit margin over time
|
||||
const { rows: overTime } = await pool.query(`
|
||||
SELECT
|
||||
to_char(o.date, 'YYYY-MM-DD') as date,
|
||||
ROUND(
|
||||
(SUM(o.price * o.quantity - p.cost_price * o.quantity) /
|
||||
NULLIF(SUM(o.price * o.quantity), 0) * 100)::numeric, 1
|
||||
) as profitMargin,
|
||||
ROUND(SUM(o.price * o.quantity)::numeric, 3) as revenue,
|
||||
ROUND(SUM(p.cost_price * o.quantity)::numeric, 3) as cost
|
||||
FROM products p
|
||||
LEFT JOIN orders o ON p.pid = o.pid
|
||||
WHERE o.date >= CURRENT_DATE - INTERVAL '30 days'
|
||||
GROUP BY to_char(o.date, 'YYYY-MM-DD')
|
||||
ORDER BY date
|
||||
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 with category paths
|
||||
// Get top performing products by profit margin
|
||||
const { rows: topProducts } = await pool.query(`
|
||||
WITH RECURSIVE category_path AS (
|
||||
SELECT
|
||||
@@ -140,26 +146,28 @@ router.get('/profit', async (req, res) => {
|
||||
(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
|
||||
p.title as product,
|
||||
c.name as category,
|
||||
cp.path as categoryPath,
|
||||
ROUND(
|
||||
(SUM(o.price * o.quantity - p.cost_price * o.quantity) /
|
||||
NULLIF(SUM(o.price * o.quantity), 0) * 100)::numeric, 1
|
||||
) as profitMargin,
|
||||
ROUND(SUM(o.price * o.quantity)::numeric, 3) as revenue,
|
||||
ROUND(SUM(p.cost_price * o.quantity)::numeric, 3) as cost
|
||||
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 p.pid, p.title, c.name, cp.path
|
||||
HAVING SUM(o.price * o.quantity) > 0
|
||||
ORDER BY profitMargin DESC
|
||||
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
|
||||
`);
|
||||
|
||||
@@ -184,93 +192,52 @@ router.get('/vendors', async (req, res) => {
|
||||
|
||||
console.log('Fetching vendor performance data...');
|
||||
|
||||
// First check if we have any vendors with sales
|
||||
const { rows: [checkData] } = await pool.query(`
|
||||
SELECT COUNT(DISTINCT p.vendor) as vendor_count,
|
||||
COUNT(DISTINCT o.order_number) as order_count
|
||||
FROM products p
|
||||
LEFT JOIN orders o ON p.pid = o.pid
|
||||
WHERE p.vendor IS NOT NULL
|
||||
`);
|
||||
|
||||
console.log('Vendor data check:', checkData);
|
||||
|
||||
// Get vendor performance metrics
|
||||
// Get vendor performance metrics from the vendor_metrics table
|
||||
const { rows: rawPerformance } = await pool.query(`
|
||||
WITH monthly_sales AS (
|
||||
SELECT
|
||||
p.vendor,
|
||||
ROUND(SUM(CASE
|
||||
WHEN o.date >= CURRENT_DATE - INTERVAL '30 days'
|
||||
THEN o.price * o.quantity
|
||||
ELSE 0
|
||||
END)::numeric, 3) as current_month,
|
||||
ROUND(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)::numeric, 3) as previous_month
|
||||
FROM products p
|
||||
LEFT JOIN orders o ON p.pid = o.pid
|
||||
WHERE p.vendor IS NOT NULL
|
||||
AND o.date >= CURRENT_DATE - INTERVAL '60 days'
|
||||
GROUP BY p.vendor
|
||||
)
|
||||
SELECT
|
||||
p.vendor,
|
||||
ROUND(SUM(o.price * o.quantity)::numeric, 3) as sales_volume,
|
||||
COALESCE(ROUND(
|
||||
(SUM(o.price * o.quantity - p.cost_price * o.quantity) /
|
||||
NULLIF(SUM(o.price * o.quantity), 0) * 100)::numeric, 1
|
||||
), 0) as profit_margin,
|
||||
COALESCE(ROUND(
|
||||
(SUM(o.quantity) / NULLIF(AVG(p.stock_quantity), 0))::numeric, 1
|
||||
), 0) as stock_turnover,
|
||||
COUNT(DISTINCT p.pid) as product_count,
|
||||
ROUND(
|
||||
((ms.current_month / NULLIF(ms.previous_month, 0)) - 1) * 100,
|
||||
1
|
||||
) as growth
|
||||
FROM products p
|
||||
LEFT JOIN orders o ON p.pid = o.pid
|
||||
LEFT JOIN monthly_sales ms ON p.vendor = ms.vendor
|
||||
WHERE p.vendor IS NOT NULL
|
||||
AND o.date >= CURRENT_DATE - INTERVAL '30 days'
|
||||
GROUP BY p.vendor, ms.current_month, ms.previous_month
|
||||
ORDER BY sales_volume DESC
|
||||
LIMIT 10
|
||||
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 an estimate of growth based on 7-day vs 30-day revenue
|
||||
CASE
|
||||
WHEN revenue_30d > 0
|
||||
THEN ((revenue_7d * 4.0) / revenue_30d - 1) * 100
|
||||
ELSE 0
|
||||
END as growth
|
||||
FROM vendor_metrics
|
||||
WHERE revenue_30d > 0
|
||||
ORDER BY revenue_30d DESC
|
||||
LIMIT 20
|
||||
`);
|
||||
|
||||
// Transform to camelCase properties for frontend consumption
|
||||
const performance = rawPerformance.map(item => ({
|
||||
vendor: item.vendor,
|
||||
salesVolume: Number(item.sales_volume) || 0,
|
||||
profitMargin: Number(item.profit_margin) || 0,
|
||||
stockTurnover: Number(item.stock_turnover) || 0,
|
||||
productCount: Number(item.product_count) || 0,
|
||||
growth: Number(item.growth) || 0
|
||||
// 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
|
||||
p.vendor,
|
||||
COALESCE(ROUND(
|
||||
SUM(o.price * o.quantity) / NULLIF(COUNT(DISTINCT p.pid), 0),
|
||||
2
|
||||
), 0) as sales_per_product,
|
||||
COALESCE(ROUND(
|
||||
AVG((p.price - p.cost_price) / NULLIF(p.cost_price, 0) * 100),
|
||||
2
|
||||
), 0) as average_margin,
|
||||
COUNT(DISTINCT p.pid) as size
|
||||
FROM products p
|
||||
LEFT JOIN orders o ON p.pid = o.pid
|
||||
WHERE p.vendor IS NOT NULL
|
||||
AND o.date >= CURRENT_DATE - INTERVAL '30 days'
|
||||
GROUP BY p.vendor
|
||||
HAVING COUNT(DISTINCT p.pid) > 0
|
||||
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
|
||||
`);
|
||||
@@ -294,58 +261,7 @@ router.get('/vendors', async (req, res) => {
|
||||
});
|
||||
} catch (error) {
|
||||
console.error('Error fetching vendor performance:', error);
|
||||
console.error('Error details:', error.message);
|
||||
|
||||
// Return dummy data on error with complete structure
|
||||
res.json({
|
||||
performance: [
|
||||
{
|
||||
vendor: "Example Vendor 1",
|
||||
salesVolume: 10000,
|
||||
profitMargin: 25.5,
|
||||
stockTurnover: 3.2,
|
||||
productCount: 15,
|
||||
growth: 12.3
|
||||
},
|
||||
{
|
||||
vendor: "Example Vendor 2",
|
||||
salesVolume: 8500,
|
||||
profitMargin: 22.8,
|
||||
stockTurnover: 2.9,
|
||||
productCount: 12,
|
||||
growth: 8.7
|
||||
},
|
||||
{
|
||||
vendor: "Example Vendor 3",
|
||||
salesVolume: 6200,
|
||||
profitMargin: 19.5,
|
||||
stockTurnover: 2.5,
|
||||
productCount: 8,
|
||||
growth: 5.2
|
||||
}
|
||||
],
|
||||
comparison: [
|
||||
{
|
||||
vendor: "Example Vendor 1",
|
||||
salesPerProduct: 650,
|
||||
averageMargin: 35.2,
|
||||
size: 15
|
||||
},
|
||||
{
|
||||
vendor: "Example Vendor 2",
|
||||
salesPerProduct: 710,
|
||||
averageMargin: 28.5,
|
||||
size: 12
|
||||
},
|
||||
{
|
||||
vendor: "Example Vendor 3",
|
||||
salesPerProduct: 770,
|
||||
averageMargin: 22.8,
|
||||
size: 8
|
||||
}
|
||||
],
|
||||
trends: []
|
||||
});
|
||||
res.status(500).json({ error: 'Failed to fetch vendor performance data' });
|
||||
}
|
||||
});
|
||||
|
||||
@@ -353,108 +269,119 @@ router.get('/vendors', async (req, res) => {
|
||||
router.get('/stock', async (req, res) => {
|
||||
try {
|
||||
const pool = req.app.locals.pool;
|
||||
console.log('Fetching stock analysis data...');
|
||||
|
||||
// Get global configuration values
|
||||
const { rows: configs } = await pool.query(`
|
||||
SELECT
|
||||
st.low_stock_threshold,
|
||||
tc.calculation_period_days as turnover_period
|
||||
FROM stock_thresholds st
|
||||
CROSS JOIN turnover_config tc
|
||||
WHERE st.id = 1 AND tc.id = 1
|
||||
`);
|
||||
|
||||
const config = configs[0] || {
|
||||
low_stock_threshold: 5,
|
||||
turnover_period: 30
|
||||
};
|
||||
// Use the new metrics tables to get data
|
||||
|
||||
// Get turnover by category
|
||||
const { rows: turnoverByCategory } = await pool.query(`
|
||||
SELECT
|
||||
c.name as category,
|
||||
ROUND((SUM(o.quantity) / NULLIF(AVG(p.stock_quantity), 0))::numeric, 1) as turnoverRate,
|
||||
ROUND(AVG(p.stock_quantity)::numeric, 0) as averageStock,
|
||||
SUM(o.quantity) as totalSales
|
||||
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 '${config.turnover_period} days'
|
||||
GROUP BY c.name
|
||||
HAVING ROUND((SUM(o.quantity) / NULLIF(AVG(p.stock_quantity), 0))::numeric, 1) > 0
|
||||
ORDER BY turnoverRate DESC
|
||||
LIMIT 10
|
||||
`);
|
||||
|
||||
// Get stock levels over time
|
||||
const { rows: stockLevels } = await pool.query(`
|
||||
SELECT
|
||||
to_char(o.date, 'YYYY-MM-DD') as date,
|
||||
SUM(CASE WHEN p.stock_quantity > $1 THEN 1 ELSE 0 END) as inStock,
|
||||
SUM(CASE WHEN p.stock_quantity <= $1 AND p.stock_quantity > 0 THEN 1 ELSE 0 END) as lowStock,
|
||||
SUM(CASE WHEN p.stock_quantity = 0 THEN 1 ELSE 0 END) as outOfStock
|
||||
FROM products p
|
||||
LEFT JOIN orders o ON p.pid = o.pid
|
||||
WHERE o.date >= CURRENT_DATE - INTERVAL '${config.turnover_period} days'
|
||||
GROUP BY to_char(o.date, 'YYYY-MM-DD')
|
||||
ORDER BY date
|
||||
`, [config.low_stock_threshold]);
|
||||
|
||||
// Get critical stock items
|
||||
const { rows: criticalItems } = await pool.query(`
|
||||
WITH product_thresholds AS (
|
||||
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
|
||||
p.pid,
|
||||
COALESCE(
|
||||
(SELECT reorder_days
|
||||
FROM stock_thresholds st
|
||||
WHERE st.vendor = p.vendor LIMIT 1),
|
||||
(SELECT reorder_days
|
||||
FROM stock_thresholds st
|
||||
WHERE st.vendor IS NULL LIMIT 1),
|
||||
14
|
||||
) as reorder_days
|
||||
FROM products p
|
||||
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
|
||||
p.title as product,
|
||||
p.SKU as sku,
|
||||
p.stock_quantity as stockQuantity,
|
||||
GREATEST(ROUND((AVG(o.quantity) * pt.reorder_days)::numeric), $1) as reorderPoint,
|
||||
ROUND((SUM(o.quantity) / NULLIF(p.stock_quantity, 0))::numeric, 1) as turnoverRate,
|
||||
CASE
|
||||
WHEN p.stock_quantity = 0 THEN 0
|
||||
ELSE ROUND((p.stock_quantity / NULLIF((SUM(o.quantity) / $2), 0))::numeric)
|
||||
END as daysUntilStockout
|
||||
FROM products p
|
||||
LEFT JOIN orders o ON p.pid = o.pid
|
||||
JOIN product_thresholds pt ON p.pid = pt.pid
|
||||
WHERE o.date >= CURRENT_DATE - INTERVAL '${config.turnover_period} days'
|
||||
AND p.managing_stock = true
|
||||
GROUP BY p.pid, pt.reorder_days
|
||||
HAVING
|
||||
CASE
|
||||
WHEN p.stock_quantity = 0 THEN 0
|
||||
ELSE ROUND((p.stock_quantity / NULLIF((SUM(o.quantity) / $2), 0))::numeric)
|
||||
END < $3
|
||||
AND
|
||||
CASE
|
||||
WHEN p.stock_quantity = 0 THEN 0
|
||||
ELSE ROUND((p.stock_quantity / NULLIF((SUM(o.quantity) / $2), 0))::numeric)
|
||||
END >= 0
|
||||
ORDER BY daysUntilStockout
|
||||
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
|
||||
`, [
|
||||
config.low_stock_threshold,
|
||||
config.turnover_period,
|
||||
config.turnover_period
|
||||
]);
|
||||
|
||||
res.json({ turnoverByCategory, stockLevels, criticalItems });
|
||||
`);
|
||||
|
||||
// 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' });
|
||||
res.status(500).json({ error: 'Failed to fetch stock analysis', details: error.message });
|
||||
}
|
||||
});
|
||||
|
||||
|
||||
Reference in New Issue
Block a user