Frontend fixes - categories, deal with new hierarchy, misc fixes
This commit is contained in:
@@ -62,10 +62,30 @@ router.get('/profit', async (req, res) => {
|
||||
try {
|
||||
const pool = req.app.locals.pool;
|
||||
|
||||
// Get profit margins by category
|
||||
// Get profit margins by category with full path
|
||||
const [byCategory] = await pool.query(`
|
||||
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
|
||||
)
|
||||
SELECT
|
||||
c.name as category,
|
||||
cp.path as categoryPath,
|
||||
ROUND(
|
||||
(SUM(o.price * o.quantity - p.cost_price * o.quantity) /
|
||||
NULLIF(SUM(o.price * o.quantity), 0)) * 100, 1
|
||||
@@ -76,8 +96,9 @@ router.get('/profit', async (req, res) => {
|
||||
LEFT 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 30 DAY)
|
||||
GROUP BY c.name
|
||||
GROUP BY c.name, cp.path
|
||||
ORDER BY profitMargin DESC
|
||||
LIMIT 10
|
||||
`);
|
||||
@@ -106,10 +127,31 @@ router.get('/profit', async (req, res) => {
|
||||
ORDER BY formatted_date
|
||||
`);
|
||||
|
||||
// Get top performing products
|
||||
// Get top performing products with category paths
|
||||
const [topProducts] = await pool.query(`
|
||||
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
|
||||
)
|
||||
SELECT
|
||||
p.title as product,
|
||||
c.name as category,
|
||||
cp.path as categoryPath,
|
||||
ROUND(
|
||||
(SUM(o.price * o.quantity - p.cost_price * o.quantity) /
|
||||
NULLIF(SUM(o.price * o.quantity), 0)) * 100, 1
|
||||
@@ -118,8 +160,11 @@ router.get('/profit', async (req, res) => {
|
||||
CAST(SUM(p.cost_price * o.quantity) AS DECIMAL(15,3)) as cost
|
||||
FROM products p
|
||||
LEFT 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 30 DAY)
|
||||
GROUP BY p.pid, p.title
|
||||
GROUP BY p.pid, p.title, c.name, cp.path
|
||||
HAVING revenue > 0
|
||||
ORDER BY profitMargin DESC
|
||||
LIMIT 10
|
||||
@@ -446,11 +491,36 @@ router.get('/categories', async (req, res) => {
|
||||
try {
|
||||
const pool = req.app.locals.pool;
|
||||
|
||||
// Get category performance metrics
|
||||
// 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 category performance metrics with full path
|
||||
const [performance] = await pool.query(`
|
||||
WITH monthly_sales AS (
|
||||
${categoryPathCTE},
|
||||
monthly_sales AS (
|
||||
SELECT
|
||||
c.name,
|
||||
cp.path,
|
||||
SUM(CASE
|
||||
WHEN o.date >= DATE_SUB(CURDATE(), INTERVAL 30 DAY)
|
||||
THEN o.price * o.quantity
|
||||
@@ -466,11 +536,13 @@ router.get('/categories', async (req, res) => {
|
||||
LEFT 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)
|
||||
GROUP BY c.name
|
||||
GROUP BY c.name, cp.path
|
||||
)
|
||||
SELECT
|
||||
c.name as category,
|
||||
cp.path as categoryPath,
|
||||
SUM(o.price * o.quantity) as revenue,
|
||||
SUM(o.price * o.quantity - p.cost_price * o.quantity) as profit,
|
||||
ROUND(
|
||||
@@ -482,43 +554,51 @@ router.get('/categories', async (req, res) => {
|
||||
LEFT 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
|
||||
LEFT JOIN monthly_sales ms ON c.name = ms.name
|
||||
JOIN category_path cp ON c.cat_id = cp.cat_id
|
||||
LEFT JOIN monthly_sales ms ON c.name = ms.name AND cp.path = ms.path
|
||||
WHERE o.date >= DATE_SUB(CURDATE(), INTERVAL 60 DAY)
|
||||
GROUP BY c.name, ms.current_month, ms.previous_month
|
||||
GROUP BY c.name, cp.path, ms.current_month, ms.previous_month
|
||||
HAVING revenue > 0
|
||||
ORDER BY revenue DESC
|
||||
LIMIT 10
|
||||
`);
|
||||
|
||||
// Get category revenue distribution
|
||||
// Get category revenue distribution with full path
|
||||
const [distribution] = await pool.query(`
|
||||
${categoryPathCTE}
|
||||
SELECT
|
||||
c.name as category,
|
||||
cp.path as categoryPath,
|
||||
SUM(o.price * o.quantity) as value
|
||||
FROM products p
|
||||
LEFT 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 30 DAY)
|
||||
GROUP BY c.name
|
||||
GROUP BY c.name, cp.path
|
||||
HAVING value > 0
|
||||
ORDER BY value DESC
|
||||
LIMIT 6
|
||||
`);
|
||||
|
||||
// Get category sales trends
|
||||
// Get category sales trends with full path
|
||||
const [trends] = await pool.query(`
|
||||
${categoryPathCTE}
|
||||
SELECT
|
||||
c.name as category,
|
||||
cp.path as categoryPath,
|
||||
DATE_FORMAT(o.date, '%b %Y') as month,
|
||||
SUM(o.price * o.quantity) as sales
|
||||
FROM products p
|
||||
LEFT 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 6 MONTH)
|
||||
GROUP BY
|
||||
c.name,
|
||||
cp.path,
|
||||
DATE_FORMAT(o.date, '%b %Y'),
|
||||
DATE_FORMAT(o.date, '%Y-%m')
|
||||
ORDER BY
|
||||
@@ -535,76 +615,97 @@ router.get('/categories', async (req, res) => {
|
||||
|
||||
// Forecast endpoint
|
||||
router.get('/forecast', async (req, res) => {
|
||||
try {
|
||||
const { brand, startDate, endDate } = req.query;
|
||||
const pool = req.app.locals.pool;
|
||||
try {
|
||||
const { brand, startDate, endDate } = req.query;
|
||||
const pool = req.app.locals.pool;
|
||||
|
||||
const [results] = await pool.query(`
|
||||
WITH category_metrics AS (
|
||||
SELECT
|
||||
c.cat_id,
|
||||
c.name as category_name,
|
||||
p.brand,
|
||||
COUNT(DISTINCT p.pid) as num_products,
|
||||
CAST(COALESCE(ROUND(SUM(o.quantity) / DATEDIFF(?, ?), 2), 0) AS DECIMAL(15,3)) as avg_daily_sales,
|
||||
COALESCE(SUM(o.quantity), 0) as total_sold,
|
||||
CAST(COALESCE(ROUND(SUM(o.quantity) / COUNT(DISTINCT p.pid), 2), 0) AS DECIMAL(15,3)) as avgTotalSold,
|
||||
CAST(COALESCE(ROUND(AVG(o.price), 2), 0) AS DECIMAL(15,3)) as avg_price
|
||||
FROM categories c
|
||||
JOIN product_categories pc ON c.cat_id = pc.cat_id
|
||||
JOIN products p ON pc.pid = p.pid
|
||||
LEFT JOIN product_metrics pm ON p.pid = pm.pid
|
||||
LEFT JOIN orders o ON p.pid = o.pid
|
||||
AND o.date BETWEEN ? AND ?
|
||||
AND o.canceled = false
|
||||
WHERE p.brand = ?
|
||||
AND pm.first_received_date BETWEEN ? AND ?
|
||||
GROUP BY c.cat_id, c.name, p.brand
|
||||
),
|
||||
product_metrics AS (
|
||||
SELECT
|
||||
p.pid,
|
||||
p.title,
|
||||
p.SKU,
|
||||
p.stock_quantity,
|
||||
pc.cat_id,
|
||||
pm.first_received_date,
|
||||
COALESCE(SUM(o.quantity), 0) as total_sold,
|
||||
CAST(COALESCE(ROUND(AVG(o.price), 2), 0) AS DECIMAL(15,3)) as avg_price
|
||||
FROM products p
|
||||
JOIN product_categories pc ON p.pid = pc.pid
|
||||
JOIN product_metrics pm ON p.pid = pm.pid
|
||||
LEFT JOIN orders o ON p.pid = o.pid
|
||||
AND o.date BETWEEN ? AND ?
|
||||
AND o.canceled = false
|
||||
WHERE p.brand = ?
|
||||
AND pm.first_received_date BETWEEN ? AND ?
|
||||
GROUP BY p.pid, p.title, p.SKU, p.stock_quantity, pc.cat_id, pm.first_received_date
|
||||
)
|
||||
SELECT
|
||||
cm.*,
|
||||
JSON_ARRAYAGG(
|
||||
JSON_OBJECT(
|
||||
'pid', pm.pid,
|
||||
'title', pm.title,
|
||||
'SKU', pm.SKU,
|
||||
'stock_quantity', pm.stock_quantity,
|
||||
'total_sold', pm.total_sold,
|
||||
'avg_price', pm.avg_price,
|
||||
'first_received_date', DATE_FORMAT(pm.first_received_date, '%Y-%m-%d')
|
||||
)
|
||||
) as products
|
||||
FROM category_metrics cm
|
||||
JOIN product_metrics pm ON cm.cat_id = pm.cat_id
|
||||
GROUP BY cm.cat_id, cm.category_name, cm.brand, cm.num_products, cm.avg_daily_sales, cm.total_sold, cm.avgTotalSold, cm.avg_price
|
||||
ORDER BY cm.total_sold DESC
|
||||
`, [startDate, endDate, startDate, endDate, brand, startDate, endDate, startDate, endDate, brand, startDate, endDate]);
|
||||
const [results] = await pool.query(`
|
||||
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
|
||||
),
|
||||
category_metrics AS (
|
||||
SELECT
|
||||
c.cat_id,
|
||||
c.name as category_name,
|
||||
cp.path,
|
||||
p.brand,
|
||||
COUNT(DISTINCT p.pid) as num_products,
|
||||
CAST(COALESCE(ROUND(SUM(o.quantity) / DATEDIFF(?, ?), 2), 0) AS DECIMAL(15,3)) as avg_daily_sales,
|
||||
COALESCE(SUM(o.quantity), 0) as total_sold,
|
||||
CAST(COALESCE(ROUND(SUM(o.quantity) / COUNT(DISTINCT p.pid), 2), 0) AS DECIMAL(15,3)) as avgTotalSold,
|
||||
CAST(COALESCE(ROUND(AVG(o.price), 2), 0) AS DECIMAL(15,3)) as avg_price
|
||||
FROM categories c
|
||||
JOIN product_categories pc ON c.cat_id = pc.cat_id
|
||||
JOIN products p ON pc.pid = p.pid
|
||||
JOIN category_path cp ON c.cat_id = cp.cat_id
|
||||
LEFT JOIN product_metrics pmet ON p.pid = pmet.pid
|
||||
LEFT JOIN orders o ON p.pid = o.pid
|
||||
AND o.date BETWEEN ? AND ?
|
||||
AND o.canceled = false
|
||||
WHERE p.brand = ?
|
||||
AND pmet.first_received_date BETWEEN ? AND ?
|
||||
GROUP BY c.cat_id, c.name, cp.path, p.brand
|
||||
),
|
||||
product_details AS (
|
||||
SELECT
|
||||
p.pid,
|
||||
p.title,
|
||||
p.SKU,
|
||||
p.stock_quantity,
|
||||
pc.cat_id,
|
||||
pmet.first_received_date,
|
||||
COALESCE(SUM(o.quantity), 0) as total_sold,
|
||||
CAST(COALESCE(ROUND(AVG(o.price), 2), 0) AS DECIMAL(15,3)) as avg_price
|
||||
FROM products p
|
||||
JOIN product_categories pc ON p.pid = pc.pid
|
||||
JOIN product_metrics pmet ON p.pid = pmet.pid
|
||||
LEFT JOIN orders o ON p.pid = o.pid
|
||||
AND o.date BETWEEN ? AND ?
|
||||
AND o.canceled = false
|
||||
WHERE p.brand = ?
|
||||
AND pmet.first_received_date BETWEEN ? AND ?
|
||||
GROUP BY p.pid, p.title, p.SKU, p.stock_quantity, pc.cat_id, pmet.first_received_date
|
||||
)
|
||||
SELECT
|
||||
cm.*,
|
||||
JSON_ARRAYAGG(
|
||||
JSON_OBJECT(
|
||||
'pid', pd.pid,
|
||||
'title', pd.title,
|
||||
'SKU', pd.SKU,
|
||||
'stock_quantity', pd.stock_quantity,
|
||||
'total_sold', pd.total_sold,
|
||||
'avg_price', pd.avg_price,
|
||||
'first_received_date', DATE_FORMAT(pd.first_received_date, '%Y-%m-%d')
|
||||
)
|
||||
) as products
|
||||
FROM category_metrics cm
|
||||
JOIN product_details pd ON cm.cat_id = pd.cat_id
|
||||
GROUP BY cm.cat_id, cm.category_name, cm.path, cm.brand, cm.num_products, cm.avg_daily_sales, cm.total_sold, cm.avgTotalSold, cm.avg_price
|
||||
ORDER BY cm.total_sold DESC
|
||||
`, [endDate, startDate, startDate, endDate, brand, startDate, endDate, startDate, endDate, brand, startDate, endDate]);
|
||||
|
||||
res.json(results);
|
||||
} catch (error) {
|
||||
console.error('Error fetching forecast data:', error);
|
||||
res.status(500).json({ error: 'Failed to fetch forecast data' });
|
||||
}
|
||||
res.json(results);
|
||||
} catch (error) {
|
||||
console.error('Error fetching forecast data:', error);
|
||||
res.status(500).json({ error: 'Failed to fetch forecast data' });
|
||||
}
|
||||
});
|
||||
|
||||
module.exports = router;
|
||||
Reference in New Issue
Block a user