Add backend routes

This commit is contained in:
2025-01-17 16:07:31 -05:00
parent 48c7ab9134
commit 118344b730
2 changed files with 658 additions and 388 deletions

View File

@@ -1,374 +1,666 @@
const express = require('express'); const express = require('express');
const router = express.Router(); const router = express.Router();
const db = require('../utils/db');
// Get dashboard stats // Helper function to execute queries using the connection pool
router.get('/stats', async (req, res) => { async function executeQuery(sql, params = []) {
const pool = req.app.locals.pool; const pool = db.getPool();
if (!pool) {
throw new Error('Database pool not initialized');
}
return pool.query(sql, params);
}
// GET /dashboard/stock/metrics
// Returns brand-level stock metrics
router.get('/stock/metrics', async (req, res) => {
try { try {
const [stats] = await pool.query(` const [rows] = await executeQuery(`
WITH OrderStats AS (
SELECT SELECT
COUNT(DISTINCT o.order_number) as total_orders, bm.*,
SUM(o.price * o.quantity) as total_revenue, COALESCE(
AVG(subtotal) as average_order_value SUM(CASE
FROM orders o WHEN pm.stock_status = 'Critical' THEN 1
LEFT JOIN (
SELECT order_number, SUM(price * quantity) as subtotal
FROM orders
WHERE DATE(date) >= DATE_SUB(CURDATE(), INTERVAL 30 DAY)
AND canceled = false
GROUP BY order_number
) t ON o.order_number = t.order_number
WHERE DATE(o.date) >= DATE_SUB(CURDATE(), INTERVAL 30 DAY)
AND o.canceled = false
),
ProfitStats AS (
SELECT
SUM((o.price - p.cost_price) * o.quantity) as total_profit,
SUM(o.price * o.quantity) as revenue
FROM orders o
JOIN products p ON o.product_id = p.product_id
WHERE DATE(o.date) >= DATE_SUB(CURDATE(), INTERVAL 30 DAY)
AND o.canceled = false
),
ProductStats AS (
SELECT
COUNT(*) as total_products,
COUNT(CASE WHEN stock_quantity <= 5 THEN 1 END) as low_stock_products
FROM products
WHERE visible = true
)
SELECT
ps.total_products,
ps.low_stock_products,
os.total_orders,
os.average_order_value,
os.total_revenue,
prs.total_profit,
CASE
WHEN prs.revenue > 0 THEN (prs.total_profit / prs.revenue) * 100
ELSE 0 ELSE 0
END as profit_margin END)
FROM ProductStats ps , 0) as critical_stock_count,
CROSS JOIN OrderStats os COALESCE(
CROSS JOIN ProfitStats prs SUM(CASE
`); WHEN pm.stock_status = 'Reorder' THEN 1
res.json({ ELSE 0
...stats[0], END)
averageOrderValue: parseFloat(stats[0].average_order_value) || 0, , 0) as reorder_count,
totalRevenue: parseFloat(stats[0].total_revenue) || 0, COALESCE(
profitMargin: parseFloat(stats[0].profit_margin) || 0 SUM(CASE
}); WHEN pm.stock_status = 'Overstocked' THEN 1
} catch (error) { ELSE 0
console.error('Error fetching dashboard stats:', error); END)
res.status(500).json({ error: 'Failed to fetch dashboard stats' }); , 0) as overstock_count
} FROM brand_metrics bm
}); LEFT JOIN products p ON p.brand = bm.brand
LEFT JOIN product_metrics pm ON p.product_id = pm.product_id
// Get sales overview data GROUP BY bm.brand
router.get('/sales-overview', async (req, res) => { ORDER BY bm.total_revenue DESC
const pool = req.app.locals.pool;
try {
const [rows] = await pool.query(`
SELECT
DATE(date) as date,
SUM(price * quantity) as total
FROM orders
WHERE DATE(date) >= DATE_SUB(CURDATE(), INTERVAL 30 DAY)
AND canceled = false
GROUP BY DATE(date)
ORDER BY date ASC
`);
res.json(rows.map(row => ({
...row,
total: parseFloat(row.total || 0)
})));
} catch (error) {
console.error('Error fetching sales overview:', error);
res.status(500).json({ error: 'Failed to fetch sales overview' });
}
});
// Get recent orders
router.get('/recent-orders', async (req, res) => {
const pool = req.app.locals.pool;
try {
const [rows] = await pool.query(`
SELECT
o1.order_number as order_id,
o1.customer as customer_name,
SUM(o2.price * o2.quantity) as total_amount,
o1.date as order_date
FROM orders o1
JOIN orders o2 ON o1.order_number = o2.order_number
WHERE o1.canceled = false
GROUP BY o1.order_number, o1.customer, o1.date
ORDER BY o1.date DESC
LIMIT 5
`);
res.json(rows.map(row => ({
...row,
total_amount: parseFloat(row.total_amount || 0),
order_date: row.order_date
})));
} catch (error) {
console.error('Error fetching recent orders:', error);
res.status(500).json({ error: 'Failed to fetch recent orders' });
}
});
// Get category stats
router.get('/category-stats', async (req, res) => {
const pool = req.app.locals.pool;
try {
const [rows] = await pool.query(`
SELECT
c.name as category,
COUNT(DISTINCT pc.product_id) as count
FROM categories c
LEFT JOIN product_categories pc ON c.id = pc.category_id
LEFT JOIN products p ON pc.product_id = p.product_id
WHERE p.visible = true
GROUP BY c.name
ORDER BY count DESC
LIMIT 10
`); `);
res.json(rows); res.json(rows);
} catch (error) { } catch (err) {
console.error('Error fetching category stats:', error); console.error('Error fetching stock metrics:', err);
res.status(500).json({ error: 'Failed to fetch category stats' }); res.status(500).json({ error: 'Failed to fetch stock metrics' });
} }
}); });
// Get stock levels // GET /dashboard/purchase/metrics
router.get('/stock-levels', async (req, res) => { // Returns purchase order metrics by vendor
const pool = req.app.locals.pool; router.get('/purchase/metrics', async (req, res) => {
try { try {
const [rows] = await pool.query(` const [rows] = await executeQuery(`
SELECT SELECT
SUM(CASE WHEN stock_quantity = 0 THEN 1 ELSE 0 END) as outOfStock, vm.*,
SUM(CASE WHEN stock_quantity > 0 AND stock_quantity <= 5 THEN 1 ELSE 0 END) as lowStock, COUNT(DISTINCT CASE
SUM(CASE WHEN stock_quantity > 5 AND stock_quantity <= 20 THEN 1 ELSE 0 END) as inStock, WHEN po.status = 'open' THEN po.po_id
SUM(CASE WHEN stock_quantity > 20 THEN 1 ELSE 0 END) as overStock END) as active_orders,
FROM products COUNT(DISTINCT CASE
WHERE visible = true WHEN po.status = 'open'
AND po.expected_date < CURDATE()
THEN po.po_id
END) as overdue_orders,
SUM(CASE
WHEN po.status = 'open'
THEN po.ordered * po.cost_price
ELSE 0
END) as active_order_value
FROM vendor_metrics vm
LEFT JOIN purchase_orders po ON vm.vendor = po.vendor
GROUP BY vm.vendor
ORDER BY vm.total_purchase_value DESC
`); `);
res.json(rows[0]); res.json(rows);
} catch (error) { } catch (err) {
console.error('Error fetching stock levels:', error); console.error('Error fetching purchase metrics:', err);
res.status(500).json({ error: 'Failed to fetch stock levels' }); res.status(500).json({ error: 'Failed to fetch purchase metrics' });
} }
}); });
// Get sales by category // GET /dashboard/replenishment/metrics
router.get('/sales-by-category', async (req, res) => { // Returns replenishment needs by category
const pool = req.app.locals.pool; router.get('/replenishment/metrics', async (req, res) => {
try { try {
const [rows] = await pool.query(` const [rows] = await executeQuery(`
WITH category_replenishment AS (
SELECT SELECT
c.name as category, c.id as category_id,
SUM(o.price * o.quantity) as total c.name as category_name,
COUNT(DISTINCT CASE
WHEN pm.stock_status IN ('Critical', 'Reorder')
THEN p.product_id
END) as products_to_replenish,
SUM(CASE
WHEN pm.stock_status IN ('Critical', 'Reorder')
THEN pm.reorder_qty
ELSE 0
END) as total_units_needed,
SUM(CASE
WHEN pm.stock_status IN ('Critical', 'Reorder')
THEN pm.reorder_qty * p.cost_price
ELSE 0
END) as total_replenishment_cost,
SUM(CASE
WHEN pm.stock_status IN ('Critical', 'Reorder')
THEN pm.reorder_qty * p.price
ELSE 0
END) as total_replenishment_retail
FROM categories c
JOIN product_categories pc ON c.id = pc.category_id
JOIN products p ON pc.product_id = p.product_id
JOIN product_metrics pm ON p.product_id = pm.product_id
WHERE p.replenishable = true
GROUP BY c.id, c.name
)
SELECT
cr.*,
cm.total_value as category_total_value,
cm.turnover_rate as category_turnover_rate
FROM category_replenishment cr
LEFT JOIN category_metrics cm ON cr.category_id = cm.category_id
WHERE cr.products_to_replenish > 0
ORDER BY cr.total_replenishment_cost DESC
`);
res.json(rows);
} catch (err) {
console.error('Error fetching replenishment metrics:', err);
res.status(500).json({ error: 'Failed to fetch replenishment metrics' });
}
});
// GET /dashboard/forecast/metrics
// Returns sales forecasts for specified period
router.get('/forecast/metrics', async (req, res) => {
const days = Math.max(1, Math.min(365, parseInt(req.query.days) || 30));
try {
const [rows] = await executeQuery(`
WITH daily_forecasts AS (
SELECT
forecast_date,
SUM(forecast_units) as total_units,
SUM(forecast_revenue) as total_revenue,
AVG(confidence_level) as avg_confidence
FROM sales_forecasts
WHERE forecast_date BETWEEN CURDATE() AND DATE_ADD(CURDATE(), INTERVAL ? DAY)
GROUP BY forecast_date
),
category_forecasts_summary AS (
SELECT
c.name as category_name,
SUM(cf.forecast_units) as category_units,
SUM(cf.forecast_revenue) as category_revenue,
AVG(cf.confidence_level) as category_confidence
FROM category_forecasts cf
JOIN categories c ON cf.category_id = c.id
WHERE cf.forecast_date BETWEEN CURDATE() AND DATE_ADD(CURDATE(), INTERVAL ? DAY)
GROUP BY c.id, c.name
)
SELECT
SUM(df.total_units) as total_forecast_units,
SUM(df.total_revenue) as total_forecast_revenue,
AVG(df.avg_confidence) as overall_confidence,
JSON_ARRAYAGG(
JSON_OBJECT(
'date', df.forecast_date,
'units', df.total_units,
'revenue', df.total_revenue,
'confidence', df.avg_confidence
)
) as daily_data,
JSON_ARRAYAGG(
JSON_OBJECT(
'category', cfs.category_name,
'units', cfs.category_units,
'revenue', cfs.category_revenue,
'confidence', cfs.category_confidence
)
) as category_data
FROM daily_forecasts df
CROSS JOIN category_forecasts_summary cfs
`, [days, days]);
res.json(rows[0]);
} catch (err) {
console.error('Error fetching forecast metrics:', err);
res.status(500).json({ error: 'Failed to fetch forecast metrics' });
}
});
// GET /dashboard/overstock/metrics
// Returns overstock metrics by category
router.get('/overstock/metrics', async (req, res) => {
try {
const [rows] = await executeQuery(`
WITH category_overstock AS (
SELECT
c.id as category_id,
c.name as category_name,
COUNT(DISTINCT CASE
WHEN pm.stock_status = 'Overstocked'
THEN p.product_id
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.id = pc.category_id
JOIN products p ON pc.product_id = p.product_id
JOIN product_metrics pm ON p.product_id = pm.product_id
GROUP BY c.id, c.name
)
SELECT
co.*,
cm.total_value as category_total_value,
cm.turnover_rate as category_turnover_rate
FROM category_overstock co
LEFT JOIN category_metrics cm ON co.category_id = cm.category_id
WHERE co.overstocked_products > 0
ORDER BY co.total_excess_cost DESC
`);
res.json(rows);
} catch (err) {
console.error('Error fetching overstock metrics:', err);
res.status(500).json({ error: 'Failed to fetch overstock metrics' });
}
});
// GET /dashboard/overstock/products
// Returns list of most overstocked products
router.get('/overstock/products', async (req, res) => {
const limit = parseInt(req.query.limit) || 50;
try {
const [rows] = await executeQuery(`
SELECT
p.product_id,
p.SKU,
p.title,
p.brand,
p.vendor,
p.stock_quantity,
p.cost_price,
p.price,
pm.daily_sales_avg,
pm.days_of_inventory,
pm.overstocked_amt,
(pm.overstocked_amt * p.cost_price) as excess_cost,
(pm.overstocked_amt * p.price) as excess_retail,
GROUP_CONCAT(c.name) as categories
FROM products p
JOIN product_metrics pm ON p.product_id = pm.product_id
LEFT JOIN product_categories pc ON p.product_id = pc.product_id
LEFT JOIN categories c ON pc.category_id = c.id
WHERE pm.stock_status = 'Overstocked'
GROUP BY p.product_id
ORDER BY excess_cost DESC
LIMIT ?
`, [limit]);
res.json(rows);
} catch (err) {
console.error('Error fetching overstocked products:', err);
res.status(500).json({ error: 'Failed to fetch overstocked products' });
}
});
// GET /dashboard/best-sellers
// Returns best-selling products, vendors, and categories
router.get('/best-sellers', async (req, res) => {
try {
const [products] = await executeQuery(`
SELECT
p.product_id,
p.SKU,
p.title,
p.brand,
p.vendor,
pm.total_revenue,
pm.daily_sales_avg,
pm.number_of_orders,
GROUP_CONCAT(c.name) as categories
FROM products p
JOIN product_metrics pm ON p.product_id = pm.product_id
LEFT JOIN product_categories pc ON p.product_id = pc.product_id
LEFT JOIN categories c ON pc.category_id = c.id
GROUP BY p.product_id
ORDER BY pm.total_revenue DESC
LIMIT 10
`);
const [vendors] = await executeQuery(`
SELECT
vm.*
FROM vendor_metrics vm
ORDER BY vm.total_revenue DESC
LIMIT 10
`);
const [categories] = await executeQuery(`
SELECT
c.name,
cm.*
FROM category_metrics cm
JOIN categories c ON cm.category_id = c.id
ORDER BY cm.total_value DESC
LIMIT 10
`);
res.json({
products,
vendors,
categories
});
} catch (err) {
console.error('Error fetching best sellers:', err);
res.status(500).json({ error: 'Failed to fetch best sellers' });
}
});
// GET /dashboard/sales/metrics
// Returns sales metrics for specified period
router.get('/sales/metrics', async (req, res) => {
const days = Math.max(1, Math.min(365, parseInt(req.query.days) || 30));
try {
const [rows] = await executeQuery(`
WITH daily_sales AS (
SELECT
DATE(o.date) as sale_date,
COUNT(DISTINCT o.order_number) as total_orders,
SUM(o.quantity) as total_units,
SUM(o.price * o.quantity) as total_revenue,
SUM(p.cost_price * o.quantity) as total_cogs,
SUM((o.price - p.cost_price) * o.quantity) as total_profit
FROM orders o
JOIN products p ON o.product_id = p.product_id
WHERE o.canceled = false
AND o.date >= DATE_SUB(CURDATE(), INTERVAL ? DAY)
GROUP BY DATE(o.date)
),
category_sales AS (
SELECT
c.name as category_name,
COUNT(DISTINCT o.order_number) as category_orders,
SUM(o.quantity) as category_units,
SUM(o.price * o.quantity) as category_revenue
FROM orders o FROM orders o
JOIN products p ON o.product_id = p.product_id JOIN products p ON o.product_id = p.product_id
JOIN product_categories pc ON p.product_id = pc.product_id JOIN product_categories pc ON p.product_id = pc.product_id
JOIN categories c ON pc.category_id = c.id JOIN categories c ON pc.category_id = c.id
WHERE o.canceled = false WHERE o.canceled = false
AND DATE(o.date) >= DATE_SUB(CURDATE(), INTERVAL 30 DAY) AND o.date >= DATE_SUB(CURDATE(), INTERVAL ? DAY)
GROUP BY c.name GROUP BY c.id, c.name
ORDER BY total DESC
LIMIT 6
`);
const total = rows.reduce((sum, row) => sum + parseFloat(row.total || 0), 0);
res.json(rows.map(row => ({
category: row.category || 'Uncategorized',
total: parseFloat(row.total || 0),
percentage: total > 0 ? (parseFloat(row.total || 0) / total) : 0
})));
} catch (error) {
console.error('Error fetching sales by category:', error);
res.status(500).json({ error: 'Failed to fetch sales by category' });
}
});
// Get inventory health summary
router.get('/inventory/health/summary', async (req, res) => {
const pool = req.app.locals.pool;
try {
// First check what statuses exist
const [checkStatuses] = await pool.query(`
SELECT DISTINCT stock_status
FROM product_metrics
WHERE stock_status IS NOT NULL
`);
console.log('Available stock statuses:', checkStatuses.map(row => row.stock_status));
const [rows] = await pool.query(`
WITH normalized_status AS (
SELECT
CASE
WHEN stock_status = 'Overstocked' THEN 'Overstock'
WHEN stock_status = 'New' THEN 'Healthy'
ELSE stock_status
END as status
FROM product_metrics
WHERE stock_status IS NOT NULL
) )
SELECT SELECT
status as stock_status, COUNT(DISTINCT ds.sale_date) as days_with_sales,
COUNT(*) as count SUM(ds.total_orders) as total_orders,
FROM normalized_status SUM(ds.total_units) as total_units,
GROUP BY status SUM(ds.total_revenue) as total_revenue,
`); SUM(ds.total_cogs) as total_cogs,
SUM(ds.total_profit) as total_profit,
console.log('Raw inventory health summary:', rows); AVG(ds.total_orders) as avg_daily_orders,
AVG(ds.total_units) as avg_daily_units,
// Convert array to object with lowercase keys AVG(ds.total_revenue) as avg_daily_revenue,
const summary = { JSON_ARRAYAGG(
critical: 0, JSON_OBJECT(
reorder: 0, 'date', ds.sale_date,
healthy: 0, 'orders', ds.total_orders,
overstock: 0 'units', ds.total_units,
}; 'revenue', ds.total_revenue,
'cogs', ds.total_cogs,
rows.forEach(row => { 'profit', ds.total_profit
const key = row.stock_status.toLowerCase(); )
if (key in summary) { ) as daily_data,
summary[key] = parseInt(row.count); JSON_ARRAYAGG(
} JSON_OBJECT(
}); 'category', cs.category_name,
'orders', cs.category_orders,
// Calculate total 'units', cs.category_units,
summary.total = Object.values(summary).reduce((a, b) => a + b, 0); 'revenue', cs.category_revenue
)
console.log('Final inventory health summary:', summary); ) as category_data
res.json(summary); FROM daily_sales ds
} catch (error) { CROSS JOIN category_sales cs
console.error('Error fetching inventory health summary:', error); `, [days, days]);
res.status(500).json({ error: 'Failed to fetch inventory health summary' }); res.json(rows[0]);
} catch (err) {
console.error('Error fetching sales metrics:', err);
res.status(500).json({ error: 'Failed to fetch sales metrics' });
} }
}); });
// Get low stock alerts // GET /dashboard/low-stock/products
router.get('/inventory/low-stock', async (req, res) => { // Returns list of products with critical or low stock levels
const pool = req.app.locals.pool; router.get('/low-stock/products', async (req, res) => {
const limit = parseInt(req.query.limit) || 50;
try { try {
const [rows] = await pool.query(` const [rows] = await executeQuery(`
SELECT SELECT
p.product_id, p.product_id,
p.sku, p.SKU,
p.title, p.title,
p.brand,
p.vendor,
p.stock_quantity, p.stock_quantity,
pm.reorder_point, p.cost_price,
pm.days_of_inventory, p.price,
pm.daily_sales_avg, pm.daily_sales_avg,
pm.stock_status pm.days_of_inventory,
FROM product_metrics pm pm.reorder_qty,
JOIN products p ON pm.product_id = p.product_id (pm.reorder_qty * p.cost_price) as reorder_cost,
GROUP_CONCAT(c.name) as categories
FROM products p
JOIN product_metrics pm ON p.product_id = pm.product_id
LEFT JOIN product_categories pc ON p.product_id = pc.product_id
LEFT JOIN categories c ON pc.category_id = c.id
WHERE pm.stock_status IN ('Critical', 'Reorder') WHERE pm.stock_status IN ('Critical', 'Reorder')
AND p.replenishable = true
GROUP BY p.product_id
ORDER BY ORDER BY
CASE pm.stock_status CASE pm.stock_status
WHEN 'Critical' THEN 1 WHEN 'Critical' THEN 1
WHEN 'Reorder' THEN 2 WHEN 'Reorder' THEN 2
ELSE 3
END, END,
pm.days_of_inventory ASC pm.days_of_inventory ASC
LIMIT 50 LIMIT ?
`); `, [limit]);
res.json(rows); res.json(rows);
} catch (error) { } catch (err) {
console.error('Error fetching low stock alerts:', error); console.error('Error fetching low stock products:', err);
res.status(500).json({ error: 'Failed to fetch low stock alerts' }); res.status(500).json({ error: 'Failed to fetch low stock products' });
} }
}); });
// Get vendor performance metrics // GET /dashboard/trending/products
router.get('/vendors/metrics', async (req, res) => { // Returns list of trending products based on recent sales velocity
const pool = req.app.locals.pool; router.get('/trending/products', async (req, res) => {
const days = parseInt(req.query.days) || 30;
const limit = parseInt(req.query.limit) || 20;
try { try {
console.log('Fetching vendor metrics...'); const [rows] = await executeQuery(`
const [rows] = await pool.query(` WITH recent_sales AS (
SELECT SELECT
vendor, o.product_id,
avg_lead_time_days, COUNT(DISTINCT o.order_number) as recent_orders,
on_time_delivery_rate, SUM(o.quantity) as recent_units,
order_fill_rate, SUM(o.price * o.quantity) as recent_revenue
total_orders, FROM orders o
total_late_orders, WHERE o.canceled = false
total_purchase_value, AND o.date >= DATE_SUB(CURDATE(), INTERVAL ? DAY)
avg_order_value GROUP BY o.product_id
FROM vendor_metrics )
ORDER BY on_time_delivery_rate DESC
`);
console.log('Found vendor metrics:', rows.length, 'rows');
console.log('First row sample:', rows[0]);
const mappedRows = rows.map(row => ({
...row,
avg_lead_time_days: parseFloat(row.avg_lead_time_days || 0),
on_time_delivery_rate: parseFloat(row.on_time_delivery_rate || 0),
order_fill_rate: parseFloat(row.order_fill_rate || 0),
total_purchase_value: parseFloat(row.total_purchase_value || 0),
avg_order_value: parseFloat(row.avg_order_value || 0)
}));
console.log('First mapped row sample:', mappedRows[0]);
res.json(mappedRows);
} catch (error) {
console.error('Error fetching vendor metrics:', error);
res.status(500).json({ error: 'Failed to fetch vendor metrics' });
}
});
// Get trending products
router.get('/products/trending', async (req, res) => {
const pool = req.app.locals.pool;
try {
// First check if we have any data
const [checkData] = await pool.query(`
SELECT COUNT(*) as count,
MAX(total_revenue) as max_revenue,
MAX(daily_sales_avg) as max_daily_sales,
COUNT(DISTINCT product_id) as products_with_metrics
FROM product_metrics
WHERE total_revenue > 0 OR daily_sales_avg > 0
`);
console.log('Product metrics stats:', checkData[0]);
if (checkData[0].count === 0) {
console.log('No products with metrics found');
return res.json([]);
}
// Get trending products
const [rows] = await pool.query(`
SELECT SELECT
p.product_id, p.product_id,
p.sku, p.SKU,
p.title, p.title,
COALESCE(pm.daily_sales_avg, 0) as daily_sales_avg, p.brand,
COALESCE(pm.weekly_sales_avg, 0) as weekly_sales_avg, p.vendor,
CASE p.stock_quantity,
WHEN pm.weekly_sales_avg > 0 AND pm.daily_sales_avg > 0 rs.recent_orders,
THEN ((pm.daily_sales_avg - pm.weekly_sales_avg) / pm.weekly_sales_avg) * 100 rs.recent_units,
ELSE 0 rs.recent_revenue,
END as growth_rate, pm.daily_sales_avg,
COALESCE(pm.total_revenue, 0) as total_revenue pm.stock_status,
FROM products p (rs.recent_units / ?) as daily_velocity,
INNER JOIN product_metrics pm ON p.product_id = pm.product_id ((rs.recent_units / ?) - pm.daily_sales_avg) / pm.daily_sales_avg * 100 as velocity_change,
WHERE (pm.total_revenue > 0 OR pm.daily_sales_avg > 0) GROUP_CONCAT(c.name) as categories
AND p.visible = true FROM recent_sales rs
ORDER BY growth_rate DESC JOIN products p ON rs.product_id = p.product_id
LIMIT 50 JOIN product_metrics pm ON p.product_id = pm.product_id
`); LEFT JOIN product_categories pc ON p.product_id = pc.product_id
LEFT JOIN categories c ON pc.category_id = c.id
console.log('Trending products:', rows); GROUP BY p.product_id
HAVING velocity_change > 0
ORDER BY velocity_change DESC
LIMIT ?
`, [days, days, days, limit]);
res.json(rows); res.json(rows);
} catch (error) { } catch (err) {
console.error('Error fetching trending products:', error); console.error('Error fetching trending products:', err);
res.status(500).json({ error: 'Failed to fetch trending products' }); res.status(500).json({ error: 'Failed to fetch trending products' });
} }
}); });
// GET /dashboard/vendor/performance
// Returns detailed vendor performance metrics
router.get('/vendor/performance', async (req, res) => {
try {
const [rows] = await executeQuery(`
WITH vendor_orders AS (
SELECT
po.vendor,
COUNT(DISTINCT po.po_id) as total_orders,
AVG(DATEDIFF(po.delivery_date, po.order_date)) as avg_lead_time,
AVG(CASE
WHEN po.status = 'completed'
THEN DATEDIFF(po.delivery_date, po.expected_date)
END) as avg_delay,
SUM(CASE
WHEN po.status = 'completed' AND po.delivery_date <= po.expected_date
THEN 1
ELSE 0
END) * 100.0 / COUNT(*) as on_time_delivery_rate,
AVG(po.fill_rate) as avg_fill_rate
FROM purchase_orders po
WHERE po.order_date >= DATE_SUB(CURDATE(), INTERVAL 180 DAY)
GROUP BY po.vendor
)
SELECT
v.*,
vo.total_orders,
vo.avg_lead_time,
vo.avg_delay,
vo.on_time_delivery_rate,
vo.avg_fill_rate,
vm.total_purchase_value,
vm.total_revenue,
vm.product_count,
vm.active_products
FROM vendors v
JOIN vendor_orders vo ON v.vendor = vo.vendor
JOIN vendor_metrics vm ON v.vendor = vm.vendor
ORDER BY vm.total_revenue DESC
`);
res.json(rows);
} catch (err) {
console.error('Error fetching vendor performance:', err);
res.status(500).json({ error: 'Failed to fetch vendor performance' });
}
});
// GET /dashboard/key-metrics
// Returns key business metrics and KPIs
router.get('/key-metrics', async (req, res) => {
const days = Math.max(1, Math.min(365, parseInt(req.query.days) || 30));
try {
const [rows] = await executeQuery(`
WITH inventory_summary AS (
SELECT
COUNT(*) as total_products,
SUM(p.stock_quantity * p.cost_price) as total_inventory_value,
AVG(pm.turnover_rate) as avg_turnover_rate,
COUNT(CASE WHEN pm.stock_status = 'Critical' THEN 1 END) as critical_stock_count,
COUNT(CASE WHEN pm.stock_status = 'Overstocked' THEN 1 END) as overstock_count
FROM products p
JOIN product_metrics pm ON p.product_id = pm.product_id
),
sales_summary AS (
SELECT
COUNT(DISTINCT order_number) as total_orders,
SUM(quantity) as total_units_sold,
SUM(price * quantity) as total_revenue,
AVG(price * quantity) as avg_order_value
FROM orders
WHERE canceled = false
AND date >= DATE_SUB(CURDATE(), INTERVAL ? DAY)
),
purchase_summary AS (
SELECT
COUNT(DISTINCT po_id) as total_pos,
SUM(ordered * cost_price) as total_po_value,
COUNT(CASE WHEN status = 'open' THEN 1 END) as open_pos
FROM purchase_orders
WHERE order_date >= DATE_SUB(CURDATE(), INTERVAL ? DAY)
)
SELECT
i.*,
s.*,
p.*
FROM inventory_summary i
CROSS JOIN sales_summary s
CROSS JOIN purchase_summary p
`, [days, days]);
res.json(rows[0]);
} catch (err) {
console.error('Error fetching key metrics:', err);
res.status(500).json({ error: 'Failed to fetch key metrics' });
}
});
// GET /dashboard/inventory-health
// Returns overall inventory health metrics
router.get('/inventory-health', async (req, res) => {
try {
const [rows] = await executeQuery(`
WITH stock_distribution AS (
SELECT
COUNT(*) as total_products,
SUM(CASE WHEN pm.stock_status = 'Healthy' THEN 1 ELSE 0 END) * 100.0 / COUNT(*) as healthy_stock_percent,
SUM(CASE WHEN pm.stock_status = 'Critical' THEN 1 ELSE 0 END) * 100.0 / COUNT(*) as critical_stock_percent,
SUM(CASE WHEN pm.stock_status = 'Reorder' THEN 1 ELSE 0 END) * 100.0 / COUNT(*) as reorder_stock_percent,
SUM(CASE WHEN pm.stock_status = 'Overstocked' THEN 1 ELSE 0 END) * 100.0 / COUNT(*) as overstock_percent,
AVG(pm.turnover_rate) as avg_turnover_rate,
AVG(pm.days_of_inventory) as avg_days_inventory
FROM products p
JOIN product_metrics pm ON p.product_id = pm.product_id
WHERE p.replenishable = true
),
value_distribution AS (
SELECT
SUM(p.stock_quantity * p.cost_price) as total_inventory_value,
SUM(CASE
WHEN pm.stock_status = 'Healthy'
THEN p.stock_quantity * p.cost_price
ELSE 0
END) * 100.0 / SUM(p.stock_quantity * p.cost_price) as healthy_value_percent,
SUM(CASE
WHEN pm.stock_status = 'Critical'
THEN p.stock_quantity * p.cost_price
ELSE 0
END) * 100.0 / SUM(p.stock_quantity * p.cost_price) as critical_value_percent,
SUM(CASE
WHEN pm.stock_status = 'Overstocked'
THEN p.stock_quantity * p.cost_price
ELSE 0
END) * 100.0 / SUM(p.stock_quantity * p.cost_price) as overstock_value_percent
FROM products p
JOIN product_metrics pm ON p.product_id = pm.product_id
),
category_health AS (
SELECT
c.name as category_name,
COUNT(*) as category_products,
SUM(CASE WHEN pm.stock_status = 'Healthy' THEN 1 ELSE 0 END) * 100.0 / COUNT(*) as category_healthy_percent,
AVG(pm.turnover_rate) as category_turnover_rate
FROM categories c
JOIN product_categories pc ON c.id = pc.category_id
JOIN products p ON pc.product_id = p.product_id
JOIN product_metrics pm ON p.product_id = pm.product_id
WHERE p.replenishable = true
GROUP BY c.id, c.name
)
SELECT
sd.*,
vd.*,
JSON_ARRAYAGG(
JSON_OBJECT(
'category', ch.category_name,
'products', ch.category_products,
'healthy_percent', ch.category_healthy_percent,
'turnover_rate', ch.category_turnover_rate
)
) as category_health
FROM stock_distribution sd
CROSS JOIN value_distribution vd
CROSS JOIN category_health ch
`);
res.json(rows[0]);
} catch (err) {
console.error('Error fetching inventory health:', err);
res.status(500).json({ error: 'Failed to fetch inventory health' });
}
});
module.exports = router; module.exports = router;

View File

@@ -1,23 +1 @@
/**
* Format a number as currency with the specified locale and currency code
* @param value - The number to format
* @param locale - The locale to use for formatting (defaults to 'en-US')
* @param currency - The currency code to use (defaults to 'USD')
* @returns Formatted currency string
*/
export function formatCurrency(
value: number | null | undefined,
locale: string = 'en-US',
currency: string = 'USD'
): string {
if (value === null || value === undefined) {
return '$0.00';
}
return new Intl.NumberFormat(locale, {
style: 'currency',
currency: currency,
minimumFractionDigits: 2,
maximumFractionDigits: 2,
}).format(value);
}