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 [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, 1 ), 0 ) as profitMargin, COALESCE( ROUND( (AVG(p.price / NULLIF(p.cost_price, 0) - 1) * 100), 1 ), 0 ) as averageMarkup, COALESCE( ROUND( SUM(o.quantity) / NULLIF(AVG(p.stock_quantity), 0), 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), 2 ), 0 ) as averageOrderValue FROM products p LEFT JOIN orders o ON p.pid = o.pid WHERE o.date >= DATE_SUB(CURDATE(), INTERVAL 30 DAY) `); // Ensure all values are numbers const stats = { profitMargin: Number(results[0].profitMargin) || 0, averageMarkup: Number(results[0].averageMarkup) || 0, stockTurnoverRate: Number(results[0].stockTurnoverRate) || 0, vendorCount: Number(results[0].vendorCount) || 0, categoryCount: Number(results[0].categoryCount) || 0, averageOrderValue: Number(results[0].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 const [byCategory] = await pool.query(` SELECT c.name as category, ROUND( (SUM(o.price * o.quantity - p.cost_price * o.quantity) / NULLIF(SUM(o.price * o.quantity), 0)) * 100, 1 ) as profitMargin, CAST(SUM(o.price * o.quantity) AS DECIMAL(15,3)) as revenue, 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 WHERE o.date >= DATE_SUB(CURDATE(), INTERVAL 30 DAY) GROUP BY c.name ORDER BY profitMargin DESC LIMIT 10 `); // Get profit margin trend over time const [overTime] = await pool.query(` SELECT formatted_date as date, ROUND( (SUM(o.price * o.quantity - p.cost_price * o.quantity) / NULLIF(SUM(o.price * o.quantity), 0)) * 100, 1 ) as profitMargin, CAST(SUM(o.price * o.quantity) AS DECIMAL(15,3)) as revenue, 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 CROSS JOIN ( SELECT DATE_FORMAT(o.date, '%Y-%m-%d') as formatted_date FROM orders o WHERE o.date >= DATE_SUB(CURDATE(), INTERVAL 30 DAY) GROUP BY DATE_FORMAT(o.date, '%Y-%m-%d') ) dates WHERE o.date >= DATE_SUB(CURDATE(), INTERVAL 30 DAY) AND DATE_FORMAT(o.date, '%Y-%m-%d') = dates.formatted_date GROUP BY formatted_date ORDER BY formatted_date `); // Get top performing products const [topProducts] = await pool.query(` SELECT p.title as product, ROUND( (SUM(o.price * o.quantity - p.cost_price * o.quantity) / NULLIF(SUM(o.price * o.quantity), 0)) * 100, 1 ) as profitMargin, CAST(SUM(o.price * o.quantity) AS DECIMAL(15,3)) as revenue, 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 WHERE o.date >= DATE_SUB(CURDATE(), INTERVAL 30 DAY) GROUP BY p.pid, p.title HAVING revenue > 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; console.log('Fetching vendor performance data...'); // First check if we have any vendors with sales const [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[0]); // Get vendor performance metrics const [performance] = await pool.query(` WITH monthly_sales AS ( SELECT p.vendor, CAST(SUM(CASE WHEN o.date >= DATE_SUB(CURDATE(), INTERVAL 30 DAY) THEN o.price * o.quantity ELSE 0 END) AS DECIMAL(15,3)) as current_month, CAST(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) AS DECIMAL(15,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 >= DATE_SUB(CURDATE(), INTERVAL 60 DAY) GROUP BY p.vendor ) SELECT p.vendor, CAST(SUM(o.price * o.quantity) AS DECIMAL(15,3)) as salesVolume, COALESCE(ROUND( (SUM(o.price * o.quantity - p.cost_price * o.quantity) / NULLIF(SUM(o.price * o.quantity), 0)) * 100, 1 ), 0) as profitMargin, COALESCE(ROUND( SUM(o.quantity) / NULLIF(AVG(p.stock_quantity), 0), 1 ), 0) as stockTurnover, COUNT(DISTINCT p.pid) as productCount, 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 >= DATE_SUB(CURDATE(), INTERVAL 30 DAY) GROUP BY p.vendor, ms.current_month, ms.previous_month ORDER BY salesVolume DESC LIMIT 10 `); console.log('Performance data:', performance); // Get vendor comparison data const [comparison] = await pool.query(` SELECT p.vendor, CAST(COALESCE(ROUND(SUM(o.price * o.quantity) / NULLIF(COUNT(DISTINCT p.pid), 0), 2), 0) AS DECIMAL(15,3)) as salesPerProduct, COALESCE(ROUND(AVG((o.price - p.cost_price) / NULLIF(o.price, 0) * 100), 1), 0) as averageMargin, COUNT(DISTINCT p.pid) as size FROM products p LEFT JOIN orders o ON p.pid = o.pid AND o.date >= DATE_SUB(CURDATE(), INTERVAL 30 DAY) WHERE p.vendor IS NOT NULL GROUP BY p.vendor ORDER BY salesPerProduct DESC LIMIT 20 `); console.log('Comparison data:', comparison); // Get vendor sales trends const [trends] = await pool.query(` SELECT p.vendor, DATE_FORMAT(o.date, '%b %Y') as month, CAST(COALESCE(SUM(o.price * o.quantity), 0) AS DECIMAL(15,3)) as sales FROM products p LEFT JOIN orders o ON p.pid = o.pid WHERE p.vendor IS NOT NULL AND o.date >= DATE_SUB(CURDATE(), INTERVAL 6 MONTH) GROUP BY p.vendor, DATE_FORMAT(o.date, '%b %Y'), DATE_FORMAT(o.date, '%Y-%m') ORDER BY p.vendor, DATE_FORMAT(o.date, '%Y-%m') `); console.log('Trends data:', trends); res.json({ performance, comparison, trends }); } catch (error) { console.error('Error fetching vendor performance:', error); res.status(500).json({ error: 'Failed to fetch vendor performance' }); } }); // Get stock analysis data router.get('/stock', async (req, res) => { try { const pool = req.app.locals.pool; // Get global configuration values const [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 [turnoverByCategory] = await pool.query(` SELECT c.name as category, ROUND(SUM(o.quantity) / NULLIF(AVG(p.stock_quantity), 0), 1) as turnoverRate, ROUND(AVG(p.stock_quantity), 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 >= DATE_SUB(CURDATE(), INTERVAL ? DAY) GROUP BY c.name HAVING turnoverRate > 0 ORDER BY turnoverRate DESC LIMIT 10 `, [config.turnover_period]); // Get stock levels over time const [stockLevels] = await pool.query(` SELECT DATE_FORMAT(o.date, '%Y-%m-%d') as date, SUM(CASE WHEN p.stock_quantity > ? THEN 1 ELSE 0 END) as inStock, SUM(CASE WHEN p.stock_quantity <= ? 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 >= DATE_SUB(CURDATE(), INTERVAL ? DAY) GROUP BY DATE_FORMAT(o.date, '%Y-%m-%d') ORDER BY date `, [ config.low_stock_threshold, config.low_stock_threshold, config.turnover_period ]); // Get critical stock items const [criticalItems] = await pool.query(` WITH product_thresholds AS ( SELECT p.pid, COALESCE( (SELECT reorder_days FROM stock_thresholds st JOIN product_categories pc ON st.cat_id = pc.cat_id WHERE pc.pid = p.pid AND st.vendor = p.vendor LIMIT 1), (SELECT reorder_days FROM stock_thresholds st JOIN product_categories pc ON st.cat_id = pc.cat_id WHERE pc.pid = p.pid AND st.vendor IS NULL LIMIT 1), (SELECT reorder_days FROM stock_thresholds st WHERE st.cat_id IS NULL AND st.vendor = p.vendor LIMIT 1), (SELECT reorder_days FROM stock_thresholds st WHERE st.cat_id IS NULL AND 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), ?) as reorderPoint, ROUND(SUM(o.quantity) / NULLIF(p.stock_quantity, 0), 1) as turnoverRate, CASE WHEN p.stock_quantity = 0 THEN 0 ELSE ROUND(p.stock_quantity / NULLIF((SUM(o.quantity) / ?), 0)) 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 >= DATE_SUB(CURDATE(), INTERVAL ? DAY) AND p.managing_stock = true GROUP BY p.pid HAVING daysUntilStockout < ? AND daysUntilStockout >= 0 ORDER BY daysUntilStockout LIMIT 10 `, [ config.low_stock_threshold, config.turnover_period, 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 [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 >= DATE_SUB(CURDATE(), INTERVAL 30 DAY) GROUP BY p.price, c.name HAVING salesVolume > 0 ORDER BY revenue DESC LIMIT 50 `); // Get price elasticity data (price changes vs demand) const [elasticity] = await pool.query(` SELECT DATE_FORMAT(o.date, '%Y-%m-%d') 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 >= DATE_SUB(CURDATE(), INTERVAL 30 DAY) GROUP BY DATE_FORMAT(o.date, '%Y-%m-%d') ORDER BY date `); // Get price optimization recommendations const [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 >= DATE_SUB(CURDATE(), INTERVAL 30 DAY) GROUP BY p.pid, p.price HAVING ABS(recommendedPrice - currentPrice) > 0 ORDER BY potentialRevenue - 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; // Get category performance metrics const [performance] = await pool.query(` WITH monthly_sales AS ( SELECT c.name, SUM(CASE WHEN o.date >= DATE_SUB(CURDATE(), INTERVAL 30 DAY) THEN o.price * o.quantity ELSE 0 END) as current_month, 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) 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 WHERE o.date >= DATE_SUB(CURDATE(), INTERVAL 60 DAY) GROUP BY c.name ) SELECT c.name as category, 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 LEFT JOIN monthly_sales ms ON c.name = ms.name WHERE o.date >= DATE_SUB(CURDATE(), INTERVAL 60 DAY) GROUP BY c.name, ms.current_month, ms.previous_month HAVING revenue > 0 ORDER BY revenue DESC LIMIT 10 `); // Get category revenue distribution const [distribution] = await pool.query(` SELECT c.name as category, 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 WHERE o.date >= DATE_SUB(CURDATE(), INTERVAL 30 DAY) GROUP BY c.name HAVING value > 0 ORDER BY value DESC LIMIT 6 `); // Get category sales trends const [trends] = await pool.query(` SELECT c.name as category, 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 WHERE o.date >= DATE_SUB(CURDATE(), INTERVAL 6 MONTH) GROUP BY c.name, DATE_FORMAT(o.date, '%b %Y'), DATE_FORMAT(o.date, '%Y-%m') ORDER BY c.name, DATE_FORMAT(o.date, '%Y-%m') `); 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 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]); 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;