933 lines
38 KiB
JavaScript
933 lines
38 KiB
JavaScript
const express = require('express');
|
|
const router = express.Router();
|
|
const db = require('../utils/db');
|
|
|
|
// Import status codes
|
|
const { ReceivingStatus } = require('../types/status-codes');
|
|
|
|
// Helper function to execute queries using the connection pool
|
|
async function executeQuery(sql, params = []) {
|
|
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 {
|
|
// Get stock metrics
|
|
const { rows: [stockMetrics] } = await executeQuery(`
|
|
SELECT
|
|
COALESCE(COUNT(*), 0)::integer as total_products,
|
|
COALESCE(COUNT(CASE WHEN stock_quantity > 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,
|
|
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 stock_quantity > 0 THEN stock_quantity * price END), 0)::numeric, 3) as total_retail
|
|
FROM products
|
|
`);
|
|
|
|
console.log('Raw stockMetrics from database:', stockMetrics);
|
|
console.log('stockMetrics.total_products:', stockMetrics.total_products);
|
|
console.log('stockMetrics.products_in_stock:', stockMetrics.products_in_stock);
|
|
console.log('stockMetrics.total_units:', stockMetrics.total_units);
|
|
console.log('stockMetrics.total_cost:', stockMetrics.total_cost);
|
|
console.log('stockMetrics.total_retail:', stockMetrics.total_retail);
|
|
|
|
// Get brand stock values with Other category
|
|
const { rows: brandValues } = await executeQuery(`
|
|
WITH brand_totals AS (
|
|
SELECT
|
|
COALESCE(brand, 'Unbranded') as brand,
|
|
COUNT(DISTINCT pid)::integer as variant_count,
|
|
COALESCE(SUM(stock_quantity), 0)::integer as stock_units,
|
|
ROUND(COALESCE(SUM(stock_quantity * cost_price), 0)::numeric, 3) as stock_cost,
|
|
ROUND(COALESCE(SUM(stock_quantity * price), 0)::numeric, 3) as stock_retail
|
|
FROM products
|
|
WHERE stock_quantity > 0
|
|
GROUP BY COALESCE(brand, 'Unbranded')
|
|
HAVING ROUND(COALESCE(SUM(stock_quantity * cost_price), 0)::numeric, 3) > 0
|
|
),
|
|
other_brands AS (
|
|
SELECT
|
|
'Other' as brand,
|
|
SUM(variant_count)::integer as variant_count,
|
|
SUM(stock_units)::integer as stock_units,
|
|
ROUND(SUM(stock_cost)::numeric, 3) as stock_cost,
|
|
ROUND(SUM(stock_retail)::numeric, 3) as stock_retail
|
|
FROM brand_totals
|
|
WHERE stock_cost <= 5000
|
|
),
|
|
main_brands AS (
|
|
SELECT *
|
|
FROM brand_totals
|
|
WHERE stock_cost > 5000
|
|
ORDER BY stock_cost DESC
|
|
)
|
|
SELECT * FROM main_brands
|
|
UNION ALL
|
|
SELECT * FROM other_brands
|
|
WHERE stock_cost > 0
|
|
ORDER BY CASE WHEN brand = 'Other' THEN 1 ELSE 0 END, stock_cost DESC
|
|
`);
|
|
|
|
// Format the response with explicit type conversion
|
|
const response = {
|
|
totalProducts: parseInt(stockMetrics.total_products) || 0,
|
|
productsInStock: parseInt(stockMetrics.products_in_stock) || 0,
|
|
totalStockUnits: parseInt(stockMetrics.total_units) || 0,
|
|
totalStockCost: parseFloat(stockMetrics.total_cost) || 0,
|
|
totalStockRetail: parseFloat(stockMetrics.total_retail) || 0,
|
|
brandStock: brandValues.map(v => ({
|
|
brand: v.brand,
|
|
variants: parseInt(v.variant_count) || 0,
|
|
units: parseInt(v.stock_units) || 0,
|
|
cost: parseFloat(v.stock_cost) || 0,
|
|
retail: parseFloat(v.stock_retail) || 0
|
|
}))
|
|
};
|
|
|
|
res.json(response);
|
|
} catch (err) {
|
|
console.error('Error fetching stock metrics:', err);
|
|
res.status(500).json({ error: 'Failed to fetch stock metrics' });
|
|
}
|
|
});
|
|
|
|
// GET /dashboard/purchase/metrics
|
|
// Returns purchase order metrics by vendor
|
|
router.get('/purchase/metrics', async (req, res) => {
|
|
try {
|
|
const { rows: [poMetrics] } = await executeQuery(`
|
|
SELECT
|
|
COALESCE(COUNT(DISTINCT CASE
|
|
WHEN po.receiving_status < $1
|
|
THEN po.po_id
|
|
END), 0)::integer as active_pos,
|
|
COALESCE(COUNT(DISTINCT CASE
|
|
WHEN po.receiving_status < $1
|
|
AND po.expected_date < CURRENT_DATE
|
|
THEN po.po_id
|
|
END), 0)::integer as overdue_pos,
|
|
COALESCE(SUM(CASE
|
|
WHEN po.receiving_status < $1
|
|
THEN po.ordered
|
|
ELSE 0
|
|
END), 0)::integer as total_units,
|
|
ROUND(COALESCE(SUM(CASE
|
|
WHEN po.receiving_status < $1
|
|
THEN po.ordered * po.cost_price
|
|
ELSE 0
|
|
END), 0)::numeric, 3) as total_cost,
|
|
ROUND(COALESCE(SUM(CASE
|
|
WHEN po.receiving_status < $1
|
|
THEN po.ordered * p.price
|
|
ELSE 0
|
|
END), 0)::numeric, 3) as total_retail
|
|
FROM purchase_orders po
|
|
JOIN products p ON po.pid = p.pid
|
|
`, [ReceivingStatus.PartialReceived]);
|
|
|
|
const { rows: vendorOrders } = await executeQuery(`
|
|
SELECT
|
|
po.vendor,
|
|
COUNT(DISTINCT po.po_id)::integer as orders,
|
|
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 * p.price), 0)::numeric, 3) as retail
|
|
FROM purchase_orders po
|
|
JOIN products p ON po.pid = p.pid
|
|
WHERE po.receiving_status < $1
|
|
GROUP BY po.vendor
|
|
HAVING ROUND(COALESCE(SUM(po.ordered * po.cost_price), 0)::numeric, 3) > 0
|
|
ORDER BY cost DESC
|
|
`, [ReceivingStatus.PartialReceived]);
|
|
|
|
// Format response to match PurchaseMetricsData interface
|
|
const response = {
|
|
activePurchaseOrders: parseInt(poMetrics.active_pos) || 0,
|
|
overduePurchaseOrders: parseInt(poMetrics.overdue_pos) || 0,
|
|
onOrderUnits: parseInt(poMetrics.total_units) || 0,
|
|
onOrderCost: parseFloat(poMetrics.total_cost) || 0,
|
|
onOrderRetail: parseFloat(poMetrics.total_retail) || 0,
|
|
vendorOrders: vendorOrders.map(v => ({
|
|
vendor: v.vendor,
|
|
orders: parseInt(v.orders) || 0,
|
|
units: parseInt(v.units) || 0,
|
|
cost: parseFloat(v.cost) || 0,
|
|
retail: parseFloat(v.retail) || 0
|
|
}))
|
|
};
|
|
|
|
res.json(response);
|
|
} catch (err) {
|
|
console.error('Error fetching purchase metrics:', err);
|
|
res.status(500).json({ error: 'Failed to fetch purchase metrics' });
|
|
}
|
|
});
|
|
|
|
// GET /dashboard/replenishment/metrics
|
|
// Returns replenishment needs by category
|
|
router.get('/replenishment/metrics', async (req, res) => {
|
|
try {
|
|
// Get summary metrics
|
|
const { rows: [metrics] } = await executeQuery(`
|
|
SELECT
|
|
COUNT(DISTINCT p.pid)::integer as products_to_replenish,
|
|
COALESCE(SUM(CASE
|
|
WHEN p.stock_quantity < 0 THEN ABS(p.stock_quantity) + pm.reorder_qty
|
|
ELSE pm.reorder_qty
|
|
END), 0)::integer as total_units_needed,
|
|
ROUND(COALESCE(SUM(CASE
|
|
WHEN p.stock_quantity < 0 THEN (ABS(p.stock_quantity) + pm.reorder_qty) * p.cost_price
|
|
ELSE pm.reorder_qty * p.cost_price
|
|
END), 0)::numeric, 3) as total_cost,
|
|
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
|
|
const { rows: variants } = await executeQuery(`
|
|
SELECT
|
|
p.pid,
|
|
p.title,
|
|
p.stock_quantity::integer as current_stock,
|
|
CASE
|
|
WHEN p.stock_quantity < 0 THEN ABS(p.stock_quantity) + pm.reorder_qty
|
|
ELSE pm.reorder_qty
|
|
END::integer as replenish_qty,
|
|
ROUND(CASE
|
|
WHEN p.stock_quantity < 0 THEN (ABS(p.stock_quantity) + pm.reorder_qty) * p.cost_price
|
|
ELSE pm.reorder_qty * p.cost_price
|
|
END::numeric, 3) as replenish_cost,
|
|
ROUND(CASE
|
|
WHEN p.stock_quantity < 0 THEN (ABS(p.stock_quantity) + pm.reorder_qty) * p.price
|
|
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
|
|
CASE pm.stock_status
|
|
WHEN 'Critical' THEN 1
|
|
WHEN 'Reorder' THEN 2
|
|
END,
|
|
replenish_cost DESC
|
|
LIMIT 5
|
|
`);
|
|
|
|
// Format response
|
|
const response = {
|
|
productsToReplenish: parseInt(metrics.products_to_replenish) || 0,
|
|
unitsToReplenish: parseInt(metrics.total_units_needed) || 0,
|
|
replenishmentCost: parseFloat(metrics.total_cost) || 0,
|
|
replenishmentRetail: parseFloat(metrics.total_retail) || 0,
|
|
topVariants: variants.map(v => ({
|
|
id: v.pid,
|
|
title: v.title,
|
|
currentStock: parseInt(v.current_stock) || 0,
|
|
replenishQty: parseInt(v.replenish_qty) || 0,
|
|
replenishCost: parseFloat(v.replenish_cost) || 0,
|
|
replenishRetail: parseFloat(v.replenish_retail) || 0,
|
|
status: v.stock_status
|
|
}))
|
|
};
|
|
|
|
res.json(response);
|
|
} 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 { startDate, endDate } = req.query;
|
|
try {
|
|
// Get summary metrics
|
|
const [metrics] = await executeQuery(`
|
|
SELECT
|
|
COALESCE(SUM(forecast_units), 0) as total_forecast_units,
|
|
COALESCE(SUM(forecast_revenue), 0) as total_forecast_revenue,
|
|
COALESCE(AVG(confidence_level), 0) as overall_confidence
|
|
FROM sales_forecasts
|
|
WHERE forecast_date BETWEEN ? AND ?
|
|
`, [startDate, endDate]);
|
|
|
|
// Get daily forecasts
|
|
const [dailyForecasts] = await executeQuery(`
|
|
SELECT
|
|
DATE(forecast_date) as date,
|
|
COALESCE(SUM(forecast_revenue), 0) as revenue,
|
|
COALESCE(AVG(confidence_level), 0) as confidence
|
|
FROM sales_forecasts
|
|
WHERE forecast_date BETWEEN ? AND ?
|
|
GROUP BY DATE(forecast_date)
|
|
ORDER BY date
|
|
`, [startDate, endDate]);
|
|
|
|
// Get category forecasts
|
|
const [categoryForecasts] = await executeQuery(`
|
|
SELECT
|
|
c.name as category,
|
|
COALESCE(SUM(cf.forecast_units), 0) as units,
|
|
COALESCE(SUM(cf.forecast_revenue), 0) as revenue,
|
|
COALESCE(AVG(cf.confidence_level), 0) as confidence
|
|
FROM category_forecasts cf
|
|
JOIN categories c ON cf.category_id = c.cat_id
|
|
WHERE cf.forecast_date BETWEEN ? AND ?
|
|
GROUP BY c.cat_id, c.name
|
|
ORDER BY revenue DESC
|
|
`, [startDate, endDate]);
|
|
|
|
// Format response
|
|
const response = {
|
|
forecastSales: parseInt(metrics[0].total_forecast_units) || 0,
|
|
forecastRevenue: parseFloat(metrics[0].total_forecast_revenue) || 0,
|
|
confidenceLevel: parseFloat(metrics[0].overall_confidence) || 0,
|
|
dailyForecasts: dailyForecasts.map(d => ({
|
|
date: d.date,
|
|
revenue: parseFloat(d.revenue) || 0,
|
|
confidence: parseFloat(d.confidence) || 0
|
|
})),
|
|
categoryForecasts: categoryForecasts.map(c => ({
|
|
category: c.category,
|
|
units: parseInt(c.units) || 0,
|
|
revenue: parseFloat(c.revenue) || 0,
|
|
confidence: parseFloat(c.confidence) || 0
|
|
}))
|
|
};
|
|
|
|
res.json(response);
|
|
} 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.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
|
|
)
|
|
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,
|
|
CONCAT('[', GROUP_CONCAT(
|
|
JSON_OBJECT(
|
|
'category', category_name,
|
|
'products', overstocked_products,
|
|
'units', total_excess_units,
|
|
'cost', total_excess_cost,
|
|
'retail', total_excess_retail
|
|
)
|
|
), ']') as category_data
|
|
FROM (
|
|
SELECT *
|
|
FROM category_overstock
|
|
WHERE overstocked_products > 0
|
|
ORDER BY total_excess_cost DESC
|
|
LIMIT 8
|
|
) filtered_categories
|
|
`);
|
|
|
|
// Format response with explicit type conversion
|
|
const response = {
|
|
overstockedProducts: parseInt(rows[0].total_overstocked) || 0,
|
|
total_excess_units: parseInt(rows[0].total_excess_units) || 0,
|
|
total_excess_cost: parseFloat(rows[0].total_excess_cost) || 0,
|
|
total_excess_retail: parseFloat(rows[0].total_excess_retail) || 0,
|
|
category_data: rows[0].category_data ?
|
|
JSON.parse(rows[0].category_data).map(obj => ({
|
|
category: obj.category,
|
|
products: parseInt(obj.products) || 0,
|
|
units: parseInt(obj.units) || 0,
|
|
cost: parseFloat(obj.cost) || 0,
|
|
retail: parseFloat(obj.retail) || 0
|
|
})) : []
|
|
};
|
|
|
|
res.json(response);
|
|
} 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.pid,
|
|
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.pid = pm.pid
|
|
LEFT JOIN product_categories pc ON p.pid = pc.pid
|
|
LEFT JOIN categories c ON pc.cat_id = c.cat_id
|
|
WHERE pm.stock_status = 'Overstocked'
|
|
GROUP BY p.pid
|
|
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 pool = req.app.locals.pool;
|
|
|
|
// Common CTE for category paths
|
|
const categoryPathCTE = `
|
|
WITH RECURSIVE category_path AS (
|
|
SELECT
|
|
c.cat_id,
|
|
c.name,
|
|
c.parent_id,
|
|
CAST(c.name AS CHAR(1000)) as path
|
|
FROM categories c
|
|
WHERE c.parent_id IS NULL
|
|
|
|
UNION ALL
|
|
|
|
SELECT
|
|
c.cat_id,
|
|
c.name,
|
|
c.parent_id,
|
|
CONCAT(cp.path, ' > ', c.name)
|
|
FROM categories c
|
|
JOIN category_path cp ON c.parent_id = cp.cat_id
|
|
)
|
|
`;
|
|
|
|
// Get best selling products
|
|
const [products] = await pool.query(`
|
|
SELECT
|
|
p.pid,
|
|
p.SKU as sku,
|
|
p.title,
|
|
SUM(o.quantity) as units_sold,
|
|
CAST(SUM(o.price * o.quantity) AS DECIMAL(15,3)) as revenue,
|
|
CAST(SUM(o.price * o.quantity - p.cost_price * o.quantity) AS DECIMAL(15,3)) as profit
|
|
FROM products p
|
|
JOIN orders o ON p.pid = o.pid
|
|
WHERE o.date >= DATE_SUB(CURDATE(), INTERVAL 30 DAY)
|
|
AND o.canceled = false
|
|
GROUP BY p.pid
|
|
ORDER BY units_sold DESC
|
|
LIMIT 10
|
|
`);
|
|
|
|
// Get best selling brands
|
|
const [brands] = await pool.query(`
|
|
SELECT
|
|
p.brand,
|
|
SUM(o.quantity) as units_sold,
|
|
CAST(SUM(o.price * o.quantity) AS DECIMAL(15,3)) as revenue,
|
|
CAST(SUM(o.price * o.quantity - p.cost_price * o.quantity) AS DECIMAL(15,3)) as profit,
|
|
ROUND(
|
|
((SUM(CASE
|
|
WHEN o.date >= DATE_SUB(CURDATE(), INTERVAL 30 DAY)
|
|
THEN o.price * o.quantity
|
|
ELSE 0
|
|
END) /
|
|
NULLIF(SUM(CASE
|
|
WHEN o.date >= DATE_SUB(CURDATE(), INTERVAL 60 DAY)
|
|
AND o.date < DATE_SUB(CURDATE(), INTERVAL 30 DAY)
|
|
THEN o.price * o.quantity
|
|
ELSE 0
|
|
END), 0)) - 1) * 100,
|
|
1
|
|
) as growth_rate
|
|
FROM products p
|
|
JOIN orders o ON p.pid = o.pid
|
|
WHERE o.date >= DATE_SUB(CURDATE(), INTERVAL 60 DAY)
|
|
AND o.canceled = false
|
|
GROUP BY p.brand
|
|
ORDER BY units_sold DESC
|
|
LIMIT 10
|
|
`);
|
|
|
|
// Get best selling categories with full path
|
|
const [categories] = await pool.query(`
|
|
${categoryPathCTE}
|
|
SELECT
|
|
c.cat_id,
|
|
c.name,
|
|
cp.path as categoryPath,
|
|
SUM(o.quantity) as units_sold,
|
|
CAST(SUM(o.price * o.quantity) AS DECIMAL(15,3)) as revenue,
|
|
CAST(SUM(o.price * o.quantity - p.cost_price * o.quantity) AS DECIMAL(15,3)) as profit,
|
|
ROUND(
|
|
((SUM(CASE
|
|
WHEN o.date >= DATE_SUB(CURDATE(), INTERVAL 30 DAY)
|
|
THEN o.price * o.quantity
|
|
ELSE 0
|
|
END) /
|
|
NULLIF(SUM(CASE
|
|
WHEN o.date >= DATE_SUB(CURDATE(), INTERVAL 60 DAY)
|
|
AND o.date < DATE_SUB(CURDATE(), INTERVAL 30 DAY)
|
|
THEN o.price * o.quantity
|
|
ELSE 0
|
|
END), 0)) - 1) * 100,
|
|
1
|
|
) as growth_rate
|
|
FROM products p
|
|
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 >= DATE_SUB(CURDATE(), INTERVAL 60 DAY)
|
|
AND o.canceled = false
|
|
GROUP BY c.cat_id, c.name, cp.path
|
|
ORDER BY units_sold DESC
|
|
LIMIT 10
|
|
`);
|
|
|
|
res.json({ products, brands, 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 { startDate, endDate } = req.query;
|
|
try {
|
|
// Get daily sales data
|
|
const [dailyRows] = await executeQuery(`
|
|
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.pid = p.pid
|
|
WHERE o.canceled = false
|
|
AND o.date BETWEEN ? AND ?
|
|
GROUP BY DATE(o.date)
|
|
ORDER BY sale_date
|
|
`, [startDate, endDate]);
|
|
|
|
// Get summary metrics
|
|
const [metrics] = await executeQuery(`
|
|
SELECT
|
|
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.pid = p.pid
|
|
WHERE o.canceled = false
|
|
AND o.date BETWEEN ? AND ?
|
|
`, [startDate, endDate]);
|
|
|
|
const response = {
|
|
totalOrders: parseInt(metrics[0]?.total_orders) || 0,
|
|
totalUnitsSold: parseInt(metrics[0]?.total_units) || 0,
|
|
totalCogs: parseFloat(metrics[0]?.total_cogs) || 0,
|
|
totalRevenue: parseFloat(metrics[0]?.total_revenue) || 0,
|
|
dailySales: dailyRows.map(day => ({
|
|
date: day.sale_date,
|
|
units: parseInt(day.total_units) || 0,
|
|
revenue: parseFloat(day.total_revenue) || 0,
|
|
cogs: parseFloat(day.total_cogs) || 0
|
|
}))
|
|
};
|
|
|
|
res.json(response);
|
|
} catch (err) {
|
|
console.error('Error fetching sales metrics:', err);
|
|
res.status(500).json({ error: 'Failed to fetch sales metrics' });
|
|
}
|
|
});
|
|
|
|
// GET /dashboard/low-stock/products
|
|
// Returns list of products with critical or low stock levels
|
|
router.get('/low-stock/products', async (req, res) => {
|
|
const limit = parseInt(req.query.limit) || 50;
|
|
try {
|
|
const [rows] = await executeQuery(`
|
|
SELECT
|
|
p.pid,
|
|
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.reorder_qty,
|
|
(pm.reorder_qty * p.cost_price) as reorder_cost,
|
|
GROUP_CONCAT(c.name) as categories
|
|
FROM products p
|
|
JOIN product_metrics pm ON p.pid = pm.pid
|
|
LEFT JOIN product_categories pc ON p.pid = pc.pid
|
|
LEFT JOIN categories c ON pc.cat_id = c.cat_id
|
|
WHERE pm.stock_status IN ('Critical', 'Reorder')
|
|
AND p.replenishable = true
|
|
GROUP BY p.pid
|
|
ORDER BY
|
|
CASE pm.stock_status
|
|
WHEN 'Critical' THEN 1
|
|
WHEN 'Reorder' THEN 2
|
|
END,
|
|
pm.days_of_inventory ASC
|
|
LIMIT ?
|
|
`, [limit]);
|
|
res.json(rows);
|
|
} catch (err) {
|
|
console.error('Error fetching low stock products:', err);
|
|
res.status(500).json({ error: 'Failed to fetch low stock products' });
|
|
}
|
|
});
|
|
|
|
// GET /dashboard/trending/products
|
|
// Returns list of trending products based on recent sales velocity
|
|
router.get('/trending/products', async (req, res) => {
|
|
const days = parseInt(req.query.days) || 30;
|
|
const limit = parseInt(req.query.limit) || 20;
|
|
try {
|
|
const [rows] = await executeQuery(`
|
|
WITH recent_sales AS (
|
|
SELECT
|
|
o.pid,
|
|
COUNT(DISTINCT o.order_number) as recent_orders,
|
|
SUM(o.quantity) as recent_units,
|
|
SUM(o.price * o.quantity) as recent_revenue
|
|
FROM orders o
|
|
WHERE o.canceled = false
|
|
AND o.date >= DATE_SUB(CURDATE(), INTERVAL ? DAY)
|
|
GROUP BY o.pid
|
|
)
|
|
SELECT
|
|
p.pid,
|
|
p.SKU,
|
|
p.title,
|
|
p.brand,
|
|
p.vendor,
|
|
p.stock_quantity,
|
|
rs.recent_orders,
|
|
rs.recent_units,
|
|
rs.recent_revenue,
|
|
pm.daily_sales_avg,
|
|
pm.stock_status,
|
|
(rs.recent_units / ?) as daily_velocity,
|
|
((rs.recent_units / ?) - pm.daily_sales_avg) / pm.daily_sales_avg * 100 as velocity_change,
|
|
GROUP_CONCAT(c.name) as categories
|
|
FROM recent_sales rs
|
|
JOIN products p ON rs.pid = p.pid
|
|
JOIN product_metrics pm ON p.pid = pm.pid
|
|
LEFT JOIN product_categories pc ON p.pid = pc.pid
|
|
LEFT JOIN categories c ON pc.cat_id = c.cat_id
|
|
GROUP BY p.pid
|
|
HAVING velocity_change > 0
|
|
ORDER BY velocity_change DESC
|
|
LIMIT ?
|
|
`, [days, days, limit]);
|
|
res.json(rows);
|
|
} catch (err) {
|
|
console.error('Error fetching trending products:', err);
|
|
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,
|
|
CAST(AVG(DATEDIFF(po.received_date, po.date)) AS DECIMAL(10,2)) as avg_lead_time,
|
|
CAST(AVG(CASE
|
|
WHEN po.status = 'completed'
|
|
THEN DATEDIFF(po.received_date, po.expected_date)
|
|
END) AS DECIMAL(10,2)) as avg_delay,
|
|
CAST(SUM(CASE
|
|
WHEN po.status = 'completed' AND po.received_date <= po.expected_date
|
|
THEN 1
|
|
ELSE 0
|
|
END) * 100.0 / COUNT(*) AS DECIMAL(10,2)) as on_time_delivery_rate,
|
|
CAST(AVG(CASE
|
|
WHEN po.status = 'completed'
|
|
THEN po.received / po.ordered * 100
|
|
ELSE NULL
|
|
END) AS DECIMAL(10,2)) as avg_fill_rate
|
|
FROM purchase_orders po
|
|
WHERE po.date >= DATE_SUB(CURDATE(), INTERVAL 180 DAY)
|
|
GROUP BY po.vendor
|
|
)
|
|
SELECT
|
|
vd.vendor,
|
|
vd.contact_name,
|
|
vd.status,
|
|
CAST(vo.total_orders AS SIGNED) as total_orders,
|
|
vo.avg_lead_time,
|
|
vo.avg_delay,
|
|
vo.on_time_delivery_rate,
|
|
vo.avg_fill_rate
|
|
FROM vendor_details vd
|
|
JOIN vendor_orders vo ON vd.vendor = vo.vendor
|
|
WHERE vd.status = 'active'
|
|
ORDER BY vo.on_time_delivery_rate DESC
|
|
`);
|
|
|
|
// Format response with explicit number parsing
|
|
const formattedRows = rows.map(row => ({
|
|
vendor: row.vendor,
|
|
contact_name: row.contact_name,
|
|
status: row.status,
|
|
total_orders: parseInt(row.total_orders) || 0,
|
|
avg_lead_time: parseFloat(row.avg_lead_time) || 0,
|
|
avg_delay: parseFloat(row.avg_delay) || 0,
|
|
on_time_delivery_rate: parseFloat(row.on_time_delivery_rate) || 0,
|
|
avg_fill_rate: parseFloat(row.avg_fill_rate) || 0
|
|
}));
|
|
|
|
res.json(formattedRows);
|
|
} 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.pid = pm.pid
|
|
),
|
|
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.pid = pm.pid
|
|
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.pid = pm.pid
|
|
),
|
|
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.cat_id = pc.cat_id
|
|
JOIN products p ON pc.pid = p.pid
|
|
JOIN product_metrics pm ON p.pid = pm.pid
|
|
WHERE p.replenishable = true
|
|
GROUP BY c.cat_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' });
|
|
}
|
|
});
|
|
|
|
// GET /dashboard/replenish/products
|
|
// Returns top products that need replenishment
|
|
router.get('/replenish/products', async (req, res) => {
|
|
const limit = Math.max(1, Math.min(100, parseInt(req.query.limit) || 50));
|
|
try {
|
|
const [products] = await executeQuery(`
|
|
SELECT
|
|
p.pid,
|
|
p.SKU as sku,
|
|
p.title,
|
|
p.stock_quantity,
|
|
pm.daily_sales_avg,
|
|
pm.reorder_qty,
|
|
pm.last_purchase_date
|
|
FROM products p
|
|
JOIN product_metrics pm ON p.pid = pm.pid
|
|
WHERE p.replenishable = true
|
|
AND pm.stock_status IN ('Critical', 'Reorder')
|
|
AND pm.reorder_qty > 0
|
|
ORDER BY
|
|
CASE pm.stock_status
|
|
WHEN 'Critical' THEN 1
|
|
WHEN 'Reorder' THEN 2
|
|
END,
|
|
pm.reorder_qty * p.cost_price DESC
|
|
LIMIT ?
|
|
`, [limit]);
|
|
|
|
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) {
|
|
console.error('Error fetching products to replenish:', err);
|
|
res.status(500).json({ error: 'Failed to fetch products to replenish' });
|
|
}
|
|
});
|
|
|
|
module.exports = router;
|