diff --git a/inventory-server/db/metrics-schema.sql b/inventory-server/db/metrics-schema.sql index 9632237..90bd2f3 100644 --- a/inventory-server/db/metrics-schema.sql +++ b/inventory-server/db/metrics-schema.sql @@ -94,19 +94,86 @@ CREATE TABLE IF NOT EXISTS product_time_aggregates ( INDEX idx_date (year, month) ); --- New table for vendor performance +-- New table for vendor metrics CREATE TABLE IF NOT EXISTS vendor_metrics ( vendor VARCHAR(100) NOT NULL, - last_calculated_at TIMESTAMP NOT NULL, + last_calculated_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP, + -- Performance metrics avg_lead_time_days DECIMAL(10,3), on_time_delivery_rate DECIMAL(5,2), order_fill_rate DECIMAL(5,2), - total_orders INT, - total_late_orders INT, - total_purchase_value DECIMAL(10,3), + total_orders INT DEFAULT 0, + total_late_orders INT DEFAULT 0, + total_purchase_value DECIMAL(10,3) DEFAULT 0, avg_order_value DECIMAL(10,3), + -- Product metrics + active_products INT DEFAULT 0, + total_products INT DEFAULT 0, + -- Financial metrics + total_revenue DECIMAL(10,3) DEFAULT 0, + avg_margin_percent DECIMAL(5,2), + -- Status + status VARCHAR(20) DEFAULT 'active', PRIMARY KEY (vendor), - INDEX idx_vendor_performance (on_time_delivery_rate) + FOREIGN KEY (vendor) REFERENCES vendor_details(vendor) ON DELETE CASCADE, + INDEX idx_vendor_performance (on_time_delivery_rate), + INDEX idx_vendor_status (status) +); + +-- New table for category metrics +CREATE TABLE IF NOT EXISTS category_metrics ( + category_id BIGINT NOT NULL, + last_calculated_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP, + -- Product metrics + product_count INT DEFAULT 0, + active_products INT DEFAULT 0, + -- Financial metrics + total_value DECIMAL(10,3) DEFAULT 0, + avg_margin DECIMAL(5,2), + turnover_rate DECIMAL(10,3), + growth_rate DECIMAL(5,2), + -- Status + status VARCHAR(20) DEFAULT 'active', + PRIMARY KEY (category_id), + FOREIGN KEY (category_id) REFERENCES categories(id) ON DELETE CASCADE, + INDEX idx_category_status (status), + INDEX idx_category_growth (growth_rate) +); + +-- New table for vendor time-based metrics +CREATE TABLE IF NOT EXISTS vendor_time_metrics ( + vendor VARCHAR(100) NOT NULL, + year INT NOT NULL, + month INT NOT NULL, + -- Order metrics + total_orders INT DEFAULT 0, + late_orders INT DEFAULT 0, + avg_lead_time_days DECIMAL(10,3), + -- Financial metrics + total_purchase_value DECIMAL(10,3) DEFAULT 0, + total_revenue DECIMAL(10,3) DEFAULT 0, + avg_margin_percent DECIMAL(5,2), + PRIMARY KEY (vendor, year, month), + FOREIGN KEY (vendor) REFERENCES vendor_details(vendor) ON DELETE CASCADE, + INDEX idx_vendor_date (year, month) +); + +-- New table for category time-based metrics +CREATE TABLE IF NOT EXISTS category_time_metrics ( + category_id BIGINT NOT NULL, + year INT NOT NULL, + month INT NOT NULL, + -- Product metrics + product_count INT DEFAULT 0, + active_products INT DEFAULT 0, + -- Financial metrics + total_value DECIMAL(10,3) DEFAULT 0, + total_revenue DECIMAL(10,3) DEFAULT 0, + avg_margin DECIMAL(5,2), + turnover_rate DECIMAL(10,3), + PRIMARY KEY (category_id, year, month), + FOREIGN KEY (category_id) REFERENCES categories(id) ON DELETE CASCADE, + INDEX idx_category_date (year, month) ); -- New table for category-based sales metrics @@ -265,4 +332,57 @@ JOIN LEFT JOIN orders o ON p.product_id = o.product_id AND o.canceled = false GROUP BY - c.id, c.name, p.brand; \ No newline at end of file + c.id, c.name, p.brand; + +-- Create view for vendor performance trends +CREATE OR REPLACE VIEW vendor_performance_trends AS +SELECT + v.vendor, + v.contact_name, + v.status, + vm.avg_lead_time_days, + vm.on_time_delivery_rate, + vm.order_fill_rate, + vm.total_orders, + vm.total_late_orders, + vm.total_purchase_value, + vm.avg_order_value, + vm.active_products, + vm.total_products, + vm.total_revenue, + vm.avg_margin_percent, + CASE + WHEN vm.order_fill_rate >= 95 THEN 'Excellent' + WHEN vm.order_fill_rate >= 85 THEN 'Good' + WHEN vm.order_fill_rate >= 75 THEN 'Fair' + ELSE 'Poor' + END as performance_rating +FROM + vendor_details v +LEFT JOIN + vendor_metrics vm ON v.vendor = vm.vendor; + +-- Create view for category performance trends +CREATE OR REPLACE VIEW category_performance_trends AS +SELECT + c.id as category_id, + c.name, + c.description, + c.parent_category, + c.status, + cm.product_count, + cm.active_products, + cm.total_value, + cm.avg_margin, + cm.turnover_rate, + cm.growth_rate, + CASE + WHEN cm.growth_rate >= 20 THEN 'High Growth' + WHEN cm.growth_rate >= 5 THEN 'Growing' + WHEN cm.growth_rate >= -5 THEN 'Stable' + ELSE 'Declining' + END as performance_rating +FROM + categories c +LEFT JOIN + category_metrics cm ON c.id = cm.category_id; \ No newline at end of file diff --git a/inventory-server/db/schema.sql b/inventory-server/db/schema.sql index 5125396..65be6f9 100644 --- a/inventory-server/db/schema.sql +++ b/inventory-server/db/schema.sql @@ -38,8 +38,26 @@ CREATE TABLE products ( CREATE TABLE categories ( id BIGINT AUTO_INCREMENT PRIMARY KEY, name VARCHAR(100) NOT NULL, + description TEXT, + parent_category VARCHAR(100), created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, - UNIQUE KEY unique_name (name) + updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP, + status VARCHAR(20) DEFAULT 'active', + UNIQUE KEY unique_name (name), + INDEX idx_parent (parent_category), + INDEX idx_status (status) +) ENGINE=InnoDB; + +-- Create vendor_details table +CREATE TABLE vendor_details ( + vendor VARCHAR(100) PRIMARY KEY, + contact_name VARCHAR(100), + email VARCHAR(255), + phone VARCHAR(50), + status VARCHAR(20) DEFAULT 'active', + created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, + updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP, + INDEX idx_status (status) ) ENGINE=InnoDB; -- Create product_categories junction table diff --git a/inventory-server/scripts/calculate-metrics.js b/inventory-server/scripts/calculate-metrics.js index 0a8d757..e7c7011 100644 --- a/inventory-server/scripts/calculate-metrics.js +++ b/inventory-server/scripts/calculate-metrics.js @@ -547,7 +547,194 @@ async function calculateCategorySalesMetrics(connection, startTime, totalProduct `); } -// Update the main calculation function to include category sales metrics +// Add new functions for vendor and category metrics +async function calculateVendorMetrics(connection) { + console.log('Calculating vendor metrics...'); + + // Calculate vendor performance metrics + await connection.query(` + INSERT INTO vendor_metrics ( + vendor, + avg_lead_time_days, + on_time_delivery_rate, + order_fill_rate, + total_orders, + total_late_orders, + total_purchase_value, + avg_order_value, + active_products, + total_products, + total_revenue, + avg_margin_percent, + status + ) + SELECT + vd.vendor, + -- Lead time metrics + AVG(DATEDIFF(po.received_date, po.date)) as avg_lead_time_days, + -- On-time delivery rate + (COUNT(CASE WHEN po.received_date <= po.expected_date THEN 1 END) / COUNT(*)) * 100 as on_time_delivery_rate, + -- Order fill rate + (SUM(po.received) / SUM(po.ordered)) * 100 as order_fill_rate, + COUNT(DISTINCT po.po_id) as total_orders, + COUNT(DISTINCT CASE WHEN po.received_date > po.expected_date THEN po.po_id END) as total_late_orders, + SUM(po.cost_price * po.ordered) as total_purchase_value, + AVG(po.cost_price * po.ordered) as avg_order_value, + -- Product counts + COUNT(DISTINCT CASE WHEN p.visible = true THEN p.product_id END) as active_products, + COUNT(DISTINCT p.product_id) as total_products, + -- Financial metrics + SUM(o.price * o.quantity) as total_revenue, + AVG(((o.price - p.cost_price) / o.price) * 100) as avg_margin_percent, + vd.status + FROM vendor_details vd + LEFT JOIN products p ON vd.vendor = p.vendor + LEFT JOIN purchase_orders po ON p.product_id = po.product_id + LEFT JOIN orders o ON p.product_id = o.product_id AND o.canceled = false + GROUP BY vd.vendor, vd.status + ON DUPLICATE KEY UPDATE + avg_lead_time_days = VALUES(avg_lead_time_days), + on_time_delivery_rate = VALUES(on_time_delivery_rate), + order_fill_rate = VALUES(order_fill_rate), + total_orders = VALUES(total_orders), + total_late_orders = VALUES(total_late_orders), + total_purchase_value = VALUES(total_purchase_value), + avg_order_value = VALUES(avg_order_value), + active_products = VALUES(active_products), + total_products = VALUES(total_products), + total_revenue = VALUES(total_revenue), + avg_margin_percent = VALUES(avg_margin_percent), + status = VALUES(status), + last_calculated_at = CURRENT_TIMESTAMP + `); + + // Calculate vendor time-based metrics + await connection.query(` + INSERT INTO vendor_time_metrics ( + vendor, + year, + month, + total_orders, + late_orders, + avg_lead_time_days, + total_purchase_value, + total_revenue, + avg_margin_percent + ) + SELECT + vd.vendor, + YEAR(po.date) as year, + MONTH(po.date) as month, + COUNT(DISTINCT po.po_id) as total_orders, + COUNT(DISTINCT CASE WHEN po.received_date > po.expected_date THEN po.po_id END) as late_orders, + AVG(DATEDIFF(po.received_date, po.date)) as avg_lead_time_days, + SUM(po.cost_price * po.ordered) as total_purchase_value, + SUM(o.price * o.quantity) as total_revenue, + AVG(((o.price - p.cost_price) / o.price) * 100) as avg_margin_percent + FROM vendor_details vd + LEFT JOIN products p ON vd.vendor = p.vendor + LEFT JOIN purchase_orders po ON p.product_id = po.product_id + LEFT JOIN orders o ON p.product_id = o.product_id AND o.canceled = false + WHERE po.date >= DATE_SUB(CURRENT_DATE, INTERVAL 12 MONTH) + GROUP BY vd.vendor, YEAR(po.date), MONTH(po.date) + ON DUPLICATE KEY UPDATE + total_orders = VALUES(total_orders), + late_orders = VALUES(late_orders), + avg_lead_time_days = VALUES(avg_lead_time_days), + total_purchase_value = VALUES(total_purchase_value), + total_revenue = VALUES(total_revenue), + avg_margin_percent = VALUES(avg_margin_percent) + `); +} + +async function calculateCategoryMetrics(connection) { + console.log('Calculating category metrics...'); + + // Calculate category performance metrics + await connection.query(` + INSERT INTO category_metrics ( + category_id, + product_count, + active_products, + total_value, + avg_margin, + turnover_rate, + growth_rate, + status + ) + SELECT + c.id as category_id, + COUNT(DISTINCT p.product_id) as product_count, + COUNT(DISTINCT CASE WHEN p.visible = true THEN p.product_id END) as active_products, + SUM(p.stock_quantity * p.cost_price) as total_value, + AVG(((p.price - p.cost_price) / p.price) * 100) as avg_margin, + -- Turnover rate calculation + SUM(o.quantity) / NULLIF(AVG(p.stock_quantity), 0) as turnover_rate, + -- Growth rate calculation (comparing current month to previous month) + (( + SUM(CASE WHEN o.date >= DATE_SUB(CURRENT_DATE, INTERVAL 1 MONTH) THEN o.quantity ELSE 0 END) - + SUM(CASE WHEN o.date BETWEEN DATE_SUB(CURRENT_DATE, INTERVAL 2 MONTH) AND DATE_SUB(CURRENT_DATE, INTERVAL 1 MONTH) THEN o.quantity ELSE 0 END) + ) / NULLIF( + SUM(CASE WHEN o.date BETWEEN DATE_SUB(CURRENT_DATE, INTERVAL 2 MONTH) AND DATE_SUB(CURRENT_DATE, INTERVAL 1 MONTH) THEN o.quantity ELSE 0 END), + 0 + ) * 100) as growth_rate, + c.status + FROM categories c + LEFT JOIN product_categories pc ON c.id = pc.category_id + LEFT JOIN products p ON pc.product_id = p.product_id + LEFT JOIN orders o ON p.product_id = o.product_id AND o.canceled = false + GROUP BY c.id, c.status + ON DUPLICATE KEY UPDATE + product_count = VALUES(product_count), + active_products = VALUES(active_products), + total_value = VALUES(total_value), + avg_margin = VALUES(avg_margin), + turnover_rate = VALUES(turnover_rate), + growth_rate = VALUES(growth_rate), + status = VALUES(status), + last_calculated_at = CURRENT_TIMESTAMP + `); + + // Calculate category time-based metrics + await connection.query(` + INSERT INTO category_time_metrics ( + category_id, + year, + month, + product_count, + active_products, + total_value, + total_revenue, + avg_margin, + turnover_rate + ) + SELECT + c.id as category_id, + YEAR(o.date) as year, + MONTH(o.date) as month, + COUNT(DISTINCT p.product_id) as product_count, + COUNT(DISTINCT CASE WHEN p.visible = true THEN p.product_id END) as active_products, + SUM(p.stock_quantity * p.cost_price) as total_value, + SUM(o.price * o.quantity) as total_revenue, + AVG(((p.price - p.cost_price) / p.price) * 100) as avg_margin, + SUM(o.quantity) / NULLIF(AVG(p.stock_quantity), 0) as turnover_rate + FROM categories c + LEFT JOIN product_categories pc ON c.id = pc.category_id + LEFT JOIN products p ON pc.product_id = p.product_id + LEFT JOIN orders o ON p.product_id = o.product_id AND o.canceled = false + WHERE o.date >= DATE_SUB(CURRENT_DATE, INTERVAL 12 MONTH) + GROUP BY c.id, YEAR(o.date), MONTH(o.date) + ON DUPLICATE KEY UPDATE + product_count = VALUES(product_count), + active_products = VALUES(active_products), + total_value = VALUES(total_value), + total_revenue = VALUES(total_revenue), + avg_margin = VALUES(avg_margin), + turnover_rate = VALUES(turnover_rate) + `); +} + +// Update the main calculation function to include the new metrics async function calculateMetrics() { let pool; const startTime = Date.now(); diff --git a/inventory-server/scripts/reset-metrics.js b/inventory-server/scripts/reset-metrics.js index 357a27e..09e1aa8 100644 --- a/inventory-server/scripts/reset-metrics.js +++ b/inventory-server/scripts/reset-metrics.js @@ -43,179 +43,37 @@ const REQUIRED_CORE_TABLES = [ ]; async function resetMetrics() { - outputProgress({ - status: 'running', - operation: 'Starting metrics reset', - percentage: '0' - }); - - const connection = await mysql.createConnection(dbConfig); - + let connection; try { - // First verify that core tables exist - outputProgress({ - status: 'running', - operation: 'Verifying core tables exist', - percentage: '10' - }); + connection = await mysql.createConnection(dbConfig); + await connection.beginTransaction(); - // Use SHOW TABLES to verify core tables exist - const [showTables] = await connection.query('SHOW TABLES'); - const existingTables = showTables.map(t => Object.values(t)[0]); - - outputProgress({ - operation: 'Core tables verification', - message: { - found: existingTables, - required: REQUIRED_CORE_TABLES - } - }); - - // Check if any core tables are missing - const missingCoreTables = REQUIRED_CORE_TABLES.filter( - t => !existingTables.includes(t) - ); - - if (missingCoreTables.length > 0) { - throw new Error( - `Core tables missing: ${missingCoreTables.join(', ')}. Please run reset-db.js first.` - ); - } - - // Verify all core tables use InnoDB - const [engineStatus] = await connection.query('SHOW TABLE STATUS WHERE Name IN (?)', [REQUIRED_CORE_TABLES]); - const nonInnoDBTables = engineStatus.filter(t => t.Engine !== 'InnoDB'); + // Reset existing metrics tables + await connection.query('TRUNCATE TABLE temp_sales_metrics'); + await connection.query('TRUNCATE TABLE temp_purchase_metrics'); + await connection.query('TRUNCATE TABLE product_metrics'); + await connection.query('TRUNCATE TABLE product_time_aggregates'); - if (nonInnoDBTables.length > 0) { - throw new Error( - `Tables using non-InnoDB engine: ${nonInnoDBTables.map(t => t.Name).join(', ')}` - ); - } + // Reset vendor metrics tables + await connection.query('TRUNCATE TABLE vendor_metrics'); + await connection.query('TRUNCATE TABLE vendor_time_metrics'); + + // Reset category metrics tables + await connection.query('TRUNCATE TABLE category_metrics'); + await connection.query('TRUNCATE TABLE category_time_metrics'); - // Disable foreign key checks first - await connection.query('SET FOREIGN_KEY_CHECKS = 0'); - - // Drop the metrics views first - outputProgress({ - status: 'running', - operation: 'Dropping metrics views', - percentage: '15' - }); - await connection.query('DROP VIEW IF EXISTS inventory_health, product_sales_trends'); - - // Drop only the metrics tables if they exist - const [existing] = await connection.query(` - SELECT GROUP_CONCAT(table_name) as tables - FROM information_schema.tables - WHERE table_schema = DATABASE() - AND table_name IN (${METRICS_TABLES.map(table => `'${table}'`).join(',')}) - `); - - if (existing[0].tables) { - outputProgress({ - status: 'running', - operation: 'Dropping existing metrics tables', - percentage: '20' - }); - const dropQuery = ` - DROP TABLE IF EXISTS - ${existing[0].tables - .split(',') - .map(table => '`' + table + '`') - .join(', ')} - `; - await connection.query(dropQuery); - } - - // Read metrics schema in its entirety - outputProgress({ - status: 'running', - operation: 'Creating metrics tables', - percentage: '40' - }); - const schemaPath = path.join(__dirname, '../db/metrics-schema.sql'); - const schemaSQL = fs.readFileSync(schemaPath, 'utf8'); - - // Run the entire metrics-schema so it creates - // the metrics tables and indexes in one shot - await connection.query(schemaSQL); - - // Read and execute config schema - outputProgress({ - status: 'running', - operation: 'Creating configuration tables', - percentage: '60' - }); - const configSchemaPath = path.join(__dirname, '../db/config-schema.sql'); - const configSchemaSQL = fs.readFileSync(configSchemaPath, 'utf8'); - - // Run the config schema - await connection.query(configSchemaSQL); - - // Verify all tables were actually created using SHOW TABLES - const [verifyTables] = await connection.query('SHOW TABLES'); - const tablesAfterCreation = verifyTables.map(t => Object.values(t)[0]); - - // First verify metrics tables - outputProgress({ - status: 'running', - operation: 'Verifying metrics tables', - message: { - found: tablesAfterCreation, - required: METRICS_TABLES - } - }); - - const missingMetricsTables = METRICS_TABLES.filter( - t => !tablesAfterCreation.includes(t) - ); - - if (missingMetricsTables.length > 0) { - throw new Error( - `Failed to create metrics tables: ${missingMetricsTables.join(', ')}` - ); - } - - // Then verify config tables - outputProgress({ - status: 'running', - operation: 'Verifying config tables', - message: { - found: tablesAfterCreation, - required: CONFIG_TABLES - } - }); - - const missingConfigTables = CONFIG_TABLES.filter( - t => !tablesAfterCreation.includes(t) - ); - - if (missingConfigTables.length > 0) { - throw new Error( - `Failed to create config tables: ${missingConfigTables.join(', ')}` - ); - } - - // Re-enable foreign key checks - await connection.query('SET FOREIGN_KEY_CHECKS = 1'); - - outputProgress({ - status: 'complete', - operation: 'Metrics and config tables have been reset', - percentage: '100' - }); - - return { success: true }; + await connection.commit(); + console.log('All metrics tables reset successfully'); } catch (error) { + if (connection) { + await connection.rollback(); + } console.error('Error resetting metrics:', error); - outputProgress({ - status: 'error', - operation: 'Failed to reset metrics', - error: error.message - }); throw error; } finally { - await connection.end(); + if (connection) { + await connection.end(); + } } } diff --git a/inventory-server/src/routes/categories.js b/inventory-server/src/routes/categories.js new file mode 100644 index 0000000..a83d4cb --- /dev/null +++ b/inventory-server/src/routes/categories.js @@ -0,0 +1,120 @@ +const express = require('express'); +const router = express.Router(); + +// Get categories with pagination, filtering, and sorting +router.get('/', async (req, res) => { + const pool = req.app.locals.pool; + try { + const page = parseInt(req.query.page) || 1; + const limit = parseInt(req.query.limit) || 50; + const offset = (page - 1) * limit; + const search = req.query.search || ''; + const parent = req.query.parent || 'all'; + const performance = req.query.performance || 'all'; + const sortColumn = req.query.sortColumn || 'name'; + const sortDirection = req.query.sortDirection || 'asc'; + + // Build the WHERE clause based on filters + const whereConditions = []; + const params = []; + + if (search) { + whereConditions.push('(c.name LIKE ? OR c.description LIKE ?)'); + params.push(`%${search}%`, `%${search}%`); + } + + if (parent !== 'all') { + if (parent === 'none') { + whereConditions.push('c.parent_category IS NULL'); + } else { + whereConditions.push('c.parent_category = ?'); + params.push(parent); + } + } + + if (performance !== 'all') { + switch (performance) { + case 'high_growth': + whereConditions.push('cm.growth_rate >= 20'); + break; + case 'growing': + whereConditions.push('cm.growth_rate >= 5 AND cm.growth_rate < 20'); + break; + case 'stable': + whereConditions.push('cm.growth_rate >= -5 AND cm.growth_rate < 5'); + break; + case 'declining': + whereConditions.push('cm.growth_rate < -5'); + break; + } + } + + const whereClause = whereConditions.length > 0 + ? 'WHERE ' + whereConditions.join(' AND ') + : ''; + + // Get total count for pagination + const [countResult] = await pool.query(` + SELECT COUNT(DISTINCT c.id) as total + FROM categories c + LEFT JOIN category_metrics cm ON c.id = cm.category_id + ${whereClause} + `, params); + + // Get parent categories for filter dropdown + const [parentCategories] = await pool.query(` + SELECT DISTINCT parent_category + FROM categories + WHERE parent_category IS NOT NULL + ORDER BY parent_category + `); + + // Get categories with metrics + const [categories] = await pool.query(` + SELECT + c.id as category_id, + c.name, + c.description, + c.parent_category, + cm.product_count, + cm.total_value, + cm.avg_margin, + cm.turnover_rate, + cm.growth_rate, + cm.status + FROM categories c + LEFT JOIN category_metrics cm ON c.id = cm.category_id + ${whereClause} + ORDER BY ${sortColumn} ${sortDirection} + LIMIT ? OFFSET ? + `, [...params, limit, offset]); + + // Get overall stats + const [stats] = await pool.query(` + SELECT + COUNT(DISTINCT c.id) as totalCategories, + COUNT(DISTINCT CASE WHEN cm.status = 'active' THEN c.id END) as activeCategories, + SUM(cm.total_value) as totalValue, + AVG(cm.avg_margin) as avgMargin, + AVG(cm.growth_rate) as avgGrowth + FROM categories c + LEFT JOIN category_metrics cm ON c.id = cm.category_id + `); + + res.json({ + categories, + parentCategories: parentCategories.map(p => p.parent_category), + stats: stats[0], + pagination: { + total: countResult[0].total, + pages: Math.ceil(countResult[0].total / limit), + current: page, + } + }); + } catch (error) { + console.error('Error fetching categories:', error); + res.status(500).json({ error: 'Failed to fetch categories' }); + } +}); + +module.exports = router; \ No newline at end of file diff --git a/inventory-server/src/routes/vendors.js b/inventory-server/src/routes/vendors.js new file mode 100644 index 0000000..0c97685 --- /dev/null +++ b/inventory-server/src/routes/vendors.js @@ -0,0 +1,108 @@ +const express = require('express'); +const router = express.Router(); + +// Get vendors with pagination, filtering, and sorting +router.get('/', async (req, res) => { + const pool = req.app.locals.pool; + try { + const page = parseInt(req.query.page) || 1; + const limit = parseInt(req.query.limit) || 50; + const offset = (page - 1) * limit; + const search = req.query.search || ''; + const status = req.query.status || 'all'; + const performance = req.query.performance || 'all'; + const sortColumn = req.query.sortColumn || 'name'; + const sortDirection = req.query.sortDirection || 'asc'; + + // Build the WHERE clause based on filters + const whereConditions = []; + const params = []; + + if (search) { + whereConditions.push('(p.vendor LIKE ? OR vm.contact_name LIKE ?)'); + params.push(`%${search}%`, `%${search}%`); + } + + if (status !== 'all') { + whereConditions.push('vm.status = ?'); + params.push(status); + } + + if (performance !== 'all') { + switch (performance) { + case 'excellent': + whereConditions.push('vm.order_fill_rate >= 95'); + break; + case 'good': + whereConditions.push('vm.order_fill_rate >= 85 AND vm.order_fill_rate < 95'); + break; + case 'fair': + whereConditions.push('vm.order_fill_rate >= 75 AND vm.order_fill_rate < 85'); + break; + case 'poor': + whereConditions.push('vm.order_fill_rate < 75'); + break; + } + } + + const whereClause = whereConditions.length > 0 + ? 'WHERE ' + whereConditions.join(' AND ') + : ''; + + // Get total count for pagination + const [countResult] = await pool.query(` + SELECT COUNT(DISTINCT p.vendor) as total + FROM products p + LEFT JOIN vendor_metrics vm ON p.vendor = vm.vendor + ${whereClause} + `, params); + + // Get vendors with metrics + const [vendors] = await pool.query(` + SELECT + p.vendor as name, + vm.contact_name, + vm.email, + vm.phone, + vm.status, + vm.avg_lead_time_days, + vm.on_time_delivery_rate, + vm.order_fill_rate, + vm.total_orders, + COUNT(DISTINCT p.product_id) as active_products + FROM products p + LEFT JOIN vendor_metrics vm ON p.vendor = vm.vendor + ${whereClause} + GROUP BY p.vendor + ORDER BY ${sortColumn} ${sortDirection} + LIMIT ? OFFSET ? + `, [...params, limit, offset]); + + // Get overall stats + const [stats] = await pool.query(` + SELECT + COUNT(DISTINCT p.vendor) as totalVendors, + COUNT(DISTINCT CASE WHEN vm.status = 'active' THEN p.vendor END) as activeVendors, + AVG(vm.avg_lead_time_days) as avgLeadTime, + AVG(vm.order_fill_rate) as avgFillRate, + AVG(vm.on_time_delivery_rate) as avgOnTimeDelivery + FROM products p + LEFT JOIN vendor_metrics vm ON p.vendor = vm.vendor + `); + + res.json({ + vendors, + stats: stats[0], + pagination: { + total: countResult[0].total, + pages: Math.ceil(countResult[0].total / limit), + current: page, + } + }); + } catch (error) { + console.error('Error fetching vendors:', error); + res.status(500).json({ error: 'Failed to fetch vendors' }); + } +}); + +module.exports = router; \ No newline at end of file diff --git a/inventory-server/src/server.js b/inventory-server/src/server.js index 228f186..1d31b02 100755 --- a/inventory-server/src/server.js +++ b/inventory-server/src/server.js @@ -14,6 +14,8 @@ const analyticsRouter = require('./routes/analytics'); const purchaseOrdersRouter = require('./routes/purchase-orders'); const configRouter = require('./routes/config'); const metricsRouter = require('./routes/metrics'); +const vendorsRouter = require('./routes/vendors'); +const categoriesRouter = require('./routes/categories'); // Get the absolute path to the .env file const envPath = path.resolve(process.cwd(), '.env'); @@ -87,6 +89,8 @@ app.use('/api/analytics', analyticsRouter); app.use('/api/purchase-orders', purchaseOrdersRouter); app.use('/api/config', configRouter); app.use('/api/metrics', metricsRouter); +app.use('/api/vendors', vendorsRouter); +app.use('/api/categories', categoriesRouter); // Basic health check route app.get('/health', (req, res) => {