Rearrange dashboard to match IP
This commit is contained in:
@@ -26,18 +26,20 @@ router.get('/stock/metrics', async (req, res) => {
|
||||
FROM products
|
||||
`);
|
||||
|
||||
// Get brand values in a separate query
|
||||
const [brandValues] = await executeQuery(`
|
||||
// Get vendor stock values
|
||||
const [vendorValues] = await executeQuery(`
|
||||
SELECT
|
||||
brand,
|
||||
COALESCE(SUM(stock_quantity * price), 0) as value
|
||||
vendor,
|
||||
COUNT(DISTINCT product_id) as variant_count,
|
||||
COALESCE(SUM(stock_quantity), 0) as stock_units,
|
||||
COALESCE(SUM(stock_quantity * cost_price), 0) as stock_cost,
|
||||
COALESCE(SUM(stock_quantity * price), 0) as stock_retail
|
||||
FROM products
|
||||
WHERE brand IS NOT NULL
|
||||
WHERE vendor IS NOT NULL
|
||||
AND stock_quantity > 0
|
||||
GROUP BY brand
|
||||
HAVING value > 0
|
||||
ORDER BY value DESC
|
||||
LIMIT 8
|
||||
GROUP BY vendor
|
||||
HAVING stock_cost > 0
|
||||
ORDER BY stock_cost DESC
|
||||
`);
|
||||
|
||||
// Format the response with explicit type conversion
|
||||
@@ -47,9 +49,12 @@ router.get('/stock/metrics', async (req, res) => {
|
||||
totalStockUnits: parseInt(stockMetrics.total_units) || 0,
|
||||
totalStockCost: parseFloat(stockMetrics.total_cost) || 0,
|
||||
totalStockRetail: parseFloat(stockMetrics.total_retail) || 0,
|
||||
brandRetailValue: brandValues.map(b => ({
|
||||
brand: b.brand,
|
||||
value: parseFloat(b.value) || 0
|
||||
vendorStock: vendorValues.map(v => ({
|
||||
vendor: v.vendor,
|
||||
variants: parseInt(v.variant_count) || 0,
|
||||
units: parseInt(v.stock_units) || 0,
|
||||
cost: parseFloat(v.stock_cost) || 0,
|
||||
retail: parseFloat(v.stock_retail) || 0
|
||||
}))
|
||||
};
|
||||
|
||||
@@ -86,20 +91,19 @@ router.get('/purchase/metrics', async (req, res) => {
|
||||
JOIN products p ON po.product_id = p.product_id
|
||||
`);
|
||||
|
||||
const [vendorValues] = await executeQuery(`
|
||||
const [vendorOrders] = await executeQuery(`
|
||||
SELECT
|
||||
po.vendor,
|
||||
COALESCE(SUM(CASE
|
||||
WHEN po.status = 'open'
|
||||
THEN po.ordered * po.cost_price
|
||||
ELSE 0
|
||||
END), 0) as value
|
||||
COUNT(DISTINCT po.po_id) as order_count,
|
||||
COALESCE(SUM(po.ordered), 0) as ordered_units,
|
||||
COALESCE(SUM(po.ordered * po.cost_price), 0) as order_cost,
|
||||
COALESCE(SUM(po.ordered * p.price), 0) as order_retail
|
||||
FROM purchase_orders po
|
||||
JOIN products p ON po.product_id = p.product_id
|
||||
WHERE po.status = 'open'
|
||||
GROUP BY po.vendor
|
||||
HAVING value > 0
|
||||
ORDER BY value DESC
|
||||
LIMIT 8
|
||||
HAVING order_cost > 0
|
||||
ORDER BY order_cost DESC
|
||||
`);
|
||||
|
||||
res.json({
|
||||
@@ -108,9 +112,12 @@ router.get('/purchase/metrics', async (req, res) => {
|
||||
onOrderUnits: parseInt(poMetrics.total_units) || 0,
|
||||
onOrderCost: parseFloat(poMetrics.total_cost) || 0,
|
||||
onOrderRetail: parseFloat(poMetrics.total_retail) || 0,
|
||||
vendorOrderValue: vendorValues.map(v => ({
|
||||
vendorOrders: vendorOrders.map(v => ({
|
||||
vendor: v.vendor,
|
||||
value: parseFloat(v.value) || 0
|
||||
orders: parseInt(v.order_count) || 0,
|
||||
units: parseInt(v.ordered_units) || 0,
|
||||
cost: parseFloat(v.order_cost) || 0,
|
||||
retail: parseFloat(v.order_retail) || 0
|
||||
}))
|
||||
});
|
||||
} catch (err) {
|
||||
@@ -150,52 +157,45 @@ router.get('/replenishment/metrics', async (req, res) => {
|
||||
WHERE p.replenishable = true
|
||||
`);
|
||||
|
||||
// Get category breakdown
|
||||
const [categories] = await executeQuery(`
|
||||
// Get top variants to replenish
|
||||
const [variants] = await executeQuery(`
|
||||
SELECT
|
||||
c.name as category,
|
||||
COUNT(DISTINCT CASE
|
||||
WHEN pm.stock_status IN ('Critical', 'Reorder')
|
||||
THEN p.product_id
|
||||
END) as products,
|
||||
SUM(CASE
|
||||
WHEN pm.stock_status IN ('Critical', 'Reorder')
|
||||
THEN pm.reorder_qty
|
||||
ELSE 0
|
||||
END) as units,
|
||||
SUM(CASE
|
||||
WHEN pm.stock_status IN ('Critical', 'Reorder')
|
||||
THEN pm.reorder_qty * p.cost_price
|
||||
ELSE 0
|
||||
END) as cost,
|
||||
SUM(CASE
|
||||
WHEN pm.stock_status IN ('Critical', 'Reorder')
|
||||
THEN pm.reorder_qty * p.price
|
||||
ELSE 0
|
||||
END) as retail
|
||||
FROM categories c
|
||||
JOIN product_categories pc ON c.id = pc.category_id
|
||||
JOIN products p ON pc.product_id = p.product_id
|
||||
p.product_id,
|
||||
p.title,
|
||||
p.stock_quantity as current_stock,
|
||||
pm.reorder_qty as replenish_qty,
|
||||
(pm.reorder_qty * p.cost_price) as replenish_cost,
|
||||
(pm.reorder_qty * p.price) as replenish_retail,
|
||||
pm.stock_status,
|
||||
DATE_FORMAT(pm.planning_period_end, '%b %d, %Y') as planning_period
|
||||
FROM products p
|
||||
JOIN product_metrics pm ON p.product_id = pm.product_id
|
||||
WHERE p.replenishable = true
|
||||
GROUP BY c.id, c.name
|
||||
HAVING products > 0
|
||||
ORDER BY cost DESC
|
||||
LIMIT 8
|
||||
AND pm.stock_status IN ('Critical', 'Reorder')
|
||||
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,
|
||||
totalUnitsToReplenish: parseInt(metrics.total_units_needed) || 0,
|
||||
totalReplenishmentCost: parseFloat(metrics.total_cost) || 0,
|
||||
totalReplenishmentRetail: parseFloat(metrics.total_retail) || 0,
|
||||
categoryData: categories.map(c => ({
|
||||
category: c.category,
|
||||
products: parseInt(c.products) || 0,
|
||||
units: parseInt(c.units) || 0,
|
||||
cost: parseFloat(c.cost) || 0,
|
||||
retail: parseFloat(c.retail) || 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.product_id,
|
||||
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,
|
||||
planningPeriod: v.planning_period
|
||||
}))
|
||||
};
|
||||
|
||||
@@ -833,4 +833,56 @@ router.get('/inventory-health', async (req, res) => {
|
||||
}
|
||||
});
|
||||
|
||||
// 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.product_id,
|
||||
p.SKU,
|
||||
p.title,
|
||||
p.stock_quantity as current_stock,
|
||||
pm.reorder_qty as replenish_qty,
|
||||
(pm.reorder_qty * p.cost_price) as replenish_cost,
|
||||
(pm.reorder_qty * p.price) as replenish_retail,
|
||||
CASE
|
||||
WHEN pm.daily_sales_avg > 0
|
||||
THEN FLOOR(p.stock_quantity / pm.daily_sales_avg)
|
||||
ELSE NULL
|
||||
END as days_until_stockout
|
||||
FROM products p
|
||||
JOIN product_metrics pm ON p.product_id = pm.product_id
|
||||
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,
|
||||
replenish_cost DESC
|
||||
LIMIT ?
|
||||
`, [limit]);
|
||||
|
||||
// Format response
|
||||
const response = products.map(p => ({
|
||||
product_id: p.product_id,
|
||||
SKU: p.SKU,
|
||||
title: p.title,
|
||||
current_stock: parseInt(p.current_stock) || 0,
|
||||
replenish_qty: parseInt(p.replenish_qty) || 0,
|
||||
replenish_cost: parseFloat(p.replenish_cost) || 0,
|
||||
replenish_retail: parseFloat(p.replenish_retail) || 0,
|
||||
days_until_stockout: p.days_until_stockout
|
||||
}));
|
||||
|
||||
res.json(response);
|
||||
} catch (err) {
|
||||
console.error('Error fetching products to replenish:', err);
|
||||
res.status(500).json({ error: 'Failed to fetch products to replenish' });
|
||||
}
|
||||
});
|
||||
|
||||
module.exports = router;
|
||||
Reference in New Issue
Block a user