Update frontend to match part 1
This commit is contained in:
@@ -38,15 +38,14 @@ router.get('/stock/metrics', async (req, res) => {
|
||||
const [brandValues] = await executeQuery(`
|
||||
WITH brand_totals AS (
|
||||
SELECT
|
||||
brand,
|
||||
COUNT(DISTINCT product_id) as variant_count,
|
||||
COALESCE(brand, 'Unbranded') as brand,
|
||||
COUNT(DISTINCT pid) 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
|
||||
CAST(COALESCE(SUM(stock_quantity * cost_price), 0) AS DECIMAL(15,3)) as stock_cost,
|
||||
CAST(COALESCE(SUM(stock_quantity * price), 0) AS DECIMAL(15,3)) as stock_retail
|
||||
FROM products
|
||||
WHERE brand IS NOT NULL
|
||||
AND stock_quantity > 0
|
||||
GROUP BY brand
|
||||
WHERE stock_quantity > 0
|
||||
GROUP BY COALESCE(brand, 'Unbranded')
|
||||
HAVING stock_cost > 0
|
||||
),
|
||||
other_brands AS (
|
||||
@@ -54,8 +53,8 @@ router.get('/stock/metrics', async (req, res) => {
|
||||
'Other' as brand,
|
||||
SUM(variant_count) as variant_count,
|
||||
SUM(stock_units) as stock_units,
|
||||
SUM(stock_cost) as stock_cost,
|
||||
SUM(stock_retail) as stock_retail
|
||||
CAST(SUM(stock_cost) AS DECIMAL(15,3)) as stock_cost,
|
||||
CAST(SUM(stock_retail) AS DECIMAL(15,3)) as stock_retail
|
||||
FROM brand_totals
|
||||
WHERE stock_cost <= 5000
|
||||
),
|
||||
@@ -101,24 +100,24 @@ router.get('/purchase/metrics', async (req, res) => {
|
||||
try {
|
||||
const [rows] = await executeQuery(`
|
||||
SELECT
|
||||
COALESCE(COUNT(DISTINCT CASE WHEN po.status = 'open' THEN po.po_id END), 0) as active_pos,
|
||||
COALESCE(COUNT(DISTINCT CASE WHEN po.receiving_status < 30 THEN po.po_id END), 0) as active_pos,
|
||||
COALESCE(COUNT(DISTINCT CASE
|
||||
WHEN po.status = 'open' AND po.expected_date < CURDATE()
|
||||
WHEN po.receiving_status < 30 AND po.expected_date < CURDATE()
|
||||
THEN po.po_id
|
||||
END), 0) as overdue_pos,
|
||||
COALESCE(SUM(CASE WHEN po.status = 'open' THEN po.ordered ELSE 0 END), 0) as total_units,
|
||||
COALESCE(SUM(CASE
|
||||
WHEN po.status = 'open'
|
||||
COALESCE(SUM(CASE WHEN po.receiving_status < 30 THEN po.ordered ELSE 0 END), 0) as total_units,
|
||||
CAST(COALESCE(SUM(CASE
|
||||
WHEN po.receiving_status < 30
|
||||
THEN po.ordered * po.cost_price
|
||||
ELSE 0
|
||||
END), 0) as total_cost,
|
||||
COALESCE(SUM(CASE
|
||||
WHEN po.status = 'open'
|
||||
END), 0) AS DECIMAL(15,3)) as total_cost,
|
||||
CAST(COALESCE(SUM(CASE
|
||||
WHEN po.receiving_status < 30
|
||||
THEN po.ordered * p.price
|
||||
ELSE 0
|
||||
END), 0) as total_retail
|
||||
END), 0) AS DECIMAL(15,3)) as total_retail
|
||||
FROM purchase_orders po
|
||||
JOIN products p ON po.product_id = p.product_id
|
||||
JOIN products p ON po.pid = p.pid
|
||||
`);
|
||||
const poMetrics = rows[0];
|
||||
|
||||
@@ -134,11 +133,11 @@ router.get('/purchase/metrics', async (req, res) => {
|
||||
po.vendor,
|
||||
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
|
||||
CAST(COALESCE(SUM(po.ordered * po.cost_price), 0) AS DECIMAL(15,3)) as order_cost,
|
||||
CAST(COALESCE(SUM(po.ordered * p.price), 0) AS DECIMAL(15,3)) as order_retail
|
||||
FROM purchase_orders po
|
||||
JOIN products p ON po.product_id = p.product_id
|
||||
WHERE po.status = 'open'
|
||||
JOIN products p ON po.pid = p.pid
|
||||
WHERE po.receiving_status < 30
|
||||
GROUP BY po.vendor
|
||||
HAVING order_cost > 0
|
||||
ORDER BY order_cost DESC
|
||||
@@ -173,21 +172,21 @@ router.get('/replenishment/metrics', async (req, res) => {
|
||||
// Get summary metrics
|
||||
const [metrics] = await executeQuery(`
|
||||
SELECT
|
||||
COUNT(DISTINCT p.product_id) as products_to_replenish,
|
||||
COUNT(DISTINCT p.pid) 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) as total_units_needed,
|
||||
COALESCE(SUM(CASE
|
||||
CAST(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) as total_cost,
|
||||
COALESCE(SUM(CASE
|
||||
END), 0) AS DECIMAL(15,3)) as total_cost,
|
||||
CAST(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) as total_retail
|
||||
END), 0) AS DECIMAL(15,3)) as total_retail
|
||||
FROM products p
|
||||
JOIN product_metrics pm ON p.product_id = pm.product_id
|
||||
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)
|
||||
@@ -197,24 +196,24 @@ router.get('/replenishment/metrics', async (req, res) => {
|
||||
// Get top variants to replenish
|
||||
const [variants] = await executeQuery(`
|
||||
SELECT
|
||||
p.product_id,
|
||||
p.pid,
|
||||
p.title,
|
||||
p.stock_quantity as current_stock,
|
||||
CASE
|
||||
WHEN p.stock_quantity < 0 THEN ABS(p.stock_quantity) + pm.reorder_qty
|
||||
ELSE pm.reorder_qty
|
||||
END as replenish_qty,
|
||||
CASE
|
||||
CAST(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 as replenish_cost,
|
||||
CASE
|
||||
END AS DECIMAL(15,3)) as replenish_cost,
|
||||
CAST(CASE
|
||||
WHEN p.stock_quantity < 0 THEN (ABS(p.stock_quantity) + pm.reorder_qty) * p.price
|
||||
ELSE pm.reorder_qty * p.price
|
||||
END as replenish_retail,
|
||||
END AS DECIMAL(15,3)) as replenish_retail,
|
||||
pm.stock_status
|
||||
FROM products p
|
||||
JOIN product_metrics pm ON p.product_id = pm.product_id
|
||||
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)
|
||||
@@ -235,7 +234,7 @@ router.get('/replenishment/metrics', async (req, res) => {
|
||||
replenishmentCost: parseFloat(metrics[0].total_cost) || 0,
|
||||
replenishmentRetail: parseFloat(metrics[0].total_retail) || 0,
|
||||
topVariants: variants.map(v => ({
|
||||
id: v.product_id,
|
||||
id: v.pid,
|
||||
title: v.title,
|
||||
currentStock: parseInt(v.current_stock) || 0,
|
||||
replenishQty: parseInt(v.replenish_qty) || 0,
|
||||
@@ -287,9 +286,9 @@ router.get('/forecast/metrics', async (req, res) => {
|
||||
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.id
|
||||
JOIN categories c ON cf.cat_id = c.cat_id
|
||||
WHERE cf.forecast_date BETWEEN ? AND ?
|
||||
GROUP BY c.id, c.name
|
||||
GROUP BY c.cat_id, c.name
|
||||
ORDER BY revenue DESC
|
||||
`, [startDate, endDate]);
|
||||
|
||||
@@ -325,11 +324,11 @@ router.get('/overstock/metrics', async (req, res) => {
|
||||
const [rows] = await executeQuery(`
|
||||
WITH category_overstock AS (
|
||||
SELECT
|
||||
c.id as category_id,
|
||||
c.cat_id,
|
||||
c.name as category_name,
|
||||
COUNT(DISTINCT CASE
|
||||
WHEN pm.stock_status = 'Overstocked'
|
||||
THEN p.product_id
|
||||
THEN p.pid
|
||||
END) as overstocked_products,
|
||||
SUM(CASE
|
||||
WHEN pm.stock_status = 'Overstocked'
|
||||
@@ -347,10 +346,10 @@ router.get('/overstock/metrics', async (req, res) => {
|
||||
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
|
||||
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,
|
||||
@@ -405,7 +404,7 @@ router.get('/overstock/products', async (req, res) => {
|
||||
try {
|
||||
const [rows] = await executeQuery(`
|
||||
SELECT
|
||||
p.product_id,
|
||||
p.pid,
|
||||
p.SKU,
|
||||
p.title,
|
||||
p.brand,
|
||||
@@ -420,11 +419,11 @@ router.get('/overstock/products', async (req, res) => {
|
||||
(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
|
||||
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.product_id
|
||||
GROUP BY p.pid
|
||||
ORDER BY excess_cost DESC
|
||||
LIMIT ?
|
||||
`, [limit]);
|
||||
@@ -442,7 +441,7 @@ router.get('/best-sellers', async (req, res) => {
|
||||
const [products] = await executeQuery(`
|
||||
WITH product_sales AS (
|
||||
SELECT
|
||||
p.product_id,
|
||||
p.pid,
|
||||
p.SKU as sku,
|
||||
p.title,
|
||||
-- Current period (last 30 days)
|
||||
@@ -468,13 +467,13 @@ router.get('/best-sellers', async (req, res) => {
|
||||
ELSE 0
|
||||
END) as previous_revenue
|
||||
FROM products p
|
||||
JOIN orders o ON p.product_id = o.product_id
|
||||
JOIN orders o ON p.pid = o.pid
|
||||
WHERE o.canceled = false
|
||||
AND o.date >= DATE_SUB(CURRENT_DATE, INTERVAL 60 DAY)
|
||||
GROUP BY p.product_id, p.SKU, p.title
|
||||
GROUP BY p.pid, p.SKU, p.title
|
||||
)
|
||||
SELECT
|
||||
product_id,
|
||||
pid,
|
||||
sku,
|
||||
title,
|
||||
units_sold,
|
||||
@@ -520,7 +519,7 @@ router.get('/best-sellers', async (req, res) => {
|
||||
ELSE 0
|
||||
END) as previous_revenue
|
||||
FROM products p
|
||||
JOIN orders o ON p.product_id = o.product_id
|
||||
JOIN orders o ON p.pid = o.pid
|
||||
WHERE o.canceled = false
|
||||
AND o.date >= DATE_SUB(CURRENT_DATE, INTERVAL 60 DAY)
|
||||
AND p.brand IS NOT NULL
|
||||
@@ -547,7 +546,7 @@ router.get('/best-sellers', async (req, res) => {
|
||||
const [categories] = await executeQuery(`
|
||||
WITH category_sales AS (
|
||||
SELECT
|
||||
c.id as category_id,
|
||||
c.cat_id,
|
||||
c.name,
|
||||
-- Current period (last 30 days)
|
||||
SUM(CASE
|
||||
@@ -572,15 +571,15 @@ router.get('/best-sellers', async (req, res) => {
|
||||
ELSE 0
|
||||
END) as previous_revenue
|
||||
FROM categories c
|
||||
JOIN product_categories pc ON c.id = pc.category_id
|
||||
JOIN products p ON pc.product_id = p.product_id
|
||||
JOIN orders o ON p.product_id = o.product_id
|
||||
JOIN product_categories pc ON c.cat_id = pc.cat_id
|
||||
JOIN products p ON pc.pid = p.pid
|
||||
JOIN orders o ON p.pid = o.pid
|
||||
WHERE o.canceled = false
|
||||
AND o.date >= DATE_SUB(CURRENT_DATE, INTERVAL 60 DAY)
|
||||
GROUP BY c.id, c.name
|
||||
GROUP BY c.cat_id, c.name
|
||||
)
|
||||
SELECT
|
||||
category_id,
|
||||
cat_id as category_id,
|
||||
name,
|
||||
units_sold,
|
||||
revenue,
|
||||
@@ -616,7 +615,7 @@ router.get('/best-sellers', async (req, res) => {
|
||||
}));
|
||||
|
||||
const formattedCategories = categories.map(c => ({
|
||||
category_id: c.category_id,
|
||||
category_id: c.cat_id,
|
||||
name: c.name,
|
||||
units_sold: parseInt(c.units_sold) || 0,
|
||||
revenue: parseFloat(c.revenue) || 0,
|
||||
@@ -650,7 +649,7 @@ router.get('/sales/metrics', async (req, res) => {
|
||||
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
|
||||
JOIN products p ON o.pid = p.pid
|
||||
WHERE o.canceled = false
|
||||
AND o.date BETWEEN ? AND ?
|
||||
GROUP BY DATE(o.date)
|
||||
@@ -666,7 +665,7 @@ router.get('/sales/metrics', async (req, res) => {
|
||||
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
|
||||
JOIN products p ON o.pid = p.pid
|
||||
WHERE o.canceled = false
|
||||
AND o.date BETWEEN ? AND ?
|
||||
`, [startDate, endDate]);
|
||||
@@ -698,7 +697,7 @@ router.get('/low-stock/products', async (req, res) => {
|
||||
try {
|
||||
const [rows] = await executeQuery(`
|
||||
SELECT
|
||||
p.product_id,
|
||||
p.pid,
|
||||
p.SKU,
|
||||
p.title,
|
||||
p.brand,
|
||||
@@ -712,12 +711,12 @@ router.get('/low-stock/products', async (req, res) => {
|
||||
(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
|
||||
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.product_id
|
||||
GROUP BY p.pid
|
||||
ORDER BY
|
||||
CASE pm.stock_status
|
||||
WHEN 'Critical' THEN 1
|
||||
@@ -742,17 +741,17 @@ router.get('/trending/products', async (req, res) => {
|
||||
const [rows] = await executeQuery(`
|
||||
WITH recent_sales AS (
|
||||
SELECT
|
||||
o.product_id,
|
||||
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.product_id
|
||||
GROUP BY o.pid
|
||||
)
|
||||
SELECT
|
||||
p.product_id,
|
||||
p.pid,
|
||||
p.SKU,
|
||||
p.title,
|
||||
p.brand,
|
||||
@@ -767,11 +766,11 @@ router.get('/trending/products', async (req, res) => {
|
||||
((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.product_id = p.product_id
|
||||
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
|
||||
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 ?
|
||||
@@ -859,7 +858,7 @@ router.get('/key-metrics', async (req, res) => {
|
||||
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
|
||||
JOIN product_metrics pm ON p.pid = pm.pid
|
||||
),
|
||||
sales_summary AS (
|
||||
SELECT
|
||||
@@ -909,7 +908,7 @@ router.get('/inventory-health', async (req, res) => {
|
||||
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
|
||||
JOIN product_metrics pm ON p.pid = pm.pid
|
||||
WHERE p.replenishable = true
|
||||
),
|
||||
value_distribution AS (
|
||||
@@ -931,7 +930,7 @@ router.get('/inventory-health', async (req, res) => {
|
||||
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
|
||||
JOIN product_metrics pm ON p.pid = pm.pid
|
||||
),
|
||||
category_health AS (
|
||||
SELECT
|
||||
@@ -940,11 +939,11 @@ router.get('/inventory-health', async (req, res) => {
|
||||
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
|
||||
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.id, c.name
|
||||
GROUP BY c.cat_id, c.name
|
||||
)
|
||||
SELECT
|
||||
sd.*,
|
||||
@@ -975,20 +974,15 @@ router.get('/replenish/products', async (req, res) => {
|
||||
try {
|
||||
const [products] = await executeQuery(`
|
||||
SELECT
|
||||
p.product_id,
|
||||
p.SKU,
|
||||
p.pid,
|
||||
p.SKU as 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
|
||||
p.stock_quantity,
|
||||
pm.daily_sales_avg,
|
||||
pm.reorder_qty,
|
||||
pm.last_purchase_date
|
||||
FROM products p
|
||||
JOIN product_metrics pm ON p.product_id = pm.product_id
|
||||
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
|
||||
@@ -997,23 +991,16 @@ router.get('/replenish/products', async (req, res) => {
|
||||
WHEN 'Critical' THEN 1
|
||||
WHEN 'Reorder' THEN 2
|
||||
END,
|
||||
replenish_cost DESC
|
||||
pm.reorder_qty * p.cost_price 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);
|
||||
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' });
|
||||
|
||||
Reference in New Issue
Block a user