Get frontend dashboard/analytics mostly loading data again

This commit is contained in:
2025-04-08 00:02:43 -04:00
parent 43f76e4ac0
commit f271f3aae4
8 changed files with 575 additions and 613 deletions

View File

@@ -100,27 +100,27 @@ BEGIN
AVG(CASE WHEN snapshot_date BETWEEN _calculation_date - INTERVAL '29 days' AND _calculation_date THEN eod_stock_retail END) AS avg_stock_retail_30d, AVG(CASE WHEN snapshot_date BETWEEN _calculation_date - INTERVAL '29 days' AND _calculation_date THEN eod_stock_retail END) AS avg_stock_retail_30d,
AVG(CASE WHEN snapshot_date BETWEEN _calculation_date - INTERVAL '29 days' AND _calculation_date THEN eod_stock_gross END) AS avg_stock_gross_30d, AVG(CASE WHEN snapshot_date BETWEEN _calculation_date - INTERVAL '29 days' AND _calculation_date THEN eod_stock_gross END) AS avg_stock_gross_30d,
-- Lifetime (Using product.total_sold instead of snapshot summation for historical accuracy) -- Lifetime (Using historical total from products table)
p.historical_total_sold AS lifetime_sales, (SELECT total_sold FROM public.products WHERE public.products.pid = daily_product_snapshots.pid) AS lifetime_sales,
COALESCE( COALESCE(
-- Option 1: Use 30-day average price if available -- Option 1: Use 30-day average price if available
CASE WHEN SUM(CASE WHEN snapshot_date >= _calculation_date - INTERVAL '29 days' AND snapshot_date <= _calculation_date THEN units_sold ELSE 0 END) > 0 THEN CASE WHEN SUM(CASE WHEN snapshot_date >= _calculation_date - INTERVAL '29 days' AND snapshot_date <= _calculation_date THEN units_sold ELSE 0 END) > 0 THEN
p.historical_total_sold * ( (SELECT total_sold FROM public.products WHERE public.products.pid = daily_product_snapshots.pid) * (
SUM(CASE WHEN snapshot_date >= _calculation_date - INTERVAL '29 days' AND snapshot_date <= _calculation_date THEN net_revenue ELSE 0 END) / SUM(CASE WHEN snapshot_date >= _calculation_date - INTERVAL '29 days' AND snapshot_date <= _calculation_date THEN net_revenue ELSE 0 END) /
NULLIF(SUM(CASE WHEN snapshot_date >= _calculation_date - INTERVAL '29 days' AND snapshot_date <= _calculation_date THEN units_sold ELSE 0 END), 0) NULLIF(SUM(CASE WHEN snapshot_date >= _calculation_date - INTERVAL '29 days' AND snapshot_date <= _calculation_date THEN units_sold ELSE 0 END), 0)
) )
ELSE NULL END, ELSE NULL END,
-- Option 2: Try 365-day average price if available -- Option 2: Try 365-day average price if available
CASE WHEN SUM(CASE WHEN snapshot_date >= _calculation_date - INTERVAL '364 days' AND snapshot_date <= _calculation_date THEN units_sold ELSE 0 END) > 0 THEN CASE WHEN SUM(CASE WHEN snapshot_date >= _calculation_date - INTERVAL '364 days' AND snapshot_date <= _calculation_date THEN units_sold ELSE 0 END) > 0 THEN
p.historical_total_sold * ( (SELECT total_sold FROM public.products WHERE public.products.pid = daily_product_snapshots.pid) * (
SUM(CASE WHEN snapshot_date >= _calculation_date - INTERVAL '364 days' AND snapshot_date <= _calculation_date THEN net_revenue ELSE 0 END) / SUM(CASE WHEN snapshot_date >= _calculation_date - INTERVAL '364 days' AND snapshot_date <= _calculation_date THEN net_revenue ELSE 0 END) /
NULLIF(SUM(CASE WHEN snapshot_date >= _calculation_date - INTERVAL '364 days' AND snapshot_date <= _calculation_date THEN units_sold ELSE 0 END), 0) NULLIF(SUM(CASE WHEN snapshot_date >= _calculation_date - INTERVAL '364 days' AND snapshot_date <= _calculation_date THEN units_sold ELSE 0 END), 0)
) )
ELSE NULL END, ELSE NULL END,
-- Option 3: Use current price from products table -- Option 3: Use current price from products table
p.historical_total_sold * p.current_price, (SELECT total_sold * price FROM public.products WHERE public.products.pid = daily_product_snapshots.pid),
-- Option 4: Use regular price if current price might be zero -- Option 4: Use regular price if current price might be zero
p.historical_total_sold * p.current_regular_price, (SELECT total_sold * regular_price FROM public.products WHERE public.products.pid = daily_product_snapshots.pid),
-- Final fallback: Use accumulated revenue (less accurate for old products) -- Final fallback: Use accumulated revenue (less accurate for old products)
SUM(net_revenue) SUM(net_revenue)
) AS lifetime_revenue, ) AS lifetime_revenue,

View File

