Fix and update bestsellers component

This commit is contained in:
2025-01-18 01:01:37 -05:00
parent 1b4447f886
commit 9003300d0d
2 changed files with 240 additions and 90 deletions

View File

@@ -440,62 +440,194 @@ router.get('/overstock/products', async (req, res) => {
router.get('/best-sellers', async (req, res) => {
try {
const [products] = await executeQuery(`
WITH product_sales AS (
SELECT
p.product_id,
p.SKU as sku,
p.title,
-- Current period (last 30 days)
SUM(CASE
WHEN o.date >= DATE_SUB(CURRENT_DATE, INTERVAL 30 DAY)
THEN o.quantity
ELSE 0
END) as units_sold,
SUM(CASE
WHEN o.date >= DATE_SUB(CURRENT_DATE, INTERVAL 30 DAY)
THEN o.price * o.quantity
ELSE 0
END) as revenue,
SUM(CASE
WHEN o.date >= DATE_SUB(CURRENT_DATE, INTERVAL 30 DAY)
THEN (o.price - p.cost_price) * o.quantity
ELSE 0
END) as profit,
-- Previous period (30-60 days ago)
SUM(CASE
WHEN o.date BETWEEN DATE_SUB(CURRENT_DATE, INTERVAL 60 DAY) AND DATE_SUB(CURRENT_DATE, INTERVAL 30 DAY)
THEN o.price * o.quantity
ELSE 0
END) as previous_revenue
FROM products p
JOIN orders o ON p.product_id = o.product_id
WHERE o.canceled = false
AND o.date >= DATE_SUB(CURRENT_DATE, INTERVAL 60 DAY)
GROUP BY p.product_id, p.SKU, p.title
)
SELECT
p.product_id,
p.SKU,
p.title,
p.brand,
p.vendor,
pm.total_revenue,
pm.daily_sales_avg,
pm.number_of_orders,
SUM(o.quantity) as units_sold,
GROUP_CONCAT(c.name) as categories
FROM products p
JOIN product_metrics pm ON p.product_id = pm.product_id
LEFT JOIN orders o ON p.product_id = o.product_id AND o.canceled = false
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
ORDER BY pm.total_revenue DESC
LIMIT 10
product_id,
sku,
title,
units_sold,
revenue,
profit,
CASE
WHEN previous_revenue > 0
THEN ((revenue - previous_revenue) / previous_revenue * 100)
WHEN revenue > 0
THEN 100
ELSE 0
END as growth_rate
FROM product_sales
WHERE units_sold > 0
ORDER BY revenue DESC
LIMIT 50
`);
const [vendors] = await executeQuery(`
const [brands] = await executeQuery(`
WITH brand_sales AS (
SELECT
p.brand,
-- Current period (last 30 days)
SUM(CASE
WHEN o.date >= DATE_SUB(CURRENT_DATE, INTERVAL 30 DAY)
THEN o.quantity
ELSE 0
END) as units_sold,
SUM(CASE
WHEN o.date >= DATE_SUB(CURRENT_DATE, INTERVAL 30 DAY)
THEN o.price * o.quantity
ELSE 0
END) as revenue,
SUM(CASE
WHEN o.date >= DATE_SUB(CURRENT_DATE, INTERVAL 30 DAY)
THEN (o.price - p.cost_price) * o.quantity
ELSE 0
END) as profit,
-- Previous period (30-60 days ago)
SUM(CASE
WHEN o.date BETWEEN DATE_SUB(CURRENT_DATE, INTERVAL 60 DAY) AND DATE_SUB(CURRENT_DATE, INTERVAL 30 DAY)
THEN o.price * o.quantity
ELSE 0
END) as previous_revenue
FROM products p
JOIN orders o ON p.product_id = o.product_id
WHERE o.canceled = false
AND o.date >= DATE_SUB(CURRENT_DATE, INTERVAL 60 DAY)
AND p.brand IS NOT NULL
GROUP BY p.brand
)
SELECT
vm.*,
COALESCE(SUM(o.quantity), 0) as products_sold
FROM vendor_metrics vm
LEFT JOIN orders o ON vm.vendor = o.vendor AND o.canceled = false
GROUP BY vm.vendor
ORDER BY vm.total_revenue DESC
LIMIT 10
brand,
units_sold,
revenue,
profit,
CASE
WHEN previous_revenue > 0
THEN ((revenue - previous_revenue) / previous_revenue * 100)
WHEN revenue > 0
THEN 100
ELSE 0
END as growth_rate
FROM brand_sales
WHERE units_sold > 0
ORDER BY revenue DESC
LIMIT 50
`);
const [categories] = await executeQuery(`
WITH category_sales AS (
SELECT
c.id as category_id,
c.name,
-- Current period (last 30 days)
SUM(CASE
WHEN o.date >= DATE_SUB(CURRENT_DATE, INTERVAL 30 DAY)
THEN o.quantity
ELSE 0
END) as units_sold,
SUM(CASE
WHEN o.date >= DATE_SUB(CURRENT_DATE, INTERVAL 30 DAY)
THEN o.price * o.quantity
ELSE 0
END) as revenue,
SUM(CASE
WHEN o.date >= DATE_SUB(CURRENT_DATE, INTERVAL 30 DAY)
THEN (o.price - p.cost_price) * o.quantity
ELSE 0
END) as profit,
-- Previous period (30-60 days ago)
SUM(CASE
WHEN o.date BETWEEN DATE_SUB(CURRENT_DATE, INTERVAL 60 DAY) AND DATE_SUB(CURRENT_DATE, INTERVAL 30 DAY)
THEN o.price * o.quantity
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
WHERE o.canceled = false
AND o.date >= DATE_SUB(CURRENT_DATE, INTERVAL 60 DAY)
GROUP BY c.id, c.name
)
SELECT
c.name,
cm.*
FROM category_metrics cm
JOIN categories c ON cm.category_id = c.id
ORDER BY cm.total_value DESC
LIMIT 10
category_id,
name,
units_sold,
revenue,
profit,
CASE
WHEN previous_revenue > 0
THEN ((revenue - previous_revenue) / previous_revenue * 100)
WHEN revenue > 0
THEN 100
ELSE 0
END as growth_rate
FROM category_sales
WHERE units_sold > 0
ORDER BY revenue DESC
LIMIT 50
`);
// Format response with explicit type conversion
const formattedProducts = products.map(p => ({
...p,
total_revenue: parseFloat(p.total_revenue) || 0,
daily_sales_avg: parseFloat(p.daily_sales_avg) || 0,
number_of_orders: parseInt(p.number_of_orders) || 0,
units_sold: parseInt(p.units_sold) || 0,
categories: p.categories ? p.categories.split(',') : []
revenue: parseFloat(p.revenue) || 0,
profit: parseFloat(p.profit) || 0,
growth_rate: parseFloat(p.growth_rate) || 0
}));
const formattedBrands = brands.map(b => ({
brand: b.brand,
units_sold: parseInt(b.units_sold) || 0,
revenue: parseFloat(b.revenue) || 0,
profit: parseFloat(b.profit) || 0,
growth_rate: parseFloat(b.growth_rate) || 0
}));
const formattedCategories = categories.map(c => ({
category_id: c.category_id,
name: c.name,
units_sold: parseInt(c.units_sold) || 0,
revenue: parseFloat(c.revenue) || 0,
profit: parseFloat(c.profit) || 0,
growth_rate: parseFloat(c.growth_rate) || 0
}));
res.json({
products: formattedProducts,
vendors,
categories
brands: formattedBrands,
categories: formattedCategories
});
} catch (err) {
console.error('Error fetching best sellers:', err);