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 {
|
try {
|
||||||
const pool = req.app.locals.pool;
|
const pool = req.app.locals.pool;
|
||||||
|
|
||||||
// Get profit margins by category
|
// Get profit margins by category with full path
|
||||||
const [byCategory] = await pool.query(`
|
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
|
SELECT
|
||||||
c.name as category,
|
c.name as category,
|
||||||
|
cp.path as categoryPath,
|
||||||
ROUND(
|
ROUND(
|
||||||
(SUM(o.price * o.quantity - p.cost_price * o.quantity) /
|
(SUM(o.price * o.quantity - p.cost_price * o.quantity) /
|
||||||
NULLIF(SUM(o.price * o.quantity), 0)) * 100, 1
|
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
|
LEFT JOIN orders o ON p.pid = o.pid
|
||||||
JOIN product_categories pc ON p.pid = pc.pid
|
JOIN product_categories pc ON p.pid = pc.pid
|
||||||
JOIN categories c ON pc.cat_id = c.cat_id
|
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)
|
WHERE o.date >= DATE_SUB(CURDATE(), INTERVAL 30 DAY)
|
||||||
GROUP BY c.name
|
GROUP BY c.name, cp.path
|
||||||
ORDER BY profitMargin DESC
|
ORDER BY profitMargin DESC
|
||||||
LIMIT 10
|
LIMIT 10
|
||||||
`);
|
`);
|
||||||
@@ -106,10 +127,31 @@ router.get('/profit', async (req, res) => {
|
|||||||
ORDER BY formatted_date
|
ORDER BY formatted_date
|
||||||
`);
|
`);
|
||||||
|
|
||||||
// Get top performing products
|
// Get top performing products with category paths
|
||||||
const [topProducts] = await pool.query(`
|
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
|
SELECT
|
||||||
p.title as product,
|
p.title as product,
|
||||||
|
c.name as category,
|
||||||
|
cp.path as categoryPath,
|
||||||
ROUND(
|
ROUND(
|
||||||
(SUM(o.price * o.quantity - p.cost_price * o.quantity) /
|
(SUM(o.price * o.quantity - p.cost_price * o.quantity) /
|
||||||
NULLIF(SUM(o.price * o.quantity), 0)) * 100, 1
|
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
|
CAST(SUM(p.cost_price * o.quantity) AS DECIMAL(15,3)) as cost
|
||||||
FROM products p
|
FROM products p
|
||||||
LEFT JOIN orders o ON p.pid = o.pid
|
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)
|
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
|
HAVING revenue > 0
|
||||||
ORDER BY profitMargin DESC
|
ORDER BY profitMargin DESC
|
||||||
LIMIT 10
|
LIMIT 10
|
||||||
@@ -446,11 +491,36 @@ router.get('/categories', async (req, res) => {
|
|||||||
try {
|
try {
|
||||||
const pool = req.app.locals.pool;
|
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(`
|
const [performance] = await pool.query(`
|
||||||
WITH monthly_sales AS (
|
${categoryPathCTE},
|
||||||
|
monthly_sales AS (
|
||||||
SELECT
|
SELECT
|
||||||
c.name,
|
c.name,
|
||||||
|
cp.path,
|
||||||
SUM(CASE
|
SUM(CASE
|
||||||
WHEN o.date >= DATE_SUB(CURDATE(), INTERVAL 30 DAY)
|
WHEN o.date >= DATE_SUB(CURDATE(), INTERVAL 30 DAY)
|
||||||
THEN o.price * o.quantity
|
THEN o.price * o.quantity
|
||||||
@@ -466,11 +536,13 @@ router.get('/categories', async (req, res) => {
|
|||||||
LEFT JOIN orders o ON p.pid = o.pid
|
LEFT JOIN orders o ON p.pid = o.pid
|
||||||
JOIN product_categories pc ON p.pid = pc.pid
|
JOIN product_categories pc ON p.pid = pc.pid
|
||||||
JOIN categories c ON pc.cat_id = c.cat_id
|
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)
|
WHERE o.date >= DATE_SUB(CURDATE(), INTERVAL 60 DAY)
|
||||||
GROUP BY c.name
|
GROUP BY c.name, cp.path
|
||||||
)
|
)
|
||||||
SELECT
|
SELECT
|
||||||
c.name as category,
|
c.name as category,
|
||||||
|
cp.path as categoryPath,
|
||||||
SUM(o.price * o.quantity) as revenue,
|
SUM(o.price * o.quantity) as revenue,
|
||||||
SUM(o.price * o.quantity - p.cost_price * o.quantity) as profit,
|
SUM(o.price * o.quantity - p.cost_price * o.quantity) as profit,
|
||||||
ROUND(
|
ROUND(
|
||||||
@@ -482,43 +554,51 @@ router.get('/categories', async (req, res) => {
|
|||||||
LEFT JOIN orders o ON p.pid = o.pid
|
LEFT JOIN orders o ON p.pid = o.pid
|
||||||
JOIN product_categories pc ON p.pid = pc.pid
|
JOIN product_categories pc ON p.pid = pc.pid
|
||||||
JOIN categories c ON pc.cat_id = c.cat_id
|
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)
|
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
|
HAVING revenue > 0
|
||||||
ORDER BY revenue DESC
|
ORDER BY revenue DESC
|
||||||
LIMIT 10
|
LIMIT 10
|
||||||
`);
|
`);
|
||||||
|
|
||||||
// Get category revenue distribution
|
// Get category revenue distribution with full path
|
||||||
const [distribution] = await pool.query(`
|
const [distribution] = await pool.query(`
|
||||||
|
${categoryPathCTE}
|
||||||
SELECT
|
SELECT
|
||||||
c.name as category,
|
c.name as category,
|
||||||
|
cp.path as categoryPath,
|
||||||
SUM(o.price * o.quantity) as value
|
SUM(o.price * o.quantity) as value
|
||||||
FROM products p
|
FROM products p
|
||||||
LEFT JOIN orders o ON p.pid = o.pid
|
LEFT JOIN orders o ON p.pid = o.pid
|
||||||
JOIN product_categories pc ON p.pid = pc.pid
|
JOIN product_categories pc ON p.pid = pc.pid
|
||||||
JOIN categories c ON pc.cat_id = c.cat_id
|
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)
|
WHERE o.date >= DATE_SUB(CURDATE(), INTERVAL 30 DAY)
|
||||||
GROUP BY c.name
|
GROUP BY c.name, cp.path
|
||||||
HAVING value > 0
|
HAVING value > 0
|
||||||
ORDER BY value DESC
|
ORDER BY value DESC
|
||||||
LIMIT 6
|
LIMIT 6
|
||||||
`);
|
`);
|
||||||
|
|
||||||
// Get category sales trends
|
// Get category sales trends with full path
|
||||||
const [trends] = await pool.query(`
|
const [trends] = await pool.query(`
|
||||||
|
${categoryPathCTE}
|
||||||
SELECT
|
SELECT
|
||||||
c.name as category,
|
c.name as category,
|
||||||
|
cp.path as categoryPath,
|
||||||
DATE_FORMAT(o.date, '%b %Y') as month,
|
DATE_FORMAT(o.date, '%b %Y') as month,
|
||||||
SUM(o.price * o.quantity) as sales
|
SUM(o.price * o.quantity) as sales
|
||||||
FROM products p
|
FROM products p
|
||||||
LEFT JOIN orders o ON p.pid = o.pid
|
LEFT JOIN orders o ON p.pid = o.pid
|
||||||
JOIN product_categories pc ON p.pid = pc.pid
|
JOIN product_categories pc ON p.pid = pc.pid
|
||||||
JOIN categories c ON pc.cat_id = c.cat_id
|
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)
|
WHERE o.date >= DATE_SUB(CURDATE(), INTERVAL 6 MONTH)
|
||||||
GROUP BY
|
GROUP BY
|
||||||
c.name,
|
c.name,
|
||||||
|
cp.path,
|
||||||
DATE_FORMAT(o.date, '%b %Y'),
|
DATE_FORMAT(o.date, '%b %Y'),
|
||||||
DATE_FORMAT(o.date, '%Y-%m')
|
DATE_FORMAT(o.date, '%Y-%m')
|
||||||
ORDER BY
|
ORDER BY
|
||||||
@@ -535,76 +615,97 @@ router.get('/categories', async (req, res) => {
|
|||||||
|
|
||||||
// Forecast endpoint
|
// Forecast endpoint
|
||||||
router.get('/forecast', async (req, res) => {
|
router.get('/forecast', async (req, res) => {
|
||||||
try {
|
try {
|
||||||
const { brand, startDate, endDate } = req.query;
|
const { brand, startDate, endDate } = req.query;
|
||||||
const pool = req.app.locals.pool;
|
const pool = req.app.locals.pool;
|
||||||
|
|
||||||
const [results] = await pool.query(`
|
const [results] = await pool.query(`
|
||||||
WITH category_metrics AS (
|
WITH RECURSIVE category_path AS (
|
||||||
SELECT
|
SELECT
|
||||||
c.cat_id,
|
c.cat_id,
|
||||||
c.name as category_name,
|
c.name,
|
||||||
p.brand,
|
c.parent_id,
|
||||||
COUNT(DISTINCT p.pid) as num_products,
|
CAST(c.name AS CHAR(1000)) as path
|
||||||
CAST(COALESCE(ROUND(SUM(o.quantity) / DATEDIFF(?, ?), 2), 0) AS DECIMAL(15,3)) as avg_daily_sales,
|
FROM categories c
|
||||||
COALESCE(SUM(o.quantity), 0) as total_sold,
|
WHERE c.parent_id IS NULL
|
||||||
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
|
UNION ALL
|
||||||
FROM categories c
|
|
||||||
JOIN product_categories pc ON c.cat_id = pc.cat_id
|
SELECT
|
||||||
JOIN products p ON pc.pid = p.pid
|
c.cat_id,
|
||||||
LEFT JOIN product_metrics pm ON p.pid = pm.pid
|
c.name,
|
||||||
LEFT JOIN orders o ON p.pid = o.pid
|
c.parent_id,
|
||||||
AND o.date BETWEEN ? AND ?
|
CONCAT(cp.path, ' > ', c.name)
|
||||||
AND o.canceled = false
|
FROM categories c
|
||||||
WHERE p.brand = ?
|
JOIN category_path cp ON c.parent_id = cp.cat_id
|
||||||
AND pm.first_received_date BETWEEN ? AND ?
|
),
|
||||||
GROUP BY c.cat_id, c.name, p.brand
|
category_metrics AS (
|
||||||
),
|
SELECT
|
||||||
product_metrics AS (
|
c.cat_id,
|
||||||
SELECT
|
c.name as category_name,
|
||||||
p.pid,
|
cp.path,
|
||||||
p.title,
|
p.brand,
|
||||||
p.SKU,
|
COUNT(DISTINCT p.pid) as num_products,
|
||||||
p.stock_quantity,
|
CAST(COALESCE(ROUND(SUM(o.quantity) / DATEDIFF(?, ?), 2), 0) AS DECIMAL(15,3)) as avg_daily_sales,
|
||||||
pc.cat_id,
|
COALESCE(SUM(o.quantity), 0) as total_sold,
|
||||||
pm.first_received_date,
|
CAST(COALESCE(ROUND(SUM(o.quantity) / COUNT(DISTINCT p.pid), 2), 0) AS DECIMAL(15,3)) as avgTotalSold,
|
||||||
COALESCE(SUM(o.quantity), 0) as total_sold,
|
CAST(COALESCE(ROUND(AVG(o.price), 2), 0) AS DECIMAL(15,3)) as avg_price
|
||||||
CAST(COALESCE(ROUND(AVG(o.price), 2), 0) AS DECIMAL(15,3)) as avg_price
|
FROM categories c
|
||||||
FROM products p
|
JOIN product_categories pc ON c.cat_id = pc.cat_id
|
||||||
JOIN product_categories pc ON p.pid = pc.pid
|
JOIN products p ON pc.pid = p.pid
|
||||||
JOIN product_metrics pm ON p.pid = pm.pid
|
JOIN category_path cp ON c.cat_id = cp.cat_id
|
||||||
LEFT JOIN orders o ON p.pid = o.pid
|
LEFT JOIN product_metrics pmet ON p.pid = pmet.pid
|
||||||
AND o.date BETWEEN ? AND ?
|
LEFT JOIN orders o ON p.pid = o.pid
|
||||||
AND o.canceled = false
|
AND o.date BETWEEN ? AND ?
|
||||||
WHERE p.brand = ?
|
AND o.canceled = false
|
||||||
AND pm.first_received_date BETWEEN ? AND ?
|
WHERE p.brand = ?
|
||||||
GROUP BY p.pid, p.title, p.SKU, p.stock_quantity, pc.cat_id, pm.first_received_date
|
AND pmet.first_received_date BETWEEN ? AND ?
|
||||||
)
|
GROUP BY c.cat_id, c.name, cp.path, p.brand
|
||||||
SELECT
|
),
|
||||||
cm.*,
|
product_details AS (
|
||||||
JSON_ARRAYAGG(
|
SELECT
|
||||||
JSON_OBJECT(
|
p.pid,
|
||||||
'pid', pm.pid,
|
p.title,
|
||||||
'title', pm.title,
|
p.SKU,
|
||||||
'SKU', pm.SKU,
|
p.stock_quantity,
|
||||||
'stock_quantity', pm.stock_quantity,
|
pc.cat_id,
|
||||||
'total_sold', pm.total_sold,
|
pmet.first_received_date,
|
||||||
'avg_price', pm.avg_price,
|
COALESCE(SUM(o.quantity), 0) as total_sold,
|
||||||
'first_received_date', DATE_FORMAT(pm.first_received_date, '%Y-%m-%d')
|
CAST(COALESCE(ROUND(AVG(o.price), 2), 0) AS DECIMAL(15,3)) as avg_price
|
||||||
)
|
FROM products p
|
||||||
) as products
|
JOIN product_categories pc ON p.pid = pc.pid
|
||||||
FROM category_metrics cm
|
JOIN product_metrics pmet ON p.pid = pmet.pid
|
||||||
JOIN product_metrics pm ON cm.cat_id = pm.cat_id
|
LEFT JOIN orders o ON p.pid = o.pid
|
||||||
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
|
AND o.date BETWEEN ? AND ?
|
||||||
ORDER BY cm.total_sold DESC
|
AND o.canceled = false
|
||||||
`, [startDate, endDate, startDate, endDate, brand, startDate, endDate, startDate, endDate, brand, startDate, endDate]);
|
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);
|
res.json(results);
|
||||||
} catch (error) {
|
} catch (error) {
|
||||||
console.error('Error fetching forecast data:', error);
|
console.error('Error fetching forecast data:', error);
|
||||||
res.status(500).json({ error: 'Failed to fetch forecast data' });
|
res.status(500).json({ error: 'Failed to fetch forecast data' });
|
||||||
}
|
}
|
||||||
});
|
});
|
||||||
|
|
||||||
module.exports = router;
|
module.exports = router;
|
||||||
@@ -5,60 +5,84 @@ const router = express.Router();
|
|||||||
router.get('/', async (req, res) => {
|
router.get('/', async (req, res) => {
|
||||||
const pool = req.app.locals.pool;
|
const pool = req.app.locals.pool;
|
||||||
try {
|
try {
|
||||||
// Get parent categories for filter dropdown
|
// Get all categories with metrics and hierarchy info
|
||||||
const [parentCategories] = await pool.query(`
|
|
||||||
SELECT DISTINCT c2.name as parent_name
|
|
||||||
FROM categories c1
|
|
||||||
JOIN categories c2 ON c1.parent_cat_id = c2.cat_id
|
|
||||||
WHERE c1.parent_cat_id IS NOT NULL
|
|
||||||
ORDER BY c2.name
|
|
||||||
`);
|
|
||||||
|
|
||||||
// Get all categories with metrics
|
|
||||||
const [categories] = await pool.query(`
|
const [categories] = await pool.query(`
|
||||||
SELECT
|
SELECT
|
||||||
c.cat_id,
|
c.cat_id,
|
||||||
c.name,
|
c.name,
|
||||||
|
c.type,
|
||||||
|
c.parent_id,
|
||||||
c.description,
|
c.description,
|
||||||
COALESCE(p.name, '') as parent_name,
|
c.status,
|
||||||
|
p.name as parent_name,
|
||||||
|
p.type as parent_type,
|
||||||
COALESCE(cm.product_count, 0) as product_count,
|
COALESCE(cm.product_count, 0) as product_count,
|
||||||
|
COALESCE(cm.active_products, 0) as active_products,
|
||||||
CAST(COALESCE(cm.total_value, 0) AS DECIMAL(15,3)) as total_value,
|
CAST(COALESCE(cm.total_value, 0) AS DECIMAL(15,3)) as total_value,
|
||||||
COALESCE(cm.avg_margin, 0) as avg_margin,
|
COALESCE(cm.avg_margin, 0) as avg_margin,
|
||||||
COALESCE(cm.turnover_rate, 0) as turnover_rate,
|
COALESCE(cm.turnover_rate, 0) as turnover_rate,
|
||||||
COALESCE(cm.growth_rate, 0) as growth_rate,
|
COALESCE(cm.growth_rate, 0) as growth_rate
|
||||||
COALESCE(cm.status, 'inactive') as status
|
|
||||||
FROM categories c
|
FROM categories c
|
||||||
LEFT JOIN categories p ON c.parent_cat_id = p.cat_id
|
LEFT JOIN categories p ON c.parent_id = p.cat_id
|
||||||
LEFT JOIN category_metrics cm ON c.cat_id = cm.cat_id
|
LEFT JOIN category_metrics cm ON c.cat_id = cm.category_id
|
||||||
ORDER BY c.name ASC
|
ORDER BY
|
||||||
|
CASE
|
||||||
|
WHEN c.type = 10 THEN 1 -- sections first
|
||||||
|
WHEN c.type = 11 THEN 2 -- categories second
|
||||||
|
WHEN c.type = 12 THEN 3 -- subcategories third
|
||||||
|
WHEN c.type = 13 THEN 4 -- subsubcategories fourth
|
||||||
|
WHEN c.type = 20 THEN 5 -- themes fifth
|
||||||
|
WHEN c.type = 21 THEN 6 -- subthemes last
|
||||||
|
ELSE 7
|
||||||
|
END,
|
||||||
|
c.name ASC
|
||||||
`);
|
`);
|
||||||
|
|
||||||
// Get overall stats
|
// Get overall stats
|
||||||
const [stats] = await pool.query(`
|
const [stats] = await pool.query(`
|
||||||
SELECT
|
SELECT
|
||||||
COUNT(DISTINCT c.cat_id) as totalCategories,
|
COUNT(DISTINCT c.cat_id) as totalCategories,
|
||||||
COUNT(DISTINCT CASE WHEN cm.status = 'active' THEN c.cat_id END) as activeCategories,
|
COUNT(DISTINCT CASE WHEN c.status = 'active' THEN c.cat_id END) as activeCategories,
|
||||||
CAST(COALESCE(SUM(cm.total_value), 0) AS DECIMAL(15,3)) as totalValue,
|
CAST(COALESCE(SUM(cm.total_value), 0) AS DECIMAL(15,3)) as totalValue,
|
||||||
COALESCE(ROUND(AVG(NULLIF(cm.avg_margin, 0)), 1), 0) as avgMargin,
|
COALESCE(ROUND(AVG(NULLIF(cm.avg_margin, 0)), 1), 0) as avgMargin,
|
||||||
COALESCE(ROUND(AVG(NULLIF(cm.growth_rate, 0)), 1), 0) as avgGrowth
|
COALESCE(ROUND(AVG(NULLIF(cm.growth_rate, 0)), 1), 0) as avgGrowth
|
||||||
FROM categories c
|
FROM categories c
|
||||||
LEFT JOIN category_metrics cm ON c.cat_id = cm.cat_id
|
LEFT JOIN category_metrics cm ON c.cat_id = cm.category_id
|
||||||
|
`);
|
||||||
|
|
||||||
|
// Get type counts for filtering
|
||||||
|
const [typeCounts] = await pool.query(`
|
||||||
|
SELECT
|
||||||
|
type,
|
||||||
|
COUNT(*) as count
|
||||||
|
FROM categories
|
||||||
|
GROUP BY type
|
||||||
|
ORDER BY type
|
||||||
`);
|
`);
|
||||||
|
|
||||||
res.json({
|
res.json({
|
||||||
categories: categories.map(cat => ({
|
categories: categories.map(cat => ({
|
||||||
id: cat.cat_id,
|
cat_id: cat.cat_id,
|
||||||
name: cat.name,
|
name: cat.name,
|
||||||
|
type: cat.type,
|
||||||
|
parent_id: cat.parent_id,
|
||||||
|
parent_name: cat.parent_name,
|
||||||
|
parent_type: cat.parent_type,
|
||||||
description: cat.description,
|
description: cat.description,
|
||||||
parent_category: cat.parent_name,
|
status: cat.status,
|
||||||
product_count: parseInt(cat.product_count),
|
metrics: {
|
||||||
total_value: parseFloat(cat.total_value),
|
product_count: parseInt(cat.product_count),
|
||||||
avg_margin: parseFloat(cat.avg_margin),
|
active_products: parseInt(cat.active_products),
|
||||||
turnover_rate: parseFloat(cat.turnover_rate),
|
total_value: parseFloat(cat.total_value),
|
||||||
growth_rate: parseFloat(cat.growth_rate),
|
avg_margin: parseFloat(cat.avg_margin),
|
||||||
status: cat.status
|
turnover_rate: parseFloat(cat.turnover_rate),
|
||||||
|
growth_rate: parseFloat(cat.growth_rate)
|
||||||
|
}
|
||||||
|
})),
|
||||||
|
typeCounts: typeCounts.map(tc => ({
|
||||||
|
type: tc.type,
|
||||||
|
count: parseInt(tc.count)
|
||||||
})),
|
})),
|
||||||
parentCategories: parentCategories.map(p => p.parent_name),
|
|
||||||
stats: {
|
stats: {
|
||||||
totalCategories: parseInt(stats[0].totalCategories),
|
totalCategories: parseInt(stats[0].totalCategories),
|
||||||
activeCategories: parseInt(stats[0].activeCategories),
|
activeCategories: parseInt(stats[0].activeCategories),
|
||||||
|
|||||||
@@ -443,198 +443,116 @@ router.get('/overstock/products', async (req, res) => {
|
|||||||
// Returns best-selling products, vendors, and categories
|
// Returns best-selling products, vendors, and categories
|
||||||
router.get('/best-sellers', async (req, res) => {
|
router.get('/best-sellers', async (req, res) => {
|
||||||
try {
|
try {
|
||||||
const [products] = await executeQuery(`
|
const pool = req.app.locals.pool;
|
||||||
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 [brands] = await executeQuery(`
|
// Common CTE for category paths
|
||||||
WITH brand_sales AS (
|
const categoryPathCTE = `
|
||||||
SELECT
|
WITH RECURSIVE category_path AS (
|
||||||
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 (
|
|
||||||
SELECT
|
SELECT
|
||||||
c.cat_id,
|
c.cat_id,
|
||||||
c.name,
|
c.name,
|
||||||
-- Current period (last 30 days)
|
c.parent_id,
|
||||||
SUM(CASE
|
CAST(c.name AS CHAR(1000)) as path
|
||||||
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
|
FROM categories c
|
||||||
JOIN product_categories pc ON c.cat_id = pc.cat_id
|
WHERE c.parent_id IS NULL
|
||||||
JOIN products p ON pc.pid = p.pid
|
|
||||||
JOIN orders o ON p.pid = o.pid
|
UNION ALL
|
||||||
WHERE o.canceled = false
|
|
||||||
AND o.date >= DATE_SUB(CURRENT_DATE, INTERVAL 60 DAY)
|
SELECT
|
||||||
GROUP BY c.cat_id, c.name
|
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
|
SELECT
|
||||||
cat_id,
|
p.pid,
|
||||||
name,
|
p.SKU as sku,
|
||||||
units_sold,
|
p.title,
|
||||||
revenue,
|
SUM(o.quantity) as units_sold,
|
||||||
profit,
|
CAST(SUM(o.price * o.quantity) AS DECIMAL(15,3)) as revenue,
|
||||||
CASE
|
CAST(SUM(o.price * o.quantity - p.cost_price * o.quantity) AS DECIMAL(15,3)) as profit
|
||||||
WHEN previous_revenue > 0
|
FROM products p
|
||||||
THEN ((revenue - previous_revenue) / previous_revenue * 100)
|
JOIN orders o ON p.pid = o.pid
|
||||||
WHEN revenue > 0
|
WHERE o.date >= DATE_SUB(CURDATE(), INTERVAL 30 DAY)
|
||||||
THEN 100
|
AND o.canceled = false
|
||||||
ELSE 0
|
GROUP BY p.pid
|
||||||
END as growth_rate
|
ORDER BY units_sold DESC
|
||||||
FROM category_sales
|
LIMIT 10
|
||||||
WHERE units_sold > 0
|
|
||||||
ORDER BY revenue DESC
|
|
||||||
LIMIT 50
|
|
||||||
`);
|
`);
|
||||||
|
|
||||||
// Format response with explicit type conversion
|
// Get best selling brands
|
||||||
const formattedProducts = products.map(p => ({
|
const [brands] = await pool.query(`
|
||||||
pid: p.pid,
|
SELECT
|
||||||
sku: p.sku,
|
p.brand,
|
||||||
title: p.title,
|
SUM(o.quantity) as units_sold,
|
||||||
units_sold: parseInt(p.units_sold) || 0,
|
CAST(SUM(o.price * o.quantity) AS DECIMAL(15,3)) as revenue,
|
||||||
revenue: p.revenue.toString(),
|
CAST(SUM(o.price * o.quantity - p.cost_price * o.quantity) AS DECIMAL(15,3)) as profit,
|
||||||
profit: p.profit.toString(),
|
ROUND(
|
||||||
growth_rate: p.growth_rate.toString()
|
((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 => ({
|
// Get best selling categories with full path
|
||||||
brand: b.brand,
|
const [categories] = await pool.query(`
|
||||||
units_sold: parseInt(b.units_sold) || 0,
|
${categoryPathCTE}
|
||||||
revenue: b.revenue.toString(),
|
SELECT
|
||||||
profit: b.profit.toString(),
|
c.cat_id,
|
||||||
growth_rate: b.growth_rate.toString()
|
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 => ({
|
res.json({ products, brands, categories });
|
||||||
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
|
|
||||||
});
|
|
||||||
} catch (err) {
|
} catch (err) {
|
||||||
console.error('Error fetching best sellers:', err);
|
console.error('Error fetching best sellers:', err);
|
||||||
res.status(500).json({ error: 'Failed to fetch best sellers' });
|
res.status(500).json({ error: 'Failed to fetch best sellers' });
|
||||||
|
|||||||
@@ -167,32 +167,64 @@ router.get('/', async (req, res) => {
|
|||||||
|
|
||||||
// Main query with all fields
|
// Main query with all fields
|
||||||
const query = `
|
const query = `
|
||||||
WITH product_thresholds AS (
|
WITH RECURSIVE
|
||||||
SELECT
|
category_path AS (
|
||||||
p.pid,
|
SELECT
|
||||||
COALESCE(
|
c.cat_id,
|
||||||
(SELECT overstock_days FROM stock_thresholds st
|
c.name,
|
||||||
WHERE st.category_id IN (
|
c.parent_id,
|
||||||
SELECT pc.cat_id
|
CAST(c.name AS CHAR(1000)) as path
|
||||||
FROM product_categories pc
|
FROM categories c
|
||||||
WHERE pc.pid = p.pid
|
WHERE c.parent_id IS NULL
|
||||||
)
|
|
||||||
AND (st.vendor = p.vendor OR st.vendor IS NULL)
|
UNION ALL
|
||||||
ORDER BY st.vendor IS NULL
|
|
||||||
LIMIT 1),
|
SELECT
|
||||||
(SELECT overstock_days FROM stock_thresholds st
|
c.cat_id,
|
||||||
WHERE st.category_id IS NULL
|
c.name,
|
||||||
AND (st.vendor = p.vendor OR st.vendor IS NULL)
|
c.parent_id,
|
||||||
ORDER BY st.vendor IS NULL
|
CONCAT(cp.path, ' > ', c.name)
|
||||||
LIMIT 1),
|
FROM categories c
|
||||||
90
|
JOIN category_path cp ON c.parent_id = cp.cat_id
|
||||||
) as target_days
|
),
|
||||||
FROM products p
|
product_thresholds AS (
|
||||||
)
|
SELECT
|
||||||
|
p.pid,
|
||||||
|
COALESCE(
|
||||||
|
(SELECT overstock_days FROM stock_thresholds st
|
||||||
|
WHERE st.category_id IN (
|
||||||
|
SELECT pc.cat_id
|
||||||
|
FROM product_categories pc
|
||||||
|
WHERE pc.pid = p.pid
|
||||||
|
)
|
||||||
|
AND (st.vendor = p.vendor OR st.vendor IS NULL)
|
||||||
|
ORDER BY st.vendor IS NULL
|
||||||
|
LIMIT 1),
|
||||||
|
(SELECT overstock_days FROM stock_thresholds st
|
||||||
|
WHERE st.category_id IS NULL
|
||||||
|
AND (st.vendor = p.vendor OR st.vendor IS NULL)
|
||||||
|
ORDER BY st.vendor IS NULL
|
||||||
|
LIMIT 1),
|
||||||
|
90
|
||||||
|
) as target_days
|
||||||
|
FROM products p
|
||||||
|
),
|
||||||
|
product_leaf_categories AS (
|
||||||
|
-- Find categories that aren't parents to other categories for this product
|
||||||
|
SELECT DISTINCT pc.cat_id
|
||||||
|
FROM product_categories pc
|
||||||
|
WHERE NOT EXISTS (
|
||||||
|
SELECT 1
|
||||||
|
FROM categories child
|
||||||
|
JOIN product_categories child_pc ON child.cat_id = child_pc.cat_id
|
||||||
|
WHERE child.parent_id = pc.cat_id
|
||||||
|
AND child_pc.pid = pc.pid
|
||||||
|
)
|
||||||
|
)
|
||||||
SELECT
|
SELECT
|
||||||
p.*,
|
p.*,
|
||||||
COALESCE(p.brand, 'Unbranded') as brand,
|
COALESCE(p.brand, 'Unbranded') as brand,
|
||||||
GROUP_CONCAT(DISTINCT c.name) as categories,
|
GROUP_CONCAT(DISTINCT CONCAT(c.cat_id, ':', c.name)) as categories,
|
||||||
pm.daily_sales_avg,
|
pm.daily_sales_avg,
|
||||||
pm.weekly_sales_avg,
|
pm.weekly_sales_avg,
|
||||||
pm.monthly_sales_avg,
|
pm.monthly_sales_avg,
|
||||||
@@ -227,7 +259,8 @@ router.get('/', async (req, res) => {
|
|||||||
LEFT JOIN product_categories pc ON p.pid = pc.pid
|
LEFT JOIN product_categories pc ON p.pid = pc.pid
|
||||||
LEFT JOIN categories c ON pc.cat_id = c.cat_id
|
LEFT JOIN categories c ON pc.cat_id = c.cat_id
|
||||||
LEFT JOIN product_thresholds pt ON p.pid = pt.pid
|
LEFT JOIN product_thresholds pt ON p.pid = pt.pid
|
||||||
${whereClause}
|
JOIN product_leaf_categories plc ON c.cat_id = plc.cat_id
|
||||||
|
${whereClause ? 'WHERE ' + whereClause.substring(6) : ''}
|
||||||
GROUP BY p.pid
|
GROUP BY p.pid
|
||||||
ORDER BY ${sortColumn} ${sortDirection}
|
ORDER BY ${sortColumn} ${sortDirection}
|
||||||
LIMIT ? OFFSET ?
|
LIMIT ? OFFSET ?
|
||||||
@@ -351,130 +384,160 @@ router.get('/trending', async (req, res) => {
|
|||||||
|
|
||||||
// Get a single product
|
// Get a single product
|
||||||
router.get('/:id', async (req, res) => {
|
router.get('/:id', async (req, res) => {
|
||||||
const pool = req.app.locals.pool;
|
|
||||||
try {
|
try {
|
||||||
// Get basic product data with metrics
|
const pool = req.app.locals.pool;
|
||||||
const [rows] = await pool.query(
|
const id = parseInt(req.params.id);
|
||||||
`SELECT
|
|
||||||
|
// 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 product details with category paths
|
||||||
|
const [productRows] = await pool.query(`
|
||||||
|
SELECT
|
||||||
p.*,
|
p.*,
|
||||||
GROUP_CONCAT(DISTINCT c.name) as categories,
|
|
||||||
pm.daily_sales_avg,
|
pm.daily_sales_avg,
|
||||||
pm.weekly_sales_avg,
|
pm.weekly_sales_avg,
|
||||||
pm.monthly_sales_avg,
|
pm.monthly_sales_avg,
|
||||||
pm.days_of_inventory,
|
pm.days_of_inventory,
|
||||||
pm.reorder_point,
|
pm.reorder_point,
|
||||||
pm.safety_stock,
|
pm.safety_stock,
|
||||||
|
pm.stock_status,
|
||||||
|
pm.abc_class,
|
||||||
pm.avg_margin_percent,
|
pm.avg_margin_percent,
|
||||||
pm.total_revenue,
|
pm.total_revenue,
|
||||||
pm.inventory_value,
|
pm.inventory_value,
|
||||||
pm.turnover_rate,
|
pm.turnover_rate,
|
||||||
pm.abc_class,
|
pm.gmroi,
|
||||||
pm.stock_status,
|
pm.cost_of_goods_sold,
|
||||||
|
pm.gross_profit,
|
||||||
pm.avg_lead_time_days,
|
pm.avg_lead_time_days,
|
||||||
pm.current_lead_time,
|
pm.current_lead_time,
|
||||||
pm.target_lead_time,
|
pm.target_lead_time,
|
||||||
pm.lead_time_status,
|
pm.lead_time_status,
|
||||||
pm.gmroi,
|
pm.reorder_qty,
|
||||||
pm.cost_of_goods_sold,
|
pm.overstocked_amt
|
||||||
pm.gross_profit
|
|
||||||
FROM products p
|
FROM products p
|
||||||
LEFT JOIN product_metrics pm ON p.pid = pm.pid
|
LEFT JOIN product_metrics pm ON p.pid = pm.pid
|
||||||
LEFT JOIN product_categories pc ON p.pid = pc.pid
|
WHERE p.pid = ?
|
||||||
LEFT JOIN categories c ON pc.cat_id = c.cat_id
|
`, [id]);
|
||||||
WHERE p.pid = ? AND p.visible = true
|
|
||||||
GROUP BY p.pid`,
|
if (!productRows.length) {
|
||||||
[req.params.id]
|
|
||||||
);
|
|
||||||
|
|
||||||
if (rows.length === 0) {
|
|
||||||
return res.status(404).json({ error: 'Product not found' });
|
return res.status(404).json({ error: 'Product not found' });
|
||||||
}
|
}
|
||||||
|
|
||||||
// Get vendor performance metrics
|
// Get categories and their paths separately to avoid GROUP BY issues
|
||||||
const [vendorMetrics] = await pool.query(
|
const [categoryRows] = await pool.query(`
|
||||||
`SELECT * FROM vendor_metrics WHERE vendor = ?`,
|
WITH RECURSIVE
|
||||||
[rows[0].vendor]
|
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
|
||||||
|
),
|
||||||
|
product_leaf_categories AS (
|
||||||
|
-- Find categories assigned to this product that aren't parents
|
||||||
|
-- of other categories assigned to this product
|
||||||
|
SELECT pc.cat_id
|
||||||
|
FROM product_categories pc
|
||||||
|
WHERE pc.pid = ?
|
||||||
|
AND NOT EXISTS (
|
||||||
|
-- Check if there are any child categories also assigned to this product
|
||||||
|
SELECT 1
|
||||||
|
FROM categories child
|
||||||
|
JOIN product_categories child_pc ON child.cat_id = child_pc.cat_id
|
||||||
|
WHERE child.parent_id = pc.cat_id
|
||||||
|
AND child_pc.pid = pc.pid
|
||||||
|
)
|
||||||
|
)
|
||||||
|
SELECT
|
||||||
|
c.cat_id,
|
||||||
|
c.name as category_name,
|
||||||
|
cp.path as full_path
|
||||||
|
FROM product_categories pc
|
||||||
|
JOIN categories c ON pc.cat_id = c.cat_id
|
||||||
|
JOIN category_path cp ON c.cat_id = cp.cat_id
|
||||||
|
JOIN product_leaf_categories plc ON c.cat_id = plc.cat_id
|
||||||
|
WHERE pc.pid = ?
|
||||||
|
ORDER BY cp.path
|
||||||
|
`, [id, id]);
|
||||||
|
|
||||||
|
// Transform the results
|
||||||
|
const categoryPathMap = categoryRows.reduce((acc, row) => {
|
||||||
|
// Use cat_id in the key to differentiate categories with the same name
|
||||||
|
acc[`${row.cat_id}:${row.category_name}`] = row.full_path;
|
||||||
|
return acc;
|
||||||
|
}, {});
|
||||||
|
|
||||||
// Transform the data to match frontend expectations
|
|
||||||
const product = {
|
const product = {
|
||||||
// Basic product info
|
...productRows[0],
|
||||||
pid: rows[0].pid,
|
// Include cat_id in categories array to match the keys in categoryPathMap
|
||||||
title: rows[0].title,
|
categories: categoryRows.map(row => `${row.cat_id}:${row.category_name}`),
|
||||||
SKU: rows[0].SKU,
|
category_paths: categoryPathMap,
|
||||||
barcode: rows[0].barcode,
|
price: parseFloat(productRows[0].price),
|
||||||
created_at: rows[0].created_at,
|
regular_price: parseFloat(productRows[0].regular_price),
|
||||||
updated_at: rows[0].updated_at,
|
cost_price: parseFloat(productRows[0].cost_price),
|
||||||
|
landing_cost_price: parseFloat(productRows[0].landing_cost_price),
|
||||||
// Inventory fields
|
stock_quantity: parseInt(productRows[0].stock_quantity),
|
||||||
stock_quantity: parseInt(rows[0].stock_quantity),
|
moq: parseInt(productRows[0].moq),
|
||||||
moq: parseInt(rows[0].moq),
|
uom: parseInt(productRows[0].uom),
|
||||||
uom: parseInt(rows[0].uom),
|
managing_stock: Boolean(productRows[0].managing_stock),
|
||||||
managing_stock: Boolean(rows[0].managing_stock),
|
replenishable: Boolean(productRows[0].replenishable),
|
||||||
replenishable: Boolean(rows[0].replenishable),
|
daily_sales_avg: parseFloat(productRows[0].daily_sales_avg) || 0,
|
||||||
|
weekly_sales_avg: parseFloat(productRows[0].weekly_sales_avg) || 0,
|
||||||
// Pricing fields
|
monthly_sales_avg: parseFloat(productRows[0].monthly_sales_avg) || 0,
|
||||||
price: parseFloat(rows[0].price),
|
avg_quantity_per_order: parseFloat(productRows[0].avg_quantity_per_order) || 0,
|
||||||
regular_price: parseFloat(rows[0].regular_price),
|
number_of_orders: parseInt(productRows[0].number_of_orders) || 0,
|
||||||
cost_price: parseFloat(rows[0].cost_price),
|
first_sale_date: productRows[0].first_sale_date || null,
|
||||||
landing_cost_price: parseFloat(rows[0].landing_cost_price),
|
last_sale_date: productRows[0].last_sale_date || null,
|
||||||
|
days_of_inventory: parseFloat(productRows[0].days_of_inventory) || 0,
|
||||||
// Categorization
|
weeks_of_inventory: parseFloat(productRows[0].weeks_of_inventory) || 0,
|
||||||
categories: rows[0].categories ? rows[0].categories.split(',') : [],
|
reorder_point: parseFloat(productRows[0].reorder_point) || 0,
|
||||||
tags: rows[0].tags ? rows[0].tags.split(',') : [],
|
safety_stock: parseFloat(productRows[0].safety_stock) || 0,
|
||||||
options: rows[0].options ? JSON.parse(rows[0].options) : {},
|
avg_margin_percent: parseFloat(productRows[0].avg_margin_percent) || 0,
|
||||||
|
total_revenue: parseFloat(productRows[0].total_revenue) || 0,
|
||||||
// Vendor info
|
inventory_value: parseFloat(productRows[0].inventory_value) || 0,
|
||||||
vendor: rows[0].vendor,
|
cost_of_goods_sold: parseFloat(productRows[0].cost_of_goods_sold) || 0,
|
||||||
vendor_reference: rows[0].vendor_reference,
|
gross_profit: parseFloat(productRows[0].gross_profit) || 0,
|
||||||
brand: rows[0].brand,
|
gmroi: parseFloat(productRows[0].gmroi) || 0,
|
||||||
|
avg_lead_time_days: parseFloat(productRows[0].avg_lead_time_days) || 0,
|
||||||
// URLs
|
current_lead_time: parseFloat(productRows[0].current_lead_time) || 0,
|
||||||
permalink: rows[0].permalink,
|
target_lead_time: parseFloat(productRows[0].target_lead_time) || 0,
|
||||||
image: rows[0].image,
|
lead_time_status: productRows[0].lead_time_status || null,
|
||||||
|
reorder_qty: parseInt(productRows[0].reorder_qty) || 0,
|
||||||
// Metrics
|
overstocked_amt: parseInt(productRows[0].overstocked_amt) || 0
|
||||||
metrics: {
|
|
||||||
// Sales metrics
|
|
||||||
daily_sales_avg: parseFloat(rows[0].daily_sales_avg) || 0,
|
|
||||||
weekly_sales_avg: parseFloat(rows[0].weekly_sales_avg) || 0,
|
|
||||||
monthly_sales_avg: parseFloat(rows[0].monthly_sales_avg) || 0,
|
|
||||||
|
|
||||||
// Inventory metrics
|
|
||||||
days_of_inventory: parseInt(rows[0].days_of_inventory) || 0,
|
|
||||||
reorder_point: parseInt(rows[0].reorder_point) || 0,
|
|
||||||
safety_stock: parseInt(rows[0].safety_stock) || 0,
|
|
||||||
stock_status: rows[0].stock_status || 'Unknown',
|
|
||||||
abc_class: rows[0].abc_class || 'C',
|
|
||||||
|
|
||||||
// Financial metrics
|
|
||||||
avg_margin_percent: parseFloat(rows[0].avg_margin_percent) || 0,
|
|
||||||
total_revenue: parseFloat(rows[0].total_revenue) || 0,
|
|
||||||
inventory_value: parseFloat(rows[0].inventory_value) || 0,
|
|
||||||
turnover_rate: parseFloat(rows[0].turnover_rate) || 0,
|
|
||||||
gmroi: parseFloat(rows[0].gmroi) || 0,
|
|
||||||
cost_of_goods_sold: parseFloat(rows[0].cost_of_goods_sold) || 0,
|
|
||||||
gross_profit: parseFloat(rows[0].gross_profit) || 0,
|
|
||||||
|
|
||||||
// Lead time metrics
|
|
||||||
avg_lead_time_days: parseInt(rows[0].avg_lead_time_days) || 0,
|
|
||||||
current_lead_time: parseInt(rows[0].current_lead_time) || 0,
|
|
||||||
target_lead_time: parseInt(rows[0].target_lead_time) || 14,
|
|
||||||
lead_time_status: rows[0].lead_time_status || 'Unknown',
|
|
||||||
reorder_qty: parseInt(rows[0].reorder_qty) || 0,
|
|
||||||
overstocked_amt: parseInt(rows[0].overstocked_amt) || 0
|
|
||||||
},
|
|
||||||
|
|
||||||
// Vendor performance (if available)
|
|
||||||
vendor_performance: vendorMetrics.length ? {
|
|
||||||
avg_lead_time_days: parseFloat(vendorMetrics[0].avg_lead_time_days) || 0,
|
|
||||||
on_time_delivery_rate: parseFloat(vendorMetrics[0].on_time_delivery_rate) || 0,
|
|
||||||
order_fill_rate: parseFloat(vendorMetrics[0].order_fill_rate) || 0,
|
|
||||||
total_orders: parseInt(vendorMetrics[0].total_orders) || 0,
|
|
||||||
total_late_orders: parseInt(vendorMetrics[0].total_late_orders) || 0,
|
|
||||||
total_purchase_value: parseFloat(vendorMetrics[0].total_purchase_value) || 0,
|
|
||||||
avg_order_value: parseFloat(vendorMetrics[0].avg_order_value) || 0
|
|
||||||
} : null
|
|
||||||
};
|
};
|
||||||
|
|
||||||
res.json(product);
|
res.json(product);
|
||||||
|
|||||||
@@ -6,6 +6,7 @@ import config from '../../config';
|
|||||||
interface CategoryData {
|
interface CategoryData {
|
||||||
performance: {
|
performance: {
|
||||||
category: string;
|
category: string;
|
||||||
|
categoryPath: string; // Full hierarchy path
|
||||||
revenue: number;
|
revenue: number;
|
||||||
profit: number;
|
profit: number;
|
||||||
growth: number;
|
growth: number;
|
||||||
@@ -13,10 +14,12 @@ interface CategoryData {
|
|||||||
}[];
|
}[];
|
||||||
distribution: {
|
distribution: {
|
||||||
category: string;
|
category: string;
|
||||||
|
categoryPath: string; // Full hierarchy path
|
||||||
value: number;
|
value: number;
|
||||||
}[];
|
}[];
|
||||||
trends: {
|
trends: {
|
||||||
category: string;
|
category: string;
|
||||||
|
categoryPath: string; // Full hierarchy path
|
||||||
month: string;
|
month: string;
|
||||||
sales: number;
|
sales: number;
|
||||||
}[];
|
}[];
|
||||||
@@ -36,6 +39,7 @@ export function CategoryPerformance() {
|
|||||||
return {
|
return {
|
||||||
performance: rawData.performance.map((item: any) => ({
|
performance: rawData.performance.map((item: any) => ({
|
||||||
...item,
|
...item,
|
||||||
|
categoryPath: item.categoryPath || item.category,
|
||||||
revenue: Number(item.revenue) || 0,
|
revenue: Number(item.revenue) || 0,
|
||||||
profit: Number(item.profit) || 0,
|
profit: Number(item.profit) || 0,
|
||||||
growth: Number(item.growth) || 0,
|
growth: Number(item.growth) || 0,
|
||||||
@@ -43,10 +47,12 @@ export function CategoryPerformance() {
|
|||||||
})),
|
})),
|
||||||
distribution: rawData.distribution.map((item: any) => ({
|
distribution: rawData.distribution.map((item: any) => ({
|
||||||
...item,
|
...item,
|
||||||
|
categoryPath: item.categoryPath || item.category,
|
||||||
value: Number(item.value) || 0
|
value: Number(item.value) || 0
|
||||||
})),
|
})),
|
||||||
trends: rawData.trends.map((item: any) => ({
|
trends: rawData.trends.map((item: any) => ({
|
||||||
...item,
|
...item,
|
||||||
|
categoryPath: item.categoryPath || item.category,
|
||||||
sales: Number(item.sales) || 0
|
sales: Number(item.sales) || 0
|
||||||
}))
|
}))
|
||||||
};
|
};
|
||||||
@@ -63,6 +69,8 @@ export function CategoryPerformance() {
|
|||||||
return <span className={color}>{value}</span>;
|
return <span className={color}>{value}</span>;
|
||||||
};
|
};
|
||||||
|
|
||||||
|
const getShortCategoryName = (path: string) => path.split(' > ').pop() || path;
|
||||||
|
|
||||||
return (
|
return (
|
||||||
<div className="grid gap-4">
|
<div className="grid gap-4">
|
||||||
<div className="grid gap-4 md:grid-cols-2">
|
<div className="grid gap-4 md:grid-cols-2">
|
||||||
@@ -76,24 +84,34 @@ export function CategoryPerformance() {
|
|||||||
<Pie
|
<Pie
|
||||||
data={data.distribution}
|
data={data.distribution}
|
||||||
dataKey="value"
|
dataKey="value"
|
||||||
nameKey="category"
|
nameKey="categoryPath"
|
||||||
cx="50%"
|
cx="50%"
|
||||||
cy="50%"
|
cy="50%"
|
||||||
outerRadius={100}
|
outerRadius={100}
|
||||||
fill="#8884d8"
|
fill="#8884d8"
|
||||||
label={(entry) => entry.category}
|
label={({ categoryPath }) => getShortCategoryName(categoryPath)}
|
||||||
>
|
>
|
||||||
{data.distribution.map((entry, index) => (
|
{data.distribution.map((entry, index) => (
|
||||||
<Cell
|
<Cell
|
||||||
key={entry.category}
|
key={`${entry.category}-${index}`}
|
||||||
fill={COLORS[index % COLORS.length]}
|
fill={COLORS[index % COLORS.length]}
|
||||||
/>
|
/>
|
||||||
))}
|
))}
|
||||||
</Pie>
|
</Pie>
|
||||||
<Tooltip
|
<Tooltip
|
||||||
formatter={(value: number) => [`$${value.toLocaleString()}`, 'Revenue']}
|
formatter={(value: number, name: string, props: any) => [
|
||||||
|
`$${value.toLocaleString()}`,
|
||||||
|
<div key="tooltip">
|
||||||
|
<div className="font-medium">Category Path:</div>
|
||||||
|
<div className="text-sm text-muted-foreground">{props.payload.categoryPath}</div>
|
||||||
|
<div className="mt-1">Revenue</div>
|
||||||
|
</div>
|
||||||
|
]}
|
||||||
|
/>
|
||||||
|
<Legend
|
||||||
|
formatter={(value) => getShortCategoryName(value)}
|
||||||
|
wrapperStyle={{ fontSize: '12px' }}
|
||||||
/>
|
/>
|
||||||
<Legend />
|
|
||||||
</PieChart>
|
</PieChart>
|
||||||
</ResponsiveContainer>
|
</ResponsiveContainer>
|
||||||
</CardContent>
|
</CardContent>
|
||||||
@@ -106,10 +124,33 @@ export function CategoryPerformance() {
|
|||||||
<CardContent>
|
<CardContent>
|
||||||
<ResponsiveContainer width="100%" height={300}>
|
<ResponsiveContainer width="100%" height={300}>
|
||||||
<BarChart data={data.performance}>
|
<BarChart data={data.performance}>
|
||||||
<XAxis dataKey="category" />
|
<XAxis
|
||||||
|
dataKey="categoryPath"
|
||||||
|
tick={({ x, y, payload }) => (
|
||||||
|
<g transform={`translate(${x},${y})`}>
|
||||||
|
<text
|
||||||
|
x={0}
|
||||||
|
y={0}
|
||||||
|
dy={16}
|
||||||
|
textAnchor="end"
|
||||||
|
fill="#888888"
|
||||||
|
transform="rotate(-35)"
|
||||||
|
>
|
||||||
|
{getShortCategoryName(payload.value)}
|
||||||
|
</text>
|
||||||
|
</g>
|
||||||
|
)}
|
||||||
|
/>
|
||||||
<YAxis tickFormatter={(value) => `${value}%`} />
|
<YAxis tickFormatter={(value) => `${value}%`} />
|
||||||
<Tooltip
|
<Tooltip
|
||||||
formatter={(value: number) => [`${value.toFixed(1)}%`, 'Growth Rate']}
|
formatter={(value: number, name: string, props: any) => [
|
||||||
|
`${value.toFixed(1)}%`,
|
||||||
|
<div key="tooltip">
|
||||||
|
<div className="font-medium">Category Path:</div>
|
||||||
|
<div className="text-sm text-muted-foreground">{props.payload.categoryPath}</div>
|
||||||
|
<div className="mt-1">Growth Rate</div>
|
||||||
|
</div>
|
||||||
|
]}
|
||||||
/>
|
/>
|
||||||
<Bar
|
<Bar
|
||||||
dataKey="growth"
|
dataKey="growth"
|
||||||
@@ -131,8 +172,11 @@ export function CategoryPerformance() {
|
|||||||
{data.performance.map((category) => (
|
{data.performance.map((category) => (
|
||||||
<div key={category.category} className="flex items-center">
|
<div key={category.category} className="flex items-center">
|
||||||
<div className="flex-1">
|
<div className="flex-1">
|
||||||
<p className="text-sm font-medium">{category.category}</p>
|
<div className="space-y-1">
|
||||||
<p className="text-sm text-muted-foreground">
|
<p className="text-sm font-medium">{getShortCategoryName(category.categoryPath)}</p>
|
||||||
|
<p className="text-xs text-muted-foreground">{category.categoryPath}</p>
|
||||||
|
</div>
|
||||||
|
<p className="text-sm text-muted-foreground mt-1">
|
||||||
{category.productCount} products
|
{category.productCount} products
|
||||||
</p>
|
</p>
|
||||||
</div>
|
</div>
|
||||||
|
|||||||
@@ -6,6 +6,7 @@ import config from '../../config';
|
|||||||
interface ProfitData {
|
interface ProfitData {
|
||||||
byCategory: {
|
byCategory: {
|
||||||
category: string;
|
category: string;
|
||||||
|
categoryPath: string; // Full hierarchy path
|
||||||
profitMargin: number;
|
profitMargin: number;
|
||||||
revenue: number;
|
revenue: number;
|
||||||
cost: number;
|
cost: number;
|
||||||
@@ -18,6 +19,8 @@ interface ProfitData {
|
|||||||
}[];
|
}[];
|
||||||
topProducts: {
|
topProducts: {
|
||||||
product: string;
|
product: string;
|
||||||
|
category: string;
|
||||||
|
categoryPath: string; // Full hierarchy path
|
||||||
profitMargin: number;
|
profitMargin: number;
|
||||||
revenue: number;
|
revenue: number;
|
||||||
cost: number;
|
cost: number;
|
||||||
@@ -36,6 +39,7 @@ export function ProfitAnalysis() {
|
|||||||
return {
|
return {
|
||||||
byCategory: rawData.byCategory.map((item: any) => ({
|
byCategory: rawData.byCategory.map((item: any) => ({
|
||||||
...item,
|
...item,
|
||||||
|
categoryPath: item.categoryPath || item.category,
|
||||||
profitMargin: Number(item.profitMargin) || 0,
|
profitMargin: Number(item.profitMargin) || 0,
|
||||||
revenue: Number(item.revenue) || 0,
|
revenue: Number(item.revenue) || 0,
|
||||||
cost: Number(item.cost) || 0
|
cost: Number(item.cost) || 0
|
||||||
@@ -48,6 +52,7 @@ export function ProfitAnalysis() {
|
|||||||
})),
|
})),
|
||||||
topProducts: rawData.topProducts.map((item: any) => ({
|
topProducts: rawData.topProducts.map((item: any) => ({
|
||||||
...item,
|
...item,
|
||||||
|
categoryPath: item.categoryPath || item.category,
|
||||||
profitMargin: Number(item.profitMargin) || 0,
|
profitMargin: Number(item.profitMargin) || 0,
|
||||||
revenue: Number(item.revenue) || 0,
|
revenue: Number(item.revenue) || 0,
|
||||||
cost: Number(item.cost) || 0
|
cost: Number(item.cost) || 0
|
||||||
@@ -60,6 +65,8 @@ export function ProfitAnalysis() {
|
|||||||
return <div>Loading profit analysis...</div>;
|
return <div>Loading profit analysis...</div>;
|
||||||
}
|
}
|
||||||
|
|
||||||
|
const getShortCategoryName = (path: string) => path.split(' > ').pop() || path;
|
||||||
|
|
||||||
return (
|
return (
|
||||||
<div className="grid gap-4">
|
<div className="grid gap-4">
|
||||||
<div className="grid gap-4 md:grid-cols-2">
|
<div className="grid gap-4 md:grid-cols-2">
|
||||||
@@ -70,10 +77,33 @@ export function ProfitAnalysis() {
|
|||||||
<CardContent>
|
<CardContent>
|
||||||
<ResponsiveContainer width="100%" height={300}>
|
<ResponsiveContainer width="100%" height={300}>
|
||||||
<BarChart data={data.byCategory}>
|
<BarChart data={data.byCategory}>
|
||||||
<XAxis dataKey="category" />
|
<XAxis
|
||||||
|
dataKey="categoryPath"
|
||||||
|
tick={({ x, y, payload }) => (
|
||||||
|
<g transform={`translate(${x},${y})`}>
|
||||||
|
<text
|
||||||
|
x={0}
|
||||||
|
y={0}
|
||||||
|
dy={16}
|
||||||
|
textAnchor="end"
|
||||||
|
fill="#888888"
|
||||||
|
transform="rotate(-35)"
|
||||||
|
>
|
||||||
|
{getShortCategoryName(payload.value)}
|
||||||
|
</text>
|
||||||
|
</g>
|
||||||
|
)}
|
||||||
|
/>
|
||||||
<YAxis tickFormatter={(value) => `${value}%`} />
|
<YAxis tickFormatter={(value) => `${value}%`} />
|
||||||
<Tooltip
|
<Tooltip
|
||||||
formatter={(value: number) => [`${value.toFixed(1)}%`, 'Profit Margin']}
|
formatter={(value: number, name: string, props: any) => [
|
||||||
|
`${value.toFixed(1)}%`,
|
||||||
|
<div key="tooltip">
|
||||||
|
<div className="font-medium">Category Path:</div>
|
||||||
|
<div className="text-sm text-muted-foreground">{props.payload.categoryPath}</div>
|
||||||
|
<div className="mt-1">Profit Margin</div>
|
||||||
|
</div>
|
||||||
|
]}
|
||||||
/>
|
/>
|
||||||
<Bar
|
<Bar
|
||||||
dataKey="profitMargin"
|
dataKey="profitMargin"
|
||||||
@@ -123,7 +153,11 @@ export function ProfitAnalysis() {
|
|||||||
<div key={product.product} className="flex items-center">
|
<div key={product.product} className="flex items-center">
|
||||||
<div className="flex-1">
|
<div className="flex-1">
|
||||||
<p className="text-sm font-medium">{product.product}</p>
|
<p className="text-sm font-medium">{product.product}</p>
|
||||||
<p className="text-sm text-muted-foreground">
|
<div className="text-xs text-muted-foreground space-y-1">
|
||||||
|
<p className="font-medium">Category:</p>
|
||||||
|
<p>{product.categoryPath}</p>
|
||||||
|
</div>
|
||||||
|
<p className="text-sm text-muted-foreground mt-1">
|
||||||
Revenue: ${product.revenue.toLocaleString()}
|
Revenue: ${product.revenue.toLocaleString()}
|
||||||
</p>
|
</p>
|
||||||
</div>
|
</div>
|
||||||
|
|||||||
@@ -18,6 +18,7 @@ interface Product {
|
|||||||
interface Category {
|
interface Category {
|
||||||
cat_id: number;
|
cat_id: number;
|
||||||
name: string;
|
name: string;
|
||||||
|
categoryPath: string;
|
||||||
units_sold: number;
|
units_sold: number;
|
||||||
revenue: string;
|
revenue: string;
|
||||||
profit: string;
|
profit: string;
|
||||||
@@ -159,7 +160,14 @@ export function BestSellers() {
|
|||||||
<TableBody>
|
<TableBody>
|
||||||
{data?.categories.map((category) => (
|
{data?.categories.map((category) => (
|
||||||
<TableRow key={category.cat_id}>
|
<TableRow key={category.cat_id}>
|
||||||
<TableCell>{category.name}</TableCell>
|
<TableCell>
|
||||||
|
<div className="font-medium">{category.name}</div>
|
||||||
|
{category.categoryPath && (
|
||||||
|
<div className="text-sm text-muted-foreground">
|
||||||
|
{category.categoryPath}
|
||||||
|
</div>
|
||||||
|
)}
|
||||||
|
</TableCell>
|
||||||
<TableCell className="text-right">{category.units_sold}</TableCell>
|
<TableCell className="text-right">{category.units_sold}</TableCell>
|
||||||
<TableCell className="text-right">{formatCurrency(Number(category.revenue))}</TableCell>
|
<TableCell className="text-right">{formatCurrency(Number(category.revenue))}</TableCell>
|
||||||
<TableCell className="text-right">{formatCurrency(Number(category.profit))}</TableCell>
|
<TableCell className="text-right">{formatCurrency(Number(category.profit))}</TableCell>
|
||||||
|
|||||||
@@ -17,6 +17,7 @@ interface Product {
|
|||||||
|
|
||||||
export interface ForecastItem {
|
export interface ForecastItem {
|
||||||
category: string;
|
category: string;
|
||||||
|
categoryPath: string;
|
||||||
avgDailySales: number;
|
avgDailySales: number;
|
||||||
totalSold: number;
|
totalSold: number;
|
||||||
numProducts: number;
|
numProducts: number;
|
||||||
@@ -44,6 +45,16 @@ export const columns: ColumnDef<ForecastItem>[] = [
|
|||||||
{
|
{
|
||||||
accessorKey: "category",
|
accessorKey: "category",
|
||||||
header: "Category",
|
header: "Category",
|
||||||
|
cell: ({ row }) => (
|
||||||
|
<div>
|
||||||
|
<div className="font-medium">{row.original.category}</div>
|
||||||
|
{row.original.categoryPath && (
|
||||||
|
<div className="text-sm text-muted-foreground">
|
||||||
|
{row.original.categoryPath}
|
||||||
|
</div>
|
||||||
|
)}
|
||||||
|
</div>
|
||||||
|
),
|
||||||
},
|
},
|
||||||
{
|
{
|
||||||
accessorKey: "avgDailySales",
|
accessorKey: "avgDailySales",
|
||||||
|
|||||||
@@ -123,6 +123,8 @@ interface Product {
|
|||||||
notes: string;
|
notes: string;
|
||||||
lead_time_days: number | null;
|
lead_time_days: number | null;
|
||||||
}>;
|
}>;
|
||||||
|
|
||||||
|
category_paths?: Record<string, string>;
|
||||||
}
|
}
|
||||||
|
|
||||||
interface ProductDetailProps {
|
interface ProductDetailProps {
|
||||||
@@ -255,22 +257,28 @@ export function ProductDetail({ productId, onClose }: ProductDetailProps) {
|
|||||||
</div>
|
</div>
|
||||||
<div>
|
<div>
|
||||||
<dt className="text-sm text-muted-foreground">Categories</dt>
|
<dt className="text-sm text-muted-foreground">Categories</dt>
|
||||||
<dd className="flex flex-wrap gap-2">
|
<dd className="flex flex-col gap-2">
|
||||||
{product?.categories?.map(category => (
|
{product?.category_paths ?
|
||||||
<span key={category} className="inline-flex items-center rounded-md bg-muted px-2 py-1 text-xs font-medium ring-1 ring-inset ring-muted">
|
Object.entries(product.category_paths).map(([key, fullPath], index) => {
|
||||||
{category}
|
const [, leafCategory] = key.split(':');
|
||||||
</span>
|
return (
|
||||||
)) || "N/A"}
|
<div key={key} className="flex flex-col">
|
||||||
|
<span className="inline-flex items-center rounded-md bg-muted px-2 py-1 text-xs font-medium ring-1 ring-inset ring-muted">
|
||||||
|
{leafCategory}
|
||||||
|
</span>
|
||||||
|
<span className="text-xs text-muted-foreground ml-2 mt-1">
|
||||||
|
{fullPath}
|
||||||
|
</span>
|
||||||
|
</div>
|
||||||
|
);
|
||||||
|
})
|
||||||
|
: "N/A"}
|
||||||
</dd>
|
</dd>
|
||||||
</div>
|
</div>
|
||||||
<div>
|
<div>
|
||||||
<dt className="text-sm text-muted-foreground">Tags</dt>
|
<dt className="text-sm text-muted-foreground">Tags</dt>
|
||||||
<dd className="flex flex-wrap gap-2">
|
<dd className="flex flex-wrap gap-2">
|
||||||
{product?.tags?.map(tag => (
|
N/A
|
||||||
<span key={tag} className="inline-flex items-center rounded-md bg-muted px-2 py-1 text-xs font-medium ring-1 ring-inset ring-muted">
|
|
||||||
{tag}
|
|
||||||
</span>
|
|
||||||
)) || "N/A"}
|
|
||||||
</dd>
|
</dd>
|
||||||
</div>
|
</div>
|
||||||
</dl>
|
</dl>
|
||||||
@@ -307,11 +315,11 @@ export function ProductDetail({ productId, onClose }: ProductDetailProps) {
|
|||||||
</div>
|
</div>
|
||||||
<div>
|
<div>
|
||||||
<dt className="text-sm text-muted-foreground">Status</dt>
|
<dt className="text-sm text-muted-foreground">Status</dt>
|
||||||
<dd>{product?.metrics?.stock_status}</dd>
|
<dd>{product?.stock_status || "N/A"}</dd>
|
||||||
</div>
|
</div>
|
||||||
<div>
|
<div>
|
||||||
<dt className="text-sm text-muted-foreground">Days of Stock</dt>
|
<dt className="text-sm text-muted-foreground">Days of Stock</dt>
|
||||||
<dd>{product?.metrics?.days_of_inventory} days</dd>
|
<dd>{product?.days_of_inventory || 0} days</dd>
|
||||||
</div>
|
</div>
|
||||||
</dl>
|
</dl>
|
||||||
</Card>
|
</Card>
|
||||||
@@ -321,15 +329,15 @@ export function ProductDetail({ productId, onClose }: ProductDetailProps) {
|
|||||||
<dl className="space-y-2">
|
<dl className="space-y-2">
|
||||||
<div>
|
<div>
|
||||||
<dt className="text-sm text-muted-foreground">Daily Sales</dt>
|
<dt className="text-sm text-muted-foreground">Daily Sales</dt>
|
||||||
<dd>{product?.metrics?.daily_sales_avg?.toFixed(1)} units</dd>
|
<dd>{product?.daily_sales_avg?.toFixed(1) || "0.0"} units</dd>
|
||||||
</div>
|
</div>
|
||||||
<div>
|
<div>
|
||||||
<dt className="text-sm text-muted-foreground">Weekly Sales</dt>
|
<dt className="text-sm text-muted-foreground">Weekly Sales</dt>
|
||||||
<dd>{product?.metrics?.weekly_sales_avg?.toFixed(1)} units</dd>
|
<dd>{product?.weekly_sales_avg?.toFixed(1) || "0.0"} units</dd>
|
||||||
</div>
|
</div>
|
||||||
<div>
|
<div>
|
||||||
<dt className="text-sm text-muted-foreground">Monthly Sales</dt>
|
<dt className="text-sm text-muted-foreground">Monthly Sales</dt>
|
||||||
<dd>{product?.metrics?.monthly_sales_avg?.toFixed(1)} units</dd>
|
<dd>{product?.monthly_sales_avg?.toFixed(1) || "0.0"} units</dd>
|
||||||
</div>
|
</div>
|
||||||
</dl>
|
</dl>
|
||||||
</Card>
|
</Card>
|
||||||
@@ -356,19 +364,19 @@ export function ProductDetail({ productId, onClose }: ProductDetailProps) {
|
|||||||
<dl className="space-y-2">
|
<dl className="space-y-2">
|
||||||
<div>
|
<div>
|
||||||
<dt className="text-sm text-muted-foreground">Total Revenue</dt>
|
<dt className="text-sm text-muted-foreground">Total Revenue</dt>
|
||||||
<dd>${formatPrice(product?.metrics.total_revenue)}</dd>
|
<dd>${formatPrice(product?.total_revenue)}</dd>
|
||||||
</div>
|
</div>
|
||||||
<div>
|
<div>
|
||||||
<dt className="text-sm text-muted-foreground">Gross Profit</dt>
|
<dt className="text-sm text-muted-foreground">Gross Profit</dt>
|
||||||
<dd>${formatPrice(product?.metrics.gross_profit)}</dd>
|
<dd>${formatPrice(product?.gross_profit)}</dd>
|
||||||
</div>
|
</div>
|
||||||
<div>
|
<div>
|
||||||
<dt className="text-sm text-muted-foreground">Margin</dt>
|
<dt className="text-sm text-muted-foreground">Margin</dt>
|
||||||
<dd>{product?.metrics.avg_margin_percent.toFixed(2)}%</dd>
|
<dd>{product?.avg_margin_percent?.toFixed(2) || "0.00"}%</dd>
|
||||||
</div>
|
</div>
|
||||||
<div>
|
<div>
|
||||||
<dt className="text-sm text-muted-foreground">GMROI</dt>
|
<dt className="text-sm text-muted-foreground">GMROI</dt>
|
||||||
<dd>{product?.metrics.gmroi.toFixed(2)}</dd>
|
<dd>{product?.gmroi?.toFixed(2) || "0.00"}</dd>
|
||||||
</div>
|
</div>
|
||||||
</dl>
|
</dl>
|
||||||
</Card>
|
</Card>
|
||||||
@@ -378,15 +386,15 @@ export function ProductDetail({ productId, onClose }: ProductDetailProps) {
|
|||||||
<dl className="space-y-2">
|
<dl className="space-y-2">
|
||||||
<div>
|
<div>
|
||||||
<dt className="text-sm text-muted-foreground">Current Lead Time</dt>
|
<dt className="text-sm text-muted-foreground">Current Lead Time</dt>
|
||||||
<dd>{product?.metrics.current_lead_time}</dd>
|
<dd>{product?.current_lead_time || "N/A"}</dd>
|
||||||
</div>
|
</div>
|
||||||
<div>
|
<div>
|
||||||
<dt className="text-sm text-muted-foreground">Target Lead Time</dt>
|
<dt className="text-sm text-muted-foreground">Target Lead Time</dt>
|
||||||
<dd>{product?.metrics.target_lead_time}</dd>
|
<dd>{product?.target_lead_time || "N/A"}</dd>
|
||||||
</div>
|
</div>
|
||||||
<div>
|
<div>
|
||||||
<dt className="text-sm text-muted-foreground">Lead Time Status</dt>
|
<dt className="text-sm text-muted-foreground">Lead Time Status</dt>
|
||||||
<dd>{product?.metrics.lead_time_status}</dd>
|
<dd>{product?.lead_time_status || "N/A"}</dd>
|
||||||
</div>
|
</div>
|
||||||
</dl>
|
</dl>
|
||||||
</Card>
|
</Card>
|
||||||
@@ -408,11 +416,11 @@ export function ProductDetail({ productId, onClose }: ProductDetailProps) {
|
|||||||
</div>
|
</div>
|
||||||
<div>
|
<div>
|
||||||
<dt className="text-sm text-muted-foreground">Days of Inventory</dt>
|
<dt className="text-sm text-muted-foreground">Days of Inventory</dt>
|
||||||
<dd className="text-2xl font-semibold">{product?.metrics?.days_of_inventory || 0}</dd>
|
<dd className="text-2xl font-semibold">{product?.days_of_inventory || 0}</dd>
|
||||||
</div>
|
</div>
|
||||||
<div>
|
<div>
|
||||||
<dt className="text-sm text-muted-foreground">Status</dt>
|
<dt className="text-sm text-muted-foreground">Status</dt>
|
||||||
<dd className="text-2xl font-semibold">{product?.metrics?.stock_status || "N/A"}</dd>
|
<dd className="text-2xl font-semibold">{product?.stock_status || "N/A"}</dd>
|
||||||
</div>
|
</div>
|
||||||
</dl>
|
</dl>
|
||||||
</Card>
|
</Card>
|
||||||
@@ -422,15 +430,15 @@ export function ProductDetail({ productId, onClose }: ProductDetailProps) {
|
|||||||
<dl className="grid grid-cols-3 gap-4">
|
<dl className="grid grid-cols-3 gap-4">
|
||||||
<div>
|
<div>
|
||||||
<dt className="text-sm text-muted-foreground">Reorder Point</dt>
|
<dt className="text-sm text-muted-foreground">Reorder Point</dt>
|
||||||
<dd>{product?.metrics?.reorder_point || 0}</dd>
|
<dd>{product?.reorder_point || 0}</dd>
|
||||||
</div>
|
</div>
|
||||||
<div>
|
<div>
|
||||||
<dt className="text-sm text-muted-foreground">Safety Stock</dt>
|
<dt className="text-sm text-muted-foreground">Safety Stock</dt>
|
||||||
<dd>{product?.metrics?.safety_stock || 0}</dd>
|
<dd>{product?.safety_stock || 0}</dd>
|
||||||
</div>
|
</div>
|
||||||
<div>
|
<div>
|
||||||
<dt className="text-sm text-muted-foreground">ABC Class</dt>
|
<dt className="text-sm text-muted-foreground">ABC Class</dt>
|
||||||
<dd>{product?.metrics?.abc_class || "N/A"}</dd>
|
<dd>{product?.abc_class || "N/A"}</dd>
|
||||||
</div>
|
</div>
|
||||||
</dl>
|
</dl>
|
||||||
</Card>
|
</Card>
|
||||||
@@ -551,15 +559,15 @@ export function ProductDetail({ productId, onClose }: ProductDetailProps) {
|
|||||||
<dl className="grid grid-cols-3 gap-4">
|
<dl className="grid grid-cols-3 gap-4">
|
||||||
<div>
|
<div>
|
||||||
<dt className="text-sm text-muted-foreground">Gross Profit</dt>
|
<dt className="text-sm text-muted-foreground">Gross Profit</dt>
|
||||||
<dd className="text-2xl font-semibold">${formatPrice(product?.metrics.gross_profit)}</dd>
|
<dd className="text-2xl font-semibold">${formatPrice(product?.gross_profit)}</dd>
|
||||||
</div>
|
</div>
|
||||||
<div>
|
<div>
|
||||||
<dt className="text-sm text-muted-foreground">GMROI</dt>
|
<dt className="text-sm text-muted-foreground">GMROI</dt>
|
||||||
<dd className="text-2xl font-semibold">{product?.metrics.gmroi.toFixed(2)}</dd>
|
<dd className="text-2xl font-semibold">{product?.gmroi?.toFixed(2) || "0.00"}</dd>
|
||||||
</div>
|
</div>
|
||||||
<div>
|
<div>
|
||||||
<dt className="text-sm text-muted-foreground">Margin %</dt>
|
<dt className="text-sm text-muted-foreground">Margin %</dt>
|
||||||
<dd className="text-2xl font-semibold">{product?.metrics.avg_margin_percent.toFixed(2)}%</dd>
|
<dd className="text-2xl font-semibold">{product?.avg_margin_percent?.toFixed(2) || "0.00"}%</dd>
|
||||||
</div>
|
</div>
|
||||||
</dl>
|
</dl>
|
||||||
</Card>
|
</Card>
|
||||||
@@ -569,7 +577,7 @@ export function ProductDetail({ productId, onClose }: ProductDetailProps) {
|
|||||||
<dl className="grid grid-cols-2 gap-4">
|
<dl className="grid grid-cols-2 gap-4">
|
||||||
<div>
|
<div>
|
||||||
<dt className="text-sm text-muted-foreground">Cost of Goods Sold</dt>
|
<dt className="text-sm text-muted-foreground">Cost of Goods Sold</dt>
|
||||||
<dd>${formatPrice(product?.metrics.cost_of_goods_sold)}</dd>
|
<dd>${formatPrice(product?.cost_of_goods_sold)}</dd>
|
||||||
</div>
|
</div>
|
||||||
<div>
|
<div>
|
||||||
<dt className="text-sm text-muted-foreground">Landing Cost</dt>
|
<dt className="text-sm text-muted-foreground">Landing Cost</dt>
|
||||||
|
|||||||
@@ -14,9 +14,9 @@ interface Category {
|
|||||||
name: string;
|
name: string;
|
||||||
type: number;
|
type: number;
|
||||||
parent_id: number | null;
|
parent_id: number | null;
|
||||||
|
parent_name: string | null;
|
||||||
|
parent_type: number | null;
|
||||||
description: string | null;
|
description: string | null;
|
||||||
created_at: string;
|
|
||||||
updated_at: string;
|
|
||||||
status: string;
|
status: string;
|
||||||
metrics?: {
|
metrics?: {
|
||||||
product_count: number;
|
product_count: number;
|
||||||
@@ -30,23 +30,41 @@ interface Category {
|
|||||||
|
|
||||||
interface CategoryFilters {
|
interface CategoryFilters {
|
||||||
search: string;
|
search: string;
|
||||||
parent: string;
|
type: string;
|
||||||
performance: string;
|
performance: string;
|
||||||
}
|
}
|
||||||
|
|
||||||
|
const TYPE_LABELS: Record<number, string> = {
|
||||||
|
10: 'Section',
|
||||||
|
11: 'Category',
|
||||||
|
12: 'Subcategory',
|
||||||
|
13: 'Sub-subcategory',
|
||||||
|
20: 'Theme',
|
||||||
|
21: 'Subtheme'
|
||||||
|
};
|
||||||
|
|
||||||
|
function getCategoryStatusVariant(status: string): "default" | "secondary" | "destructive" | "outline" {
|
||||||
|
switch (status.toLowerCase()) {
|
||||||
|
case 'active':
|
||||||
|
return 'default';
|
||||||
|
case 'inactive':
|
||||||
|
return 'secondary';
|
||||||
|
case 'archived':
|
||||||
|
return 'destructive';
|
||||||
|
default:
|
||||||
|
return 'outline';
|
||||||
|
}
|
||||||
|
}
|
||||||
|
|
||||||
export function Categories() {
|
export function Categories() {
|
||||||
const [page, setPage] = useState(1);
|
const [page, setPage] = useState(1);
|
||||||
const [sortColumn, setSortColumn] = useState<keyof Category>("name");
|
const [sortColumn, setSortColumn] = useState<keyof Category>("name");
|
||||||
const [sortDirection, setSortDirection] = useState<"asc" | "desc">("asc");
|
const [sortDirection, setSortDirection] = useState<"asc" | "desc">("asc");
|
||||||
const [filters, setFilters] = useState<CategoryFilters>({
|
const [filters, setFilters] = useState<CategoryFilters>({
|
||||||
search: "",
|
search: "",
|
||||||
parent: "all",
|
type: "all",
|
||||||
performance: "all",
|
performance: "all",
|
||||||
});
|
});
|
||||||
const [] = useState({
|
|
||||||
column: 'name',
|
|
||||||
direction: 'asc'
|
|
||||||
});
|
|
||||||
|
|
||||||
const { data, isLoading } = useQuery({
|
const { data, isLoading } = useQuery({
|
||||||
queryKey: ["categories"],
|
queryKey: ["categories"],
|
||||||
@@ -74,13 +92,9 @@ export function Categories() {
|
|||||||
);
|
);
|
||||||
}
|
}
|
||||||
|
|
||||||
// Apply parent filter
|
// Apply type filter
|
||||||
if (filters.parent !== 'all') {
|
if (filters.type !== 'all') {
|
||||||
if (filters.parent === 'none') {
|
filtered = filtered.filter(category => category.type === parseInt(filters.type));
|
||||||
filtered = filtered.filter(category => !category.parent_id);
|
|
||||||
} else {
|
|
||||||
filtered = filtered.filter(category => category.parent_id === Number(filters.parent));
|
|
||||||
}
|
|
||||||
}
|
}
|
||||||
|
|
||||||
// Apply performance filter
|
// Apply performance filter
|
||||||
@@ -99,6 +113,19 @@ export function Categories() {
|
|||||||
|
|
||||||
// Apply sorting
|
// Apply sorting
|
||||||
filtered.sort((a, b) => {
|
filtered.sort((a, b) => {
|
||||||
|
// First sort by type if not explicitly sorting by another column
|
||||||
|
if (sortColumn === "name") {
|
||||||
|
if (a.type !== b.type) {
|
||||||
|
return a.type - b.type;
|
||||||
|
}
|
||||||
|
// Then by parent hierarchy
|
||||||
|
if (a.parent_id !== b.parent_id) {
|
||||||
|
if (!a.parent_id) return -1;
|
||||||
|
if (!b.parent_id) return 1;
|
||||||
|
return a.parent_id - b.parent_id;
|
||||||
|
}
|
||||||
|
}
|
||||||
|
|
||||||
const aVal = a[sortColumn];
|
const aVal = a[sortColumn];
|
||||||
const bVal = b[sortColumn];
|
const bVal = b[sortColumn];
|
||||||
|
|
||||||
@@ -251,17 +278,18 @@ export function Categories() {
|
|||||||
className="h-8 w-[150px] lg:w-[250px]"
|
className="h-8 w-[150px] lg:w-[250px]"
|
||||||
/>
|
/>
|
||||||
<Select
|
<Select
|
||||||
value={filters.parent}
|
value={filters.type}
|
||||||
onValueChange={(value) => setFilters(prev => ({ ...prev, parent: value }))}
|
onValueChange={(value) => setFilters(prev => ({ ...prev, type: value }))}
|
||||||
>
|
>
|
||||||
<SelectTrigger className="h-8 w-[180px]">
|
<SelectTrigger className="h-8 w-[180px]">
|
||||||
<SelectValue placeholder="Parent Category" />
|
<SelectValue placeholder="Category Type" />
|
||||||
</SelectTrigger>
|
</SelectTrigger>
|
||||||
<SelectContent>
|
<SelectContent>
|
||||||
<SelectItem value="all">All Categories</SelectItem>
|
<SelectItem value="all">All Types</SelectItem>
|
||||||
<SelectItem value="none">Top Level Only</SelectItem>
|
{data?.typeCounts?.map(tc => (
|
||||||
{data?.parentCategories?.map((parent: string) => (
|
<SelectItem key={tc.type} value={tc.type.toString()}>
|
||||||
<SelectItem key={parent} value={parent}>{parent}</SelectItem>
|
{TYPE_LABELS[tc.type]} ({tc.count})
|
||||||
|
</SelectItem>
|
||||||
))}
|
))}
|
||||||
</SelectContent>
|
</SelectContent>
|
||||||
</Select>
|
</Select>
|
||||||
@@ -287,8 +315,8 @@ export function Categories() {
|
|||||||
<Table>
|
<Table>
|
||||||
<TableHeader>
|
<TableHeader>
|
||||||
<TableRow>
|
<TableRow>
|
||||||
<TableHead>Name</TableHead>
|
|
||||||
<TableHead>Type</TableHead>
|
<TableHead>Type</TableHead>
|
||||||
|
<TableHead>Name</TableHead>
|
||||||
<TableHead>Parent</TableHead>
|
<TableHead>Parent</TableHead>
|
||||||
<TableHead className="text-right">Products</TableHead>
|
<TableHead className="text-right">Products</TableHead>
|
||||||
<TableHead className="text-right">Active</TableHead>
|
<TableHead className="text-right">Active</TableHead>
|
||||||
@@ -302,15 +330,37 @@ export function Categories() {
|
|||||||
<TableBody>
|
<TableBody>
|
||||||
{isLoading ? (
|
{isLoading ? (
|
||||||
<TableRow>
|
<TableRow>
|
||||||
<TableCell colSpan={8} className="text-center py-8">
|
<TableCell colSpan={10} className="text-center py-8">
|
||||||
Loading categories...
|
Loading categories...
|
||||||
</TableCell>
|
</TableCell>
|
||||||
</TableRow>
|
</TableRow>
|
||||||
) : paginatedData.map((category: Category) => (
|
) : paginatedData.map((category: Category) => (
|
||||||
<TableRow key={category.cat_id}>
|
<TableRow key={category.cat_id}>
|
||||||
<TableCell>{category.name}</TableCell>
|
<TableCell>
|
||||||
<TableCell>{getPerformanceBadge(category.metrics?.growth_rate ?? 0)}</TableCell>
|
<Badge variant="outline">
|
||||||
<TableCell>{category.parent_id ? getParentName(category.parent_id) : '-'}</TableCell>
|
{TYPE_LABELS[category.type]}
|
||||||
|
</Badge>
|
||||||
|
</TableCell>
|
||||||
|
<TableCell>
|
||||||
|
<div className="flex flex-col gap-1">
|
||||||
|
<div className="flex items-center gap-2">
|
||||||
|
<span className="font-medium">{category.name}</span>
|
||||||
|
<Badge variant="outline" className="h-5">
|
||||||
|
{TYPE_LABELS[category.type]}
|
||||||
|
</Badge>
|
||||||
|
</div>
|
||||||
|
{category.description && (
|
||||||
|
<div className="text-xs text-muted-foreground">{category.description}</div>
|
||||||
|
)}
|
||||||
|
</div>
|
||||||
|
</TableCell>
|
||||||
|
<TableCell className="text-sm text-muted-foreground">
|
||||||
|
{category.type === 10 ? category.name : // Section
|
||||||
|
category.type === 11 ? `${category.parent_name}` : // Category
|
||||||
|
category.type === 12 ? `${category.parent_name} > ${category.name}` : // Subcategory
|
||||||
|
category.type === 13 ? `${category.parent_name} > ${category.name}` : // Sub-subcategory
|
||||||
|
category.parent_name ? `${category.parent_name} > ${category.name}` : category.name}
|
||||||
|
</TableCell>
|
||||||
<TableCell className="text-right">{category.metrics?.product_count || 0}</TableCell>
|
<TableCell className="text-right">{category.metrics?.product_count || 0}</TableCell>
|
||||||
<TableCell className="text-right">{category.metrics?.active_products || 0}</TableCell>
|
<TableCell className="text-right">{category.metrics?.active_products || 0}</TableCell>
|
||||||
<TableCell className="text-right">{formatCurrency(category.metrics?.total_value || 0)}</TableCell>
|
<TableCell className="text-right">{formatCurrency(category.metrics?.total_value || 0)}</TableCell>
|
||||||
@@ -326,7 +376,7 @@ export function Categories() {
|
|||||||
))}
|
))}
|
||||||
{!isLoading && !paginatedData.length && (
|
{!isLoading && !paginatedData.length && (
|
||||||
<TableRow>
|
<TableRow>
|
||||||
<TableCell colSpan={8} className="text-center py-8 text-muted-foreground">
|
<TableCell colSpan={10} className="text-center py-8 text-muted-foreground">
|
||||||
No categories found
|
No categories found
|
||||||
</TableCell>
|
</TableCell>
|
||||||
</TableRow>
|
</TableRow>
|
||||||
|
|||||||
@@ -60,6 +60,7 @@ export default function Forecasting() {
|
|||||||
const data = await response.json();
|
const data = await response.json();
|
||||||
return data.map((item: any) => ({
|
return data.map((item: any) => ({
|
||||||
category: item.category_name,
|
category: item.category_name,
|
||||||
|
categoryPath: item.path,
|
||||||
avgDailySales: Number(item.avg_daily_sales) || 0,
|
avgDailySales: Number(item.avg_daily_sales) || 0,
|
||||||
totalSold: Number(item.total_sold) || 0,
|
totalSold: Number(item.total_sold) || 0,
|
||||||
numProducts: Number(item.num_products) || 0,
|
numProducts: Number(item.num_products) || 0,
|
||||||
@@ -74,7 +75,8 @@ export default function Forecasting() {
|
|||||||
daily_sales_avg: Number(p.daily_sales_avg) || 0,
|
daily_sales_avg: Number(p.daily_sales_avg) || 0,
|
||||||
forecast_units: Number(p.forecast_units) || 0,
|
forecast_units: Number(p.forecast_units) || 0,
|
||||||
forecast_revenue: Number(p.forecast_revenue) || 0,
|
forecast_revenue: Number(p.forecast_revenue) || 0,
|
||||||
confidence_level: Number(p.confidence_level) || 0
|
confidence_level: Number(p.confidence_level) || 0,
|
||||||
|
categoryPath: item.path
|
||||||
}))
|
}))
|
||||||
}));
|
}));
|
||||||
},
|
},
|
||||||
|
|||||||
Reference in New Issue
Block a user