Frontend fixes - categories, deal with new hierarchy, misc fixes
This commit is contained in:
@@ -443,198 +443,116 @@ router.get('/overstock/products', async (req, res) => {
|
||||
// Returns best-selling products, vendors, and categories
|
||||
router.get('/best-sellers', async (req, res) => {
|
||||
try {
|
||||
const [products] = await executeQuery(`
|
||||
WITH product_sales AS (
|
||||
SELECT
|
||||
p.pid,
|
||||
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.pid = o.pid
|
||||
WHERE o.canceled = false
|
||||
AND o.date >= DATE_SUB(CURRENT_DATE, INTERVAL 60 DAY)
|
||||
GROUP BY p.pid, p.SKU, p.title
|
||||
)
|
||||
SELECT
|
||||
pid,
|
||||
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 pool = req.app.locals.pool;
|
||||
|
||||
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.pid = o.pid
|
||||
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
|
||||
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 (
|
||||
// Common CTE for category paths
|
||||
const categoryPathCTE = `
|
||||
WITH RECURSIVE category_path AS (
|
||||
SELECT
|
||||
c.cat_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
|
||||
c.parent_id,
|
||||
CAST(c.name AS CHAR(1000)) as path
|
||||
FROM categories c
|
||||
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.cat_id, c.name
|
||||
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
|
||||
cat_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
|
||||
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
|
||||
`);
|
||||
|
||||
// Format response with explicit type conversion
|
||||
const formattedProducts = products.map(p => ({
|
||||
pid: p.pid,
|
||||
sku: p.sku,
|
||||
title: p.title,
|
||||
units_sold: parseInt(p.units_sold) || 0,
|
||||
revenue: p.revenue.toString(),
|
||||
profit: p.profit.toString(),
|
||||
growth_rate: p.growth_rate.toString()
|
||||
}));
|
||||
// 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
|
||||
`);
|
||||
|
||||
const formattedBrands = brands.map(b => ({
|
||||
brand: b.brand,
|
||||
units_sold: parseInt(b.units_sold) || 0,
|
||||
revenue: b.revenue.toString(),
|
||||
profit: b.profit.toString(),
|
||||
growth_rate: b.growth_rate.toString()
|
||||
}));
|
||||
// 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
|
||||
`);
|
||||
|
||||
const formattedCategories = categories.map(c => ({
|
||||
cat_id: c.cat_id,
|
||||
name: c.name,
|
||||
units_sold: parseInt(c.units_sold) || 0,
|
||||
revenue: c.revenue.toString(),
|
||||
profit: c.profit.toString(),
|
||||
growth_rate: c.growth_rate.toString()
|
||||
}));
|
||||
|
||||
res.json({
|
||||
products: formattedProducts,
|
||||
brands: formattedBrands,
|
||||
categories: formattedCategories
|
||||
});
|
||||
res.json({ products, brands, categories });
|
||||
} catch (err) {
|
||||
console.error('Error fetching best sellers:', err);
|
||||
res.status(500).json({ error: 'Failed to fetch best sellers' });
|
||||
|
||||
Reference in New Issue
Block a user