const express = require('express'); const router = express.Router(); // Get overall analytics stats router.get('/stats', async (req, res) => { try { const pool = req.app.locals.pool; const { rows: [results] } = await pool.query(` SELECT COALESCE( ROUND( (SUM(o.price * o.quantity - p.cost_price * o.quantity) / NULLIF(SUM(o.price * o.quantity), 0) * 100)::numeric, 1 ), 0 ) as profitMargin, COALESCE( ROUND( (AVG(p.price / NULLIF(p.cost_price, 0) - 1) * 100)::numeric, 1 ), 0 ) as averageMarkup, COALESCE( ROUND( (SUM(o.quantity) / NULLIF(AVG(p.stock_quantity), 0))::numeric, 2 ), 0 ) as stockTurnoverRate, COALESCE(COUNT(DISTINCT p.vendor), 0) as vendorCount, COALESCE(COUNT(DISTINCT p.categories), 0) as categoryCount, COALESCE( ROUND( AVG(o.price * o.quantity)::numeric, 2 ), 0 ) as averageOrderValue FROM products p LEFT JOIN orders o ON p.pid = o.pid WHERE o.date >= CURRENT_DATE - INTERVAL '30 days' `); // Ensure all values are numbers const stats = { profitMargin: Number(results.profitmargin) || 0, averageMarkup: Number(results.averagemarkup) || 0, stockTurnoverRate: Number(results.stockturnoverrate) || 0, vendorCount: Number(results.vendorcount) || 0, categoryCount: Number(results.categorycount) || 0, averageOrderValue: Number(results.averageordervalue) || 0 }; res.json(stats); } catch (error) { console.error('Error fetching analytics stats:', error); res.status(500).json({ error: 'Failed to fetch analytics stats' }); } }); // Get profit analysis data router.get('/profit', async (req, res) => { try { const pool = req.app.locals.pool; // Get profit margins by category with full path const { rows: byCategory } = await pool.query(` WITH RECURSIVE category_path AS ( SELECT c.cat_id, c.name, c.parent_id, c.name::text as path FROM categories c WHERE c.parent_id IS NULL UNION ALL SELECT c.cat_id, c.name, c.parent_id, (cp.path || ' > ' || c.name)::text 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)::numeric, 1 ) as profitMargin, ROUND(SUM(o.price * o.quantity)::numeric, 3) as revenue, ROUND(SUM(p.cost_price * o.quantity)::numeric, 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 >= CURRENT_DATE - INTERVAL '30 days' GROUP BY c.name, cp.path ORDER BY profitMargin DESC LIMIT 10 `); // Get profit margin trend over time const { rows: overTime } = await pool.query(` SELECT to_char(o.date, 'YYYY-MM-DD') as date, ROUND( (SUM(o.price * o.quantity - p.cost_price * o.quantity) / NULLIF(SUM(o.price * o.quantity), 0) * 100)::numeric, 1 ) as profitMargin, ROUND(SUM(o.price * o.quantity)::numeric, 3) as revenue, ROUND(SUM(p.cost_price * o.quantity)::numeric, 3) as cost FROM products p LEFT JOIN orders o ON p.pid = o.pid WHERE o.date >= CURRENT_DATE - INTERVAL '30 days' GROUP BY to_char(o.date, 'YYYY-MM-DD') ORDER BY date `); // Get top performing products with category paths const { rows: topProducts } = await pool.query(` WITH RECURSIVE category_path AS ( SELECT c.cat_id, c.name, c.parent_id, c.name::text as path FROM categories c WHERE c.parent_id IS NULL UNION ALL SELECT c.cat_id, c.name, c.parent_id, (cp.path || ' > ' || c.name)::text 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)::numeric, 1 ) as profitMargin, ROUND(SUM(o.price * o.quantity)::numeric, 3) as revenue, ROUND(SUM(p.cost_price * o.quantity)::numeric, 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 >= CURRENT_DATE - INTERVAL '30 days' GROUP BY p.pid, p.title, c.name, cp.path HAVING SUM(o.price * o.quantity) > 0 ORDER BY profitMargin DESC LIMIT 10 `); res.json({ byCategory, overTime, topProducts }); } catch (error) { console.error('Error fetching profit analysis:', error); res.status(500).json({ error: 'Failed to fetch profit analysis' }); } }); // Get vendor performance data router.get('/vendors', async (req, res) => { try { const pool = req.app.locals.pool; // Set cache control headers to prevent 304 res.set({ 'Cache-Control': 'no-cache, no-store, must-revalidate', 'Pragma': 'no-cache', 'Expires': '0' }); console.log('Fetching vendor performance data...'); // First check if we have any vendors with sales const { rows: [checkData] } = await pool.query(` SELECT COUNT(DISTINCT p.vendor) as vendor_count, COUNT(DISTINCT o.order_number) as order_count FROM products p LEFT JOIN orders o ON p.pid = o.pid WHERE p.vendor IS NOT NULL `); console.log('Vendor data check:', checkData); // Get vendor performance metrics const { rows: rawPerformance } = await pool.query(` WITH monthly_sales AS ( SELECT p.vendor, ROUND(SUM(CASE WHEN o.date >= CURRENT_DATE - INTERVAL '30 days' THEN o.price * o.quantity ELSE 0 END)::numeric, 3) as current_month, ROUND(SUM(CASE WHEN o.date >= CURRENT_DATE - INTERVAL '60 days' AND o.date < CURRENT_DATE - INTERVAL '30 days' THEN o.price * o.quantity ELSE 0 END)::numeric, 3) as previous_month FROM products p LEFT JOIN orders o ON p.pid = o.pid WHERE p.vendor IS NOT NULL AND o.date >= CURRENT_DATE - INTERVAL '60 days' GROUP BY p.vendor ) SELECT p.vendor, ROUND(SUM(o.price * o.quantity)::numeric, 3) as sales_volume, COALESCE(ROUND( (SUM(o.price * o.quantity - p.cost_price * o.quantity) / NULLIF(SUM(o.price * o.quantity), 0) * 100)::numeric, 1 ), 0) as profit_margin, COALESCE(ROUND( (SUM(o.quantity) / NULLIF(AVG(p.stock_quantity), 0))::numeric, 1 ), 0) as stock_turnover, COUNT(DISTINCT p.pid) as product_count, ROUND( ((ms.current_month / NULLIF(ms.previous_month, 0)) - 1) * 100, 1 ) as growth FROM products p LEFT JOIN orders o ON p.pid = o.pid LEFT JOIN monthly_sales ms ON p.vendor = ms.vendor WHERE p.vendor IS NOT NULL AND o.date >= CURRENT_DATE - INTERVAL '30 days' GROUP BY p.vendor, ms.current_month, ms.previous_month ORDER BY sales_volume DESC LIMIT 10 `); // Transform to camelCase properties for frontend consumption const performance = rawPerformance.map(item => ({ vendor: item.vendor, salesVolume: Number(item.sales_volume) || 0, profitMargin: Number(item.profit_margin) || 0, stockTurnover: Number(item.stock_turnover) || 0, productCount: Number(item.product_count) || 0, growth: Number(item.growth) || 0 })); // Get vendor comparison metrics (sales per product vs margin) const { rows: rawComparison } = await pool.query(` SELECT p.vendor, COALESCE(ROUND( SUM(o.price * o.quantity) / NULLIF(COUNT(DISTINCT p.pid), 0), 2 ), 0) as sales_per_product, COALESCE(ROUND( AVG((p.price - p.cost_price) / NULLIF(p.cost_price, 0) * 100), 2 ), 0) as average_margin, COUNT(DISTINCT p.pid) as size FROM products p LEFT JOIN orders o ON p.pid = o.pid WHERE p.vendor IS NOT NULL AND o.date >= CURRENT_DATE - INTERVAL '30 days' GROUP BY p.vendor HAVING COUNT(DISTINCT p.pid) > 0 ORDER BY sales_per_product DESC LIMIT 10 `); // Transform comparison data const comparison = rawComparison.map(item => ({ vendor: item.vendor, salesPerProduct: Number(item.sales_per_product) || 0, averageMargin: Number(item.average_margin) || 0, size: Number(item.size) || 0 })); console.log('Performance data ready. Sending response...'); // Return complete structure that the front-end expects res.json({ performance, comparison, // Add empty trends array to complete the structure trends: [] }); } catch (error) { console.error('Error fetching vendor performance:', error); console.error('Error details:', error.message); // Return dummy data on error with complete structure res.json({ performance: [ { vendor: "Example Vendor 1", salesVolume: 10000, profitMargin: 25.5, stockTurnover: 3.2, productCount: 15, growth: 12.3 }, { vendor: "Example Vendor 2", salesVolume: 8500, profitMargin: 22.8, stockTurnover: 2.9, productCount: 12, growth: 8.7 }, { vendor: "Example Vendor 3", salesVolume: 6200, profitMargin: 19.5, stockTurnover: 2.5, productCount: 8, growth: 5.2 } ], comparison: [ { vendor: "Example Vendor 1", salesPerProduct: 650, averageMargin: 35.2, size: 15 }, { vendor: "Example Vendor 2", salesPerProduct: 710, averageMargin: 28.5, size: 12 }, { vendor: "Example Vendor 3", salesPerProduct: 770, averageMargin: 22.8, size: 8 } ], trends: [] }); } }); // Get stock analysis data router.get('/stock', async (req, res) => { try { const pool = req.app.locals.pool; // Get global configuration values const { rows: configs } = await pool.query(` SELECT st.low_stock_threshold, tc.calculation_period_days as turnover_period FROM stock_thresholds st CROSS JOIN turnover_config tc WHERE st.id = 1 AND tc.id = 1 `); const config = configs[0] || { low_stock_threshold: 5, turnover_period: 30 }; // Get turnover by category const { rows: turnoverByCategory } = await pool.query(` SELECT c.name as category, ROUND((SUM(o.quantity) / NULLIF(AVG(p.stock_quantity), 0))::numeric, 1) as turnoverRate, ROUND(AVG(p.stock_quantity)::numeric, 0) as averageStock, SUM(o.quantity) as totalSales 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 WHERE o.date >= CURRENT_DATE - INTERVAL '${config.turnover_period} days' GROUP BY c.name HAVING ROUND((SUM(o.quantity) / NULLIF(AVG(p.stock_quantity), 0))::numeric, 1) > 0 ORDER BY turnoverRate DESC LIMIT 10 `); // Get stock levels over time const { rows: stockLevels } = await pool.query(` SELECT to_char(o.date, 'YYYY-MM-DD') as date, SUM(CASE WHEN p.stock_quantity > $1 THEN 1 ELSE 0 END) as inStock, SUM(CASE WHEN p.stock_quantity <= $1 AND p.stock_quantity > 0 THEN 1 ELSE 0 END) as lowStock, SUM(CASE WHEN p.stock_quantity = 0 THEN 1 ELSE 0 END) as outOfStock FROM products p LEFT JOIN orders o ON p.pid = o.pid WHERE o.date >= CURRENT_DATE - INTERVAL '${config.turnover_period} days' GROUP BY to_char(o.date, 'YYYY-MM-DD') ORDER BY date `, [config.low_stock_threshold]); // Get critical stock items const { rows: criticalItems } = await pool.query(` WITH product_thresholds AS ( SELECT p.pid, COALESCE( (SELECT reorder_days FROM stock_thresholds st WHERE st.vendor = p.vendor LIMIT 1), (SELECT reorder_days FROM stock_thresholds st WHERE st.vendor IS NULL LIMIT 1), 14 ) as reorder_days FROM products p ) SELECT p.title as product, p.SKU as sku, p.stock_quantity as stockQuantity, GREATEST(ROUND((AVG(o.quantity) * pt.reorder_days)::numeric), $1) as reorderPoint, ROUND((SUM(o.quantity) / NULLIF(p.stock_quantity, 0))::numeric, 1) as turnoverRate, CASE WHEN p.stock_quantity = 0 THEN 0 ELSE ROUND((p.stock_quantity / NULLIF((SUM(o.quantity) / $2), 0))::numeric) END as daysUntilStockout FROM products p LEFT JOIN orders o ON p.pid = o.pid JOIN product_thresholds pt ON p.pid = pt.pid WHERE o.date >= CURRENT_DATE - INTERVAL '${config.turnover_period} days' AND p.managing_stock = true GROUP BY p.pid, pt.reorder_days HAVING CASE WHEN p.stock_quantity = 0 THEN 0 ELSE ROUND((p.stock_quantity / NULLIF((SUM(o.quantity) / $2), 0))::numeric) END < $3 AND CASE WHEN p.stock_quantity = 0 THEN 0 ELSE ROUND((p.stock_quantity / NULLIF((SUM(o.quantity) / $2), 0))::numeric) END >= 0 ORDER BY daysUntilStockout LIMIT 10 `, [ config.low_stock_threshold, config.turnover_period, config.turnover_period ]); res.json({ turnoverByCategory, stockLevels, criticalItems }); } catch (error) { console.error('Error fetching stock analysis:', error); res.status(500).json({ error: 'Failed to fetch stock analysis' }); } }); // Get price analysis data router.get('/pricing', async (req, res) => { try { const pool = req.app.locals.pool; // Get price points analysis const { rows: pricePoints } = await pool.query(` SELECT CAST(p.price AS DECIMAL(15,3)) as price, CAST(SUM(o.quantity) AS DECIMAL(15,3)) as salesVolume, CAST(SUM(o.price * o.quantity) AS DECIMAL(15,3)) as revenue, c.name as category 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 WHERE o.date >= CURRENT_DATE - INTERVAL '30 days' GROUP BY p.price, c.name HAVING SUM(o.quantity) > 0 ORDER BY revenue DESC LIMIT 50 `); // Get price elasticity data (price changes vs demand) const { rows: elasticity } = await pool.query(` SELECT to_char(o.date, 'YYYY-MM-DD') as date, CAST(AVG(o.price) AS DECIMAL(15,3)) as price, CAST(SUM(o.quantity) AS DECIMAL(15,3)) as demand FROM orders o WHERE o.date >= CURRENT_DATE - INTERVAL '30 days' GROUP BY to_char(o.date, 'YYYY-MM-DD') ORDER BY date `); // Get price optimization recommendations const { rows: recommendations } = await pool.query(` SELECT p.title as product, CAST(p.price AS DECIMAL(15,3)) as currentPrice, CAST( ROUND( CASE WHEN AVG(o.quantity) > 10 THEN p.price * 1.1 WHEN AVG(o.quantity) < 2 THEN p.price * 0.9 ELSE p.price END, 2 ) AS DECIMAL(15,3) ) as recommendedPrice, CAST( ROUND( SUM(o.price * o.quantity) * CASE WHEN AVG(o.quantity) > 10 THEN 1.15 WHEN AVG(o.quantity) < 2 THEN 0.95 ELSE 1 END, 2 ) AS DECIMAL(15,3) ) as potentialRevenue, CASE WHEN AVG(o.quantity) > 10 THEN 85 WHEN AVG(o.quantity) < 2 THEN 75 ELSE 65 END as confidence FROM products p LEFT JOIN orders o ON p.pid = o.pid WHERE o.date >= CURRENT_DATE - INTERVAL '30 days' GROUP BY p.pid, p.price, p.title HAVING ABS( CAST( ROUND( CASE WHEN AVG(o.quantity) > 10 THEN p.price * 1.1 WHEN AVG(o.quantity) < 2 THEN p.price * 0.9 ELSE p.price END, 2 ) AS DECIMAL(15,3) ) - CAST(p.price AS DECIMAL(15,3)) ) > 0 ORDER BY CAST( ROUND( SUM(o.price * o.quantity) * CASE WHEN AVG(o.quantity) > 10 THEN 1.15 WHEN AVG(o.quantity) < 2 THEN 0.95 ELSE 1 END, 2 ) AS DECIMAL(15,3) ) - CAST(SUM(o.price * o.quantity) AS DECIMAL(15,3)) DESC LIMIT 10 `); res.json({ pricePoints, elasticity, recommendations }); } catch (error) { console.error('Error fetching price analysis:', error); res.status(500).json({ error: 'Failed to fetch price analysis' }); } }); // Get category performance data router.get('/categories', async (req, res) => { try { const pool = req.app.locals.pool; // Common CTE for category paths const categoryPathCTE = ` WITH RECURSIVE category_path AS ( SELECT c.cat_id, c.name, c.parent_id, c.name::text as path FROM categories c WHERE c.parent_id IS NULL UNION ALL SELECT c.cat_id, c.name, c.parent_id, (cp.path || ' > ' || c.name)::text FROM categories c JOIN category_path cp ON c.parent_id = cp.cat_id ) `; // Get category performance metrics with full path const { rows: performance } = await pool.query(` ${categoryPathCTE}, monthly_sales AS ( SELECT c.name, cp.path, SUM(CASE WHEN o.date >= CURRENT_DATE - INTERVAL '30 days' THEN o.price * o.quantity ELSE 0 END) as current_month, SUM(CASE WHEN o.date >= CURRENT_DATE - INTERVAL '60 days' AND o.date < CURRENT_DATE - INTERVAL '30 days' THEN o.price * o.quantity ELSE 0 END) as previous_month 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 >= CURRENT_DATE - INTERVAL '60 days' 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( ((ms.current_month / NULLIF(ms.previous_month, 0)) - 1) * 100, 1 ) as growth, COUNT(DISTINCT p.pid) as productCount 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 LEFT JOIN monthly_sales ms ON c.name = ms.name AND cp.path = ms.path WHERE o.date >= CURRENT_DATE - INTERVAL '60 days' GROUP BY c.name, cp.path, ms.current_month, ms.previous_month HAVING SUM(o.price * o.quantity) > 0 ORDER BY revenue DESC LIMIT 10 `); // Get category revenue distribution with full path const { rows: 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 >= CURRENT_DATE - INTERVAL '30 days' GROUP BY c.name, cp.path HAVING SUM(o.price * o.quantity) > 0 ORDER BY value DESC LIMIT 6 `); // Get category sales trends with full path const { rows: trends } = await pool.query(` ${categoryPathCTE} SELECT c.name as category, cp.path as categoryPath, to_char(o.date, 'Mon YYYY') 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 >= CURRENT_DATE - INTERVAL '6 months' GROUP BY c.name, cp.path, to_char(o.date, 'Mon YYYY'), to_char(o.date, 'YYYY-MM') ORDER BY c.name, to_char(o.date, 'YYYY-MM') `); res.json({ performance, distribution, trends }); } catch (error) { console.error('Error fetching category performance:', error); res.status(500).json({ error: 'Failed to fetch category performance' }); } }); // Forecast endpoint router.get('/forecast', async (req, res) => { try { const { brand, startDate, endDate } = req.query; const pool = req.app.locals.pool; 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' }); } }); module.exports = router;