From 1410dc5571ae50bbc7c9667717330359d6aeadf7 Mon Sep 17 00:00:00 2001 From: Matt Date: Tue, 28 Jan 2025 17:02:11 -0500 Subject: [PATCH] Frontend fixes - categories, deal with new hierarchy, misc fixes --- inventory-server/src/routes/analytics.js | 261 ++++++++++----- inventory-server/src/routes/categories.js | 78 +++-- inventory-server/src/routes/dashboard.js | 280 ++++++---------- inventory-server/src/routes/products.js | 313 +++++++++++------- .../analytics/CategoryPerformance.tsx | 62 +++- .../components/analytics/ProfitAnalysis.tsx | 40 ++- .../src/components/dashboard/BestSellers.tsx | 10 +- .../src/components/forecasting/columns.tsx | 11 + .../src/components/products/ProductDetail.tsx | 72 ++-- inventory/src/pages/Categories.tsx | 106 ++++-- inventory/src/pages/Forecasting.tsx | 4 +- 11 files changed, 750 insertions(+), 487 deletions(-) diff --git a/inventory-server/src/routes/analytics.js b/inventory-server/src/routes/analytics.js index 8d8cc18..5da6b1d 100644 --- a/inventory-server/src/routes/analytics.js +++ b/inventory-server/src/routes/analytics.js @@ -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; \ No newline at end of file diff --git a/inventory-server/src/routes/categories.js b/inventory-server/src/routes/categories.js index d6f42f1..8bdb7f7 100644 --- a/inventory-server/src/routes/categories.js +++ b/inventory-server/src/routes/categories.js @@ -5,60 +5,84 @@ const router = express.Router(); router.get('/', async (req, res) => { const pool = req.app.locals.pool; try { - // Get parent categories for filter dropdown - 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 + // Get all categories with metrics and hierarchy info const [categories] = await pool.query(` SELECT c.cat_id, c.name, + c.type, + c.parent_id, 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.active_products, 0) as active_products, CAST(COALESCE(cm.total_value, 0) AS DECIMAL(15,3)) as total_value, COALESCE(cm.avg_margin, 0) as avg_margin, COALESCE(cm.turnover_rate, 0) as turnover_rate, - COALESCE(cm.growth_rate, 0) as growth_rate, - COALESCE(cm.status, 'inactive') as status + COALESCE(cm.growth_rate, 0) as growth_rate FROM categories c - LEFT JOIN categories p ON c.parent_cat_id = p.cat_id - LEFT JOIN category_metrics cm ON c.cat_id = cm.cat_id - ORDER BY c.name ASC + LEFT JOIN categories p ON c.parent_id = p.cat_id + LEFT JOIN category_metrics cm ON c.cat_id = cm.category_id + 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 const [stats] = await pool.query(` SELECT 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, COALESCE(ROUND(AVG(NULLIF(cm.avg_margin, 0)), 1), 0) as avgMargin, COALESCE(ROUND(AVG(NULLIF(cm.growth_rate, 0)), 1), 0) as avgGrowth 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({ categories: categories.map(cat => ({ - id: cat.cat_id, + cat_id: cat.cat_id, name: cat.name, + type: cat.type, + parent_id: cat.parent_id, + parent_name: cat.parent_name, + parent_type: cat.parent_type, description: cat.description, - parent_category: cat.parent_name, - product_count: parseInt(cat.product_count), - total_value: parseFloat(cat.total_value), - avg_margin: parseFloat(cat.avg_margin), - turnover_rate: parseFloat(cat.turnover_rate), - growth_rate: parseFloat(cat.growth_rate), - status: cat.status + status: cat.status, + metrics: { + product_count: parseInt(cat.product_count), + active_products: parseInt(cat.active_products), + total_value: parseFloat(cat.total_value), + avg_margin: parseFloat(cat.avg_margin), + 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: { totalCategories: parseInt(stats[0].totalCategories), activeCategories: parseInt(stats[0].activeCategories), diff --git a/inventory-server/src/routes/dashboard.js b/inventory-server/src/routes/dashboard.js index 4a1665f..4db5db2 100644 --- a/inventory-server/src/routes/dashboard.js +++ b/inventory-server/src/routes/dashboard.js @@ -443,198 +443,116 @@ router.get('/overstock/products', async (req, res) => { // Returns best-selling products, vendors, and categories router.get('/best-sellers', async (req, res) => { try { - const [products] = await executeQuery(` - WITH product_sales AS ( - SELECT - p.pid, - p.SKU as sku, - p.title, - -- Current period (last 30 days) - SUM(CASE - WHEN o.date >= DATE_SUB(CURRENT_DATE, INTERVAL 30 DAY) - THEN o.quantity - ELSE 0 - END) as units_sold, - SUM(CASE - WHEN o.date >= DATE_SUB(CURRENT_DATE, INTERVAL 30 DAY) - THEN o.price * o.quantity - ELSE 0 - END) as revenue, - SUM(CASE - WHEN o.date >= DATE_SUB(CURRENT_DATE, INTERVAL 30 DAY) - THEN (o.price - p.cost_price) * o.quantity - ELSE 0 - END) as profit, - -- Previous period (30-60 days ago) - SUM(CASE - WHEN o.date BETWEEN DATE_SUB(CURRENT_DATE, INTERVAL 60 DAY) AND DATE_SUB(CURRENT_DATE, INTERVAL 30 DAY) - THEN o.price * o.quantity - ELSE 0 - END) as previous_revenue - FROM products p - JOIN orders o ON p.pid = o.pid - WHERE o.canceled = false - AND o.date >= DATE_SUB(CURRENT_DATE, INTERVAL 60 DAY) - GROUP BY p.pid, p.SKU, p.title - ) - SELECT - pid, - sku, - title, - units_sold, - revenue, - profit, - CASE - WHEN previous_revenue > 0 - THEN ((revenue - previous_revenue) / previous_revenue * 100) - WHEN revenue > 0 - THEN 100 - ELSE 0 - END as growth_rate - FROM product_sales - WHERE units_sold > 0 - ORDER BY revenue DESC - LIMIT 50 - `); + const pool = req.app.locals.pool; - const [brands] = await executeQuery(` - WITH brand_sales AS ( - SELECT - p.brand, - -- Current period (last 30 days) - SUM(CASE - WHEN o.date >= DATE_SUB(CURRENT_DATE, INTERVAL 30 DAY) - THEN o.quantity - ELSE 0 - END) as units_sold, - SUM(CASE - WHEN o.date >= DATE_SUB(CURRENT_DATE, INTERVAL 30 DAY) - THEN o.price * o.quantity - ELSE 0 - END) as revenue, - SUM(CASE - WHEN o.date >= DATE_SUB(CURRENT_DATE, INTERVAL 30 DAY) - THEN (o.price - p.cost_price) * o.quantity - ELSE 0 - END) as profit, - -- Previous period (30-60 days ago) - SUM(CASE - WHEN o.date BETWEEN DATE_SUB(CURRENT_DATE, INTERVAL 60 DAY) AND DATE_SUB(CURRENT_DATE, INTERVAL 30 DAY) - THEN o.price * o.quantity - ELSE 0 - END) as previous_revenue - FROM products p - JOIN orders o ON p.pid = o.pid - WHERE o.canceled = false - AND o.date >= DATE_SUB(CURRENT_DATE, INTERVAL 60 DAY) - AND p.brand IS NOT NULL - GROUP BY p.brand - ) - SELECT - brand, - units_sold, - revenue, - profit, - CASE - WHEN previous_revenue > 0 - THEN ((revenue - previous_revenue) / previous_revenue * 100) - WHEN revenue > 0 - THEN 100 - ELSE 0 - END as growth_rate - FROM brand_sales - WHERE units_sold > 0 - ORDER BY revenue DESC - LIMIT 50 - `); - - const [categories] = await executeQuery(` - WITH category_sales AS ( + // Common CTE for category paths + const categoryPathCTE = ` + WITH RECURSIVE category_path AS ( SELECT c.cat_id, c.name, - -- Current period (last 30 days) - SUM(CASE - WHEN o.date >= DATE_SUB(CURRENT_DATE, INTERVAL 30 DAY) - THEN o.quantity - ELSE 0 - END) as units_sold, - SUM(CASE - WHEN o.date >= DATE_SUB(CURRENT_DATE, INTERVAL 30 DAY) - THEN o.price * o.quantity - ELSE 0 - END) as revenue, - SUM(CASE - WHEN o.date >= DATE_SUB(CURRENT_DATE, INTERVAL 30 DAY) - THEN (o.price - p.cost_price) * o.quantity - ELSE 0 - END) as profit, - -- Previous period (30-60 days ago) - SUM(CASE - WHEN o.date BETWEEN DATE_SUB(CURRENT_DATE, INTERVAL 60 DAY) AND DATE_SUB(CURRENT_DATE, INTERVAL 30 DAY) - THEN o.price * o.quantity - ELSE 0 - END) as previous_revenue + c.parent_id, + CAST(c.name AS CHAR(1000)) as path FROM categories c - JOIN product_categories pc ON c.cat_id = pc.cat_id - JOIN products p ON pc.pid = p.pid - JOIN orders o ON p.pid = o.pid - WHERE o.canceled = false - AND o.date >= DATE_SUB(CURRENT_DATE, INTERVAL 60 DAY) - GROUP BY c.cat_id, c.name + WHERE c.parent_id IS NULL + + UNION ALL + + SELECT + c.cat_id, + c.name, + c.parent_id, + CONCAT(cp.path, ' > ', c.name) + FROM categories c + JOIN category_path cp ON c.parent_id = cp.cat_id ) + `; + + // Get best selling products + const [products] = await pool.query(` SELECT - cat_id, - name, - units_sold, - revenue, - profit, - CASE - WHEN previous_revenue > 0 - THEN ((revenue - previous_revenue) / previous_revenue * 100) - WHEN revenue > 0 - THEN 100 - ELSE 0 - END as growth_rate - FROM category_sales - WHERE units_sold > 0 - ORDER BY revenue DESC - LIMIT 50 + p.pid, + p.SKU as sku, + p.title, + SUM(o.quantity) as units_sold, + CAST(SUM(o.price * o.quantity) AS DECIMAL(15,3)) as revenue, + CAST(SUM(o.price * o.quantity - p.cost_price * o.quantity) AS DECIMAL(15,3)) as profit + FROM products p + JOIN orders o ON p.pid = o.pid + WHERE o.date >= DATE_SUB(CURDATE(), INTERVAL 30 DAY) + AND o.canceled = false + GROUP BY p.pid + ORDER BY units_sold DESC + LIMIT 10 `); - // Format response with explicit type conversion - const formattedProducts = products.map(p => ({ - pid: p.pid, - sku: p.sku, - title: p.title, - units_sold: parseInt(p.units_sold) || 0, - revenue: p.revenue.toString(), - profit: p.profit.toString(), - growth_rate: p.growth_rate.toString() - })); + // Get best selling brands + const [brands] = await pool.query(` + SELECT + p.brand, + SUM(o.quantity) as units_sold, + CAST(SUM(o.price * o.quantity) AS DECIMAL(15,3)) as revenue, + CAST(SUM(o.price * o.quantity - p.cost_price * o.quantity) AS DECIMAL(15,3)) as profit, + ROUND( + ((SUM(CASE + WHEN o.date >= DATE_SUB(CURDATE(), INTERVAL 30 DAY) + THEN o.price * o.quantity + ELSE 0 + END) / + NULLIF(SUM(CASE + WHEN o.date >= DATE_SUB(CURDATE(), INTERVAL 60 DAY) + AND o.date < DATE_SUB(CURDATE(), INTERVAL 30 DAY) + THEN o.price * o.quantity + ELSE 0 + END), 0)) - 1) * 100, + 1 + ) as growth_rate + FROM products p + JOIN orders o ON p.pid = o.pid + WHERE o.date >= DATE_SUB(CURDATE(), INTERVAL 60 DAY) + AND o.canceled = false + GROUP BY p.brand + ORDER BY units_sold DESC + LIMIT 10 + `); - const formattedBrands = brands.map(b => ({ - brand: b.brand, - units_sold: parseInt(b.units_sold) || 0, - revenue: b.revenue.toString(), - profit: b.profit.toString(), - growth_rate: b.growth_rate.toString() - })); + // Get best selling categories with full path + const [categories] = await pool.query(` + ${categoryPathCTE} + SELECT + c.cat_id, + c.name, + cp.path as categoryPath, + SUM(o.quantity) as units_sold, + CAST(SUM(o.price * o.quantity) AS DECIMAL(15,3)) as revenue, + CAST(SUM(o.price * o.quantity - p.cost_price * o.quantity) AS DECIMAL(15,3)) as profit, + ROUND( + ((SUM(CASE + WHEN o.date >= DATE_SUB(CURDATE(), INTERVAL 30 DAY) + THEN o.price * o.quantity + ELSE 0 + END) / + NULLIF(SUM(CASE + WHEN o.date >= DATE_SUB(CURDATE(), INTERVAL 60 DAY) + AND o.date < DATE_SUB(CURDATE(), INTERVAL 30 DAY) + THEN o.price * o.quantity + ELSE 0 + END), 0)) - 1) * 100, + 1 + ) as growth_rate + FROM products p + JOIN orders o ON p.pid = o.pid + JOIN product_categories pc ON p.pid = pc.pid + JOIN categories c ON pc.cat_id = c.cat_id + JOIN category_path cp ON c.cat_id = cp.cat_id + WHERE o.date >= DATE_SUB(CURDATE(), INTERVAL 60 DAY) + AND o.canceled = false + GROUP BY c.cat_id, c.name, cp.path + ORDER BY units_sold DESC + LIMIT 10 + `); - const formattedCategories = categories.map(c => ({ - cat_id: c.cat_id, - name: c.name, - units_sold: parseInt(c.units_sold) || 0, - revenue: c.revenue.toString(), - profit: c.profit.toString(), - growth_rate: c.growth_rate.toString() - })); - - res.json({ - products: formattedProducts, - brands: formattedBrands, - categories: formattedCategories - }); + res.json({ products, brands, categories }); } catch (err) { console.error('Error fetching best sellers:', err); res.status(500).json({ error: 'Failed to fetch best sellers' }); diff --git a/inventory-server/src/routes/products.js b/inventory-server/src/routes/products.js index d0a93a7..94441ff 100755 --- a/inventory-server/src/routes/products.js +++ b/inventory-server/src/routes/products.js @@ -167,32 +167,64 @@ router.get('/', async (req, res) => { // Main query with all fields const query = ` - WITH 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 - ) + 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 + ), + 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 p.*, 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.weekly_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 categories c ON pc.cat_id = c.cat_id 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 ORDER BY ${sortColumn} ${sortDirection} LIMIT ? OFFSET ? @@ -351,130 +384,160 @@ router.get('/trending', async (req, res) => { // Get a single product router.get('/:id', async (req, res) => { - const pool = req.app.locals.pool; try { - // Get basic product data with metrics - const [rows] = await pool.query( - `SELECT + const pool = req.app.locals.pool; + const id = parseInt(req.params.id); + + // 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.*, - GROUP_CONCAT(DISTINCT c.name) as categories, pm.daily_sales_avg, pm.weekly_sales_avg, pm.monthly_sales_avg, pm.days_of_inventory, pm.reorder_point, pm.safety_stock, + pm.stock_status, + pm.abc_class, pm.avg_margin_percent, pm.total_revenue, pm.inventory_value, pm.turnover_rate, - pm.abc_class, - pm.stock_status, + pm.gmroi, + pm.cost_of_goods_sold, + pm.gross_profit, pm.avg_lead_time_days, pm.current_lead_time, pm.target_lead_time, pm.lead_time_status, - pm.gmroi, - pm.cost_of_goods_sold, - pm.gross_profit + pm.reorder_qty, + pm.overstocked_amt FROM products p LEFT JOIN product_metrics pm ON p.pid = pm.pid - LEFT JOIN product_categories pc ON p.pid = pc.pid - LEFT JOIN categories c ON pc.cat_id = c.cat_id - WHERE p.pid = ? AND p.visible = true - GROUP BY p.pid`, - [req.params.id] - ); - - if (rows.length === 0) { + WHERE p.pid = ? + `, [id]); + + if (!productRows.length) { return res.status(404).json({ error: 'Product not found' }); } - // Get vendor performance metrics - const [vendorMetrics] = await pool.query( - `SELECT * FROM vendor_metrics WHERE vendor = ?`, - [rows[0].vendor] - ); + // Get categories and their paths separately to avoid GROUP BY issues + const [categoryRows] = 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 + ), + 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 = { - // Basic product info - pid: rows[0].pid, - title: rows[0].title, - SKU: rows[0].SKU, - barcode: rows[0].barcode, - created_at: rows[0].created_at, - updated_at: rows[0].updated_at, - - // Inventory fields - stock_quantity: parseInt(rows[0].stock_quantity), - moq: parseInt(rows[0].moq), - uom: parseInt(rows[0].uom), - managing_stock: Boolean(rows[0].managing_stock), - replenishable: Boolean(rows[0].replenishable), - - // Pricing fields - price: parseFloat(rows[0].price), - regular_price: parseFloat(rows[0].regular_price), - cost_price: parseFloat(rows[0].cost_price), - landing_cost_price: parseFloat(rows[0].landing_cost_price), - - // Categorization - categories: rows[0].categories ? rows[0].categories.split(',') : [], - tags: rows[0].tags ? rows[0].tags.split(',') : [], - options: rows[0].options ? JSON.parse(rows[0].options) : {}, - - // Vendor info - vendor: rows[0].vendor, - vendor_reference: rows[0].vendor_reference, - brand: rows[0].brand, - - // URLs - permalink: rows[0].permalink, - image: rows[0].image, - - // Metrics - 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 + ...productRows[0], + // Include cat_id in categories array to match the keys in categoryPathMap + categories: categoryRows.map(row => `${row.cat_id}:${row.category_name}`), + category_paths: categoryPathMap, + price: parseFloat(productRows[0].price), + regular_price: parseFloat(productRows[0].regular_price), + cost_price: parseFloat(productRows[0].cost_price), + landing_cost_price: parseFloat(productRows[0].landing_cost_price), + stock_quantity: parseInt(productRows[0].stock_quantity), + moq: parseInt(productRows[0].moq), + uom: parseInt(productRows[0].uom), + managing_stock: Boolean(productRows[0].managing_stock), + replenishable: Boolean(productRows[0].replenishable), + daily_sales_avg: parseFloat(productRows[0].daily_sales_avg) || 0, + weekly_sales_avg: parseFloat(productRows[0].weekly_sales_avg) || 0, + monthly_sales_avg: parseFloat(productRows[0].monthly_sales_avg) || 0, + avg_quantity_per_order: parseFloat(productRows[0].avg_quantity_per_order) || 0, + number_of_orders: parseInt(productRows[0].number_of_orders) || 0, + first_sale_date: productRows[0].first_sale_date || null, + last_sale_date: productRows[0].last_sale_date || null, + days_of_inventory: parseFloat(productRows[0].days_of_inventory) || 0, + weeks_of_inventory: parseFloat(productRows[0].weeks_of_inventory) || 0, + reorder_point: parseFloat(productRows[0].reorder_point) || 0, + safety_stock: parseFloat(productRows[0].safety_stock) || 0, + avg_margin_percent: parseFloat(productRows[0].avg_margin_percent) || 0, + total_revenue: parseFloat(productRows[0].total_revenue) || 0, + inventory_value: parseFloat(productRows[0].inventory_value) || 0, + cost_of_goods_sold: parseFloat(productRows[0].cost_of_goods_sold) || 0, + gross_profit: parseFloat(productRows[0].gross_profit) || 0, + gmroi: parseFloat(productRows[0].gmroi) || 0, + avg_lead_time_days: parseFloat(productRows[0].avg_lead_time_days) || 0, + current_lead_time: parseFloat(productRows[0].current_lead_time) || 0, + target_lead_time: parseFloat(productRows[0].target_lead_time) || 0, + lead_time_status: productRows[0].lead_time_status || null, + reorder_qty: parseInt(productRows[0].reorder_qty) || 0, + overstocked_amt: parseInt(productRows[0].overstocked_amt) || 0 }; res.json(product); diff --git a/inventory/src/components/analytics/CategoryPerformance.tsx b/inventory/src/components/analytics/CategoryPerformance.tsx index 7cd9089..1d8cda3 100644 --- a/inventory/src/components/analytics/CategoryPerformance.tsx +++ b/inventory/src/components/analytics/CategoryPerformance.tsx @@ -6,6 +6,7 @@ import config from '../../config'; interface CategoryData { performance: { category: string; + categoryPath: string; // Full hierarchy path revenue: number; profit: number; growth: number; @@ -13,10 +14,12 @@ interface CategoryData { }[]; distribution: { category: string; + categoryPath: string; // Full hierarchy path value: number; }[]; trends: { category: string; + categoryPath: string; // Full hierarchy path month: string; sales: number; }[]; @@ -36,6 +39,7 @@ export function CategoryPerformance() { return { performance: rawData.performance.map((item: any) => ({ ...item, + categoryPath: item.categoryPath || item.category, revenue: Number(item.revenue) || 0, profit: Number(item.profit) || 0, growth: Number(item.growth) || 0, @@ -43,10 +47,12 @@ export function CategoryPerformance() { })), distribution: rawData.distribution.map((item: any) => ({ ...item, + categoryPath: item.categoryPath || item.category, value: Number(item.value) || 0 })), trends: rawData.trends.map((item: any) => ({ ...item, + categoryPath: item.categoryPath || item.category, sales: Number(item.sales) || 0 })) }; @@ -63,6 +69,8 @@ export function CategoryPerformance() { return {value}; }; + const getShortCategoryName = (path: string) => path.split(' > ').pop() || path; + return (
@@ -76,24 +84,34 @@ export function CategoryPerformance() { entry.category} + label={({ categoryPath }) => getShortCategoryName(categoryPath)} > {data.distribution.map((entry, index) => ( ))} [`$${value.toLocaleString()}`, 'Revenue']} + formatter={(value: number, name: string, props: any) => [ + `$${value.toLocaleString()}`, +
+
Category Path:
+
{props.payload.categoryPath}
+
Revenue
+
+ ]} + /> + getShortCategoryName(value)} + wrapperStyle={{ fontSize: '12px' }} /> - @@ -106,10 +124,33 @@ export function CategoryPerformance() { - + ( + + + {getShortCategoryName(payload.value)} + + + )} + /> `${value}%`} /> [`${value.toFixed(1)}%`, 'Growth Rate']} + formatter={(value: number, name: string, props: any) => [ + `${value.toFixed(1)}%`, +
+
Category Path:
+
{props.payload.categoryPath}
+
Growth Rate
+
+ ]} /> (
-

{category.category}

-

+

+

{getShortCategoryName(category.categoryPath)}

+

{category.categoryPath}

+
+

{category.productCount} products

diff --git a/inventory/src/components/analytics/ProfitAnalysis.tsx b/inventory/src/components/analytics/ProfitAnalysis.tsx index 5ea5464..bf4b8bf 100644 --- a/inventory/src/components/analytics/ProfitAnalysis.tsx +++ b/inventory/src/components/analytics/ProfitAnalysis.tsx @@ -6,6 +6,7 @@ import config from '../../config'; interface ProfitData { byCategory: { category: string; + categoryPath: string; // Full hierarchy path profitMargin: number; revenue: number; cost: number; @@ -18,6 +19,8 @@ interface ProfitData { }[]; topProducts: { product: string; + category: string; + categoryPath: string; // Full hierarchy path profitMargin: number; revenue: number; cost: number; @@ -36,6 +39,7 @@ export function ProfitAnalysis() { return { byCategory: rawData.byCategory.map((item: any) => ({ ...item, + categoryPath: item.categoryPath || item.category, profitMargin: Number(item.profitMargin) || 0, revenue: Number(item.revenue) || 0, cost: Number(item.cost) || 0 @@ -48,6 +52,7 @@ export function ProfitAnalysis() { })), topProducts: rawData.topProducts.map((item: any) => ({ ...item, + categoryPath: item.categoryPath || item.category, profitMargin: Number(item.profitMargin) || 0, revenue: Number(item.revenue) || 0, cost: Number(item.cost) || 0 @@ -60,6 +65,8 @@ export function ProfitAnalysis() { return
Loading profit analysis...
; } + const getShortCategoryName = (path: string) => path.split(' > ').pop() || path; + return (
@@ -70,10 +77,33 @@ export function ProfitAnalysis() { - + ( + + + {getShortCategoryName(payload.value)} + + + )} + /> `${value}%`} /> [`${value.toFixed(1)}%`, 'Profit Margin']} + formatter={(value: number, name: string, props: any) => [ + `${value.toFixed(1)}%`, +
+
Category Path:
+
{props.payload.categoryPath}
+
Profit Margin
+
+ ]} />

{product.product}

-

+

+

Category:

+

{product.categoryPath}

+
+

Revenue: ${product.revenue.toLocaleString()}

diff --git a/inventory/src/components/dashboard/BestSellers.tsx b/inventory/src/components/dashboard/BestSellers.tsx index 680ab29..412dc0c 100644 --- a/inventory/src/components/dashboard/BestSellers.tsx +++ b/inventory/src/components/dashboard/BestSellers.tsx @@ -18,6 +18,7 @@ interface Product { interface Category { cat_id: number; name: string; + categoryPath: string; units_sold: number; revenue: string; profit: string; @@ -159,7 +160,14 @@ export function BestSellers() { {data?.categories.map((category) => ( - {category.name} + +
{category.name}
+ {category.categoryPath && ( +
+ {category.categoryPath} +
+ )} +
{category.units_sold} {formatCurrency(Number(category.revenue))} {formatCurrency(Number(category.profit))} diff --git a/inventory/src/components/forecasting/columns.tsx b/inventory/src/components/forecasting/columns.tsx index 3f1c41a..8d26393 100644 --- a/inventory/src/components/forecasting/columns.tsx +++ b/inventory/src/components/forecasting/columns.tsx @@ -17,6 +17,7 @@ interface Product { export interface ForecastItem { category: string; + categoryPath: string; avgDailySales: number; totalSold: number; numProducts: number; @@ -44,6 +45,16 @@ export const columns: ColumnDef[] = [ { accessorKey: "category", header: "Category", + cell: ({ row }) => ( +
+
{row.original.category}
+ {row.original.categoryPath && ( +
+ {row.original.categoryPath} +
+ )} +
+ ), }, { accessorKey: "avgDailySales", diff --git a/inventory/src/components/products/ProductDetail.tsx b/inventory/src/components/products/ProductDetail.tsx index 73b4a12..df750ac 100644 --- a/inventory/src/components/products/ProductDetail.tsx +++ b/inventory/src/components/products/ProductDetail.tsx @@ -123,6 +123,8 @@ interface Product { notes: string; lead_time_days: number | null; }>; + + category_paths?: Record; } interface ProductDetailProps { @@ -255,22 +257,28 @@ export function ProductDetail({ productId, onClose }: ProductDetailProps) {
Categories
-
- {product?.categories?.map(category => ( - - {category} - - )) || "N/A"} +
+ {product?.category_paths ? + Object.entries(product.category_paths).map(([key, fullPath], index) => { + const [, leafCategory] = key.split(':'); + return ( +
+ + {leafCategory} + + + {fullPath} + +
+ ); + }) + : "N/A"}
Tags
- {product?.tags?.map(tag => ( - - {tag} - - )) || "N/A"} + N/A
@@ -307,11 +315,11 @@ export function ProductDetail({ productId, onClose }: ProductDetailProps) {
Status
-
{product?.metrics?.stock_status}
+
{product?.stock_status || "N/A"}
Days of Stock
-
{product?.metrics?.days_of_inventory} days
+
{product?.days_of_inventory || 0} days
@@ -321,15 +329,15 @@ export function ProductDetail({ productId, onClose }: ProductDetailProps) {
Daily Sales
-
{product?.metrics?.daily_sales_avg?.toFixed(1)} units
+
{product?.daily_sales_avg?.toFixed(1) || "0.0"} units
Weekly Sales
-
{product?.metrics?.weekly_sales_avg?.toFixed(1)} units
+
{product?.weekly_sales_avg?.toFixed(1) || "0.0"} units
Monthly Sales
-
{product?.metrics?.monthly_sales_avg?.toFixed(1)} units
+
{product?.monthly_sales_avg?.toFixed(1) || "0.0"} units
@@ -356,19 +364,19 @@ export function ProductDetail({ productId, onClose }: ProductDetailProps) {
Total Revenue
-
${formatPrice(product?.metrics.total_revenue)}
+
${formatPrice(product?.total_revenue)}
Gross Profit
-
${formatPrice(product?.metrics.gross_profit)}
+
${formatPrice(product?.gross_profit)}
Margin
-
{product?.metrics.avg_margin_percent.toFixed(2)}%
+
{product?.avg_margin_percent?.toFixed(2) || "0.00"}%
GMROI
-
{product?.metrics.gmroi.toFixed(2)}
+
{product?.gmroi?.toFixed(2) || "0.00"}
@@ -378,15 +386,15 @@ export function ProductDetail({ productId, onClose }: ProductDetailProps) {
Current Lead Time
-
{product?.metrics.current_lead_time}
+
{product?.current_lead_time || "N/A"}
Target Lead Time
-
{product?.metrics.target_lead_time}
+
{product?.target_lead_time || "N/A"}
Lead Time Status
-
{product?.metrics.lead_time_status}
+
{product?.lead_time_status || "N/A"}
@@ -408,11 +416,11 @@ export function ProductDetail({ productId, onClose }: ProductDetailProps) {
Days of Inventory
-
{product?.metrics?.days_of_inventory || 0}
+
{product?.days_of_inventory || 0}
Status
-
{product?.metrics?.stock_status || "N/A"}
+
{product?.stock_status || "N/A"}
@@ -422,15 +430,15 @@ export function ProductDetail({ productId, onClose }: ProductDetailProps) {
Reorder Point
-
{product?.metrics?.reorder_point || 0}
+
{product?.reorder_point || 0}
Safety Stock
-
{product?.metrics?.safety_stock || 0}
+
{product?.safety_stock || 0}
ABC Class
-
{product?.metrics?.abc_class || "N/A"}
+
{product?.abc_class || "N/A"}
@@ -551,15 +559,15 @@ export function ProductDetail({ productId, onClose }: ProductDetailProps) {
Gross Profit
-
${formatPrice(product?.metrics.gross_profit)}
+
${formatPrice(product?.gross_profit)}
GMROI
-
{product?.metrics.gmroi.toFixed(2)}
+
{product?.gmroi?.toFixed(2) || "0.00"}
Margin %
-
{product?.metrics.avg_margin_percent.toFixed(2)}%
+
{product?.avg_margin_percent?.toFixed(2) || "0.00"}%
@@ -569,7 +577,7 @@ export function ProductDetail({ productId, onClose }: ProductDetailProps) {
Cost of Goods Sold
-
${formatPrice(product?.metrics.cost_of_goods_sold)}
+
${formatPrice(product?.cost_of_goods_sold)}
Landing Cost
diff --git a/inventory/src/pages/Categories.tsx b/inventory/src/pages/Categories.tsx index eb16664..42dc1e8 100644 --- a/inventory/src/pages/Categories.tsx +++ b/inventory/src/pages/Categories.tsx @@ -14,9 +14,9 @@ interface Category { name: string; type: number; parent_id: number | null; + parent_name: string | null; + parent_type: number | null; description: string | null; - created_at: string; - updated_at: string; status: string; metrics?: { product_count: number; @@ -30,23 +30,41 @@ interface Category { interface CategoryFilters { search: string; - parent: string; + type: string; performance: string; } +const TYPE_LABELS: Record = { + 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() { const [page, setPage] = useState(1); const [sortColumn, setSortColumn] = useState("name"); const [sortDirection, setSortDirection] = useState<"asc" | "desc">("asc"); const [filters, setFilters] = useState({ search: "", - parent: "all", + type: "all", performance: "all", }); - const [] = useState({ - column: 'name', - direction: 'asc' - }); const { data, isLoading } = useQuery({ queryKey: ["categories"], @@ -74,13 +92,9 @@ export function Categories() { ); } - // Apply parent filter - if (filters.parent !== 'all') { - if (filters.parent === 'none') { - filtered = filtered.filter(category => !category.parent_id); - } else { - filtered = filtered.filter(category => category.parent_id === Number(filters.parent)); - } + // Apply type filter + if (filters.type !== 'all') { + filtered = filtered.filter(category => category.type === parseInt(filters.type)); } // Apply performance filter @@ -99,6 +113,19 @@ export function Categories() { // Apply sorting 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 bVal = b[sortColumn]; @@ -251,17 +278,18 @@ export function Categories() { className="h-8 w-[150px] lg:w-[250px]" /> @@ -287,8 +315,8 @@ export function Categories() { - Name Type + Name Parent Products Active @@ -302,15 +330,37 @@ export function Categories() { {isLoading ? ( - + Loading categories... ) : paginatedData.map((category: Category) => ( - {category.name} - {getPerformanceBadge(category.metrics?.growth_rate ?? 0)} - {category.parent_id ? getParentName(category.parent_id) : '-'} + + + {TYPE_LABELS[category.type]} + + + +
+
+ {category.name} + + {TYPE_LABELS[category.type]} + +
+ {category.description && ( +
{category.description}
+ )} +
+
+ + {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} + {category.metrics?.product_count || 0} {category.metrics?.active_products || 0} {formatCurrency(category.metrics?.total_value || 0)} @@ -326,7 +376,7 @@ export function Categories() { ))} {!isLoading && !paginatedData.length && ( - + No categories found diff --git a/inventory/src/pages/Forecasting.tsx b/inventory/src/pages/Forecasting.tsx index 926ec99..f956a92 100644 --- a/inventory/src/pages/Forecasting.tsx +++ b/inventory/src/pages/Forecasting.tsx @@ -60,6 +60,7 @@ export default function Forecasting() { const data = await response.json(); return data.map((item: any) => ({ category: item.category_name, + categoryPath: item.path, avgDailySales: Number(item.avg_daily_sales) || 0, totalSold: Number(item.total_sold) || 0, numProducts: Number(item.num_products) || 0, @@ -74,7 +75,8 @@ export default function Forecasting() { daily_sales_avg: Number(p.daily_sales_avg) || 0, forecast_units: Number(p.forecast_units) || 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 })) })); },