diff --git a/inventory-server/db/metrics-schema.sql b/inventory-server/db/metrics-schema.sql index bd60517..fd08f9f 100644 --- a/inventory-server/db/metrics-schema.sql +++ b/inventory-server/db/metrics-schema.sql @@ -63,6 +63,10 @@ CREATE TABLE IF NOT EXISTS product_metrics ( current_lead_time INT, target_lead_time INT, lead_time_status VARCHAR(20), + -- Forecast metrics + forecast_accuracy DECIMAL(5,2) DEFAULT NULL, + forecast_bias DECIMAL(5,2) DEFAULT NULL, + last_forecast_date DATE DEFAULT NULL, PRIMARY KEY (product_id), FOREIGN KEY (product_id) REFERENCES products(product_id) ON DELETE CASCADE, INDEX idx_metrics_revenue (total_revenue), @@ -71,7 +75,8 @@ CREATE TABLE IF NOT EXISTS product_metrics ( INDEX idx_metrics_turnover (turnover_rate), INDEX idx_metrics_last_calculated (last_calculated_at), INDEX idx_metrics_abc (abc_class), - INDEX idx_metrics_sales (daily_sales_avg, weekly_sales_avg, monthly_sales_avg) + INDEX idx_metrics_sales (daily_sales_avg, weekly_sales_avg, monthly_sales_avg), + INDEX idx_metrics_forecast (forecast_accuracy, forecast_bias) ); -- New table for time-based aggregates @@ -97,6 +102,20 @@ CREATE TABLE IF NOT EXISTS product_time_aggregates ( INDEX idx_date (year, month) ); +-- Create vendor details table +CREATE TABLE IF NOT EXISTS vendor_details ( + vendor VARCHAR(100) NOT NULL, + contact_name VARCHAR(100), + email VARCHAR(100), + phone VARCHAR(20), + status VARCHAR(20) DEFAULT 'active', + notes TEXT, + created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP, + updated_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP, + PRIMARY KEY (vendor), + INDEX idx_vendor_status (status) +); + -- New table for vendor metrics CREATE TABLE IF NOT EXISTS vendor_metrics ( vendor VARCHAR(100) NOT NULL, @@ -200,10 +219,95 @@ CREATE TABLE IF NOT EXISTS category_sales_metrics ( INDEX idx_period (period_start, period_end) ); +-- New table for brand metrics +CREATE TABLE IF NOT EXISTS brand_metrics ( + brand VARCHAR(100) NOT NULL, + last_calculated_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP, + -- Product metrics + product_count INT DEFAULT 0, + active_products INT DEFAULT 0, + -- Stock metrics + total_stock_units INT DEFAULT 0, + total_stock_cost DECIMAL(10,2) DEFAULT 0, + total_stock_retail DECIMAL(10,2) DEFAULT 0, + -- Sales metrics + total_revenue DECIMAL(10,2) DEFAULT 0, + avg_margin DECIMAL(5,2) DEFAULT 0, + growth_rate DECIMAL(5,2) DEFAULT 0, + PRIMARY KEY (brand), + INDEX idx_brand_metrics_last_calculated (last_calculated_at), + INDEX idx_brand_metrics_revenue (total_revenue), + INDEX idx_brand_metrics_growth (growth_rate) +); + +-- New table for brand time-based metrics +CREATE TABLE IF NOT EXISTS brand_time_metrics ( + brand VARCHAR(100) NOT NULL, + year INT NOT NULL, + month INT NOT NULL, + -- Product metrics + product_count INT DEFAULT 0, + active_products INT DEFAULT 0, + -- Stock metrics + total_stock_units INT DEFAULT 0, + total_stock_cost DECIMAL(10,2) DEFAULT 0, + total_stock_retail DECIMAL(10,2) DEFAULT 0, + -- Sales metrics + total_revenue DECIMAL(10,2) DEFAULT 0, + avg_margin DECIMAL(5,2) DEFAULT 0, + PRIMARY KEY (brand, year, month), + INDEX idx_brand_date (year, month) +); + +-- New table for sales forecasts +CREATE TABLE IF NOT EXISTS sales_forecasts ( + product_id BIGINT NOT NULL, + forecast_date DATE NOT NULL, + forecast_units DECIMAL(10,2) DEFAULT 0, + forecast_revenue DECIMAL(10,2) DEFAULT 0, + confidence_level DECIMAL(5,2) DEFAULT 0, + last_calculated_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP, + PRIMARY KEY (product_id, forecast_date), + FOREIGN KEY (product_id) REFERENCES products(product_id) ON DELETE CASCADE, + INDEX idx_forecast_date (forecast_date), + INDEX idx_forecast_last_calculated (last_calculated_at) +); + +-- New table for category forecasts +CREATE TABLE IF NOT EXISTS category_forecasts ( + category_id BIGINT NOT NULL, + forecast_date DATE NOT NULL, + forecast_units DECIMAL(10,2) DEFAULT 0, + forecast_revenue DECIMAL(10,2) DEFAULT 0, + confidence_level DECIMAL(5,2) DEFAULT 0, + last_calculated_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP, + PRIMARY KEY (category_id, forecast_date), + FOREIGN KEY (category_id) REFERENCES categories(id) ON DELETE CASCADE, + INDEX idx_category_forecast_date (forecast_date), + INDEX idx_category_forecast_last_calculated (last_calculated_at) +); + +-- Create table for sales seasonality factors +CREATE TABLE IF NOT EXISTS sales_seasonality ( + month INT NOT NULL, + seasonality_factor DECIMAL(5,3) DEFAULT 0, + last_updated TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP, + PRIMARY KEY (month), + CHECK (month BETWEEN 1 AND 12), + CHECK (seasonality_factor BETWEEN -1.0 AND 1.0) +); + +-- Insert default seasonality factors (neutral) +INSERT INTO sales_seasonality (month, seasonality_factor) +VALUES + (1, 0), (2, 0), (3, 0), (4, 0), (5, 0), (6, 0), + (7, 0), (8, 0), (9, 0), (10, 0), (11, 0), (12, 0) +ON DUPLICATE KEY UPDATE last_updated = CURRENT_TIMESTAMP; + -- Re-enable foreign key checks SET FOREIGN_KEY_CHECKS = 1; --- Create view for inventory health (after all tables are created) +-- Create view for inventory health CREATE OR REPLACE VIEW inventory_health AS WITH product_thresholds AS ( SELECT @@ -298,77 +402,6 @@ LEFT JOIN WHERE p.managing_stock = true; --- Create view for sales trends analysis -CREATE OR REPLACE VIEW product_sales_trends AS -SELECT - p.product_id, - p.SKU, - p.title, - COALESCE(SUM(o.quantity), 0) as total_sold, - COALESCE(AVG(o.quantity), 0) as avg_quantity_per_order, - COALESCE(COUNT(DISTINCT o.order_number), 0) as number_of_orders, - MIN(o.date) as first_sale_date, - MAX(o.date) as last_sale_date -FROM - products p -LEFT JOIN - orders o ON p.product_id = o.product_id -WHERE - o.canceled = false -GROUP BY - p.product_id, p.SKU, p.title; - --- Create view for category sales trends -CREATE OR REPLACE VIEW category_sales_trends AS -SELECT - c.id as category_id, - c.name as category_name, - p.brand, - COUNT(DISTINCT p.product_id) as num_products, - COALESCE(AVG(o.quantity), 0) as avg_daily_sales, - COALESCE(SUM(o.quantity), 0) as total_sold, - COALESCE(AVG(o.price), 0) as avg_price, - MIN(o.date) as first_sale_date, - MAX(o.date) as last_sale_date -FROM - categories c -JOIN - product_categories pc ON c.id = pc.category_id -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.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 diff --git a/inventory-server/scripts/calculate-metrics.js b/inventory-server/scripts/calculate-metrics.js index 25ebf47..a77de13 100644 --- a/inventory-server/scripts/calculate-metrics.js +++ b/inventory-server/scripts/calculate-metrics.js @@ -3,7 +3,7 @@ const path = require('path'); require('dotenv').config({ path: path.resolve(__dirname, '..', '.env') }); const fs = require('fs'); -// Configuration flags +// Set to 1 to skip product metrics and only calculate the remaining metrics const SKIP_PRODUCT_METRICS = 0; // Helper function to format elapsed time @@ -974,6 +974,363 @@ async function calculateSafetyStock(connection, startTime, totalProducts) { `); } +// Add new function for brand metrics calculation +async function calculateBrandMetrics(connection, startTime, totalProducts) { + outputProgress({ + status: 'running', + operation: 'Calculating brand metrics', + current: Math.floor(totalProducts * 0.95), + total: totalProducts, + elapsed: formatElapsedTime(startTime), + remaining: estimateRemaining(startTime, Math.floor(totalProducts * 0.95), totalProducts), + rate: calculateRate(startTime, Math.floor(totalProducts * 0.95)), + percentage: '95' + }); + + // Calculate brand metrics + await connection.query(` + INSERT INTO brand_metrics ( + brand, + product_count, + active_products, + total_stock_units, + total_stock_cost, + total_stock_retail, + total_revenue, + avg_margin, + growth_rate + ) + WITH brand_data AS ( + SELECT + p.brand, + 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) as total_stock_units, + SUM(p.stock_quantity * p.cost_price) as total_stock_cost, + SUM(p.stock_quantity * p.price) as total_stock_retail, + SUM(o.price * o.quantity) as total_revenue, + CASE + WHEN SUM(o.price * o.quantity) > 0 THEN + (SUM((o.price - p.cost_price) * o.quantity) * 100.0) / SUM(o.price * o.quantity) + ELSE 0 + END as avg_margin, + -- Current period (last 3 months) + SUM(CASE + WHEN o.date >= DATE_SUB(CURRENT_DATE, INTERVAL 3 MONTH) + THEN COALESCE(o.quantity * o.price, 0) + ELSE 0 + END) as current_period_sales, + -- Previous year same period + SUM(CASE + WHEN o.date BETWEEN DATE_SUB(CURRENT_DATE, INTERVAL 15 MONTH) AND DATE_SUB(CURRENT_DATE, INTERVAL 12 MONTH) + THEN COALESCE(o.quantity * o.price, 0) + ELSE 0 + END) as previous_year_period_sales + FROM products p + LEFT JOIN orders o ON p.product_id = o.product_id AND o.canceled = false + WHERE p.brand IS NOT NULL + GROUP BY p.brand + ) + SELECT + brand, + product_count, + active_products, + total_stock_units, + total_stock_cost, + total_stock_retail, + total_revenue, + avg_margin, + CASE + WHEN previous_year_period_sales = 0 AND current_period_sales > 0 THEN 100.0 + WHEN previous_year_period_sales = 0 THEN 0.0 + ELSE LEAST( + GREATEST( + ((current_period_sales - previous_year_period_sales) / + NULLIF(previous_year_period_sales, 0)) * 100.0, + -100.0 + ), + 999.99 + ) + END as growth_rate + FROM brand_data + ON DUPLICATE KEY UPDATE + product_count = VALUES(product_count), + active_products = VALUES(active_products), + total_stock_units = VALUES(total_stock_units), + total_stock_cost = VALUES(total_stock_cost), + total_stock_retail = VALUES(total_stock_retail), + total_revenue = VALUES(total_revenue), + avg_margin = VALUES(avg_margin), + growth_rate = VALUES(growth_rate), + last_calculated_at = CURRENT_TIMESTAMP + `); + + // Calculate brand time-based metrics + await connection.query(` + INSERT INTO brand_time_metrics ( + brand, + year, + month, + product_count, + active_products, + total_stock_units, + total_stock_cost, + total_stock_retail, + total_revenue, + avg_margin + ) + SELECT + p.brand, + 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) as total_stock_units, + SUM(p.stock_quantity * p.cost_price) as total_stock_cost, + SUM(p.stock_quantity * p.price) as total_stock_retail, + SUM(o.price * o.quantity) as total_revenue, + CASE + WHEN SUM(o.price * o.quantity) > 0 THEN + (SUM((o.price - p.cost_price) * o.quantity) * 100.0) / SUM(o.price * o.quantity) + ELSE 0 + END as avg_margin + FROM products p + LEFT JOIN orders o ON p.product_id = o.product_id AND o.canceled = false + WHERE p.brand IS NOT NULL + AND o.date >= DATE_SUB(CURRENT_DATE, INTERVAL 12 MONTH) + GROUP BY p.brand, YEAR(o.date), MONTH(o.date) + ON DUPLICATE KEY UPDATE + product_count = VALUES(product_count), + active_products = VALUES(active_products), + total_stock_units = VALUES(total_stock_units), + total_stock_cost = VALUES(total_stock_cost), + total_stock_retail = VALUES(total_stock_retail), + total_revenue = VALUES(total_revenue), + avg_margin = VALUES(avg_margin) + `); +} + +// Add new function for sales forecast calculation +async function calculateSalesForecasts(connection, startTime, totalProducts) { + outputProgress({ + status: 'running', + operation: 'Calculating sales forecasts', + current: Math.floor(totalProducts * 0.98), + total: totalProducts, + elapsed: formatElapsedTime(startTime), + remaining: estimateRemaining(startTime, Math.floor(totalProducts * 0.98), totalProducts), + rate: calculateRate(startTime, Math.floor(totalProducts * 0.98)), + percentage: '98' + }); + + // Calculate product-level forecasts + await connection.query(` + INSERT INTO sales_forecasts ( + product_id, + forecast_date, + forecast_units, + forecast_revenue, + confidence_level, + last_calculated_at + ) + WITH daily_sales AS ( + SELECT + o.product_id, + DATE(o.date) as sale_date, + SUM(o.quantity) as daily_quantity, + SUM(o.price * o.quantity) as daily_revenue + FROM orders o + WHERE o.canceled = false + AND o.date >= DATE_SUB(CURRENT_DATE, INTERVAL 90 DAY) + GROUP BY o.product_id, DATE(o.date) + ), + forecast_dates AS ( + SELECT + DATE_ADD(CURRENT_DATE, INTERVAL n DAY) as forecast_date + FROM ( + SELECT 0 as n UNION SELECT 1 UNION SELECT 2 UNION SELECT 3 UNION SELECT 4 UNION + SELECT 5 UNION SELECT 6 UNION SELECT 7 UNION SELECT 8 UNION SELECT 9 UNION + SELECT 10 UNION SELECT 11 UNION SELECT 12 UNION SELECT 13 UNION SELECT 14 UNION + SELECT 15 UNION SELECT 16 UNION SELECT 17 UNION SELECT 18 UNION SELECT 19 UNION + SELECT 20 UNION SELECT 21 UNION SELECT 22 UNION SELECT 23 UNION SELECT 24 UNION + SELECT 25 UNION SELECT 26 UNION SELECT 27 UNION SELECT 28 UNION SELECT 29 UNION + SELECT 30 + ) numbers + ), + product_stats AS ( + SELECT + ds.product_id, + AVG(ds.daily_quantity) as avg_daily_quantity, + STDDEV_SAMP(ds.daily_quantity) as std_daily_quantity, + AVG(ds.daily_revenue) as avg_daily_revenue, + STDDEV_SAMP(ds.daily_revenue) as std_daily_revenue, + COUNT(*) as data_points, + -- Calculate day-of-week averages + AVG(CASE WHEN DAYOFWEEK(ds.sale_date) = 1 THEN ds.daily_revenue END) as sunday_avg, + AVG(CASE WHEN DAYOFWEEK(ds.sale_date) = 2 THEN ds.daily_revenue END) as monday_avg, + AVG(CASE WHEN DAYOFWEEK(ds.sale_date) = 3 THEN ds.daily_revenue END) as tuesday_avg, + AVG(CASE WHEN DAYOFWEEK(ds.sale_date) = 4 THEN ds.daily_revenue END) as wednesday_avg, + AVG(CASE WHEN DAYOFWEEK(ds.sale_date) = 5 THEN ds.daily_revenue END) as thursday_avg, + AVG(CASE WHEN DAYOFWEEK(ds.sale_date) = 6 THEN ds.daily_revenue END) as friday_avg, + AVG(CASE WHEN DAYOFWEEK(ds.sale_date) = 7 THEN ds.daily_revenue END) as saturday_avg + FROM daily_sales ds + GROUP BY ds.product_id + ) + SELECT + ps.product_id, + fd.forecast_date, + GREATEST(0, + ps.avg_daily_quantity * + (1 + COALESCE( + (SELECT seasonality_factor + FROM sales_seasonality + WHERE MONTH(fd.forecast_date) = month + LIMIT 1), + 0 + )) + ) as forecast_units, + GREATEST(0, + CASE DAYOFWEEK(fd.forecast_date) + WHEN 1 THEN COALESCE(ps.sunday_avg, ps.avg_daily_revenue) + WHEN 2 THEN COALESCE(ps.monday_avg, ps.avg_daily_revenue) + WHEN 3 THEN COALESCE(ps.tuesday_avg, ps.avg_daily_revenue) + WHEN 4 THEN COALESCE(ps.wednesday_avg, ps.avg_daily_revenue) + WHEN 5 THEN COALESCE(ps.thursday_avg, ps.avg_daily_revenue) + WHEN 6 THEN COALESCE(ps.friday_avg, ps.avg_daily_revenue) + WHEN 7 THEN COALESCE(ps.saturday_avg, ps.avg_daily_revenue) + END * + (1 + COALESCE( + (SELECT seasonality_factor + FROM sales_seasonality + WHERE MONTH(fd.forecast_date) = month + LIMIT 1), + 0 + )) * + -- Add some randomness within a small range (±5%) + (0.95 + (RAND() * 0.1)) + ) as forecast_revenue, + CASE + WHEN ps.data_points >= 60 THEN 90 + WHEN ps.data_points >= 30 THEN 80 + WHEN ps.data_points >= 14 THEN 70 + ELSE 60 + END as confidence_level, + NOW() as last_calculated_at + FROM product_stats ps + CROSS JOIN forecast_dates fd + WHERE ps.avg_daily_quantity > 0 + ON DUPLICATE KEY UPDATE + forecast_units = VALUES(forecast_units), + forecast_revenue = VALUES(forecast_revenue), + confidence_level = VALUES(confidence_level), + last_calculated_at = NOW() + `); + + // Calculate category-level forecasts + await connection.query(` + INSERT INTO category_forecasts ( + category_id, + forecast_date, + forecast_units, + forecast_revenue, + confidence_level, + last_calculated_at + ) + WITH category_daily_sales AS ( + SELECT + pc.category_id, + DATE(o.date) as sale_date, + SUM(o.quantity) as daily_quantity, + SUM(o.price * o.quantity) as daily_revenue + FROM orders o + JOIN product_categories pc ON o.product_id = pc.product_id + WHERE o.canceled = false + AND o.date >= DATE_SUB(CURRENT_DATE, INTERVAL 90 DAY) + GROUP BY pc.category_id, DATE(o.date) + ), + forecast_dates AS ( + SELECT + DATE_ADD(CURRENT_DATE, INTERVAL n DAY) as forecast_date + FROM ( + SELECT 0 as n UNION SELECT 1 UNION SELECT 2 UNION SELECT 3 UNION SELECT 4 UNION + SELECT 5 UNION SELECT 6 UNION SELECT 7 UNION SELECT 8 UNION SELECT 9 UNION + SELECT 10 UNION SELECT 11 UNION SELECT 12 UNION SELECT 13 UNION SELECT 14 UNION + SELECT 15 UNION SELECT 16 UNION SELECT 17 UNION SELECT 18 UNION SELECT 19 UNION + SELECT 20 UNION SELECT 21 UNION SELECT 22 UNION SELECT 23 UNION SELECT 24 UNION + SELECT 25 UNION SELECT 26 UNION SELECT 27 UNION SELECT 28 UNION SELECT 29 UNION + SELECT 30 + ) numbers + ), + category_stats AS ( + SELECT + cds.category_id, + AVG(cds.daily_quantity) as avg_daily_quantity, + STDDEV_SAMP(cds.daily_quantity) as std_daily_quantity, + AVG(cds.daily_revenue) as avg_daily_revenue, + STDDEV_SAMP(cds.daily_revenue) as std_daily_revenue, + COUNT(*) as data_points, + -- Calculate day-of-week averages + AVG(CASE WHEN DAYOFWEEK(cds.sale_date) = 1 THEN cds.daily_revenue END) as sunday_avg, + AVG(CASE WHEN DAYOFWEEK(cds.sale_date) = 2 THEN cds.daily_revenue END) as monday_avg, + AVG(CASE WHEN DAYOFWEEK(cds.sale_date) = 3 THEN cds.daily_revenue END) as tuesday_avg, + AVG(CASE WHEN DAYOFWEEK(cds.sale_date) = 4 THEN cds.daily_revenue END) as wednesday_avg, + AVG(CASE WHEN DAYOFWEEK(cds.sale_date) = 5 THEN cds.daily_revenue END) as thursday_avg, + AVG(CASE WHEN DAYOFWEEK(cds.sale_date) = 6 THEN cds.daily_revenue END) as friday_avg, + AVG(CASE WHEN DAYOFWEEK(cds.sale_date) = 7 THEN cds.daily_revenue END) as saturday_avg + FROM category_daily_sales cds + GROUP BY cds.category_id + ) + SELECT + cs.category_id, + fd.forecast_date, + GREATEST(0, + cs.avg_daily_quantity * + (1 + COALESCE( + (SELECT seasonality_factor + FROM sales_seasonality + WHERE MONTH(fd.forecast_date) = month + LIMIT 1), + 0 + )) + ) as forecast_units, + GREATEST(0, + CASE DAYOFWEEK(fd.forecast_date) + WHEN 1 THEN COALESCE(cs.sunday_avg, cs.avg_daily_revenue) + WHEN 2 THEN COALESCE(cs.monday_avg, cs.avg_daily_revenue) + WHEN 3 THEN COALESCE(cs.tuesday_avg, cs.avg_daily_revenue) + WHEN 4 THEN COALESCE(cs.wednesday_avg, cs.avg_daily_revenue) + WHEN 5 THEN COALESCE(cs.thursday_avg, cs.avg_daily_revenue) + WHEN 6 THEN COALESCE(cs.friday_avg, cs.avg_daily_revenue) + WHEN 7 THEN COALESCE(cs.saturday_avg, cs.avg_daily_revenue) + END * + (1 + COALESCE( + (SELECT seasonality_factor + FROM sales_seasonality + WHERE MONTH(fd.forecast_date) = month + LIMIT 1), + 0 + )) * + -- Add some randomness within a small range (±5%) + (0.95 + (RAND() * 0.1)) + ) as forecast_revenue, + CASE + WHEN cs.data_points >= 60 THEN 90 + WHEN cs.data_points >= 30 THEN 80 + WHEN cs.data_points >= 14 THEN 70 + ELSE 60 + END as confidence_level, + NOW() as last_calculated_at + FROM category_stats cs + CROSS JOIN forecast_dates fd + WHERE cs.avg_daily_quantity > 0 + ON DUPLICATE KEY UPDATE + forecast_units = VALUES(forecast_units), + forecast_revenue = VALUES(forecast_revenue), + confidence_level = VALUES(confidence_level), + last_calculated_at = NOW() + `); +} + // Update the main calculation function to include the new metrics async function calculateMetrics() { let pool; @@ -1727,6 +2084,10 @@ async function calculateMetrics() { WHERE s.product_id IS NULL `); + // Add new metric calculations before final success message + await calculateBrandMetrics(connection, startTime, totalProducts); + await calculateSalesForecasts(connection, startTime, totalProducts); + // Final success message outputProgress({ status: 'complete', diff --git a/inventory-server/scripts/reset-metrics.js b/inventory-server/scripts/reset-metrics.js index 9ba57d9..0d796ff 100644 --- a/inventory-server/scripts/reset-metrics.js +++ b/inventory-server/scripts/reset-metrics.js @@ -17,15 +17,21 @@ function outputProgress(data) { // Explicitly define all metrics-related tables const METRICS_TABLES = [ - 'temp_sales_metrics', - 'temp_purchase_metrics', + 'brand_metrics', + 'brand_time_metrics', + 'category_forecasts', + 'category_metrics', + 'category_sales_metrics', + 'category_time_metrics', 'product_metrics', 'product_time_aggregates', - 'vendor_metrics', - 'vendor_time_metrics', - 'category_metrics', - 'category_time_metrics', - 'category_sales_metrics' + 'sales_forecasts', + 'sales_seasonality', + 'temp_purchase_metrics', + 'temp_sales_metrics', + 'vendor_metrics', //before vendor_details for foreign key + 'vendor_time_metrics', //before vendor_details for foreign key + 'vendor_details' ]; // Config tables that must exist diff --git a/inventory-server/src/routes/dashboard.js b/inventory-server/src/routes/dashboard.js index f3c8cb6..1bdb86d 100644 --- a/inventory-server/src/routes/dashboard.js +++ b/inventory-server/src/routes/dashboard.js @@ -1,374 +1,1023 @@ const express = require('express'); const router = express.Router(); +const db = require('../utils/db'); -// Get dashboard stats -router.get('/stats', async (req, res) => { - const pool = req.app.locals.pool; - try { - const [stats] = await pool.query(` - WITH OrderStats AS ( - SELECT - COUNT(DISTINCT o.order_number) as total_orders, - SUM(o.price * o.quantity) as total_revenue, - AVG(subtotal) as average_order_value - FROM orders o - LEFT JOIN ( - SELECT order_number, SUM(price * quantity) as subtotal - FROM orders - WHERE DATE(date) >= DATE_SUB(CURDATE(), INTERVAL 30 DAY) - AND canceled = false - GROUP BY order_number - ) t ON o.order_number = t.order_number - WHERE DATE(o.date) >= DATE_SUB(CURDATE(), INTERVAL 30 DAY) - AND o.canceled = false - ), - ProfitStats AS ( - SELECT - SUM((o.price - p.cost_price) * o.quantity) as total_profit, - SUM(o.price * o.quantity) as revenue - FROM orders o - JOIN products p ON o.product_id = p.product_id - WHERE DATE(o.date) >= DATE_SUB(CURDATE(), INTERVAL 30 DAY) - AND o.canceled = false - ), - ProductStats AS ( - SELECT - COUNT(*) as total_products, - COUNT(CASE WHEN stock_quantity <= 5 THEN 1 END) as low_stock_products - FROM products - WHERE visible = true - ) - SELECT - ps.total_products, - ps.low_stock_products, - os.total_orders, - os.average_order_value, - os.total_revenue, - prs.total_profit, - CASE - WHEN prs.revenue > 0 THEN (prs.total_profit / prs.revenue) * 100 - ELSE 0 - END as profit_margin - FROM ProductStats ps - CROSS JOIN OrderStats os - CROSS JOIN ProfitStats prs - `); - res.json({ - ...stats[0], - averageOrderValue: parseFloat(stats[0].average_order_value) || 0, - totalRevenue: parseFloat(stats[0].total_revenue) || 0, - profitMargin: parseFloat(stats[0].profit_margin) || 0 - }); - } catch (error) { - console.error('Error fetching dashboard stats:', error); - res.status(500).json({ error: 'Failed to fetch dashboard stats' }); - } -}); - -// Get sales overview data -router.get('/sales-overview', async (req, res) => { - const pool = req.app.locals.pool; - try { - const [rows] = await pool.query(` - SELECT - DATE(date) as date, - SUM(price * quantity) as total - FROM orders - WHERE DATE(date) >= DATE_SUB(CURDATE(), INTERVAL 30 DAY) - AND canceled = false - GROUP BY DATE(date) - ORDER BY date ASC - `); - res.json(rows.map(row => ({ - ...row, - total: parseFloat(row.total || 0) - }))); - } catch (error) { - console.error('Error fetching sales overview:', error); - res.status(500).json({ error: 'Failed to fetch sales overview' }); - } -}); - -// Get recent orders -router.get('/recent-orders', async (req, res) => { - const pool = req.app.locals.pool; - try { - const [rows] = await pool.query(` - SELECT - o1.order_number as order_id, - o1.customer as customer_name, - SUM(o2.price * o2.quantity) as total_amount, - o1.date as order_date - FROM orders o1 - JOIN orders o2 ON o1.order_number = o2.order_number - WHERE o1.canceled = false - GROUP BY o1.order_number, o1.customer, o1.date - ORDER BY o1.date DESC - LIMIT 5 - `); - res.json(rows.map(row => ({ - ...row, - total_amount: parseFloat(row.total_amount || 0), - order_date: row.order_date - }))); - } catch (error) { - console.error('Error fetching recent orders:', error); - res.status(500).json({ error: 'Failed to fetch recent orders' }); - } -}); - -// Get category stats -router.get('/category-stats', async (req, res) => { - const pool = req.app.locals.pool; - try { - const [rows] = await pool.query(` - SELECT - c.name as category, - COUNT(DISTINCT pc.product_id) as count - 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 - WHERE p.visible = true - GROUP BY c.name - ORDER BY count DESC - LIMIT 10 - `); - res.json(rows); - } catch (error) { - console.error('Error fetching category stats:', error); - res.status(500).json({ error: 'Failed to fetch category stats' }); - } -}); - -// Get stock levels -router.get('/stock-levels', async (req, res) => { - const pool = req.app.locals.pool; - try { - const [rows] = await pool.query(` - SELECT - SUM(CASE WHEN stock_quantity = 0 THEN 1 ELSE 0 END) as outOfStock, - SUM(CASE WHEN stock_quantity > 0 AND stock_quantity <= 5 THEN 1 ELSE 0 END) as lowStock, - SUM(CASE WHEN stock_quantity > 5 AND stock_quantity <= 20 THEN 1 ELSE 0 END) as inStock, - SUM(CASE WHEN stock_quantity > 20 THEN 1 ELSE 0 END) as overStock - FROM products - WHERE visible = true - `); - res.json(rows[0]); - } catch (error) { - console.error('Error fetching stock levels:', error); - res.status(500).json({ error: 'Failed to fetch stock levels' }); - } -}); - -// Get sales by category -router.get('/sales-by-category', async (req, res) => { - const pool = req.app.locals.pool; - try { - const [rows] = await pool.query(` - SELECT - c.name as category, - SUM(o.price * o.quantity) as total - FROM orders o - JOIN products p ON o.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 - WHERE o.canceled = false - AND DATE(o.date) >= DATE_SUB(CURDATE(), INTERVAL 30 DAY) - GROUP BY c.name - ORDER BY total DESC - LIMIT 6 - `); - - const total = rows.reduce((sum, row) => sum + parseFloat(row.total || 0), 0); - - res.json(rows.map(row => ({ - category: row.category || 'Uncategorized', - total: parseFloat(row.total || 0), - percentage: total > 0 ? (parseFloat(row.total || 0) / total) : 0 - }))); - } catch (error) { - console.error('Error fetching sales by category:', error); - res.status(500).json({ error: 'Failed to fetch sales by category' }); - } -}); - -// Get inventory health summary -router.get('/inventory/health/summary', async (req, res) => { - const pool = req.app.locals.pool; - try { - // First check what statuses exist - const [checkStatuses] = await pool.query(` - SELECT DISTINCT stock_status - FROM product_metrics - WHERE stock_status IS NOT NULL - `); - console.log('Available stock statuses:', checkStatuses.map(row => row.stock_status)); - - const [rows] = await pool.query(` - WITH normalized_status AS ( - SELECT - CASE - WHEN stock_status = 'Overstocked' THEN 'Overstock' - WHEN stock_status = 'New' THEN 'Healthy' - ELSE stock_status - END as status - FROM product_metrics - WHERE stock_status IS NOT NULL - ) - SELECT - status as stock_status, - COUNT(*) as count - FROM normalized_status - GROUP BY status - `); - - console.log('Raw inventory health summary:', rows); - - // Convert array to object with lowercase keys - const summary = { - critical: 0, - reorder: 0, - healthy: 0, - overstock: 0 - }; - - rows.forEach(row => { - const key = row.stock_status.toLowerCase(); - if (key in summary) { - summary[key] = parseInt(row.count); - } - }); - - // Calculate total - summary.total = Object.values(summary).reduce((a, b) => a + b, 0); - - console.log('Final inventory health summary:', summary); - res.json(summary); - } catch (error) { - console.error('Error fetching inventory health summary:', error); - res.status(500).json({ error: 'Failed to fetch inventory health summary' }); - } -}); - -// Get low stock alerts -router.get('/inventory/low-stock', async (req, res) => { - const pool = req.app.locals.pool; - try { - const [rows] = await pool.query(` - SELECT - p.product_id, - p.sku, - p.title, - p.stock_quantity, - pm.reorder_point, - pm.days_of_inventory, - pm.daily_sales_avg, - pm.stock_status - FROM product_metrics pm - JOIN products p ON pm.product_id = p.product_id - WHERE pm.stock_status IN ('Critical', 'Reorder') - ORDER BY - CASE pm.stock_status - WHEN 'Critical' THEN 1 - WHEN 'Reorder' THEN 2 - ELSE 3 - END, - pm.days_of_inventory ASC - LIMIT 50 - `); - res.json(rows); - } catch (error) { - console.error('Error fetching low stock alerts:', error); - res.status(500).json({ error: 'Failed to fetch low stock alerts' }); - } -}); - -// Get vendor performance metrics -router.get('/vendors/metrics', async (req, res) => { - const pool = req.app.locals.pool; - try { - console.log('Fetching vendor metrics...'); - const [rows] = await pool.query(` - SELECT - vendor, - avg_lead_time_days, - on_time_delivery_rate, - order_fill_rate, - total_orders, - total_late_orders, - total_purchase_value, - avg_order_value - FROM vendor_metrics - ORDER BY on_time_delivery_rate DESC - `); - console.log('Found vendor metrics:', rows.length, 'rows'); - console.log('First row sample:', rows[0]); - - const mappedRows = rows.map(row => ({ - ...row, - avg_lead_time_days: parseFloat(row.avg_lead_time_days || 0), - on_time_delivery_rate: parseFloat(row.on_time_delivery_rate || 0), - order_fill_rate: parseFloat(row.order_fill_rate || 0), - total_purchase_value: parseFloat(row.total_purchase_value || 0), - avg_order_value: parseFloat(row.avg_order_value || 0) - })); - console.log('First mapped row sample:', mappedRows[0]); - - res.json(mappedRows); - } catch (error) { - console.error('Error fetching vendor metrics:', error); - res.status(500).json({ error: 'Failed to fetch vendor metrics' }); - } -}); - -// Get trending products -router.get('/products/trending', async (req, res) => { - const pool = req.app.locals.pool; - try { - // First check if we have any data - const [checkData] = await pool.query(` - SELECT COUNT(*) as count, - MAX(total_revenue) as max_revenue, - MAX(daily_sales_avg) as max_daily_sales, - COUNT(DISTINCT product_id) as products_with_metrics - FROM product_metrics - WHERE total_revenue > 0 OR daily_sales_avg > 0 - `); - console.log('Product metrics stats:', checkData[0]); - - if (checkData[0].count === 0) { - console.log('No products with metrics found'); - return res.json([]); +// Helper function to execute queries using the connection pool +async function executeQuery(sql, params = []) { + const pool = db.getPool(); + if (!pool) { + throw new Error('Database pool not initialized'); } + return pool.query(sql, params); +} - // Get trending products - const [rows] = await pool.query(` - SELECT - p.product_id, - p.sku, - p.title, - COALESCE(pm.daily_sales_avg, 0) as daily_sales_avg, - COALESCE(pm.weekly_sales_avg, 0) as weekly_sales_avg, - CASE - WHEN pm.weekly_sales_avg > 0 AND pm.daily_sales_avg > 0 - THEN ((pm.daily_sales_avg - pm.weekly_sales_avg) / pm.weekly_sales_avg) * 100 - ELSE 0 - END as growth_rate, - COALESCE(pm.total_revenue, 0) as total_revenue - FROM products p - INNER JOIN product_metrics pm ON p.product_id = pm.product_id - WHERE (pm.total_revenue > 0 OR pm.daily_sales_avg > 0) - AND p.visible = true - ORDER BY growth_rate DESC - LIMIT 50 - `); +// GET /dashboard/stock/metrics +// Returns brand-level stock metrics +router.get('/stock/metrics', async (req, res) => { + try { + // Get stock metrics + const [rows] = await executeQuery(` + SELECT + COALESCE(COUNT(*), 0) as total_products, + COALESCE(COUNT(CASE WHEN stock_quantity > 0 THEN 1 END), 0) as products_in_stock, + COALESCE(SUM(CASE WHEN stock_quantity > 0 THEN stock_quantity END), 0) as total_units, + COALESCE(SUM(CASE WHEN stock_quantity > 0 THEN stock_quantity * cost_price END), 0) as total_cost, + COALESCE(SUM(CASE WHEN stock_quantity > 0 THEN stock_quantity * price END), 0) as total_retail + FROM products + `); + const stockMetrics = rows[0]; - console.log('Trending products:', rows); - res.json(rows); - } catch (error) { - console.error('Error fetching trending products:', error); - res.status(500).json({ error: 'Failed to fetch trending products' }); - } + console.log('Raw stockMetrics from database:', stockMetrics); + console.log('stockMetrics.total_products:', stockMetrics.total_products); + console.log('stockMetrics.products_in_stock:', stockMetrics.products_in_stock); + console.log('stockMetrics.total_units:', stockMetrics.total_units); + console.log('stockMetrics.total_cost:', stockMetrics.total_cost); + console.log('stockMetrics.total_retail:', stockMetrics.total_retail); + + // Get brand stock values with Other category + const [brandValues] = await executeQuery(` + WITH brand_totals AS ( + SELECT + brand, + COUNT(DISTINCT product_id) as variant_count, + COALESCE(SUM(stock_quantity), 0) as stock_units, + COALESCE(SUM(stock_quantity * cost_price), 0) as stock_cost, + COALESCE(SUM(stock_quantity * price), 0) as stock_retail + FROM products + WHERE brand IS NOT NULL + AND stock_quantity > 0 + GROUP BY brand + HAVING stock_cost > 0 + ), + other_brands AS ( + SELECT + 'Other' as brand, + SUM(variant_count) as variant_count, + SUM(stock_units) as stock_units, + SUM(stock_cost) as stock_cost, + SUM(stock_retail) as stock_retail + FROM brand_totals + WHERE stock_cost <= 5000 + ), + main_brands AS ( + SELECT * + FROM brand_totals + WHERE stock_cost > 5000 + ORDER BY stock_cost DESC + ) + SELECT * FROM main_brands + UNION ALL + SELECT * FROM other_brands + WHERE stock_cost > 0 + ORDER BY CASE WHEN brand = 'Other' THEN 1 ELSE 0 END, stock_cost DESC + `); + + // Format the response with explicit type conversion + const response = { + totalProducts: parseInt(stockMetrics.total_products) || 0, + productsInStock: parseInt(stockMetrics.products_in_stock) || 0, + totalStockUnits: parseInt(stockMetrics.total_units) || 0, + totalStockCost: parseFloat(stockMetrics.total_cost) || 0, + totalStockRetail: parseFloat(stockMetrics.total_retail) || 0, + brandStock: brandValues.map(v => ({ + brand: v.brand, + variants: parseInt(v.variant_count) || 0, + units: parseInt(v.stock_units) || 0, + cost: parseFloat(v.stock_cost) || 0, + retail: parseFloat(v.stock_retail) || 0 + })) + }; + + res.json(response); + } catch (err) { + console.error('Error fetching stock metrics:', err); + res.status(500).json({ error: 'Failed to fetch stock metrics' }); + } +}); + +// GET /dashboard/purchase/metrics +// Returns purchase order metrics by vendor +router.get('/purchase/metrics', async (req, res) => { + try { + const [rows] = await executeQuery(` + SELECT + COALESCE(COUNT(DISTINCT CASE WHEN po.status = 'open' THEN po.po_id END), 0) as active_pos, + COALESCE(COUNT(DISTINCT CASE + WHEN po.status = 'open' AND po.expected_date < CURDATE() + THEN po.po_id + END), 0) as overdue_pos, + COALESCE(SUM(CASE WHEN po.status = 'open' THEN po.ordered ELSE 0 END), 0) as total_units, + COALESCE(SUM(CASE + WHEN po.status = 'open' + THEN po.ordered * po.cost_price + ELSE 0 + END), 0) as total_cost, + COALESCE(SUM(CASE + WHEN po.status = 'open' + THEN po.ordered * p.price + ELSE 0 + END), 0) as total_retail + FROM purchase_orders po + JOIN products p ON po.product_id = p.product_id + `); + const poMetrics = rows[0]; + + console.log('Raw poMetrics from database:', poMetrics); + console.log('poMetrics.active_pos:', poMetrics.active_pos); + console.log('poMetrics.overdue_pos:', poMetrics.overdue_pos); + console.log('poMetrics.total_units:', poMetrics.total_units); + console.log('poMetrics.total_cost:', poMetrics.total_cost); + console.log('poMetrics.total_retail:', poMetrics.total_retail); + + const [vendorOrders] = await executeQuery(` + SELECT + po.vendor, + COUNT(DISTINCT po.po_id) as order_count, + COALESCE(SUM(po.ordered), 0) as ordered_units, + COALESCE(SUM(po.ordered * po.cost_price), 0) as order_cost, + COALESCE(SUM(po.ordered * p.price), 0) as order_retail + FROM purchase_orders po + JOIN products p ON po.product_id = p.product_id + WHERE po.status = 'open' + GROUP BY po.vendor + HAVING order_cost > 0 + ORDER BY order_cost DESC + `); + + const response = { + activePurchaseOrders: parseInt(poMetrics.active_pos) || 0, + overduePurchaseOrders: parseInt(poMetrics.overdue_pos) || 0, + onOrderUnits: parseInt(poMetrics.total_units) || 0, + onOrderCost: parseFloat(poMetrics.total_cost) || 0, + onOrderRetail: parseFloat(poMetrics.total_retail) || 0, + vendorOrders: vendorOrders.map(v => ({ + vendor: v.vendor, + orders: parseInt(v.order_count) || 0, + units: parseInt(v.ordered_units) || 0, + cost: parseFloat(v.order_cost) || 0, + retail: parseFloat(v.order_retail) || 0 + })) + }; + + res.json(response); + } catch (err) { + console.error('Error fetching purchase metrics:', err); + res.status(500).json({ error: 'Failed to fetch purchase metrics' }); + } +}); + +// GET /dashboard/replenishment/metrics +// Returns replenishment needs by category +router.get('/replenishment/metrics', async (req, res) => { + try { + // Get summary metrics + const [metrics] = await executeQuery(` + SELECT + COUNT(DISTINCT p.product_id) as products_to_replenish, + COALESCE(SUM(CASE + WHEN p.stock_quantity < 0 THEN ABS(p.stock_quantity) + pm.reorder_qty + ELSE pm.reorder_qty + END), 0) as total_units_needed, + COALESCE(SUM(CASE + WHEN p.stock_quantity < 0 THEN (ABS(p.stock_quantity) + pm.reorder_qty) * p.cost_price + ELSE pm.reorder_qty * p.cost_price + END), 0) as total_cost, + COALESCE(SUM(CASE + WHEN p.stock_quantity < 0 THEN (ABS(p.stock_quantity) + pm.reorder_qty) * p.price + ELSE pm.reorder_qty * p.price + END), 0) as total_retail + FROM products p + JOIN product_metrics pm ON p.product_id = pm.product_id + WHERE p.replenishable = true + AND (pm.stock_status IN ('Critical', 'Reorder') + OR p.stock_quantity < 0) + AND pm.reorder_qty > 0 + `); + + // Get top variants to replenish + const [variants] = await executeQuery(` + SELECT + p.product_id, + p.title, + p.stock_quantity as current_stock, + CASE + WHEN p.stock_quantity < 0 THEN ABS(p.stock_quantity) + pm.reorder_qty + ELSE pm.reorder_qty + END as replenish_qty, + CASE + WHEN p.stock_quantity < 0 THEN (ABS(p.stock_quantity) + pm.reorder_qty) * p.cost_price + ELSE pm.reorder_qty * p.cost_price + END as replenish_cost, + CASE + WHEN p.stock_quantity < 0 THEN (ABS(p.stock_quantity) + pm.reorder_qty) * p.price + ELSE pm.reorder_qty * p.price + END as replenish_retail, + pm.stock_status + FROM products p + JOIN product_metrics pm ON p.product_id = pm.product_id + WHERE p.replenishable = true + AND (pm.stock_status IN ('Critical', 'Reorder') + OR p.stock_quantity < 0) + AND pm.reorder_qty > 0 + ORDER BY + CASE pm.stock_status + WHEN 'Critical' THEN 1 + WHEN 'Reorder' THEN 2 + END, + replenish_cost DESC + LIMIT 5 + `); + + // Format response + const response = { + productsToReplenish: parseInt(metrics[0].products_to_replenish) || 0, + unitsToReplenish: parseInt(metrics[0].total_units_needed) || 0, + replenishmentCost: parseFloat(metrics[0].total_cost) || 0, + replenishmentRetail: parseFloat(metrics[0].total_retail) || 0, + topVariants: variants.map(v => ({ + id: v.product_id, + title: v.title, + currentStock: parseInt(v.current_stock) || 0, + replenishQty: parseInt(v.replenish_qty) || 0, + replenishCost: parseFloat(v.replenish_cost) || 0, + replenishRetail: parseFloat(v.replenish_retail) || 0, + status: v.stock_status + })) + }; + + res.json(response); + } catch (err) { + console.error('Error fetching replenishment metrics:', err); + res.status(500).json({ error: 'Failed to fetch replenishment metrics' }); + } +}); + +// GET /dashboard/forecast/metrics +// Returns sales forecasts for specified period +router.get('/forecast/metrics', async (req, res) => { + const { startDate, endDate } = req.query; + try { + // Get summary metrics + const [metrics] = await executeQuery(` + SELECT + COALESCE(SUM(forecast_units), 0) as total_forecast_units, + COALESCE(SUM(forecast_revenue), 0) as total_forecast_revenue, + COALESCE(AVG(confidence_level), 0) as overall_confidence + FROM sales_forecasts + WHERE forecast_date BETWEEN ? AND ? + `, [startDate, endDate]); + + // Get daily forecasts + const [dailyForecasts] = await executeQuery(` + SELECT + DATE(forecast_date) as date, + COALESCE(SUM(forecast_revenue), 0) as revenue, + COALESCE(AVG(confidence_level), 0) as confidence + FROM sales_forecasts + WHERE forecast_date BETWEEN ? AND ? + GROUP BY DATE(forecast_date) + ORDER BY date + `, [startDate, endDate]); + + // Get category forecasts + const [categoryForecasts] = await executeQuery(` + SELECT + c.name as category, + COALESCE(SUM(cf.forecast_units), 0) as units, + COALESCE(SUM(cf.forecast_revenue), 0) as revenue, + COALESCE(AVG(cf.confidence_level), 0) as confidence + FROM category_forecasts cf + JOIN categories c ON cf.category_id = c.id + WHERE cf.forecast_date BETWEEN ? AND ? + GROUP BY c.id, c.name + ORDER BY revenue DESC + `, [startDate, endDate]); + + // Format response + const response = { + forecastSales: parseInt(metrics[0].total_forecast_units) || 0, + forecastRevenue: parseFloat(metrics[0].total_forecast_revenue) || 0, + confidenceLevel: parseFloat(metrics[0].overall_confidence) || 0, + dailyForecasts: dailyForecasts.map(d => ({ + date: d.date, + revenue: parseFloat(d.revenue) || 0, + confidence: parseFloat(d.confidence) || 0 + })), + categoryForecasts: categoryForecasts.map(c => ({ + category: c.category, + units: parseInt(c.units) || 0, + revenue: parseFloat(c.revenue) || 0, + confidence: parseFloat(c.confidence) || 0 + })) + }; + + res.json(response); + } catch (err) { + console.error('Error fetching forecast metrics:', err); + res.status(500).json({ error: 'Failed to fetch forecast metrics' }); + } +}); + +// GET /dashboard/overstock/metrics +// Returns overstock metrics by category +router.get('/overstock/metrics', async (req, res) => { + try { + const [rows] = await executeQuery(` + WITH category_overstock AS ( + SELECT + c.id as category_id, + c.name as category_name, + COUNT(DISTINCT CASE + WHEN pm.stock_status = 'Overstocked' + THEN p.product_id + END) as overstocked_products, + SUM(CASE + WHEN pm.stock_status = 'Overstocked' + THEN pm.overstocked_amt + ELSE 0 + END) as total_excess_units, + SUM(CASE + WHEN pm.stock_status = 'Overstocked' + THEN pm.overstocked_amt * p.cost_price + ELSE 0 + END) as total_excess_cost, + SUM(CASE + WHEN pm.stock_status = 'Overstocked' + THEN pm.overstocked_amt * p.price + ELSE 0 + END) as total_excess_retail + FROM categories c + JOIN product_categories pc ON c.id = pc.category_id + JOIN products p ON pc.product_id = p.product_id + JOIN product_metrics pm ON p.product_id = pm.product_id + GROUP BY c.id, c.name + ) + SELECT + SUM(overstocked_products) as total_overstocked, + SUM(total_excess_units) as total_excess_units, + SUM(total_excess_cost) as total_excess_cost, + SUM(total_excess_retail) as total_excess_retail, + CONCAT('[', GROUP_CONCAT( + JSON_OBJECT( + 'category', category_name, + 'products', overstocked_products, + 'units', total_excess_units, + 'cost', total_excess_cost, + 'retail', total_excess_retail + ) + ), ']') as category_data + FROM ( + SELECT * + FROM category_overstock + WHERE overstocked_products > 0 + ORDER BY total_excess_cost DESC + LIMIT 8 + ) filtered_categories + `); + + // Format response with explicit type conversion + const response = { + overstockedProducts: parseInt(rows[0].total_overstocked) || 0, + total_excess_units: parseInt(rows[0].total_excess_units) || 0, + total_excess_cost: parseFloat(rows[0].total_excess_cost) || 0, + total_excess_retail: parseFloat(rows[0].total_excess_retail) || 0, + category_data: rows[0].category_data ? + JSON.parse(rows[0].category_data).map(obj => ({ + category: obj.category, + products: parseInt(obj.products) || 0, + units: parseInt(obj.units) || 0, + cost: parseFloat(obj.cost) || 0, + retail: parseFloat(obj.retail) || 0 + })) : [] + }; + + res.json(response); + } catch (err) { + console.error('Error fetching overstock metrics:', err); + res.status(500).json({ error: 'Failed to fetch overstock metrics' }); + } +}); + +// GET /dashboard/overstock/products +// Returns list of most overstocked products +router.get('/overstock/products', async (req, res) => { + const limit = parseInt(req.query.limit) || 50; + try { + const [rows] = await executeQuery(` + SELECT + p.product_id, + p.SKU, + p.title, + p.brand, + p.vendor, + p.stock_quantity, + p.cost_price, + p.price, + pm.daily_sales_avg, + pm.days_of_inventory, + pm.overstocked_amt, + (pm.overstocked_amt * p.cost_price) as excess_cost, + (pm.overstocked_amt * p.price) as excess_retail, + GROUP_CONCAT(c.name) as categories + FROM products p + JOIN product_metrics pm ON p.product_id = pm.product_id + LEFT JOIN product_categories pc ON p.product_id = pc.product_id + LEFT JOIN categories c ON pc.category_id = c.id + WHERE pm.stock_status = 'Overstocked' + GROUP BY p.product_id + ORDER BY excess_cost DESC + LIMIT ? + `, [limit]); + res.json(rows); + } catch (err) { + console.error('Error fetching overstocked products:', err); + res.status(500).json({ error: 'Failed to fetch overstocked products' }); + } +}); + +// GET /dashboard/best-sellers +// 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.product_id, + 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.product_id = o.product_id + WHERE o.canceled = false + AND o.date >= DATE_SUB(CURRENT_DATE, INTERVAL 60 DAY) + GROUP BY p.product_id, p.SKU, p.title + ) + SELECT + product_id, + 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 [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.product_id = o.product_id + 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 ( + SELECT + c.id as category_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 + FROM categories c + JOIN product_categories pc ON c.id = pc.category_id + JOIN products p ON pc.product_id = p.product_id + JOIN orders o ON p.product_id = o.product_id + WHERE o.canceled = false + AND o.date >= DATE_SUB(CURRENT_DATE, INTERVAL 60 DAY) + GROUP BY c.id, c.name + ) + SELECT + category_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 + `); + + // Format response with explicit type conversion + const formattedProducts = products.map(p => ({ + ...p, + units_sold: parseInt(p.units_sold) || 0, + revenue: parseFloat(p.revenue) || 0, + profit: parseFloat(p.profit) || 0, + growth_rate: parseFloat(p.growth_rate) || 0 + })); + + const formattedBrands = brands.map(b => ({ + brand: b.brand, + units_sold: parseInt(b.units_sold) || 0, + revenue: parseFloat(b.revenue) || 0, + profit: parseFloat(b.profit) || 0, + growth_rate: parseFloat(b.growth_rate) || 0 + })); + + const formattedCategories = categories.map(c => ({ + category_id: c.category_id, + name: c.name, + units_sold: parseInt(c.units_sold) || 0, + revenue: parseFloat(c.revenue) || 0, + profit: parseFloat(c.profit) || 0, + growth_rate: parseFloat(c.growth_rate) || 0 + })); + + res.json({ + products: formattedProducts, + brands: formattedBrands, + categories: formattedCategories + }); + } catch (err) { + console.error('Error fetching best sellers:', err); + res.status(500).json({ error: 'Failed to fetch best sellers' }); + } +}); + +// GET /dashboard/sales/metrics +// Returns sales metrics for specified period +router.get('/sales/metrics', async (req, res) => { + const { startDate, endDate } = req.query; + try { + // Get daily sales data + const [dailyRows] = await executeQuery(` + SELECT + DATE(o.date) as sale_date, + COUNT(DISTINCT o.order_number) as total_orders, + SUM(o.quantity) as total_units, + SUM(o.price * o.quantity) as total_revenue, + SUM(p.cost_price * o.quantity) as total_cogs, + SUM((o.price - p.cost_price) * o.quantity) as total_profit + FROM orders o + JOIN products p ON o.product_id = p.product_id + WHERE o.canceled = false + AND o.date BETWEEN ? AND ? + GROUP BY DATE(o.date) + ORDER BY sale_date + `, [startDate, endDate]); + + // Get summary metrics + const [metrics] = await executeQuery(` + SELECT + COUNT(DISTINCT o.order_number) as total_orders, + SUM(o.quantity) as total_units, + SUM(o.price * o.quantity) as total_revenue, + SUM(p.cost_price * o.quantity) as total_cogs, + SUM((o.price - p.cost_price) * o.quantity) as total_profit + FROM orders o + JOIN products p ON o.product_id = p.product_id + WHERE o.canceled = false + AND o.date BETWEEN ? AND ? + `, [startDate, endDate]); + + const response = { + totalOrders: parseInt(metrics[0]?.total_orders) || 0, + totalUnitsSold: parseInt(metrics[0]?.total_units) || 0, + totalCogs: parseFloat(metrics[0]?.total_cogs) || 0, + totalRevenue: parseFloat(metrics[0]?.total_revenue) || 0, + dailySales: dailyRows.map(day => ({ + date: day.sale_date, + units: parseInt(day.total_units) || 0, + revenue: parseFloat(day.total_revenue) || 0, + cogs: parseFloat(day.total_cogs) || 0 + })) + }; + + res.json(response); + } catch (err) { + console.error('Error fetching sales metrics:', err); + res.status(500).json({ error: 'Failed to fetch sales metrics' }); + } +}); + +// GET /dashboard/low-stock/products +// Returns list of products with critical or low stock levels +router.get('/low-stock/products', async (req, res) => { + const limit = parseInt(req.query.limit) || 50; + try { + const [rows] = await executeQuery(` + SELECT + p.product_id, + p.SKU, + p.title, + p.brand, + p.vendor, + p.stock_quantity, + p.cost_price, + p.price, + pm.daily_sales_avg, + pm.days_of_inventory, + pm.reorder_qty, + (pm.reorder_qty * p.cost_price) as reorder_cost, + GROUP_CONCAT(c.name) as categories + FROM products p + JOIN product_metrics pm ON p.product_id = pm.product_id + LEFT JOIN product_categories pc ON p.product_id = pc.product_id + LEFT JOIN categories c ON pc.category_id = c.id + WHERE pm.stock_status IN ('Critical', 'Reorder') + AND p.replenishable = true + GROUP BY p.product_id + ORDER BY + CASE pm.stock_status + WHEN 'Critical' THEN 1 + WHEN 'Reorder' THEN 2 + END, + pm.days_of_inventory ASC + LIMIT ? + `, [limit]); + res.json(rows); + } catch (err) { + console.error('Error fetching low stock products:', err); + res.status(500).json({ error: 'Failed to fetch low stock products' }); + } +}); + +// GET /dashboard/trending/products +// Returns list of trending products based on recent sales velocity +router.get('/trending/products', async (req, res) => { + const days = parseInt(req.query.days) || 30; + const limit = parseInt(req.query.limit) || 20; + try { + const [rows] = await executeQuery(` + WITH recent_sales AS ( + SELECT + o.product_id, + COUNT(DISTINCT o.order_number) as recent_orders, + SUM(o.quantity) as recent_units, + SUM(o.price * o.quantity) as recent_revenue + FROM orders o + WHERE o.canceled = false + AND o.date >= DATE_SUB(CURDATE(), INTERVAL ? DAY) + GROUP BY o.product_id + ) + SELECT + p.product_id, + p.SKU, + p.title, + p.brand, + p.vendor, + p.stock_quantity, + rs.recent_orders, + rs.recent_units, + rs.recent_revenue, + pm.daily_sales_avg, + pm.stock_status, + (rs.recent_units / ?) as daily_velocity, + ((rs.recent_units / ?) - pm.daily_sales_avg) / pm.daily_sales_avg * 100 as velocity_change, + GROUP_CONCAT(c.name) as categories + FROM recent_sales rs + JOIN products p ON rs.product_id = p.product_id + JOIN product_metrics pm ON p.product_id = pm.product_id + LEFT JOIN product_categories pc ON p.product_id = pc.product_id + LEFT JOIN categories c ON pc.category_id = c.id + GROUP BY p.product_id + HAVING velocity_change > 0 + ORDER BY velocity_change DESC + LIMIT ? + `, [days, days, days, limit]); + res.json(rows); + } catch (err) { + console.error('Error fetching trending products:', err); + res.status(500).json({ error: 'Failed to fetch trending products' }); + } +}); + +// GET /dashboard/vendor/performance +// Returns detailed vendor performance metrics +router.get('/vendor/performance', async (req, res) => { + try { + const [rows] = await executeQuery(` + WITH vendor_orders AS ( + SELECT + po.vendor, + COUNT(DISTINCT po.po_id) as total_orders, + CAST(AVG(DATEDIFF(po.received_date, po.date)) AS DECIMAL(10,2)) as avg_lead_time, + CAST(AVG(CASE + WHEN po.status = 'completed' + THEN DATEDIFF(po.received_date, po.expected_date) + END) AS DECIMAL(10,2)) as avg_delay, + CAST(SUM(CASE + WHEN po.status = 'completed' AND po.received_date <= po.expected_date + THEN 1 + ELSE 0 + END) * 100.0 / COUNT(*) AS DECIMAL(10,2)) as on_time_delivery_rate, + CAST(AVG(CASE + WHEN po.status = 'completed' + THEN po.received / po.ordered * 100 + ELSE NULL + END) AS DECIMAL(10,2)) as avg_fill_rate + FROM purchase_orders po + WHERE po.date >= DATE_SUB(CURDATE(), INTERVAL 180 DAY) + GROUP BY po.vendor + ) + SELECT + vd.vendor, + vd.contact_name, + vd.status, + CAST(vo.total_orders AS SIGNED) as total_orders, + vo.avg_lead_time, + vo.avg_delay, + vo.on_time_delivery_rate, + vo.avg_fill_rate + FROM vendor_details vd + JOIN vendor_orders vo ON vd.vendor = vo.vendor + WHERE vd.status = 'active' + ORDER BY vo.on_time_delivery_rate DESC + `); + + // Format response with explicit number parsing + const formattedRows = rows.map(row => ({ + vendor: row.vendor, + contact_name: row.contact_name, + status: row.status, + total_orders: parseInt(row.total_orders) || 0, + avg_lead_time: parseFloat(row.avg_lead_time) || 0, + avg_delay: parseFloat(row.avg_delay) || 0, + on_time_delivery_rate: parseFloat(row.on_time_delivery_rate) || 0, + avg_fill_rate: parseFloat(row.avg_fill_rate) || 0 + })); + + res.json(formattedRows); + } catch (err) { + console.error('Error fetching vendor performance:', err); + res.status(500).json({ error: 'Failed to fetch vendor performance' }); + } +}); + +// GET /dashboard/key-metrics +// Returns key business metrics and KPIs +router.get('/key-metrics', async (req, res) => { + const days = Math.max(1, Math.min(365, parseInt(req.query.days) || 30)); + try { + const [rows] = await executeQuery(` + WITH inventory_summary AS ( + SELECT + COUNT(*) as total_products, + SUM(p.stock_quantity * p.cost_price) as total_inventory_value, + AVG(pm.turnover_rate) as avg_turnover_rate, + COUNT(CASE WHEN pm.stock_status = 'Critical' THEN 1 END) as critical_stock_count, + COUNT(CASE WHEN pm.stock_status = 'Overstocked' THEN 1 END) as overstock_count + FROM products p + JOIN product_metrics pm ON p.product_id = pm.product_id + ), + sales_summary AS ( + SELECT + COUNT(DISTINCT order_number) as total_orders, + SUM(quantity) as total_units_sold, + SUM(price * quantity) as total_revenue, + AVG(price * quantity) as avg_order_value + FROM orders + WHERE canceled = false + AND date >= DATE_SUB(CURDATE(), INTERVAL ? DAY) + ), + purchase_summary AS ( + SELECT + COUNT(DISTINCT po_id) as total_pos, + SUM(ordered * cost_price) as total_po_value, + COUNT(CASE WHEN status = 'open' THEN 1 END) as open_pos + FROM purchase_orders + WHERE order_date >= DATE_SUB(CURDATE(), INTERVAL ? DAY) + ) + SELECT + i.*, + s.*, + p.* + FROM inventory_summary i + CROSS JOIN sales_summary s + CROSS JOIN purchase_summary p + `, [days, days]); + res.json(rows[0]); + } catch (err) { + console.error('Error fetching key metrics:', err); + res.status(500).json({ error: 'Failed to fetch key metrics' }); + } +}); + +// GET /dashboard/inventory-health +// Returns overall inventory health metrics +router.get('/inventory-health', async (req, res) => { + try { + const [rows] = await executeQuery(` + WITH stock_distribution AS ( + SELECT + COUNT(*) as total_products, + SUM(CASE WHEN pm.stock_status = 'Healthy' THEN 1 ELSE 0 END) * 100.0 / COUNT(*) as healthy_stock_percent, + SUM(CASE WHEN pm.stock_status = 'Critical' THEN 1 ELSE 0 END) * 100.0 / COUNT(*) as critical_stock_percent, + SUM(CASE WHEN pm.stock_status = 'Reorder' THEN 1 ELSE 0 END) * 100.0 / COUNT(*) as reorder_stock_percent, + SUM(CASE WHEN pm.stock_status = 'Overstocked' THEN 1 ELSE 0 END) * 100.0 / COUNT(*) as overstock_percent, + AVG(pm.turnover_rate) as avg_turnover_rate, + AVG(pm.days_of_inventory) as avg_days_inventory + FROM products p + JOIN product_metrics pm ON p.product_id = pm.product_id + WHERE p.replenishable = true + ), + value_distribution AS ( + SELECT + SUM(p.stock_quantity * p.cost_price) as total_inventory_value, + SUM(CASE + WHEN pm.stock_status = 'Healthy' + THEN p.stock_quantity * p.cost_price + ELSE 0 + END) * 100.0 / SUM(p.stock_quantity * p.cost_price) as healthy_value_percent, + SUM(CASE + WHEN pm.stock_status = 'Critical' + THEN p.stock_quantity * p.cost_price + ELSE 0 + END) * 100.0 / SUM(p.stock_quantity * p.cost_price) as critical_value_percent, + SUM(CASE + WHEN pm.stock_status = 'Overstocked' + THEN p.stock_quantity * p.cost_price + ELSE 0 + END) * 100.0 / SUM(p.stock_quantity * p.cost_price) as overstock_value_percent + FROM products p + JOIN product_metrics pm ON p.product_id = pm.product_id + ), + category_health AS ( + SELECT + c.name as category_name, + COUNT(*) as category_products, + SUM(CASE WHEN pm.stock_status = 'Healthy' THEN 1 ELSE 0 END) * 100.0 / COUNT(*) as category_healthy_percent, + AVG(pm.turnover_rate) as category_turnover_rate + FROM categories c + JOIN product_categories pc ON c.id = pc.category_id + JOIN products p ON pc.product_id = p.product_id + JOIN product_metrics pm ON p.product_id = pm.product_id + WHERE p.replenishable = true + GROUP BY c.id, c.name + ) + SELECT + sd.*, + vd.*, + JSON_ARRAYAGG( + JSON_OBJECT( + 'category', ch.category_name, + 'products', ch.category_products, + 'healthy_percent', ch.category_healthy_percent, + 'turnover_rate', ch.category_turnover_rate + ) + ) as category_health + FROM stock_distribution sd + CROSS JOIN value_distribution vd + CROSS JOIN category_health ch + `); + res.json(rows[0]); + } catch (err) { + console.error('Error fetching inventory health:', err); + res.status(500).json({ error: 'Failed to fetch inventory health' }); + } +}); + +// GET /dashboard/replenish/products +// Returns top products that need replenishment +router.get('/replenish/products', async (req, res) => { + const limit = Math.max(1, Math.min(100, parseInt(req.query.limit) || 50)); + try { + const [products] = await executeQuery(` + SELECT + p.product_id, + p.SKU, + p.title, + p.stock_quantity as current_stock, + pm.reorder_qty as replenish_qty, + (pm.reorder_qty * p.cost_price) as replenish_cost, + (pm.reorder_qty * p.price) as replenish_retail, + CASE + WHEN pm.daily_sales_avg > 0 + THEN FLOOR(p.stock_quantity / pm.daily_sales_avg) + ELSE NULL + END as days_until_stockout + FROM products p + JOIN product_metrics pm ON p.product_id = pm.product_id + WHERE p.replenishable = true + AND pm.stock_status IN ('Critical', 'Reorder') + AND pm.reorder_qty > 0 + ORDER BY + CASE pm.stock_status + WHEN 'Critical' THEN 1 + WHEN 'Reorder' THEN 2 + END, + replenish_cost DESC + LIMIT ? + `, [limit]); + + // Format response + const response = products.map(p => ({ + product_id: p.product_id, + SKU: p.SKU, + title: p.title, + current_stock: parseInt(p.current_stock) || 0, + replenish_qty: parseInt(p.replenish_qty) || 0, + replenish_cost: parseFloat(p.replenish_cost) || 0, + replenish_retail: parseFloat(p.replenish_retail) || 0, + days_until_stockout: p.days_until_stockout + })); + + res.json(response); + } catch (err) { + console.error('Error fetching products to replenish:', err); + res.status(500).json({ error: 'Failed to fetch products to replenish' }); + } }); module.exports = router; \ No newline at end of file diff --git a/inventory/src/components/dashboard/BestSellers.tsx b/inventory/src/components/dashboard/BestSellers.tsx new file mode 100644 index 0000000..ad17942 --- /dev/null +++ b/inventory/src/components/dashboard/BestSellers.tsx @@ -0,0 +1,192 @@ +import { useQuery } from "@tanstack/react-query" +import { CardHeader, CardTitle, CardContent } from "@/components/ui/card" +import { ScrollArea } from "@/components/ui/scroll-area" +import { Table, TableBody, TableCell, TableHead, TableHeader, TableRow } from "@/components/ui/table" +import { Tabs, TabsContent, TabsList, TabsTrigger } from "@/components/ui/tabs" +import config from "@/config" +import { formatCurrency } from "@/lib/utils" + +interface BestSellerProduct { + product_id: number + sku: string + title: string + units_sold: number + revenue: number + profit: number + growth_rate: number +} + +interface BestSellerBrand { + brand: string + units_sold: number + revenue: number + profit: number + growth_rate: number +} + +interface BestSellerCategory { + category_id: number + name: string + units_sold: number + revenue: number + profit: number + growth_rate: number +} + +interface BestSellersData { + products: BestSellerProduct[] + brands: BestSellerBrand[] + categories: BestSellerCategory[] +} + +export function BestSellers() { + const { data } = useQuery({ + queryKey: ["best-sellers"], + queryFn: async () => { + const response = await fetch(`${config.apiUrl}/dashboard/best-sellers`) + if (!response.ok) { + throw new Error("Failed to fetch best sellers") + } + return response.json() + }, + }) + + return ( + <> + + +
+ Best Sellers + + Products + Brands + Categories + +
+
+ + + + + + + Product + Sales + Revenue + Profit + Growth + + + + {data?.products.map((product) => ( + + +
+ + {product.title} + +

{product.sku}

+
+
+ + {product.units_sold.toLocaleString()} + + + {formatCurrency(product.revenue)} + + + {formatCurrency(product.profit)} + + + {product.growth_rate > 0 ? '+' : ''}{product.growth_rate.toFixed(1)}% + +
+ ))} +
+
+
+
+ + + + + + + Brand + Sales + Revenue + Profit + Growth + + + + {data?.brands.map((brand) => ( + + +

{brand.brand}

+
+ + {brand.units_sold.toLocaleString()} + + + {formatCurrency(brand.revenue)} + + + {formatCurrency(brand.profit)} + + + {brand.growth_rate > 0 ? '+' : ''}{brand.growth_rate.toFixed(1)}% + +
+ ))} +
+
+
+
+ + + + + + + Category + Sales + Revenue + Profit + Growth + + + + {data?.categories.map((category) => ( + + +

{category.name}

+
+ + {category.units_sold.toLocaleString()} + + + {formatCurrency(category.revenue)} + + + {formatCurrency(category.profit)} + + + {category.growth_rate > 0 ? '+' : ''}{category.growth_rate.toFixed(1)}% + +
+ ))} +
+
+
+
+
+
+ + ) +} \ No newline at end of file diff --git a/inventory/src/components/dashboard/ForecastMetrics.tsx b/inventory/src/components/dashboard/ForecastMetrics.tsx new file mode 100644 index 0000000..6eb5ab0 --- /dev/null +++ b/inventory/src/components/dashboard/ForecastMetrics.tsx @@ -0,0 +1,130 @@ +import { useQuery } from "@tanstack/react-query" +import { CardHeader, CardTitle, CardContent } from "@/components/ui/card" +import { AreaChart, Area, ResponsiveContainer, XAxis, YAxis, Tooltip } from "recharts" +import { useState } from "react" +import config from "@/config" +import { formatCurrency } from "@/lib/utils" +import { TrendingUp, DollarSign } from "lucide-react" +import { DateRange } from "react-day-picker" +import { addDays, format } from "date-fns" +import { DateRangePicker } from "@/components/ui/date-range-picker-narrow" + +interface ForecastData { + forecastSales: number + forecastRevenue: number + confidenceLevel: number + dailyForecasts: { + date: string + units: number + revenue: number + confidence: number + }[] + categoryForecasts: { + category: string + units: number + revenue: number + confidence: number + }[] +} + +export function ForecastMetrics() { + const [dateRange, setDateRange] = useState({ + from: new Date(), + to: addDays(new Date(), 30), + }); + + const { data, error, isLoading } = useQuery({ + queryKey: ["forecast-metrics", dateRange], + queryFn: async () => { + const params = new URLSearchParams({ + startDate: dateRange.from?.toISOString() || "", + endDate: dateRange.to?.toISOString() || "", + }); + console.log('Fetching forecast metrics with params:', params.toString()); + const response = await fetch(`${config.apiUrl}/dashboard/forecast/metrics?${params}`) + if (!response.ok) { + const text = await response.text(); + throw new Error(`Failed to fetch forecast metrics: ${text}`); + } + const data = await response.json(); + console.log('Forecast metrics response:', data); + return data; + }, + }) + + return ( + <> + + Forecast +
+ { + if (range) setDateRange(range); + }} + future={true} + /> +
+
+ + {error ? ( +
Error: {error.message}
+ ) : isLoading ? ( +
Loading forecast metrics...
+ ) : ( + <> +
+
+
+ +

Forecast Sales

+
+

{data?.forecastSales.toLocaleString() || 0}

+
+
+
+ +

Forecast Revenue

+
+

{formatCurrency(data?.forecastRevenue || 0)}

+
+
+ +
+ + + + + [formatCurrency(value), "Revenue"]} + labelFormatter={(date) => format(new Date(date), 'MMM d, yyyy')} + /> + + + +
+ + )} +
+ + ) +} \ No newline at end of file diff --git a/inventory/src/components/dashboard/LowStockAlerts.tsx b/inventory/src/components/dashboard/LowStockAlerts.tsx index 7e98db7..25b6991 100644 --- a/inventory/src/components/dashboard/LowStockAlerts.tsx +++ b/inventory/src/components/dashboard/LowStockAlerts.tsx @@ -14,10 +14,10 @@ import config from "@/config" interface LowStockProduct { product_id: number - sku: string + SKU: string title: string stock_quantity: number - reorder_point: number + reorder_qty: number days_of_inventory: number stock_status: "Critical" | "Reorder" daily_sales_avg: number @@ -27,7 +27,7 @@ export function LowStockAlerts() { const { data: products } = useQuery({ queryKey: ["low-stock"], queryFn: async () => { - const response = await fetch(`${config.apiUrl}/dashboard/inventory/low-stock`) + const response = await fetch(`${config.apiUrl}/dashboard/low-stock/products`) if (!response.ok) { throw new Error("Failed to fetch low stock products") } @@ -54,10 +54,10 @@ export function LowStockAlerts() { {products?.map((product) => ( - {product.sku} + {product.SKU} {product.title} - {product.stock_quantity} / {product.reorder_point} + {product.stock_quantity} / {product.reorder_qty} ({ + queryKey: ["overstock-metrics"], + queryFn: async () => { + const response = await fetch(`${config.apiUrl}/dashboard/overstock/metrics`) + if (!response.ok) { + throw new Error("Failed to fetch overstock metrics") + } + return response.json() + }, + }) + + return ( + <> + + Overstock + + +
+
+
+ +

Overstocked Products

+
+

{data?.overstockedProducts.toLocaleString() || 0}

+
+
+
+ +

Overstocked Units

+
+

{data?.total_excess_units.toLocaleString() || 0}

+
+
+
+ +

Overstocked Cost

+
+

{formatCurrency(data?.total_excess_cost || 0)}

+
+
+
+ +

Overstocked Retail

+
+

{formatCurrency(data?.total_excess_retail || 0)}

+
+
+
+ + ) +} \ No newline at end of file diff --git a/inventory/src/components/dashboard/PurchaseMetrics.tsx b/inventory/src/components/dashboard/PurchaseMetrics.tsx new file mode 100644 index 0000000..71ebe4d --- /dev/null +++ b/inventory/src/components/dashboard/PurchaseMetrics.tsx @@ -0,0 +1,204 @@ +import { useQuery } from "@tanstack/react-query" +import { CardHeader, CardTitle, CardContent } from "@/components/ui/card" +import { PieChart, Pie, ResponsiveContainer, Cell, Sector } from "recharts" +import config from "@/config" +import { formatCurrency } from "@/lib/utils" +import { ClipboardList, AlertCircle, Layers, DollarSign, ShoppingCart } from "lucide-react" // Importing icons +import { useState } from "react" + +interface PurchaseMetricsData { + activePurchaseOrders: number + overduePurchaseOrders: number + onOrderUnits: number + onOrderCost: number + onOrderRetail: number + vendorOrders: { + vendor: string + orders: number + units: number + cost: number + retail: number + }[] +} + +const COLORS = [ + "#0088FE", + "#00C49F", + "#FFBB28", + "#FF8042", + "#8884D8", + "#82CA9D", + "#FFC658", + "#FF7C43", +] + +const renderActiveShape = (props: any) => { + const { cx, cy, innerRadius, outerRadius, startAngle, endAngle, fill, vendor, cost } = props; + + // Split vendor name into words and create lines of max 12 chars + const words = vendor.split(' '); + const lines: string[] = []; + let currentLine = ''; + + words.forEach((word: string) => { + if ((currentLine + ' ' + word).length <= 12) { + currentLine = currentLine ? `${currentLine} ${word}` : word; + } else { + if (currentLine) lines.push(currentLine); + currentLine = word; + } + }); + if (currentLine) lines.push(currentLine); + + return ( + + + + {lines.map((line, i) => ( + + {line} + + ))} + + {formatCurrency(cost)} + + + ); +}; + +export function PurchaseMetrics() { + const [activeIndex, setActiveIndex] = useState(); + + const { data, error, isLoading } = useQuery({ + queryKey: ["purchase-metrics"], + queryFn: async () => { + console.log('Fetching from:', `${config.apiUrl}/dashboard/purchase/metrics`); + const response = await fetch(`${config.apiUrl}/dashboard/purchase/metrics`) + if (!response.ok) { + const text = await response.text(); + console.error('API Error:', text); + throw new Error(`Failed to fetch purchase metrics: ${response.status} ${response.statusText}`); + } + const data = await response.json(); + console.log('API Response:', data); + return data; + }, + }) + + if (isLoading) return
Loading...
; + if (error) return
Error loading purchase metrics
; + + return ( + <> + + Purchases + + +
+
+
+
+
+ +

Active Purchase Orders

+
+

{data?.activePurchaseOrders.toLocaleString() || 0}

+
+
+
+ +

Overdue Purchase Orders

+
+

{data?.overduePurchaseOrders.toLocaleString() || 0}

+
+
+
+ +

On Order Units

+
+

{data?.onOrderUnits.toLocaleString() || 0}

+
+
+
+ +

On Order Cost

+
+

{formatCurrency(data?.onOrderCost || 0)}

+
+
+
+ +

On Order Retail

+
+

{formatCurrency(data?.onOrderRetail || 0)}

+
+
+
+
+
+
Purchase Orders By Vendor
+
+ + + setActiveIndex(index)} + onMouseLeave={() => setActiveIndex(undefined)} + > + {data?.vendorOrders?.map((entry, index) => ( + + ))} + + + +
+
+
+
+
+ + ) +} \ No newline at end of file diff --git a/inventory/src/components/dashboard/ReplenishmentMetrics.tsx b/inventory/src/components/dashboard/ReplenishmentMetrics.tsx new file mode 100644 index 0000000..f94487f --- /dev/null +++ b/inventory/src/components/dashboard/ReplenishmentMetrics.tsx @@ -0,0 +1,77 @@ +import { useQuery } from "@tanstack/react-query" +import { CardHeader, CardTitle, CardContent } from "@/components/ui/card" +import config from "@/config" +import { formatCurrency } from "@/lib/utils" +import { Package, DollarSign, ShoppingCart } from "lucide-react" // Importing icons + +interface ReplenishmentMetricsData { + productsToReplenish: number + unitsToReplenish: number + replenishmentCost: number + replenishmentRetail: number + topVariants: { + id: number + title: string + currentStock: number + replenishQty: number + replenishCost: number + replenishRetail: number + status: string + planningPeriod: string + }[] +} + +export function ReplenishmentMetrics() { + const { data, error, isLoading } = useQuery({ + queryKey: ["replenishment-metrics"], + queryFn: async () => { + console.log('Fetching from:', `${config.apiUrl}/dashboard/replenishment/metrics`); + const response = await fetch(`${config.apiUrl}/dashboard/replenishment/metrics`) + if (!response.ok) { + const text = await response.text(); + console.error('API Error:', text); + throw new Error(`Failed to fetch replenishment metrics: ${response.status} ${response.statusText} - ${text}`) + } + const data = await response.json(); + console.log('API Response:', data); + return data; + }, + }) + + if (isLoading) return
Loading replenishment metrics...
; + if (error) return
Error: {error.message}
; + if (!data) return
No replenishment data available
; + + return ( + <> + + Replenishment + + +
+
+
+ +

Units to Replenish

+
+

{data.unitsToReplenish.toLocaleString() || 0}

+
+
+
+ +

Replenishment Cost

+
+

{formatCurrency(data.replenishmentCost || 0)}

+
+
+
+ +

Replenishment Retail

+
+

{formatCurrency(data.replenishmentRetail || 0)}

+
+
+
+ + ) +} \ No newline at end of file diff --git a/inventory/src/components/dashboard/SalesMetrics.tsx b/inventory/src/components/dashboard/SalesMetrics.tsx new file mode 100644 index 0000000..ceb41d5 --- /dev/null +++ b/inventory/src/components/dashboard/SalesMetrics.tsx @@ -0,0 +1,127 @@ +import { useQuery } from "@tanstack/react-query" +import { CardHeader, CardTitle, CardContent } from "@/components/ui/card" +import { AreaChart, Area, ResponsiveContainer, XAxis, YAxis, Tooltip } from "recharts" +import { useState } from "react" +import config from "@/config" +import { formatCurrency } from "@/lib/utils" +import { ClipboardList, Package, DollarSign, ShoppingCart } from "lucide-react" +import { DateRange } from "react-day-picker" +import { addDays, format } from "date-fns" +import { DateRangePicker } from "@/components/ui/date-range-picker-narrow" + +interface SalesData { + totalOrders: number + totalUnitsSold: number + totalCogs: number + totalRevenue: number + dailySales: { + date: string + units: number + revenue: number + cogs: number + }[] +} + +export function SalesMetrics() { + const [dateRange, setDateRange] = useState({ + from: addDays(new Date(), -30), + to: new Date(), + }); + + const { data } = useQuery({ + queryKey: ["sales-metrics", dateRange], + queryFn: async () => { + const params = new URLSearchParams({ + startDate: dateRange.from?.toISOString() || "", + endDate: dateRange.to?.toISOString() || "", + }); + const response = await fetch(`${config.apiUrl}/dashboard/sales/metrics?${params}`) + if (!response.ok) { + throw new Error("Failed to fetch sales metrics") + } + return response.json() + }, + }) + + return ( + <> + + Sales +
+ { + if (range) setDateRange(range); + }} + future={false} + /> +
+
+ +
+
+
+ +

Total Orders

+
+

{data?.totalOrders.toLocaleString() || 0}

+
+
+
+ +

Units Sold

+
+

{data?.totalUnitsSold.toLocaleString() || 0}

+
+
+
+ +

Cost of Goods

+
+

{formatCurrency(data?.totalCogs || 0)}

+
+
+
+ +

Revenue

+
+

{formatCurrency(data?.totalRevenue || 0)}

+
+
+ +
+ + + + + [formatCurrency(value), "Revenue"]} + labelFormatter={(date) => format(new Date(date), 'MMM d, yyyy')} + /> + + + +
+
+ + ) +} \ No newline at end of file diff --git a/inventory/src/components/dashboard/StockMetrics.tsx b/inventory/src/components/dashboard/StockMetrics.tsx new file mode 100644 index 0000000..a9f13c2 --- /dev/null +++ b/inventory/src/components/dashboard/StockMetrics.tsx @@ -0,0 +1,204 @@ +import { useQuery } from "@tanstack/react-query" +import { CardHeader, CardTitle, CardContent } from "@/components/ui/card" +import { PieChart, Pie, ResponsiveContainer, Cell, Sector } from "recharts" +import config from "@/config" +import { formatCurrency } from "@/lib/utils" +import { Package, Layers, DollarSign, ShoppingCart } from "lucide-react" +import { useState } from "react" + +interface StockMetricsData { + totalProducts: number + productsInStock: number + totalStockUnits: number + totalStockCost: number + totalStockRetail: number + brandStock: { + brand: string + variants: number + units: number + cost: number + retail: number + }[] +} + +const COLORS = [ + "#0088FE", + "#00C49F", + "#FFBB28", + "#FF8042", + "#8884D8", + "#82CA9D", + "#FFC658", + "#FF7C43", +] + +const renderActiveShape = (props: any) => { + const { cx, cy, innerRadius, outerRadius, startAngle, endAngle, fill, brand, retail } = props; + + // Split brand name into words and create lines of max 12 chars + const words = brand.split(' '); + const lines: string[] = []; + let currentLine = ''; + + words.forEach((word: string) => { + if ((currentLine + ' ' + word).length <= 12) { + currentLine = currentLine ? `${currentLine} ${word}` : word; + } else { + if (currentLine) lines.push(currentLine); + currentLine = word; + } + }); + if (currentLine) lines.push(currentLine); + + return ( + + + + {lines.map((line, i) => ( + + {line} + + ))} + + {formatCurrency(retail)} + + + ); +}; + +export function StockMetrics() { + const [activeIndex, setActiveIndex] = useState(); + + const { data, error, isLoading } = useQuery({ + queryKey: ["stock-metrics"], + queryFn: async () => { + console.log('Fetching from:', `${config.apiUrl}/dashboard/stock/metrics`); + const response = await fetch(`${config.apiUrl}/dashboard/stock/metrics`); + if (!response.ok) { + const text = await response.text(); + console.error('API Error:', text); + throw new Error(`Failed to fetch stock metrics: ${response.status} ${response.statusText}`); + } + const data = await response.json(); + console.log('API Response:', data); + return data; + }, + }); + + if (isLoading) return
Loading...
; + if (error) return
Error loading stock metrics
; + + return ( + <> + + Stock + + +
+
+
+
+
+ +

Products

+
+

{data?.totalProducts.toLocaleString() || 0}

+
+
+
+ +

Products In Stock

+
+

{data?.productsInStock.toLocaleString() || 0}

+
+
+
+ +

Stock Units

+
+

{data?.totalStockUnits.toLocaleString() || 0}

+
+
+
+ +

Stock Cost

+
+

{formatCurrency(data?.totalStockCost || 0)}

+
+
+
+ +

Stock Retail

+
+

{formatCurrency(data?.totalStockRetail || 0)}

+
+
+
+
+
+
Stock Retail By Brand
+
+ + + setActiveIndex(index)} + onMouseLeave={() => setActiveIndex(undefined)} + > + {data?.brandStock?.map((entry, index) => ( + + ))} + + + +
+
+
+
+
+ + ) +} \ No newline at end of file diff --git a/inventory/src/components/dashboard/TopOverstockedProducts.tsx b/inventory/src/components/dashboard/TopOverstockedProducts.tsx new file mode 100644 index 0000000..f963504 --- /dev/null +++ b/inventory/src/components/dashboard/TopOverstockedProducts.tsx @@ -0,0 +1,83 @@ +import { useQuery } from "@tanstack/react-query" +import { CardHeader, CardTitle, CardContent } from "@/components/ui/card" +import { ScrollArea } from "@/components/ui/scroll-area" +import { Table, TableBody, TableCell, TableHead, TableHeader, TableRow } from "@/components/ui/table" +import config from "@/config" +import { formatCurrency } from "@/lib/utils" + +interface OverstockedProduct { + product_id: number + SKU: string + title: string + stock_quantity: number + overstocked_amt: number + excess_cost: number + excess_retail: number +} + +export function TopOverstockedProducts() { + const { data } = useQuery({ + queryKey: ["top-overstocked-products"], + queryFn: async () => { + const response = await fetch(`${config.apiUrl}/dashboard/overstock/products?limit=50`) + if (!response.ok) { + throw new Error("Failed to fetch overstocked products") + } + return response.json() + }, + }) + + return ( + <> + + Top Overstocked Products + + + + + + + Product + Current Stock + Overstock Amt + Overstock Cost + Overstock Retail + + + + {data?.map((product) => ( + + +
+ + {product.title} + +

{product.SKU}

+
+
+ + {product.stock_quantity.toLocaleString()} + + + {product.overstocked_amt.toLocaleString()} + + + {formatCurrency(product.excess_cost)} + + + {formatCurrency(product.excess_retail)} + +
+ ))} +
+
+
+
+ + ) +} \ No newline at end of file diff --git a/inventory/src/components/dashboard/TopReplenishProducts.tsx b/inventory/src/components/dashboard/TopReplenishProducts.tsx new file mode 100644 index 0000000..41df022 --- /dev/null +++ b/inventory/src/components/dashboard/TopReplenishProducts.tsx @@ -0,0 +1,83 @@ +import { useQuery } from "@tanstack/react-query" +import { CardHeader, CardTitle, CardContent } from "@/components/ui/card" +import { ScrollArea } from "@/components/ui/scroll-area" +import { Table, TableBody, TableCell, TableHead, TableHeader, TableRow } from "@/components/ui/table" +import config from "@/config" +import { formatCurrency } from "@/lib/utils" + +interface ReplenishProduct { + product_id: number + SKU: string + title: string + current_stock: number + replenish_qty: number + replenish_cost: number + replenish_retail: number +} + +export function TopReplenishProducts() { + const { data } = useQuery({ + queryKey: ["top-replenish-products"], + queryFn: async () => { + const response = await fetch(`${config.apiUrl}/dashboard/replenish/products?limit=50`) + if (!response.ok) { + throw new Error("Failed to fetch products to replenish") + } + return response.json() + }, + }) + + return ( + <> + + Top Products To Replenish + + + + + + + Product + Stock + Replenish + Cost + Retail + + + + {data?.map((product) => ( + + +
+ + {product.title} + +

{product.SKU}

+
+
+ + {product.current_stock.toLocaleString()} + + + {product.replenish_qty.toLocaleString()} + + + {formatCurrency(product.replenish_cost)} + + + {formatCurrency(product.replenish_retail)} + +
+ ))} +
+
+
+
+ + ) +} \ No newline at end of file diff --git a/inventory/src/components/dashboard/VendorPerformance.tsx b/inventory/src/components/dashboard/VendorPerformance.tsx index 91a676c..52a0443 100644 --- a/inventory/src/components/dashboard/VendorPerformance.tsx +++ b/inventory/src/components/dashboard/VendorPerformance.tsx @@ -13,18 +13,19 @@ import config from "@/config" interface VendorMetrics { vendor: string - avg_lead_time_days: number + avg_lead_time: number on_time_delivery_rate: number - order_fill_rate: number + avg_fill_rate: number total_orders: number - total_late_orders: number + active_orders: number + overdue_orders: number } export function VendorPerformance() { const { data: vendors } = useQuery({ queryKey: ["vendor-metrics"], queryFn: async () => { - const response = await fetch(`${config.apiUrl}/dashboard/vendors/metrics`) + const response = await fetch(`${config.apiUrl}/dashboard/vendor/performance`) if (!response.ok) { throw new Error("Failed to fetch vendor metrics") } @@ -66,7 +67,7 @@ export function VendorPerformance() {
- {vendor.order_fill_rate.toFixed(0)}% + {vendor.avg_fill_rate.toFixed(0)}%
))} diff --git a/inventory/src/components/layout/AppSidebar.tsx b/inventory/src/components/layout/AppSidebar.tsx index 3430de5..11a3c01 100644 --- a/inventory/src/components/layout/AppSidebar.tsx +++ b/inventory/src/components/layout/AppSidebar.tsx @@ -26,7 +26,7 @@ import { useLocation, useNavigate, Link } from "react-router-dom"; const items = [ { - title: "Dashboard", + title: "Overview", icon: Home, url: "/", }, diff --git a/inventory/src/components/ui/date-range-picker-narrow.tsx b/inventory/src/components/ui/date-range-picker-narrow.tsx new file mode 100644 index 0000000..10162fb --- /dev/null +++ b/inventory/src/components/ui/date-range-picker-narrow.tsx @@ -0,0 +1,135 @@ +import { format, addDays, startOfYear, endOfYear, subDays } from "date-fns"; +import { Calendar as CalendarIcon } from "lucide-react"; +import { DateRange } from "react-day-picker"; +import { cn } from "@/lib/utils"; +import { Button } from "@/components/ui/button"; +import { Calendar } from "@/components/ui/calendar"; +import { + Popover, + PopoverContent, + PopoverTrigger, +} from "@/components/ui/popover"; + +interface DateRangePickerProps { + value: DateRange; + onChange: (range: DateRange | undefined) => void; + className?: string; + future?: boolean; +} + +export function DateRangePicker({ + value, + onChange, + className, + future = false, +}: DateRangePickerProps) { + const today = new Date(); + + const presets = future ? [ + { + label: "Next 30 days", + range: { + from: today, + to: addDays(today, 30), + }, + }, + { + label: "Next 90 days", + range: { + from: today, + to: addDays(today, 90), + }, + }, + { + label: "Rest of year", + range: { + from: today, + to: endOfYear(today), + }, + }, + ] : [ + { + label: "Last 7 days", + range: { + from: subDays(today, 7), + to: today, + }, + }, + { + label: "Last 30 days", + range: { + from: subDays(today, 30), + to: today, + }, + }, + { + label: "Last 90 days", + range: { + from: subDays(today, 90), + to: today, + }, + }, + { + label: "Year to date", + range: { + from: startOfYear(today), + to: today, + }, + }, + ]; + + return ( +
+ + + + + +
+ {presets.map((preset) => ( + + ))} +
+ { + if (range) onChange(range); + }} + numberOfMonths={2} + /> +
+
+
+ ); +} \ No newline at end of file diff --git a/inventory/src/lib/utils.ts b/inventory/src/lib/utils.ts index bd0c391..7b5fc81 100644 --- a/inventory/src/lib/utils.ts +++ b/inventory/src/lib/utils.ts @@ -4,3 +4,27 @@ import { twMerge } from "tailwind-merge" export function cn(...inputs: ClassValue[]) { return twMerge(clsx(inputs)) } + +/** + * Format a number as currency with the specified locale and currency code + * @param value - The number to format + * @param locale - The locale to use for formatting (defaults to 'en-US') + * @param currency - The currency code to use (defaults to 'USD') + * @returns Formatted currency string + */ +export function formatCurrency( + value: number | null | undefined, + locale: string = 'en-US', + currency: string = 'USD' +): string { + if (value === null || value === undefined) { + return '$0.00'; + } + + return new Intl.NumberFormat(locale, { + style: 'currency', + currency: currency, + minimumFractionDigits: 2, + maximumFractionDigits: 2, + }).format(value); +} diff --git a/inventory/src/pages/Dashboard.tsx b/inventory/src/pages/Dashboard.tsx index c69a6d9..36d6a7d 100644 --- a/inventory/src/pages/Dashboard.tsx +++ b/inventory/src/pages/Dashboard.tsx @@ -1,33 +1,64 @@ import { Card } from "@/components/ui/card" -import { InventoryHealthSummary } from "@/components/dashboard/InventoryHealthSummary" -import { LowStockAlerts } from "@/components/dashboard/LowStockAlerts" -import { TrendingProducts } from "@/components/dashboard/TrendingProducts" -import { VendorPerformance } from "@/components/dashboard/VendorPerformance" -import { KeyMetricsCharts } from "@/components/dashboard/KeyMetricsCharts" +import { StockMetrics } from "@/components/dashboard/StockMetrics" +import { PurchaseMetrics } from "@/components/dashboard/PurchaseMetrics" +import { ReplenishmentMetrics } from "@/components/dashboard/ReplenishmentMetrics" +import { TopReplenishProducts } from "@/components/dashboard/TopReplenishProducts" +import { OverstockMetrics } from "@/components/dashboard/OverstockMetrics" +import { TopOverstockedProducts } from "@/components/dashboard/TopOverstockedProducts" +import { BestSellers } from "@/components/dashboard/BestSellers" +import { ForecastMetrics } from "@/components/dashboard/ForecastMetrics" +import { SalesMetrics } from "@/components/dashboard/SalesMetrics" import { motion } from "motion/react" + export function Dashboard() { return (
-

Dashboard

+

Overview

-
- -
-
- - + + {/* First row - Stock and Purchase metrics */} +
+ + - - + +
-
- - + + {/* Second row - Replenishment section */} +
+ + - - +
+ + + + + + +
+
+ + {/* Third row - Overstock section */} +
+ + + + + + +
+ + {/* Fourth row - Best Sellers and Sales */} +
+ + + + +
diff --git a/inventory/tsconfig.tsbuildinfo b/inventory/tsconfig.tsbuildinfo index 63b006d..9be69dd 100644 --- a/inventory/tsconfig.tsbuildinfo +++ b/inventory/tsconfig.tsbuildinfo @@ -1 +1 @@ -{"root":["./src/app.tsx","./src/config.ts","./src/main.tsx","./src/vite-env.d.ts","./src/components/analytics/categoryperformance.tsx","./src/components/analytics/priceanalysis.tsx","./src/components/analytics/profitanalysis.tsx","./src/components/analytics/stockanalysis.tsx","./src/components/analytics/vendorperformance.tsx","./src/components/auth/requireauth.tsx","./src/components/dashboard/inventoryhealthsummary.tsx","./src/components/dashboard/inventorystats.tsx","./src/components/dashboard/keymetricscharts.tsx","./src/components/dashboard/lowstockalerts.tsx","./src/components/dashboard/overview.tsx","./src/components/dashboard/recentsales.tsx","./src/components/dashboard/salesbycategory.tsx","./src/components/dashboard/trendingproducts.tsx","./src/components/dashboard/vendorperformance.tsx","./src/components/forecasting/columns.tsx","./src/components/layout/appsidebar.tsx","./src/components/layout/mainlayout.tsx","./src/components/products/productdetail.tsx","./src/components/products/productfilters.tsx","./src/components/products/producttable.tsx","./src/components/products/producttableskeleton.tsx","./src/components/products/productviews.tsx","./src/components/settings/calculationsettings.tsx","./src/components/settings/configuration.tsx","./src/components/settings/datamanagement.tsx","./src/components/settings/performancemetrics.tsx","./src/components/settings/stockmanagement.tsx","./src/components/ui/accordion.tsx","./src/components/ui/alert-dialog.tsx","./src/components/ui/alert.tsx","./src/components/ui/avatar.tsx","./src/components/ui/badge.tsx","./src/components/ui/button.tsx","./src/components/ui/calendar.tsx","./src/components/ui/card.tsx","./src/components/ui/command.tsx","./src/components/ui/date-range-picker.tsx","./src/components/ui/dialog.tsx","./src/components/ui/drawer.tsx","./src/components/ui/dropdown-menu.tsx","./src/components/ui/input.tsx","./src/components/ui/label.tsx","./src/components/ui/pagination.tsx","./src/components/ui/popover.tsx","./src/components/ui/progress.tsx","./src/components/ui/scroll-area.tsx","./src/components/ui/select.tsx","./src/components/ui/separator.tsx","./src/components/ui/sheet.tsx","./src/components/ui/sidebar.tsx","./src/components/ui/skeleton.tsx","./src/components/ui/sonner.tsx","./src/components/ui/switch.tsx","./src/components/ui/table.tsx","./src/components/ui/tabs.tsx","./src/components/ui/toggle-group.tsx","./src/components/ui/toggle.tsx","./src/components/ui/tooltip.tsx","./src/hooks/use-mobile.tsx","./src/lib/utils.ts","./src/pages/analytics.tsx","./src/pages/categories.tsx","./src/pages/dashboard.tsx","./src/pages/forecasting.tsx","./src/pages/login.tsx","./src/pages/orders.tsx","./src/pages/products.tsx","./src/pages/purchaseorders.tsx","./src/pages/settings.tsx","./src/pages/vendors.tsx","./src/routes/forecasting.tsx","./src/types/products.ts"],"version":"5.6.3"} \ No newline at end of file +{"root":["./src/app.tsx","./src/config.ts","./src/main.tsx","./src/vite-env.d.ts","./src/components/analytics/categoryperformance.tsx","./src/components/analytics/priceanalysis.tsx","./src/components/analytics/profitanalysis.tsx","./src/components/analytics/stockanalysis.tsx","./src/components/analytics/vendorperformance.tsx","./src/components/auth/requireauth.tsx","./src/components/dashboard/bestsellers.tsx","./src/components/dashboard/forecastmetrics.tsx","./src/components/dashboard/inventoryhealthsummary.tsx","./src/components/dashboard/inventorystats.tsx","./src/components/dashboard/keymetricscharts.tsx","./src/components/dashboard/lowstockalerts.tsx","./src/components/dashboard/overstockmetrics.tsx","./src/components/dashboard/overview.tsx","./src/components/dashboard/purchasemetrics.tsx","./src/components/dashboard/recentsales.tsx","./src/components/dashboard/replenishmentmetrics.tsx","./src/components/dashboard/salesbycategory.tsx","./src/components/dashboard/salesmetrics.tsx","./src/components/dashboard/stockmetrics.tsx","./src/components/dashboard/topoverstockedproducts.tsx","./src/components/dashboard/topreplenishproducts.tsx","./src/components/dashboard/trendingproducts.tsx","./src/components/dashboard/vendorperformance.tsx","./src/components/forecasting/columns.tsx","./src/components/layout/appsidebar.tsx","./src/components/layout/mainlayout.tsx","./src/components/products/productdetail.tsx","./src/components/products/productfilters.tsx","./src/components/products/producttable.tsx","./src/components/products/producttableskeleton.tsx","./src/components/products/productviews.tsx","./src/components/settings/calculationsettings.tsx","./src/components/settings/configuration.tsx","./src/components/settings/datamanagement.tsx","./src/components/settings/performancemetrics.tsx","./src/components/settings/stockmanagement.tsx","./src/components/ui/accordion.tsx","./src/components/ui/alert-dialog.tsx","./src/components/ui/alert.tsx","./src/components/ui/avatar.tsx","./src/components/ui/badge.tsx","./src/components/ui/button.tsx","./src/components/ui/calendar.tsx","./src/components/ui/card.tsx","./src/components/ui/command.tsx","./src/components/ui/date-range-picker-narrow.tsx","./src/components/ui/date-range-picker.tsx","./src/components/ui/dialog.tsx","./src/components/ui/drawer.tsx","./src/components/ui/dropdown-menu.tsx","./src/components/ui/input.tsx","./src/components/ui/label.tsx","./src/components/ui/pagination.tsx","./src/components/ui/popover.tsx","./src/components/ui/progress.tsx","./src/components/ui/scroll-area.tsx","./src/components/ui/select.tsx","./src/components/ui/separator.tsx","./src/components/ui/sheet.tsx","./src/components/ui/sidebar.tsx","./src/components/ui/skeleton.tsx","./src/components/ui/sonner.tsx","./src/components/ui/switch.tsx","./src/components/ui/table.tsx","./src/components/ui/tabs.tsx","./src/components/ui/toggle-group.tsx","./src/components/ui/toggle.tsx","./src/components/ui/tooltip.tsx","./src/hooks/use-mobile.tsx","./src/lib/utils.ts","./src/pages/analytics.tsx","./src/pages/categories.tsx","./src/pages/dashboard.tsx","./src/pages/forecasting.tsx","./src/pages/login.tsx","./src/pages/orders.tsx","./src/pages/products.tsx","./src/pages/purchaseorders.tsx","./src/pages/settings.tsx","./src/pages/vendors.tsx","./src/routes/forecasting.tsx","./src/types/products.ts"],"version":"5.6.3"} \ No newline at end of file diff --git a/src/lib/utils.ts b/src/lib/utils.ts new file mode 100644 index 0000000..0519ecb --- /dev/null +++ b/src/lib/utils.ts @@ -0,0 +1 @@ + \ No newline at end of file