374 lines
11 KiB
JavaScript
374 lines
11 KiB
JavaScript
const express = require('express');
|
|
const router = express.Router();
|
|
|
|
// Get dashboard stats
|
|
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
|
|
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],
|
|
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' });
|
|
}
|
|
});
|
|
|
|
// Get sales overview data
|
|
router.get('/sales-overview', async (req, res) => {
|
|
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);
|
|
} catch (error) {
|
|
console.error('Error fetching category stats:', error);
|
|
res.status(500).json({ error: 'Failed to fetch category stats' });
|
|
}
|
|
});
|
|
|
|
// Get stock levels
|
|
router.get('/stock-levels', async (req, res) => {
|
|
const pool = req.app.locals.pool;
|
|
try {
|
|
const [rows] = await pool.query(`
|
|
SELECT
|
|
SUM(CASE WHEN stock_quantity = 0 THEN 1 ELSE 0 END) as outOfStock,
|
|
SUM(CASE WHEN stock_quantity > 0 AND stock_quantity <= 5 THEN 1 ELSE 0 END) as lowStock,
|
|
SUM(CASE WHEN stock_quantity > 5 AND stock_quantity <= 20 THEN 1 ELSE 0 END) as inStock,
|
|
SUM(CASE WHEN stock_quantity > 20 THEN 1 ELSE 0 END) as overStock
|
|
FROM products
|
|
WHERE visible = true
|
|
`);
|
|
res.json(rows[0]);
|
|
} catch (error) {
|
|
console.error('Error fetching stock levels:', error);
|
|
res.status(500).json({ error: 'Failed to fetch stock levels' });
|
|
}
|
|
});
|
|
|
|
// 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
|
|
c.name as category,
|
|
SUM(o.price * o.quantity) as total
|
|
FROM orders o
|
|
JOIN products p ON o.product_id = p.product_id
|
|
JOIN product_categories pc ON p.product_id = pc.product_id
|
|
JOIN categories c ON pc.category_id = c.id
|
|
WHERE o.canceled = false
|
|
AND DATE(o.date) >= DATE_SUB(CURDATE(), INTERVAL 30 DAY)
|
|
GROUP BY 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
|
|
status as stock_status,
|
|
COUNT(*) as count
|
|
FROM normalized_status
|
|
GROUP BY status
|
|
`);
|
|
|
|
console.log('Raw inventory health summary:', rows);
|
|
|
|
// Convert array to object with lowercase keys
|
|
const summary = {
|
|
critical: 0,
|
|
reorder: 0,
|
|
healthy: 0,
|
|
overstock: 0
|
|
};
|
|
|
|
rows.forEach(row => {
|
|
const key = row.stock_status.toLowerCase();
|
|
if (key in summary) {
|
|
summary[key] = parseInt(row.count);
|
|
}
|
|
});
|
|
|
|
// Calculate total
|
|
summary.total = Object.values(summary).reduce((a, b) => a + b, 0);
|
|
|
|
console.log('Final inventory health summary:', summary);
|
|
res.json(summary);
|
|
} catch (error) {
|
|
console.error('Error fetching inventory health summary:', error);
|
|
res.status(500).json({ error: 'Failed to fetch inventory health summary' });
|
|
}
|
|
});
|
|
|
|
// Get low stock alerts
|
|
router.get('/inventory/low-stock', async (req, res) => {
|
|
const pool = req.app.locals.pool;
|
|
try {
|
|
const [rows] = await pool.query(`
|
|
SELECT
|
|
p.product_id,
|
|
p.sku,
|
|
p.title,
|
|
p.stock_quantity,
|
|
pm.reorder_point,
|
|
pm.days_of_inventory,
|
|
pm.daily_sales_avg,
|
|
pm.stock_status
|
|
FROM product_metrics pm
|
|
JOIN products p ON pm.product_id = p.product_id
|
|
WHERE pm.stock_status IN ('Critical', 'Reorder')
|
|
ORDER BY
|
|
CASE pm.stock_status
|
|
WHEN 'Critical' THEN 1
|
|
WHEN 'Reorder' THEN 2
|
|
ELSE 3
|
|
END,
|
|
pm.days_of_inventory ASC
|
|
LIMIT 50
|
|
`);
|
|
res.json(rows);
|
|
} catch (error) {
|
|
console.error('Error fetching low stock alerts:', error);
|
|
res.status(500).json({ error: 'Failed to fetch low stock alerts' });
|
|
}
|
|
});
|
|
|
|
// Get vendor performance metrics
|
|
router.get('/vendors/metrics', async (req, res) => {
|
|
const pool = req.app.locals.pool;
|
|
try {
|
|
console.log('Fetching vendor metrics...');
|
|
const [rows] = await pool.query(`
|
|
SELECT
|
|
vendor,
|
|
avg_lead_time_days,
|
|
on_time_delivery_rate,
|
|
order_fill_rate,
|
|
total_orders,
|
|
total_late_orders,
|
|
total_purchase_value,
|
|
avg_order_value
|
|
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
|
|
p.product_id,
|
|
p.sku,
|
|
p.title,
|
|
COALESCE(pm.daily_sales_avg, 0) as daily_sales_avg,
|
|
COALESCE(pm.weekly_sales_avg, 0) as weekly_sales_avg,
|
|
CASE
|
|
WHEN pm.weekly_sales_avg > 0 AND pm.daily_sales_avg > 0
|
|
THEN ((pm.daily_sales_avg - pm.weekly_sales_avg) / pm.weekly_sales_avg) * 100
|
|
ELSE 0
|
|
END as growth_rate,
|
|
COALESCE(pm.total_revenue, 0) as total_revenue
|
|
FROM products p
|
|
INNER JOIN product_metrics pm ON p.product_id = pm.product_id
|
|
WHERE (pm.total_revenue > 0 OR pm.daily_sales_avg > 0)
|
|
AND p.visible = true
|
|
ORDER BY growth_rate DESC
|
|
LIMIT 50
|
|
`);
|
|
|
|
console.log('Trending products:', rows);
|
|
res.json(rows);
|
|
} catch (error) {
|
|
console.error('Error fetching trending products:', error);
|
|
res.status(500).json({ error: 'Failed to fetch trending products' });
|
|
}
|
|
});
|
|
|
|
module.exports = router;
|