@@ -7,37 +7,33 @@ router.get('/stats', async (req, res) => {
const pool = req.app.locals.pool; const pool = req.app.locals.pool;
const { rows: [results] } = await pool.query(` 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 SELECT
COALESCE( AVG(margin_30d) AS avg_profit_margin,
ROUND( AVG(markup_30d) AS avg_markup,
(SUM(o.price * o.quantity - p.cost_price * o.quantity) / AVG(stockturn_30d) AS avg_stock_turnover,
NULLIF(SUM(o.price * o.quantity), 0) * 100)::numeric, 1 AVG(asp_30d) AS avg_order_value
), FROM product_metrics
0 WHERE sales_30d > 0
) as profitMargin, )
COALESCE( SELECT
ROUND( COALESCE(ms.avg_profit_margin, 0) AS profitMargin,
(AVG(p.price / NULLIF(p.cost_price, 0) - 1) * 100)::numeric, 1 COALESCE(ms.avg_markup, 0) AS averageMarkup,
), COALESCE(ms.avg_stock_turnover, 0) AS stockTurnoverRate,
0 COALESCE(vc.count, 0) AS vendorCount,
) as averageMarkup, COALESCE(cc.count, 0) AS categoryCount,
COALESCE( COALESCE(ms.avg_order_value, 0) AS averageOrderValue
ROUND( FROM metrics_summary ms
(SUM(o.quantity) / NULLIF(AVG(p.stock_quantity), 0))::numeric, 2 CROSS JOIN vendor_count vc
), CROSS JOIN category_count cc
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'
`); `);
// Ensure all values are numbers // 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 JOIN category_path cp ON c.parent_id = cp.cat_id
) )
SELECT SELECT
c.name as category, cm.category_name as category,
cp.path as categoryPath, COALESCE(cp.path, cm.category_name) as categorypath,
ROUND( cm.avg_margin_30d as profitmargin,
(SUM(o.price * o.quantity - p.cost_price * o.quantity) / cm.revenue_30d as revenue,
NULLIF(SUM(o.price * o.quantity), 0) * 100)::numeric, 1 cm.cogs_30d as cost
) as profitMargin, FROM category_metrics cm
ROUND(SUM(o.price * o.quantity)::numeric, 3) as revenue, LEFT JOIN category_path cp ON cm.category_id = cp.cat_id
ROUND(SUM(p.cost_price * o.quantity)::numeric, 3) as cost WHERE cm.revenue_30d > 0
FROM products p ORDER BY cm.revenue_30d DESC
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
LIMIT 10 LIMIT 10
`); `);
// Get profit margin trend over time // Get profit margin over time
const { rows: overTime } = await pool.query(` const { rows: overTime } = await pool.query(`
WITH time_series AS (
SELECT SELECT
to_char(o.date, 'YYYY-MM-DD') as date, date_trunc('day', generate_series(
ROUND( CURRENT_DATE - INTERVAL '30 days',
(SUM(o.price * o.quantity - p.cost_price * o.quantity) / CURRENT_DATE,
NULLIF(SUM(o.price * o.quantity), 0) * 100)::numeric, 1 '1 day'::interval
) as profitMargin, ))::date AS date
ROUND(SUM(o.price * o.quantity)::numeric, 3) as revenue, ),
ROUND(SUM(p.cost_price * o.quantity)::numeric, 3) as cost daily_profits AS (
FROM products p SELECT
LEFT JOIN orders o ON p.pid = o.pid snapshot_date as date,
WHERE o.date >= CURRENT_DATE - INTERVAL '30 days' SUM(net_revenue) as revenue,
GROUP BY to_char(o.date, 'YYYY-MM-DD') SUM(cogs) as cost,
ORDER BY date 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(` const { rows: topProducts } = await pool.query(`
WITH RECURSIVE category_path AS ( WITH RECURSIVE category_path AS (
SELECT SELECT
@@ -140,26 +146,28 @@ router.get('/profit', async (req, res) => {
(cp.path || ' > ' || c.name)::text (cp.path || ' > ' || c.name)::text
FROM categories c FROM categories c
JOIN category_path cp ON c.parent_id = cp.cat_id 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 SELECT
p.title as product, pm.title as product,
c.name as category, COALESCE(pc.category, 'Uncategorized') as category,
cp.path as categoryPath, COALESCE(pc.categorypath, 'Uncategorized') as categorypath,
ROUND( pm.margin_30d as profitmargin,
(SUM(o.price * o.quantity - p.cost_price * o.quantity) / pm.revenue_30d as revenue,
NULLIF(SUM(o.price * o.quantity), 0) * 100)::numeric, 1 pm.cogs_30d as cost
) as profitMargin, FROM product_metrics pm
ROUND(SUM(o.price * o.quantity)::numeric, 3) as revenue, LEFT JOIN product_categories pc ON pm.pid = pc.pid
ROUND(SUM(p.cost_price * o.quantity)::numeric, 3) as cost WHERE pm.revenue_30d > 100
FROM products p AND pm.margin_30d > 0
LEFT JOIN orders o ON p.pid = o.pid ORDER BY pm.margin_30d DESC
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
LIMIT 10 LIMIT 10
`); `);
@@ -184,93 +192,52 @@ router.get('/vendors', async (req, res) => {
console.log('Fetching vendor performance data...'); console.log('Fetching vendor performance data...');
// First check if we have any vendors with sales // Get vendor performance metrics from the vendor_metrics table
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
const { rows: rawPerformance } = await pool.query(` const { rows: rawPerformance } = await pool.query(`
WITH monthly_sales AS (
SELECT SELECT
p.vendor, vendor_name as vendor,
ROUND(SUM(CASE revenue_30d as sales_volume,
WHEN o.date >= CURRENT_DATE - INTERVAL '30 days' avg_margin_30d as profit_margin,
THEN o.price * o.quantity 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 ELSE 0
END)::numeric, 3) as current_month, END as growth
ROUND(SUM(CASE FROM vendor_metrics
WHEN o.date >= CURRENT_DATE - INTERVAL '60 days' WHERE revenue_30d > 0
AND o.date < CURRENT_DATE - INTERVAL '30 days' ORDER BY revenue_30d DESC
THEN o.price * o.quantity LIMIT 20
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
`); `);
// Transform to camelCase properties for frontend consumption // Format the performance data
const performance = rawPerformance.map(item => ({ const performance = rawPerformance.map(vendor => ({
vendor: item.vendor, vendor: vendor.vendor,
salesVolume: Number(item.sales_volume) || 0, salesVolume: Number(vendor.sales_volume) || 0,
profitMargin: Number(item.profit_margin) || 0, profitMargin: Number(vendor.profit_margin) || 0,
stockTurnover: Number(item.stock_turnover) || 0, stockTurnover: Number(vendor.stock_turnover) || 0,
productCount: Number(item.product_count) || 0, productCount: Number(vendor.product_count) || 0,
growth: Number(item.growth) || 0 growth: Number(vendor.growth) || 0
})); }));
// Get vendor comparison metrics (sales per product vs margin) // Get vendor comparison metrics (sales per product vs margin)
const { rows: rawComparison } = await pool.query(` const { rows: rawComparison } = await pool.query(`
SELECT SELECT
p.vendor, vendor_name as vendor,
COALESCE(ROUND( CASE
SUM(o.price * o.quantity) / NULLIF(COUNT(DISTINCT p.pid), 0), WHEN active_product_count > 0
2 THEN revenue_30d / active_product_count
), 0) as sales_per_product, ELSE 0
COALESCE(ROUND( END as sales_per_product,
AVG((p.price - p.cost_price) / NULLIF(p.cost_price, 0) * 100), avg_margin_30d as average_margin,
2 product_count as size
), 0) as average_margin, FROM vendor_metrics
COUNT(DISTINCT p.pid) as size WHERE active_product_count > 0
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
ORDER BY sales_per_product DESC ORDER BY sales_per_product DESC
LIMIT 10 LIMIT 10
`); `);
@@ -294,58 +261,7 @@ router.get('/vendors', async (req, res) => {
}); });
} catch (error) { } catch (error) {
console.error('Error fetching vendor performance:', error); console.error('Error fetching vendor performance:', error);
console.error('Error details:', error.message); res.status(500).json({ error: 'Failed to fetch vendor performance data' });
// 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: []
});
} }
}); });
@@ -353,108 +269,119 @@ router.get('/vendors', async (req, res) => {
router.get('/stock', async (req, res) => { router.get('/stock', async (req, res) => {
try { try {
const pool = req.app.locals.pool; const pool = req.app.locals.pool;
console.log('Fetching stock analysis data...');
// Get global configuration values // Use the new metrics tables to get data
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
};
// Get turnover by category // Get turnover by category
const { rows: turnoverByCategory } = await pool.query(` const { rows: turnoverByCategory } = await pool.query(`
WITH category_metrics_with_path AS (
WITH RECURSIVE category_path AS (
SELECT SELECT
c.name as category, c.cat_id,
ROUND((SUM(o.quantity) / NULLIF(AVG(p.stock_quantity), 0))::numeric, 1) as turnoverRate, c.name,
ROUND(AVG(p.stock_quantity)::numeric, 0) as averageStock, c.parent_id,
SUM(o.quantity) as totalSales c.name::text as path
FROM products p FROM categories c
LEFT JOIN orders o ON p.pid = o.pid WHERE c.parent_id IS NULL
JOIN product_categories pc ON p.pid = pc.pid
JOIN categories c ON pc.cat_id = c.cat_id UNION ALL
WHERE o.date >= CURRENT_DATE - INTERVAL '${config.turnover_period} days'
GROUP BY c.name SELECT
HAVING ROUND((SUM(o.quantity) / NULLIF(AVG(p.stock_quantity), 0))::numeric, 1) > 0 c.cat_id,
ORDER BY turnoverRate DESC 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 LIMIT 10
`); `);
// Get stock levels over time // Get stock levels over time (last 30 days)
const { rows: stockLevels } = await pool.query(` 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 SELECT
to_char(o.date, 'YYYY-MM-DD') as date, snapshot_date,
SUM(CASE WHEN p.stock_quantity > $1 THEN 1 ELSE 0 END) as inStock, COUNT(DISTINCT pid) as total_products,
SUM(CASE WHEN p.stock_quantity <= $1 AND p.stock_quantity > 0 THEN 1 ELSE 0 END) as lowStock, COUNT(DISTINCT CASE WHEN eod_stock_quantity > 5 THEN pid END) as in_stock,
SUM(CASE WHEN p.stock_quantity = 0 THEN 1 ELSE 0 END) as outOfStock COUNT(DISTINCT CASE WHEN eod_stock_quantity <= 5 AND eod_stock_quantity > 0 THEN pid END) as low_stock,
FROM products p COUNT(DISTINCT CASE WHEN eod_stock_quantity = 0 THEN pid END) as out_of_stock
LEFT JOIN orders o ON p.pid = o.pid FROM daily_product_snapshots
WHERE o.date >= CURRENT_DATE - INTERVAL '${config.turnover_period} days' WHERE snapshot_date >= CURRENT_DATE - INTERVAL '30 days'
GROUP BY to_char(o.date, 'YYYY-MM-DD') GROUP BY snapshot_date
ORDER BY date
`, [config.low_stock_threshold]);
// Get critical stock items
const { rows: criticalItems } = await pool.query(`
WITH product_thresholds AS (
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
) )
SELECT SELECT
p.title as product, to_char(dr.date, 'YYYY-MM-DD') as date,
p.SKU as sku, COALESCE(dsc.in_stock, 0) as inStock,
p.stock_quantity as stockQuantity, COALESCE(dsc.low_stock, 0) as lowStock,
GREATEST(ROUND((AVG(o.quantity) * pt.reorder_days)::numeric), $1) as reorderPoint, COALESCE(dsc.out_of_stock, 0) as outOfStock
ROUND((SUM(o.quantity) / NULLIF(p.stock_quantity, 0))::numeric, 1) as turnoverRate, FROM date_range dr
CASE LEFT JOIN daily_stock_counts dsc ON dr.date = dsc.snapshot_date
WHEN p.stock_quantity = 0 THEN 0 ORDER BY dr.date
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
LIMIT 10
`, [
config.low_stock_threshold,
config.turnover_period,
config.turnover_period
]);
res.json({ turnoverByCategory, stockLevels, criticalItems }); // 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) { } catch (error) {
console.error('Error fetching stock analysis:', 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 });
} }
}); });

View File

@@ -22,11 +22,11 @@ router.get('/stock/metrics', async (req, res) => {
const { rows: [stockMetrics] } = await executeQuery(` const { rows: [stockMetrics] } = await executeQuery(`
SELECT SELECT
COALESCE(COUNT(*), 0)::integer as total_products, COALESCE(COUNT(*), 0)::integer as total_products,
COALESCE(COUNT(CASE WHEN stock_quantity > 0 THEN 1 END), 0)::integer as products_in_stock, COALESCE(COUNT(CASE WHEN current_stock > 0 THEN 1 END), 0)::integer as products_in_stock,
COALESCE(SUM(CASE WHEN stock_quantity > 0 THEN stock_quantity END), 0)::integer as total_units, COALESCE(SUM(CASE WHEN current_stock > 0 THEN current_stock END), 0)::integer as total_units,
ROUND(COALESCE(SUM(CASE WHEN stock_quantity > 0 THEN stock_quantity * cost_price END), 0)::numeric, 3) as total_cost, ROUND(COALESCE(SUM(CASE WHEN current_stock > 0 THEN current_stock_cost END), 0)::numeric, 3) as total_cost,
ROUND(COALESCE(SUM(CASE WHEN stock_quantity > 0 THEN stock_quantity * price END), 0)::numeric, 3) as total_retail ROUND(COALESCE(SUM(CASE WHEN current_stock > 0 THEN current_stock_retail END), 0)::numeric, 3) as total_retail
FROM products FROM product_metrics
`); `);
console.log('Raw stockMetrics from database:', stockMetrics); console.log('Raw stockMetrics from database:', stockMetrics);
@@ -42,13 +42,13 @@ router.get('/stock/metrics', async (req, res) => {
SELECT SELECT
COALESCE(brand, 'Unbranded') as brand, COALESCE(brand, 'Unbranded') as brand,
COUNT(DISTINCT pid)::integer as variant_count, COUNT(DISTINCT pid)::integer as variant_count,
COALESCE(SUM(stock_quantity), 0)::integer as stock_units, COALESCE(SUM(current_stock), 0)::integer as stock_units,
ROUND(COALESCE(SUM(stock_quantity * cost_price), 0)::numeric, 3) as stock_cost, ROUND(COALESCE(SUM(current_stock_cost), 0)::numeric, 3) as stock_cost,
ROUND(COALESCE(SUM(stock_quantity * price), 0)::numeric, 3) as stock_retail ROUND(COALESCE(SUM(current_stock_retail), 0)::numeric, 3) as stock_retail
FROM products FROM product_metrics
WHERE stock_quantity > 0 WHERE current_stock > 0
GROUP BY COALESCE(brand, 'Unbranded') GROUP BY COALESCE(brand, 'Unbranded')
HAVING ROUND(COALESCE(SUM(stock_quantity * cost_price), 0)::numeric, 3) > 0 HAVING ROUND(COALESCE(SUM(current_stock_cost), 0)::numeric, 3) > 0
), ),
other_brands AS ( other_brands AS (
SELECT SELECT
@@ -130,11 +130,11 @@ router.get('/purchase/metrics', async (req, res) => {
END), 0)::numeric, 3) as total_cost, END), 0)::numeric, 3) as total_cost,
ROUND(COALESCE(SUM(CASE ROUND(COALESCE(SUM(CASE
WHEN po.receiving_status NOT IN ('partial_received', 'full_received', 'paid') WHEN po.receiving_status NOT IN ('partial_received', 'full_received', 'paid')
THEN po.ordered * p.price THEN po.ordered * pm.current_price
ELSE 0 ELSE 0
END), 0)::numeric, 3) as total_retail END), 0)::numeric, 3) as total_retail
FROM purchase_orders po FROM purchase_orders po
JOIN products p ON po.pid = p.pid JOIN product_metrics pm ON po.pid = pm.pid
`); `);
const { rows: vendorOrders } = await executeQuery(` const { rows: vendorOrders } = await executeQuery(`
@@ -143,9 +143,9 @@ router.get('/purchase/metrics', async (req, res) => {
COUNT(DISTINCT po.po_id)::integer as orders, COUNT(DISTINCT po.po_id)::integer as orders,
COALESCE(SUM(po.ordered), 0)::integer as units, COALESCE(SUM(po.ordered), 0)::integer as units,
ROUND(COALESCE(SUM(po.ordered * po.cost_price), 0)::numeric, 3) as cost, ROUND(COALESCE(SUM(po.ordered * po.cost_price), 0)::numeric, 3) as cost,
ROUND(COALESCE(SUM(po.ordered * p.price), 0)::numeric, 3) as retail ROUND(COALESCE(SUM(po.ordered * pm.current_price), 0)::numeric, 3) as retail
FROM purchase_orders po FROM purchase_orders po
JOIN products p ON po.pid = p.pid JOIN product_metrics pm ON po.pid = pm.pid
WHERE po.receiving_status NOT IN ('partial_received', 'full_received', 'paid') WHERE po.receiving_status NOT IN ('partial_received', 'full_received', 'paid')
GROUP BY po.vendor GROUP BY po.vendor
HAVING ROUND(COALESCE(SUM(po.ordered * po.cost_price), 0)::numeric, 3) > 0 HAVING ROUND(COALESCE(SUM(po.ordered * po.cost_price), 0)::numeric, 3) > 0
@@ -223,54 +223,35 @@ router.get('/replenishment/metrics', async (req, res) => {
// Get summary metrics // Get summary metrics
const { rows: [metrics] } = await executeQuery(` const { rows: [metrics] } = await executeQuery(`
SELECT SELECT
COUNT(DISTINCT p.pid)::integer as products_to_replenish, COUNT(DISTINCT pm.pid)::integer as products_to_replenish,
COALESCE(SUM(CASE COALESCE(SUM(pm.replenishment_units), 0)::integer as total_units_needed,
WHEN p.stock_quantity < 0 THEN ABS(p.stock_quantity) + pm.reorder_qty ROUND(COALESCE(SUM(pm.replenishment_cost), 0)::numeric, 3) as total_cost,
ELSE pm.reorder_qty ROUND(COALESCE(SUM(pm.replenishment_retail), 0)::numeric, 3) as total_retail
END), 0)::integer as total_units_needed, FROM product_metrics pm
ROUND(COALESCE(SUM(CASE WHERE pm.is_replenishable = true
WHEN p.stock_quantity < 0 THEN (ABS(p.stock_quantity) + pm.reorder_qty) * p.cost_price AND (pm.status IN ('Critical', 'Reorder')
ELSE pm.reorder_qty * p.cost_price OR pm.current_stock < 0)
END), 0)::numeric, 3) as total_cost, AND pm.replenishment_units > 0
ROUND(COALESCE(SUM(CASE
WHEN p.stock_quantity < 0 THEN (ABS(p.stock_quantity) + pm.reorder_qty) * p.price
ELSE pm.reorder_qty * p.price
END), 0)::numeric, 3) as total_retail
FROM products p
JOIN product_metrics pm ON p.pid = pm.pid
WHERE p.replenishable = true
AND (pm.stock_status IN ('Critical', 'Reorder')
OR p.stock_quantity < 0)
AND pm.reorder_qty > 0
`); `);
// Get top variants to replenish // Get top variants to replenish
const { rows: variants } = await executeQuery(` const { rows: variants } = await executeQuery(`
SELECT SELECT
p.pid, pm.pid,
p.title, pm.title,
p.stock_quantity::integer as current_stock, pm.current_stock::integer as current_stock,
CASE pm.replenishment_units::integer as replenish_qty,
WHEN p.stock_quantity < 0 THEN ABS(p.stock_quantity) + pm.reorder_qty ROUND(pm.replenishment_cost::numeric, 3) as replenish_cost,
ELSE pm.reorder_qty ROUND(pm.replenishment_retail::numeric, 3) as replenish_retail,
END::integer as replenish_qty, pm.status,
ROUND(CASE pm.planning_period_days::text as planning_period
WHEN p.stock_quantity < 0 THEN (ABS(p.stock_quantity) + pm.reorder_qty) * p.cost_price FROM product_metrics pm
ELSE pm.reorder_qty * p.cost_price WHERE pm.is_replenishable = true
END::numeric, 3) as replenish_cost, AND (pm.status IN ('Critical', 'Reorder')
ROUND(CASE OR pm.current_stock < 0)
WHEN p.stock_quantity < 0 THEN (ABS(p.stock_quantity) + pm.reorder_qty) * p.price AND pm.replenishment_units > 0
ELSE pm.reorder_qty * p.price
END::numeric, 3) as replenish_retail,
pm.stock_status
FROM products p
JOIN product_metrics pm ON p.pid = pm.pid
WHERE p.replenishable = true
AND (pm.stock_status IN ('Critical', 'Reorder')
OR p.stock_quantity < 0)
AND pm.reorder_qty > 0
ORDER BY ORDER BY
CASE pm.stock_status CASE pm.status
WHEN 'Critical' THEN 1 WHEN 'Critical' THEN 1
WHEN 'Reorder' THEN 2 WHEN 'Reorder' THEN 2
END, END,
@@ -280,7 +261,7 @@ router.get('/replenishment/metrics', async (req, res) => {
// If no data, provide dummy data // If no data, provide dummy data
if (!metrics || variants.length === 0) { if (!metrics || variants.length === 0) {
console.log('No replenishment metrics found, returning dummy data'); console.log('No replenishment metrics found in new schema, returning dummy data');
return res.json({ return res.json({
productsToReplenish: 15, productsToReplenish: 15,
@@ -288,11 +269,11 @@ router.get('/replenishment/metrics', async (req, res) => {
replenishmentCost: 15000.00, replenishmentCost: 15000.00,
replenishmentRetail: 30000.00, replenishmentRetail: 30000.00,
topVariants: [ topVariants: [
{ id: 1, title: "Test Product 1", currentStock: 5, replenishQty: 20, replenishCost: 500, replenishRetail: 1000, status: "Critical" }, { id: 1, title: "Test Product 1", currentStock: 5, replenishQty: 20, replenishCost: 500, replenishRetail: 1000, status: "Critical", planningPeriod: "30" },
{ id: 2, title: "Test Product 2", currentStock: 10, replenishQty: 15, replenishCost: 450, replenishRetail: 900, status: "Critical" }, { id: 2, title: "Test Product 2", currentStock: 10, replenishQty: 15, replenishCost: 450, replenishRetail: 900, status: "Critical", planningPeriod: "30" },
{ id: 3, title: "Test Product 3", currentStock: 15, replenishQty: 10, replenishCost: 300, replenishRetail: 600, status: "Reorder" }, { id: 3, title: "Test Product 3", currentStock: 15, replenishQty: 10, replenishCost: 300, replenishRetail: 600, status: "Reorder", planningPeriod: "30" },
{ id: 4, title: "Test Product 4", currentStock: 20, replenishQty: 20, replenishCost: 200, replenishRetail: 400, status: "Reorder" }, { id: 4, title: "Test Product 4", currentStock: 20, replenishQty: 20, replenishCost: 200, replenishRetail: 400, status: "Reorder", planningPeriod: "30" },
{ id: 5, title: "Test Product 5", currentStock: 25, replenishQty: 10, replenishCost: 150, replenishRetail: 300, status: "Reorder" } { id: 5, title: "Test Product 5", currentStock: 25, replenishQty: 10, replenishCost: 150, replenishRetail: 300, status: "Reorder", planningPeriod: "30" }
] ]
}); });
} }
@@ -310,7 +291,8 @@ router.get('/replenishment/metrics', async (req, res) => {
replenishQty: parseInt(v.replenish_qty) || 0, replenishQty: parseInt(v.replenish_qty) || 0,
replenishCost: parseFloat(v.replenish_cost) || 0, replenishCost: parseFloat(v.replenish_cost) || 0,
replenishRetail: parseFloat(v.replenish_retail) || 0, replenishRetail: parseFloat(v.replenish_retail) || 0,
status: v.stock_status status: v.status,
planningPeriod: v.planning_period
})) }))
}; };
@@ -325,11 +307,11 @@ router.get('/replenishment/metrics', async (req, res) => {
replenishmentCost: 15000.00, replenishmentCost: 15000.00,
replenishmentRetail: 30000.00, replenishmentRetail: 30000.00,
topVariants: [ topVariants: [
{ id: 1, title: "Test Product 1", currentStock: 5, replenishQty: 20, replenishCost: 500, replenishRetail: 1000, status: "Critical" }, { id: 1, title: "Test Product 1", currentStock: 5, replenishQty: 20, replenishCost: 500, replenishRetail: 1000, status: "Critical", planningPeriod: "30" },
{ id: 2, title: "Test Product 2", currentStock: 10, replenishQty: 15, replenishCost: 450, replenishRetail: 900, status: "Critical" }, { id: 2, title: "Test Product 2", currentStock: 10, replenishQty: 15, replenishCost: 450, replenishRetail: 900, status: "Critical", planningPeriod: "30" },
{ id: 3, title: "Test Product 3", currentStock: 15, replenishQty: 10, replenishCost: 300, replenishRetail: 600, status: "Reorder" }, { id: 3, title: "Test Product 3", currentStock: 15, replenishQty: 10, replenishCost: 300, replenishRetail: 600, status: "Reorder", planningPeriod: "30" },
{ id: 4, title: "Test Product 4", currentStock: 20, replenishQty: 20, replenishCost: 200, replenishRetail: 400, status: "Reorder" }, { id: 4, title: "Test Product 4", currentStock: 20, replenishQty: 20, replenishCost: 200, replenishRetail: 400, status: "Reorder", planningPeriod: "30" },
{ id: 5, title: "Test Product 5", currentStock: 25, replenishQty: 10, replenishCost: 150, replenishRetail: 300, status: "Reorder" } { id: 5, title: "Test Product 5", currentStock: 25, replenishQty: 10, replenishCost: 150, replenishRetail: 300, status: "Reorder", planningPeriod: "30" }
] ]
}); });
} }
@@ -499,74 +481,15 @@ router.get('/forecast/metrics', async (req, res) => {
// Returns overstock metrics by category // Returns overstock metrics by category
router.get('/overstock/metrics', async (req, res) => { router.get('/overstock/metrics', async (req, res) => {
try { try {
const { rows } = await executeQuery(` // Check if we have any products with Overstock status
WITH category_overstock AS ( const { rows: [countCheck] } = await executeQuery(`
SELECT SELECT COUNT(*) as overstock_count FROM product_metrics WHERE status = 'Overstock'
c.cat_id,
c.name as category_name,
COUNT(DISTINCT CASE
WHEN pm.stock_status = 'Overstocked'
THEN p.pid
END) as overstocked_products,
SUM(CASE
WHEN pm.stock_status = 'Overstocked'
THEN pm.overstocked_amt
ELSE 0
END) as total_excess_units,
SUM(CASE
WHEN pm.stock_status = 'Overstocked'
THEN pm.overstocked_amt * p.cost_price
ELSE 0
END) as total_excess_cost,
SUM(CASE
WHEN pm.stock_status = 'Overstocked'
THEN pm.overstocked_amt * p.price
ELSE 0
END) as total_excess_retail
FROM categories c
JOIN product_categories pc ON c.cat_id = pc.cat_id
JOIN products p ON pc.pid = p.pid
JOIN product_metrics pm ON p.pid = pm.pid
GROUP BY c.cat_id, c.name
),
filtered_categories AS (
SELECT *
FROM category_overstock
WHERE overstocked_products > 0
ORDER BY total_excess_cost DESC
LIMIT 8
),
summary AS (
SELECT
SUM(overstocked_products) as total_overstocked,
SUM(total_excess_units) as total_excess_units,
SUM(total_excess_cost) as total_excess_cost,
SUM(total_excess_retail) as total_excess_retail
FROM filtered_categories
)
SELECT
s.total_overstocked,
s.total_excess_units,
s.total_excess_cost,
s.total_excess_retail,
json_agg(
json_build_object(
'category', fc.category_name,
'products', fc.overstocked_products,
'units', fc.total_excess_units,
'cost', fc.total_excess_cost,
'retail', fc.total_excess_retail
)
) as category_data
FROM summary s, filtered_categories fc
GROUP BY
s.total_overstocked,
s.total_excess_units,
s.total_excess_cost,
s.total_excess_retail
`); `);
if (rows.length === 0) { console.log('Overstock count:', countCheck.overstock_count);
// If no overstock products, return empty metrics
if (parseInt(countCheck.overstock_count) === 0) {
return res.json({ return res.json({
overstockedProducts: 0, overstockedProducts: 0,
total_excess_units: 0, total_excess_units: 0,
@@ -576,30 +499,50 @@ router.get('/overstock/metrics', async (req, res) => {
}); });
} }
// Generate dummy data if the query returned empty results // Get summary metrics in a simpler, more direct query
if (rows[0].total_overstocked === null || rows[0].total_excess_units === null) { const { rows: [summaryMetrics] } = await executeQuery(`
console.log('Empty overstock metrics results, returning dummy data'); SELECT
return res.json({ COUNT(DISTINCT pid)::integer as total_overstocked,
overstockedProducts: 10, SUM(overstocked_units)::integer as total_excess_units,
total_excess_units: 500, ROUND(SUM(overstocked_cost)::numeric, 3) as total_excess_cost,
total_excess_cost: 5000, ROUND(SUM(overstocked_retail)::numeric, 3) as total_excess_retail
total_excess_retail: 10000, FROM product_metrics
category_data: [ WHERE status = 'Overstock'
{ category: "Electronics", products: 3, units: 150, cost: 1500, retail: 3000 }, `);
{ category: "Clothing", products: 4, units: 200, cost: 2000, retail: 4000 },
{ category: "Home Goods", products: 2, units: 100, cost: 1000, retail: 2000 }, // Get category breakdowns separately
{ category: "Office Supplies", products: 1, units: 50, cost: 500, retail: 1000 } const { rows: categoryData } = await executeQuery(`
] SELECT
}); c.name as category_name,
} COUNT(DISTINCT pm.pid)::integer as overstocked_products,
SUM(pm.overstocked_units)::integer as total_excess_units,
ROUND(SUM(pm.overstocked_cost)::numeric, 3) as total_excess_cost,
ROUND(SUM(pm.overstocked_retail)::numeric, 3) as total_excess_retail
FROM categories c
JOIN product_categories pc ON c.cat_id = pc.cat_id
JOIN product_metrics pm ON pc.pid = pm.pid
WHERE pm.status = 'Overstock'
GROUP BY c.name
ORDER BY total_excess_cost DESC
LIMIT 8
`);
console.log('Summary metrics:', summaryMetrics);
console.log('Category data count:', categoryData.length);
// Format response with explicit type conversion // Format response with explicit type conversion
const response = { const response = {
overstockedProducts: parseInt(rows[0].total_overstocked) || 0, overstockedProducts: parseInt(summaryMetrics.total_overstocked) || 0,
total_excess_units: parseInt(rows[0].total_excess_units) || 0, total_excess_units: parseInt(summaryMetrics.total_excess_units) || 0,
total_excess_cost: parseFloat(rows[0].total_excess_cost) || 0, total_excess_cost: parseFloat(summaryMetrics.total_excess_cost) || 0,
total_excess_retail: parseFloat(rows[0].total_excess_retail) || 0, total_excess_retail: parseFloat(summaryMetrics.total_excess_retail) || 0,
category_data: rows[0].category_data || [] category_data: categoryData.map(cat => ({
category: cat.category_name,
products: parseInt(cat.overstocked_products) || 0,
units: parseInt(cat.total_excess_units) || 0,
cost: parseFloat(cat.total_excess_cost) || 0,
retail: parseFloat(cat.total_excess_retail) || 0
}))
}; };
res.json(response); res.json(response);
@@ -629,27 +572,26 @@ router.get('/overstock/products', async (req, res) => {
try { try {
const { rows } = await executeQuery(` const { rows } = await executeQuery(`
SELECT SELECT
p.pid, pm.pid,
p.SKU, pm.sku AS SKU,
p.title, pm.title,
p.brand, pm.brand,
p.vendor, pm.vendor,
p.stock_quantity, pm.current_stock as stock_quantity,
p.cost_price, pm.current_cost_price as cost_price,
p.price, pm.current_price as price,
pm.daily_sales_avg, pm.sales_velocity_daily as daily_sales_avg,
pm.days_of_inventory, pm.stock_cover_in_days as days_of_inventory,
pm.overstocked_amt, pm.overstocked_units,
(pm.overstocked_amt * p.cost_price) as excess_cost, pm.overstocked_cost as excess_cost,
(pm.overstocked_amt * p.price) as excess_retail, pm.overstocked_retail as excess_retail,
STRING_AGG(c.name, ', ') as categories STRING_AGG(c.name, ', ') as categories
FROM products p FROM product_metrics pm
JOIN product_metrics pm ON p.pid = pm.pid LEFT JOIN product_categories pc ON pm.pid = pc.pid
LEFT JOIN product_categories pc ON p.pid = pc.pid
LEFT JOIN categories c ON pc.cat_id = c.cat_id LEFT JOIN categories c ON pc.cat_id = c.cat_id
WHERE pm.stock_status = 'Overstocked' WHERE pm.status = 'Overstock'
GROUP BY p.pid, p.SKU, p.title, p.brand, p.vendor, p.stock_quantity, p.cost_price, p.price, GROUP BY pm.pid, pm.sku, pm.title, pm.brand, pm.vendor, pm.current_stock, pm.current_cost_price, pm.current_price,
pm.daily_sales_avg, pm.days_of_inventory, pm.overstocked_amt pm.sales_velocity_daily, pm.stock_cover_in_days, pm.overstocked_units, pm.overstocked_cost, pm.overstocked_retail
ORDER BY excess_cost DESC ORDER BY excess_cost DESC
LIMIT $1 LIMIT $1
`, [limit]); `, [limit]);
@@ -827,42 +769,38 @@ router.get('/sales/metrics', async (req, res) => {
const endDate = req.query.endDate || today.toISOString(); const endDate = req.query.endDate || today.toISOString();
try { try {
// Get daily sales data // Get daily orders and totals for the specified period
const { rows: dailyRows } = await executeQuery(` const { rows: dailyRows } = await executeQuery(`
SELECT SELECT
DATE(o.date) as sale_date, DATE(date) as sale_date,
COUNT(DISTINCT o.order_number) as total_orders, COUNT(DISTINCT order_number) as total_orders,
SUM(o.quantity) as total_units, SUM(quantity) as total_units,
SUM(o.price * o.quantity) as total_revenue, SUM(price * quantity) as total_revenue,
SUM(p.cost_price * o.quantity) as total_cogs, SUM(costeach * quantity) as total_cogs
SUM((o.price - p.cost_price) * o.quantity) as total_profit FROM orders
FROM orders o WHERE date BETWEEN $1 AND $2
JOIN products p ON o.pid = p.pid AND canceled = false
WHERE o.canceled = false GROUP BY DATE(date)
AND o.date BETWEEN $1 AND $2
GROUP BY DATE(o.date)
ORDER BY sale_date ORDER BY sale_date
`, [startDate, endDate]); `, [startDate, endDate]);
// Get summary metrics // Get overall metrics for the period
const { rows: metrics } = await executeQuery(` const { rows: [metrics] } = await executeQuery(`
SELECT SELECT
COUNT(DISTINCT o.order_number) as total_orders, COUNT(DISTINCT order_number) as total_orders,
SUM(o.quantity) as total_units, SUM(quantity) as total_units,
SUM(o.price * o.quantity) as total_revenue, SUM(price * quantity) as total_revenue,
SUM(p.cost_price * o.quantity) as total_cogs, SUM(costeach * quantity) as total_cogs
SUM((o.price - p.cost_price) * o.quantity) as total_profit FROM orders
FROM orders o WHERE date BETWEEN $1 AND $2
JOIN products p ON o.pid = p.pid AND canceled = false
WHERE o.canceled = false
AND o.date BETWEEN $1 AND $2
`, [startDate, endDate]); `, [startDate, endDate]);
const response = { const response = {
totalOrders: parseInt(metrics[0]?.total_orders) || 0, totalOrders: parseInt(metrics?.total_orders) || 0,
totalUnitsSold: parseInt(metrics[0]?.total_units) || 0, totalUnitsSold: parseInt(metrics?.total_units) || 0,
totalCogs: parseFloat(metrics[0]?.total_cogs) || 0, totalCogs: parseFloat(metrics?.total_cogs) || 0,
totalRevenue: parseFloat(metrics[0]?.total_revenue) || 0, totalRevenue: parseFloat(metrics?.total_revenue) || 0,
dailySales: dailyRows.map(day => ({ dailySales: dailyRows.map(day => ({
date: day.sale_date, date: day.sale_date,
units: parseInt(day.total_units) || 0, units: parseInt(day.total_units) || 0,
@@ -1304,39 +1242,33 @@ router.get('/inventory-health', async (req, res) => {
}); });
// GET /dashboard/replenish/products // GET /dashboard/replenish/products
// Returns top products that need replenishment // Returns list of products to replenish
router.get('/replenish/products', async (req, res) => { router.get('/replenish/products', async (req, res) => {
const limit = Math.max(1, Math.min(100, parseInt(req.query.limit) || 50)); const limit = parseInt(req.query.limit) || 50;
try { try {
const { rows: products } = await executeQuery(` const { rows } = await executeQuery(`
SELECT SELECT
p.pid, pm.pid,
p.SKU as sku, pm.sku,
p.title, pm.title,
p.stock_quantity, pm.current_stock AS stock_quantity,
pm.daily_sales_avg, pm.sales_velocity_daily AS daily_sales_avg,
pm.reorder_qty, pm.replenishment_units AS reorder_qty,
pm.last_purchase_date pm.date_last_received AS last_purchase_date
FROM products p FROM product_metrics pm
JOIN product_metrics pm ON p.pid = pm.pid WHERE pm.is_replenishable = true
WHERE p.replenishable = true AND (pm.status IN ('Critical', 'Reorder')
AND pm.stock_status IN ('Critical', 'Reorder') OR pm.current_stock < 0)
AND pm.reorder_qty > 0 AND pm.replenishment_units > 0
ORDER BY ORDER BY
CASE pm.stock_status CASE pm.status
WHEN 'Critical' THEN 1 WHEN 'Critical' THEN 1
WHEN 'Reorder' THEN 2 WHEN 'Reorder' THEN 2
END, END,
pm.reorder_qty * p.cost_price DESC pm.replenishment_cost DESC
LIMIT $1 LIMIT $1
`, [limit]); `, [limit]);
res.json(rows);
res.json(products.map(p => ({
...p,
stock_quantity: parseInt(p.stock_quantity) || 0,
daily_sales_avg: parseFloat(p.daily_sales_avg) || 0,
reorder_qty: parseInt(p.reorder_qty) || 0
})));
} catch (err) { } catch (err) {
console.error('Error fetching products to replenish:', err); console.error('Error fetching products to replenish:', err);
res.status(500).json({ error: 'Failed to fetch products to replenish' }); res.status(500).json({ error: 'Failed to fetch products to replenish' });

View File

@@ -38,21 +38,22 @@ export function CategoryPerformance() {
const rawData = await response.json(); const rawData = await response.json();
return { return {
performance: rawData.performance.map((item: any) => ({ performance: rawData.performance.map((item: any) => ({
...item, category: item.category || '',
categoryPath: item.categoryPath || item.category, categoryPath: item.categoryPath || item.categorypath || item.category || '',
revenue: Number(item.revenue) || 0, revenue: Number(item.revenue) || 0,
profit: Number(item.profit) || 0, profit: Number(item.profit) || 0,
growth: Number(item.growth) || 0, growth: Number(item.growth) || 0,
productCount: Number(item.productCount) || 0 productCount: Number(item.productCount) || Number(item.productcount) || 0
})), })),
distribution: rawData.distribution.map((item: any) => ({ distribution: rawData.distribution.map((item: any) => ({
...item, category: item.category || '',
categoryPath: item.categoryPath || item.category, categoryPath: item.categoryPath || item.categorypath || item.category || '',
value: Number(item.value) || 0 value: Number(item.value) || 0
})), })),
trends: rawData.trends.map((item: any) => ({ trends: rawData.trends.map((item: any) => ({
...item, category: item.category || '',
categoryPath: item.categoryPath || item.category, categoryPath: item.categoryPath || item.categorypath || item.category || '',
month: item.month || '',
sales: Number(item.sales) || 0 sales: Number(item.sales) || 0
})) }))
}; };

View File

@@ -25,41 +25,91 @@ interface PriceData {
} }
export function PriceAnalysis() { export function PriceAnalysis() {
const { data, isLoading } = useQuery<PriceData>({ const { data, isLoading, error } = useQuery<PriceData>({
queryKey: ['price-analysis'], queryKey: ['price-analysis'],
queryFn: async () => { queryFn: async () => {
try {
const response = await fetch(`${config.apiUrl}/analytics/pricing`); const response = await fetch(`${config.apiUrl}/analytics/pricing`);
if (!response.ok) { if (!response.ok) {
throw new Error('Failed to fetch price analysis'); throw new Error(`Failed to fetch: ${response.status}`);
} }
const rawData = await response.json(); const rawData = await response.json();
if (!rawData || !rawData.pricePoints) {
return { return {
pricePoints: rawData.pricePoints.map((item: any) => ({ pricePoints: [],
...item, elasticity: [],
recommendations: []
};
}
return {
pricePoints: (rawData.pricePoints || []).map((item: any) => ({
price: Number(item.price) || 0, price: Number(item.price) || 0,
salesVolume: Number(item.salesVolume) || 0, salesVolume: Number(item.salesVolume || item.salesvolume) || 0,
revenue: Number(item.revenue) || 0 revenue: Number(item.revenue) || 0,
category: item.category || ''
})), })),
elasticity: rawData.elasticity.map((item: any) => ({ elasticity: (rawData.elasticity || []).map((item: any) => ({
...item, date: item.date || '',
price: Number(item.price) || 0, price: Number(item.price) || 0,
demand: Number(item.demand) || 0 demand: Number(item.demand) || 0
})), })),
recommendations: rawData.recommendations.map((item: any) => ({ recommendations: (rawData.recommendations || []).map((item: any) => ({
...item, product: item.product || '',
currentPrice: Number(item.currentPrice) || 0, currentPrice: Number(item.currentPrice || item.currentprice) || 0,
recommendedPrice: Number(item.recommendedPrice) || 0, recommendedPrice: Number(item.recommendedPrice || item.recommendedprice) || 0,
potentialRevenue: Number(item.potentialRevenue) || 0, potentialRevenue: Number(item.potentialRevenue || item.potentialrevenue) || 0,
confidence: Number(item.confidence) || 0 confidence: Number(item.confidence) || 0
})) }))
}; };
} catch (err) {
console.error('Error fetching price data:', err);
throw err;
}
}, },
retry: 1
}); });
if (isLoading || !data) { if (isLoading) {
return <div>Loading price analysis...</div>; return <div>Loading price analysis...</div>;
} }
if (error || !data) {
return (
<Card className="mb-4">
<CardHeader>
<CardTitle>Price Analysis</CardTitle>
</CardHeader>
<CardContent>
<p className="text-red-500">
Unable to load price analysis. The price metrics may need to be set up in the database.
</p>
</CardContent>
</Card>
);
}
// Early return if no data to display
if (
data.pricePoints.length === 0 &&
data.elasticity.length === 0 &&
data.recommendations.length === 0
) {
return (
<Card className="mb-4">
<CardHeader>
<CardTitle>Price Analysis</CardTitle>
</CardHeader>
<CardContent>
<p className="text-muted-foreground">
No price data available. This may be because the price metrics haven't been calculated yet.
</p>
</CardContent>
</Card>
);
}
return ( return (
<div className="grid gap-4"> <div className="grid gap-4">
<div className="grid gap-4 md:grid-cols-2"> <div className="grid gap-4 md:grid-cols-2">

View File

@@ -38,22 +38,23 @@ export function ProfitAnalysis() {
const rawData = await response.json(); const rawData = await response.json();
return { return {
byCategory: rawData.byCategory.map((item: any) => ({ byCategory: rawData.byCategory.map((item: any) => ({
...item, category: item.category || '',
categoryPath: item.categoryPath || item.category, categoryPath: item.categorypath || item.category || '',
profitMargin: Number(item.profitMargin) || 0, profitMargin: item.profitmargin !== null ? Number(item.profitmargin) : 0,
revenue: Number(item.revenue) || 0, revenue: Number(item.revenue) || 0,
cost: Number(item.cost) || 0 cost: Number(item.cost) || 0
})), })),
overTime: rawData.overTime.map((item: any) => ({ overTime: rawData.overTime.map((item: any) => ({
...item, date: item.date || '',
profitMargin: Number(item.profitMargin) || 0, profitMargin: item.profitmargin !== null ? Number(item.profitmargin) : 0,
revenue: Number(item.revenue) || 0, revenue: Number(item.revenue) || 0,
cost: Number(item.cost) || 0 cost: Number(item.cost) || 0
})), })),
topProducts: rawData.topProducts.map((item: any) => ({ topProducts: rawData.topProducts.map((item: any) => ({
...item, product: item.product || '',
categoryPath: item.categoryPath || item.category, category: item.category || '',
profitMargin: Number(item.profitMargin) || 0, categoryPath: item.categorypath || item.category || '',
profitMargin: item.profitmargin !== null ? Number(item.profitmargin) : 0,
revenue: Number(item.revenue) || 0, revenue: Number(item.revenue) || 0,
cost: Number(item.cost) || 0 cost: Number(item.cost) || 0
})) }))

View File

@@ -28,42 +28,93 @@ interface StockData {
} }
export function StockAnalysis() { export function StockAnalysis() {
const { data, isLoading } = useQuery<StockData>({ const { data, isLoading, error } = useQuery<StockData>({
queryKey: ['stock-analysis'], queryKey: ['stock-analysis'],
queryFn: async () => { queryFn: async () => {
try {
const response = await fetch(`${config.apiUrl}/analytics/stock`); const response = await fetch(`${config.apiUrl}/analytics/stock`);
if (!response.ok) { if (!response.ok) {
throw new Error('Failed to fetch stock analysis'); throw new Error(`Failed to fetch: ${response.status}`);
} }
const rawData = await response.json(); const rawData = await response.json();
if (!rawData || !rawData.turnoverByCategory) {
return { return {
turnoverByCategory: rawData.turnoverByCategory.map((item: any) => ({ turnoverByCategory: [],
...item, stockLevels: [],
turnoverRate: Number(item.turnoverRate) || 0, criticalItems: []
averageStock: Number(item.averageStock) || 0, };
totalSales: Number(item.totalSales) || 0 }
return {
turnoverByCategory: (rawData.turnoverByCategory || []).map((item: any) => ({
category: item.category || '',
turnoverRate: Number(item.turnoverRate || item.turnoverrate) || 0,
averageStock: Number(item.averageStock || item.averagestock) || 0,
totalSales: Number(item.totalSales || item.totalsales) || 0
})), })),
stockLevels: rawData.stockLevels.map((item: any) => ({ stockLevels: (rawData.stockLevels || []).map((item: any) => ({
...item, date: item.date || '',
inStock: Number(item.inStock) || 0, inStock: Number(item.inStock || item.instock) || 0,
lowStock: Number(item.lowStock) || 0, lowStock: Number(item.lowStock || item.lowstock) || 0,
outOfStock: Number(item.outOfStock) || 0 outOfStock: Number(item.outOfStock || item.outofstock) || 0
})), })),
criticalItems: rawData.criticalItems.map((item: any) => ({ criticalItems: (rawData.criticalItems || []).map((item: any) => ({
...item, product: item.product || '',
stockQuantity: Number(item.stockQuantity) || 0, sku: item.sku || '',
reorderPoint: Number(item.reorderPoint) || 0, stockQuantity: Number(item.stockQuantity || item.stockquantity) || 0,
turnoverRate: Number(item.turnoverRate) || 0, reorderPoint: Number(item.reorderPoint || item.reorderpoint) || 0,
daysUntilStockout: Number(item.daysUntilStockout) || 0 turnoverRate: Number(item.turnoverRate || item.turnoverrate) || 0,
daysUntilStockout: Number(item.daysUntilStockout || item.daysuntilstockout) || 0
})) }))
}; };
} catch (err) {
console.error('Error fetching stock data:', err);
throw err;
}
}, },
retry: 1
}); });
if (isLoading || !data) { if (isLoading) {
return <div>Loading stock analysis...</div>; return <div>Loading stock analysis...</div>;
} }
if (error || !data) {
return (
<Card className="mb-4">
<CardHeader>
<CardTitle>Stock Analysis</CardTitle>
</CardHeader>
<CardContent>
<p className="text-red-500">
Unable to load stock analysis. The stock metrics may need to be set up in the database.
</p>
</CardContent>
</Card>
);
}
// Early return if no data to display
if (
data.turnoverByCategory.length === 0 &&
data.stockLevels.length === 0 &&
data.criticalItems.length === 0
) {
return (
<Card className="mb-4">
<CardHeader>
<CardTitle>Stock Analysis</CardTitle>
</CardHeader>
<CardContent>
<p className="text-muted-foreground">
No stock data available. This may be because the stock metrics haven't been calculated yet.
</p>
</CardContent>
</Card>
);
}
const getStockStatus = (daysUntilStockout: number) => { const getStockStatus = (daysUntilStockout: number) => {
if (daysUntilStockout <= 7) { if (daysUntilStockout <= 7) {
return <Badge variant="destructive">Critical</Badge>; return <Badge variant="destructive">Critical</Badge>;

View File

@@ -58,22 +58,22 @@ export function VendorPerformance() {
// Create a complete structure even if some parts are missing // Create a complete structure even if some parts are missing
const data: VendorData = { const data: VendorData = {
performance: rawData.performance.map((vendor: any) => ({ performance: rawData.performance.map((vendor: any) => ({
vendor: vendor.vendor, vendor: vendor.vendor || '',
salesVolume: Number(vendor.salesVolume) || 0, salesVolume: vendor.salesVolume !== null ? Number(vendor.salesVolume) : 0,
profitMargin: Number(vendor.profitMargin) || 0, profitMargin: vendor.profitMargin !== null ? Number(vendor.profitMargin) : 0,
stockTurnover: Number(vendor.stockTurnover) || 0, stockTurnover: vendor.stockTurnover !== null ? Number(vendor.stockTurnover) : 0,
productCount: Number(vendor.productCount) || 0, productCount: Number(vendor.productCount) || 0,
growth: Number(vendor.growth) || 0 growth: vendor.growth !== null ? Number(vendor.growth) : 0
})), })),
comparison: rawData.comparison?.map((vendor: any) => ({ comparison: rawData.comparison?.map((vendor: any) => ({
vendor: vendor.vendor, vendor: vendor.vendor || '',
salesPerProduct: Number(vendor.salesPerProduct) || 0, salesPerProduct: vendor.salesPerProduct !== null ? Number(vendor.salesPerProduct) : 0,
averageMargin: Number(vendor.averageMargin) || 0, averageMargin: vendor.averageMargin !== null ? Number(vendor.averageMargin) : 0,
size: Number(vendor.size) || 0 size: Number(vendor.size) || 0
})) || [], })) || [],
trends: rawData.trends?.map((vendor: any) => ({ trends: rawData.trends?.map((vendor: any) => ({
vendor: vendor.vendor, vendor: vendor.vendor || '',
month: vendor.month, month: vendor.month || '',
sales: Number(vendor.sales) || 0 sales: Number(vendor.sales) || 0
})) || [] })) || []
}; };