Add/update dashboard components
This commit is contained in:
@@ -6,27 +6,59 @@ router.get('/stats', async (req, res) => {
|
||||
const pool = req.app.locals.pool;
|
||||
try {
|
||||
const [stats] = await pool.query(`
|
||||
WITH OrderStats AS (
|
||||
SELECT
|
||||
COUNT(DISTINCT o.order_number) as total_orders,
|
||||
SUM(o.price * o.quantity) as total_revenue,
|
||||
AVG(subtotal) as average_order_value
|
||||
FROM orders o
|
||||
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
|
||||
COUNT(*) as totalProducts,
|
||||
COUNT(CASE WHEN stock_quantity <= 5 THEN 1 END) as lowStockProducts,
|
||||
COALESCE(
|
||||
(SELECT COUNT(DISTINCT order_number) FROM orders WHERE DATE(date) >= DATE_SUB(CURDATE(), INTERVAL 30 DAY) AND canceled = false),
|
||||
0
|
||||
) as totalOrders,
|
||||
COALESCE(
|
||||
(SELECT AVG(subtotal) FROM (
|
||||
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),
|
||||
0
|
||||
) as averageOrderValue
|
||||
FROM products
|
||||
WHERE visible = true
|
||||
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
|
||||
END as profit_margin
|
||||
FROM ProductStats ps
|
||||
CROSS JOIN OrderStats os
|
||||
CROSS JOIN ProfitStats prs
|
||||
`);
|
||||
res.json(stats[0]);
|
||||
res.json({
|
||||
...stats[0],
|
||||
averageOrderValue: parseFloat(stats[0].average_order_value) || 0,
|
||||
totalRevenue: parseFloat(stats[0].total_revenue) || 0,
|
||||
profitMargin: parseFloat(stats[0].profit_margin) || 0
|
||||
});
|
||||
} catch (error) {
|
||||
console.error('Error fetching dashboard stats:', error);
|
||||
res.status(500).json({ error: 'Failed to fetch dashboard stats' });
|
||||
@@ -126,4 +158,192 @@ router.get('/stock-levels', async (req, res) => {
|
||||
}
|
||||
});
|
||||
|
||||
// Get sales by category
|
||||
router.get('/sales-by-category', async (req, res) => {
|
||||
const pool = req.app.locals.pool;
|
||||
try {
|
||||
const [rows] = await pool.query(`
|
||||
SELECT
|
||||
p.categories as category,
|
||||
SUM(o.price * o.quantity) as total
|
||||
FROM orders o
|
||||
JOIN products p ON o.product_id = p.product_id
|
||||
WHERE o.canceled = false
|
||||
AND DATE(o.date) >= DATE_SUB(CURDATE(), INTERVAL 30 DAY)
|
||||
GROUP BY p.categories
|
||||
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 trending products
|
||||
router.get('/trending-products', async (req, res) => {
|
||||
const pool = req.app.locals.pool;
|
||||
try {
|
||||
const [rows] = await pool.query(`
|
||||
WITH CurrentSales AS (
|
||||
SELECT
|
||||
p.product_id,
|
||||
p.title,
|
||||
p.sku,
|
||||
p.stock_quantity,
|
||||
p.image,
|
||||
COALESCE(SUM(o.price * o.quantity), 0) as total_sales
|
||||
FROM products p
|
||||
LEFT JOIN orders o ON p.product_id = o.product_id
|
||||
AND o.canceled = false
|
||||
AND DATE(o.date) >= DATE_SUB(CURDATE(), INTERVAL 30 DAY)
|
||||
WHERE p.visible = true
|
||||
GROUP BY p.product_id, p.title, p.sku, p.stock_quantity, p.image
|
||||
HAVING total_sales > 0
|
||||
),
|
||||
PreviousSales AS (
|
||||
SELECT
|
||||
p.product_id,
|
||||
COALESCE(SUM(o.price * o.quantity), 0) as previous_sales
|
||||
FROM products p
|
||||
LEFT JOIN orders o ON p.product_id = o.product_id
|
||||
AND o.canceled = false
|
||||
AND DATE(o.date) BETWEEN DATE_SUB(CURDATE(), INTERVAL 60 DAY) AND DATE_SUB(CURDATE(), INTERVAL 30 DAY)
|
||||
WHERE p.visible = true
|
||||
GROUP BY p.product_id
|
||||
)
|
||||
SELECT
|
||||
cs.*,
|
||||
CASE
|
||||
WHEN COALESCE(ps.previous_sales, 0) = 0 THEN
|
||||
CASE WHEN cs.total_sales > 0 THEN 100 ELSE 0 END
|
||||
ELSE ((cs.total_sales - ps.previous_sales) / ps.previous_sales * 100)
|
||||
END as sales_growth
|
||||
FROM CurrentSales cs
|
||||
LEFT JOIN PreviousSales ps ON cs.product_id = ps.product_id
|
||||
ORDER BY cs.total_sales DESC
|
||||
LIMIT 5
|
||||
`);
|
||||
|
||||
console.log('Trending products query result:', rows);
|
||||
|
||||
res.json(rows.map(row => ({
|
||||
product_id: row.product_id,
|
||||
title: row.title,
|
||||
sku: row.sku,
|
||||
total_sales: parseFloat(row.total_sales || 0),
|
||||
sales_growth: parseFloat(row.sales_growth || 0),
|
||||
stock_quantity: parseInt(row.stock_quantity || 0),
|
||||
image_url: row.image || null
|
||||
})));
|
||||
} catch (error) {
|
||||
console.error('Error in trending products:', {
|
||||
message: error.message,
|
||||
stack: error.stack,
|
||||
code: error.code,
|
||||
sqlState: error.sqlState,
|
||||
sqlMessage: error.sqlMessage
|
||||
});
|
||||
res.status(500).json({
|
||||
error: 'Failed to fetch trending products',
|
||||
details: error.message
|
||||
});
|
||||
}
|
||||
});
|
||||
|
||||
// Get inventory metrics
|
||||
router.get('/inventory-metrics', async (req, res) => {
|
||||
const pool = req.app.locals.pool;
|
||||
try {
|
||||
// Get stock levels by category
|
||||
const [stockLevels] = await pool.query(`
|
||||
SELECT
|
||||
categories as category,
|
||||
SUM(CASE WHEN stock_quantity > 5 THEN 1 ELSE 0 END) as inStock,
|
||||
SUM(CASE WHEN stock_quantity > 0 AND stock_quantity <= 5 THEN 1 ELSE 0 END) as lowStock,
|
||||
SUM(CASE WHEN stock_quantity = 0 THEN 1 ELSE 0 END) as outOfStock
|
||||
FROM products
|
||||
WHERE visible = true
|
||||
GROUP BY categories
|
||||
ORDER BY categories ASC
|
||||
`);
|
||||
|
||||
// Get top vendors with product counts and average stock
|
||||
const [topVendors] = await pool.query(`
|
||||
SELECT
|
||||
vendor,
|
||||
COUNT(*) as productCount,
|
||||
AVG(stock_quantity) as averageStockLevel
|
||||
FROM products
|
||||
WHERE visible = true
|
||||
AND vendor IS NOT NULL
|
||||
AND vendor != ''
|
||||
GROUP BY vendor
|
||||
ORDER BY productCount DESC
|
||||
LIMIT 5
|
||||
`);
|
||||
|
||||
// Calculate stock turnover rate by category
|
||||
// Turnover = Units sold in last 30 days / Average inventory level
|
||||
const [stockTurnover] = await pool.query(`
|
||||
WITH CategorySales AS (
|
||||
SELECT
|
||||
p.categories as category,
|
||||
SUM(o.quantity) as units_sold
|
||||
FROM products p
|
||||
LEFT JOIN orders o ON p.product_id = o.product_id
|
||||
WHERE o.canceled = false
|
||||
AND DATE(o.date) >= DATE_SUB(CURDATE(), INTERVAL 30 DAY)
|
||||
GROUP BY p.categories
|
||||
),
|
||||
CategoryStock AS (
|
||||
SELECT
|
||||
categories as category,
|
||||
AVG(stock_quantity) as avg_stock
|
||||
FROM products
|
||||
WHERE visible = true
|
||||
GROUP BY categories
|
||||
)
|
||||
SELECT
|
||||
cs.category,
|
||||
CASE
|
||||
WHEN cst.avg_stock > 0 THEN (cs.units_sold / cst.avg_stock)
|
||||
ELSE 0
|
||||
END as rate
|
||||
FROM CategorySales cs
|
||||
JOIN CategoryStock cst ON cs.category = cst.category
|
||||
ORDER BY rate DESC
|
||||
`);
|
||||
|
||||
res.json({
|
||||
stockLevels: stockLevels.map(row => ({
|
||||
...row,
|
||||
inStock: parseInt(row.inStock || 0),
|
||||
lowStock: parseInt(row.lowStock || 0),
|
||||
outOfStock: parseInt(row.outOfStock || 0)
|
||||
})),
|
||||
topVendors: topVendors.map(row => ({
|
||||
vendor: row.vendor,
|
||||
productCount: parseInt(row.productCount || 0),
|
||||
averageStockLevel: parseFloat(row.averageStockLevel || 0)
|
||||
})),
|
||||
stockTurnover: stockTurnover.map(row => ({
|
||||
category: row.category,
|
||||
rate: parseFloat(row.rate || 0)
|
||||
}))
|
||||
});
|
||||
} catch (error) {
|
||||
console.error('Error fetching inventory metrics:', error);
|
||||
res.status(500).json({ error: 'Failed to fetch inventory metrics' });
|
||||
}
|
||||
});
|
||||
|
||||
module.exports = router;
|
||||
Reference in New Issue
Block a user