const express = require('express'); const router = express.Router(); // Get all purchase orders with summary metrics router.get('/', async (req, res) => { try { const pool = req.app.locals.pool; const { search, status, vendor, startDate, endDate, page = 1, limit = 100, sortColumn = 'date', sortDirection = 'desc' } = req.query; let whereClause = '1=1'; const params = []; if (search) { whereClause += ' AND (po.po_id LIKE ? OR po.vendor LIKE ? OR po.status LIKE ?)'; params.push(`%${search}%`, `%${search}%`, `%${search}%`); } if (status && status !== 'all') { whereClause += ' AND po.status = ?'; params.push(status); } if (vendor && vendor !== 'all') { whereClause += ' AND po.vendor = ?'; params.push(vendor); } if (startDate) { whereClause += ' AND po.date >= ?'; params.push(startDate); } if (endDate) { whereClause += ' AND po.date <= ?'; params.push(endDate); } // Get filtered summary metrics const [summary] = await pool.query(` WITH po_totals AS ( SELECT po_id, SUM(ordered) as total_ordered, SUM(received) as total_received, SUM(ordered * cost_price) as total_cost FROM purchase_orders po WHERE ${whereClause} GROUP BY po_id ) SELECT COUNT(DISTINCT po_id) as order_count, SUM(total_ordered) as total_ordered, SUM(total_received) as total_received, ROUND( SUM(total_received) / NULLIF(SUM(total_ordered), 0), 3 ) as fulfillment_rate, SUM(total_cost) as total_value, ROUND(AVG(total_cost), 2) as avg_cost FROM po_totals `, params); // Get total count for pagination const [countResult] = await pool.query(` SELECT COUNT(DISTINCT po_id) as total FROM purchase_orders po WHERE ${whereClause} `, params); const total = countResult[0].total; const offset = (page - 1) * limit; const pages = Math.ceil(total / limit); // Get recent purchase orders const [orders] = await pool.query(` WITH po_totals AS ( SELECT po_id, vendor, date, status, COUNT(DISTINCT product_id) as total_items, SUM(ordered) as total_quantity, SUM(ordered * cost_price) as total_cost, SUM(received) as total_received, ROUND( SUM(received) / NULLIF(SUM(ordered), 0), 3 ) as fulfillment_rate FROM purchase_orders po WHERE ${whereClause} GROUP BY po_id, vendor, date, status ) SELECT po_id as id, vendor as vendor_name, DATE_FORMAT(date, '%Y-%m-%d') as order_date, status, total_items, total_quantity, total_cost, total_received, fulfillment_rate FROM po_totals ORDER BY CASE WHEN ? = 'order_date' THEN date WHEN ? = 'vendor_name' THEN vendor WHEN ? = 'total_cost' THEN CAST(total_cost AS DECIMAL(15,2)) WHEN ? = 'total_received' THEN CAST(total_received AS DECIMAL(15,2)) WHEN ? = 'total_items' THEN CAST(total_items AS SIGNED) WHEN ? = 'total_quantity' THEN CAST(total_quantity AS SIGNED) WHEN ? = 'fulfillment_rate' THEN CAST(fulfillment_rate AS DECIMAL(5,3)) WHEN ? = 'status' THEN status ELSE date END ${sortDirection === 'desc' ? 'DESC' : 'ASC'} LIMIT ? OFFSET ? `, [...params, sortColumn, sortColumn, sortColumn, sortColumn, sortColumn, sortColumn, sortColumn, sortColumn, Number(limit), offset]); // Get unique vendors for filter options const [vendors] = await pool.query(` SELECT DISTINCT vendor FROM purchase_orders WHERE vendor IS NOT NULL AND vendor != '' ORDER BY vendor `); // Get unique statuses for filter options const [statuses] = await pool.query(` SELECT DISTINCT status FROM purchase_orders WHERE status IS NOT NULL AND status != '' ORDER BY status `); // Parse numeric values const parsedOrders = orders.map(order => ({ id: order.id, vendor_name: order.vendor_name, order_date: order.order_date, status: order.status, total_items: Number(order.total_items) || 0, total_quantity: Number(order.total_quantity) || 0, total_cost: Number(order.total_cost) || 0, total_received: Number(order.total_received) || 0, fulfillment_rate: Number(order.fulfillment_rate) || 0 })); // Parse summary metrics const parsedSummary = { order_count: Number(summary[0].order_count) || 0, total_ordered: Number(summary[0].total_ordered) || 0, total_received: Number(summary[0].total_received) || 0, fulfillment_rate: Number(summary[0].fulfillment_rate) || 0, total_value: Number(summary[0].total_value) || 0, avg_cost: Number(summary[0].avg_cost) || 0 }; res.json({ orders: parsedOrders, summary: parsedSummary, pagination: { total, pages, page: Number(page), limit: Number(limit) }, filters: { vendors: vendors.map(v => v.vendor), statuses: statuses.map(s => s.status) } }); } catch (error) { console.error('Error fetching purchase orders:', error); res.status(500).json({ error: 'Failed to fetch purchase orders' }); } }); // Get vendor performance metrics router.get('/vendor-metrics', async (req, res) => { try { const pool = req.app.locals.pool; const [metrics] = await pool.query(` WITH delivery_metrics AS ( SELECT vendor, po_id, ordered, received, cost_price, CASE WHEN status = 'received' AND received_date IS NOT NULL AND date IS NOT NULL THEN DATEDIFF(received_date, date) ELSE NULL END as delivery_days FROM purchase_orders WHERE vendor IS NOT NULL AND vendor != '' ) SELECT vendor as vendor_name, COUNT(DISTINCT po_id) as total_orders, SUM(ordered) as total_ordered, SUM(received) as total_received, ROUND( SUM(received) / NULLIF(SUM(ordered), 0), 3 ) as fulfillment_rate, ROUND( SUM(ordered * cost_price) / NULLIF(SUM(ordered), 0), 2 ) as avg_unit_cost, SUM(ordered * cost_price) as total_spend, ROUND( AVG(NULLIF(delivery_days, 0)), 1 ) as avg_delivery_days FROM delivery_metrics GROUP BY vendor HAVING total_orders > 0 ORDER BY total_spend DESC `); // Parse numeric values const parsedMetrics = metrics.map(vendor => ({ id: vendor.vendor_name, vendor_name: vendor.vendor_name, total_orders: Number(vendor.total_orders) || 0, total_ordered: Number(vendor.total_ordered) || 0, total_received: Number(vendor.total_received) || 0, fulfillment_rate: Number(vendor.fulfillment_rate) || 0, avg_unit_cost: Number(vendor.avg_unit_cost) || 0, total_spend: Number(vendor.total_spend) || 0, avg_delivery_days: vendor.avg_delivery_days === null ? null : Number(vendor.avg_delivery_days) })); res.json(parsedMetrics); } catch (error) { console.error('Error fetching vendor metrics:', error); res.status(500).json({ error: 'Failed to fetch vendor metrics' }); } }); // Get cost analysis router.get('/cost-analysis', async (req, res) => { try { const pool = req.app.locals.pool; const [analysis] = await pool.query(` SELECT c.name as categories, COUNT(DISTINCT po.product_id) as unique_products, ROUND(AVG(po.cost_price), 2) as avg_cost, MIN(po.cost_price) as min_cost, MAX(po.cost_price) as max_cost, ROUND( STDDEV(po.cost_price), 2 ) as cost_variance, SUM(po.ordered * po.cost_price) as total_spend FROM purchase_orders po JOIN products p ON po.product_id = p.product_id JOIN product_categories pc ON p.product_id = pc.product_id JOIN categories c ON pc.category_id = c.id GROUP BY c.name ORDER BY total_spend DESC `); // Parse numeric values and add ids for React keys const parsedAnalysis = analysis.map(item => ({ id: item.categories || 'Uncategorized', categories: item.categories || 'Uncategorized', unique_products: Number(item.unique_products) || 0, avg_cost: Number(item.avg_cost) || 0, min_cost: Number(item.min_cost) || 0, max_cost: Number(item.max_cost) || 0, cost_variance: Number(item.cost_variance) || 0, total_spend: Number(item.total_spend) || 0 })); // Transform the data with parsed values const transformedAnalysis = { ...parsedAnalysis[0], total_spend_by_category: parsedAnalysis.map(item => ({ id: item.categories, category: item.categories, total_spend: Number(item.total_spend) })) }; res.json(transformedAnalysis); } catch (error) { console.error('Error fetching cost analysis:', error); res.status(500).json({ error: 'Failed to fetch cost analysis' }); } }); // Get receiving status metrics router.get('/receiving-status', async (req, res) => { try { const pool = req.app.locals.pool; const [status] = await pool.query(` WITH po_totals AS ( SELECT po_id, SUM(ordered) as total_ordered, SUM(received) as total_received, SUM(ordered * cost_price) as total_cost FROM purchase_orders GROUP BY po_id ) SELECT COUNT(DISTINCT po_id) as order_count, SUM(total_ordered) as total_ordered, SUM(total_received) as total_received, ROUND( SUM(total_received) / NULLIF(SUM(total_ordered), 0), 3 ) as fulfillment_rate, SUM(total_cost) as total_value, ROUND(AVG(total_cost), 2) as avg_cost FROM po_totals `); // Parse numeric values const parsedStatus = { order_count: Number(status[0].order_count) || 0, total_ordered: Number(status[0].total_ordered) || 0, total_received: Number(status[0].total_received) || 0, fulfillment_rate: Number(status[0].fulfillment_rate) || 0, total_value: Number(status[0].total_value) || 0, avg_cost: Number(status[0].avg_cost) || 0 }; res.json(parsedStatus); } catch (error) { console.error('Error fetching receiving status:', error); res.status(500).json({ error: 'Failed to fetch receiving status' }); } }); // Get order vs received quantities by product router.get('/order-vs-received', async (req, res) => { try { const pool = req.app.locals.pool; const [quantities] = await pool.query(` SELECT p.product_id, p.title as product, p.SKU as sku, SUM(po.ordered) as ordered_quantity, SUM(po.received) as received_quantity, ROUND( SUM(po.received) / NULLIF(SUM(po.ordered), 0) * 100, 1 ) as fulfillment_rate, COUNT(DISTINCT po.po_id) as order_count FROM products p JOIN purchase_orders po ON p.product_id = po.product_id WHERE po.date >= DATE_SUB(CURDATE(), INTERVAL 90 DAY) GROUP BY p.product_id, p.title, p.SKU HAVING order_count > 0 ORDER BY ordered_quantity DESC LIMIT 20 `); // Parse numeric values and add id for React keys const parsedQuantities = quantities.map(q => ({ id: q.product_id, ...q, ordered_quantity: Number(q.ordered_quantity), received_quantity: Number(q.received_quantity), fulfillment_rate: Number(q.fulfillment_rate), order_count: Number(q.order_count) })); res.json(parsedQuantities); } catch (error) { console.error('Error fetching order vs received quantities:', error); res.status(500).json({ error: 'Failed to fetch order vs received quantities' }); } }); module.exports = router;