-- Disable foreign key checks SET FOREIGN_KEY_CHECKS = 0; -- Temporary tables for batch metrics processing CREATE TABLE IF NOT EXISTS temp_sales_metrics ( product_id BIGINT NOT NULL, daily_sales_avg DECIMAL(10,3), weekly_sales_avg DECIMAL(10,3), monthly_sales_avg DECIMAL(10,3), total_revenue DECIMAL(10,3), avg_margin_percent DECIMAL(10,3), first_sale_date DATE, last_sale_date DATE, PRIMARY KEY (product_id) ); CREATE TABLE IF NOT EXISTS temp_purchase_metrics ( product_id BIGINT NOT NULL, avg_lead_time_days INT, last_purchase_date DATE, first_received_date DATE, last_received_date DATE, PRIMARY KEY (product_id) ); -- New table for product metrics CREATE TABLE IF NOT EXISTS product_metrics ( product_id BIGINT NOT NULL, last_calculated_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP, -- Sales velocity metrics daily_sales_avg DECIMAL(10,3), weekly_sales_avg DECIMAL(10,3), monthly_sales_avg DECIMAL(10,3), avg_quantity_per_order DECIMAL(10,3), number_of_orders INT, first_sale_date DATE, last_sale_date DATE, -- Stock metrics days_of_inventory INT, weeks_of_inventory INT, reorder_point INT, safety_stock INT, reorder_qty INT DEFAULT 0, overstocked_amt INT DEFAULT 0, -- Financial metrics avg_margin_percent DECIMAL(10,3), total_revenue DECIMAL(10,3), inventory_value DECIMAL(10,3), cost_of_goods_sold DECIMAL(10,3), gross_profit DECIMAL(10,3), gmroi DECIMAL(10,3), -- Purchase metrics avg_lead_time_days INT, last_purchase_date DATE, first_received_date DATE, last_received_date DATE, -- Classification abc_class CHAR(1), stock_status VARCHAR(20), -- Turnover metrics turnover_rate DECIMAL(12,3), -- Lead time metrics current_lead_time INT, target_lead_time INT, lead_time_status VARCHAR(20), PRIMARY KEY (product_id), FOREIGN KEY (product_id) REFERENCES products(product_id) ON DELETE CASCADE, INDEX idx_metrics_revenue (total_revenue), INDEX idx_metrics_stock_status (stock_status), INDEX idx_metrics_lead_time (lead_time_status), 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) ); -- New table for time-based aggregates CREATE TABLE IF NOT EXISTS product_time_aggregates ( product_id BIGINT NOT NULL, year INT NOT NULL, month INT NOT NULL, -- Sales metrics total_quantity_sold INT DEFAULT 0, total_revenue DECIMAL(10,3) DEFAULT 0, total_cost DECIMAL(10,3) DEFAULT 0, order_count INT DEFAULT 0, -- Stock changes stock_received INT DEFAULT 0, stock_ordered INT DEFAULT 0, -- Calculated fields avg_price DECIMAL(10,3), profit_margin DECIMAL(10,3), inventory_value DECIMAL(10,3), gmroi DECIMAL(10,3), PRIMARY KEY (product_id, year, month), FOREIGN KEY (product_id) REFERENCES products(product_id) ON DELETE CASCADE, INDEX idx_date (year, month) ); -- New table for vendor metrics CREATE TABLE IF NOT EXISTS vendor_metrics ( vendor VARCHAR(100) NOT NULL, last_calculated_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP, -- Performance metrics avg_lead_time_days DECIMAL(10,3), on_time_delivery_rate DECIMAL(5,2), order_fill_rate DECIMAL(5,2), total_orders INT DEFAULT 0, total_late_orders INT DEFAULT 0, total_purchase_value DECIMAL(10,3) DEFAULT 0, avg_order_value DECIMAL(10,3), -- Product metrics active_products INT DEFAULT 0, total_products INT DEFAULT 0, -- Financial metrics total_revenue DECIMAL(10,3) DEFAULT 0, avg_margin_percent DECIMAL(5,2), -- Status status VARCHAR(20) DEFAULT 'active', PRIMARY KEY (vendor), FOREIGN KEY (vendor) REFERENCES vendor_details(vendor) ON DELETE CASCADE, INDEX idx_vendor_performance (on_time_delivery_rate), INDEX idx_vendor_status (status), INDEX idx_metrics_last_calculated (last_calculated_at), INDEX idx_vendor_metrics_orders (total_orders, total_late_orders) ); -- New table for category metrics CREATE TABLE IF NOT EXISTS category_metrics ( category_id BIGINT NOT NULL, last_calculated_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP, -- Product metrics product_count INT DEFAULT 0, active_products INT DEFAULT 0, -- Financial metrics total_value DECIMAL(10,3) DEFAULT 0, avg_margin DECIMAL(5,2), turnover_rate DECIMAL(12,3), growth_rate DECIMAL(5,2), -- Status status VARCHAR(20) DEFAULT 'active', PRIMARY KEY (category_id), FOREIGN KEY (category_id) REFERENCES categories(id) ON DELETE CASCADE, INDEX idx_category_status (status), INDEX idx_category_growth (growth_rate), INDEX idx_metrics_last_calculated (last_calculated_at), INDEX idx_category_metrics_products (product_count, active_products) ); -- New table for vendor time-based metrics CREATE TABLE IF NOT EXISTS vendor_time_metrics ( vendor VARCHAR(100) NOT NULL, year INT NOT NULL, month INT NOT NULL, -- Order metrics total_orders INT DEFAULT 0, late_orders INT DEFAULT 0, avg_lead_time_days DECIMAL(10,3), -- Financial metrics total_purchase_value DECIMAL(10,3) DEFAULT 0, total_revenue DECIMAL(10,3) DEFAULT 0, avg_margin_percent DECIMAL(5,2), PRIMARY KEY (vendor, year, month), FOREIGN KEY (vendor) REFERENCES vendor_details(vendor) ON DELETE CASCADE, INDEX idx_vendor_date (year, month) ); -- New table for category time-based metrics CREATE TABLE IF NOT EXISTS category_time_metrics ( category_id BIGINT NOT NULL, year INT NOT NULL, month INT NOT NULL, -- Product metrics product_count INT DEFAULT 0, active_products INT DEFAULT 0, -- Financial metrics total_value DECIMAL(10,3) DEFAULT 0, total_revenue DECIMAL(10,3) DEFAULT 0, avg_margin DECIMAL(5,2), turnover_rate DECIMAL(12,3), PRIMARY KEY (category_id, year, month), FOREIGN KEY (category_id) REFERENCES categories(id) ON DELETE CASCADE, INDEX idx_category_date (year, month) ); -- New table for category-based sales metrics CREATE TABLE IF NOT EXISTS category_sales_metrics ( category_id BIGINT NOT NULL, brand VARCHAR(100) NOT NULL, period_start DATE NOT NULL, period_end DATE NOT NULL, avg_daily_sales DECIMAL(10,3) DEFAULT 0, total_sold INT DEFAULT 0, num_products INT DEFAULT 0, avg_price DECIMAL(10,3) DEFAULT 0, last_calculated_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP, PRIMARY KEY (category_id, brand, period_start, period_end), FOREIGN KEY (category_id) REFERENCES categories(id) ON DELETE CASCADE, INDEX idx_category_brand (category_id, brand), INDEX idx_period (period_start, period_end) ); -- Re-enable foreign key checks SET FOREIGN_KEY_CHECKS = 1; -- Create view for inventory health (after all tables are created) CREATE OR REPLACE VIEW inventory_health AS WITH product_thresholds AS ( SELECT p.product_id, COALESCE( -- Try category+vendor specific (SELECT critical_days FROM stock_thresholds st JOIN product_categories pc ON st.category_id = pc.category_id WHERE pc.product_id = p.product_id AND st.vendor = p.vendor LIMIT 1), -- Try category specific (SELECT critical_days FROM stock_thresholds st JOIN product_categories pc ON st.category_id = pc.category_id WHERE pc.product_id = p.product_id AND st.vendor IS NULL LIMIT 1), -- Try vendor specific (SELECT critical_days FROM stock_thresholds st WHERE st.category_id IS NULL AND st.vendor = p.vendor LIMIT 1), -- Fall back to default (SELECT critical_days FROM stock_thresholds st WHERE st.category_id IS NULL AND st.vendor IS NULL LIMIT 1), 7 ) as critical_days, COALESCE( -- Try category+vendor specific (SELECT reorder_days FROM stock_thresholds st JOIN product_categories pc ON st.category_id = pc.category_id WHERE pc.product_id = p.product_id AND st.vendor = p.vendor LIMIT 1), -- Try category specific (SELECT reorder_days FROM stock_thresholds st JOIN product_categories pc ON st.category_id = pc.category_id WHERE pc.product_id = p.product_id AND st.vendor IS NULL LIMIT 1), -- Try vendor specific (SELECT reorder_days FROM stock_thresholds st WHERE st.category_id IS NULL AND st.vendor = p.vendor LIMIT 1), -- Fall back to default (SELECT reorder_days FROM stock_thresholds st WHERE st.category_id IS NULL AND st.vendor IS NULL LIMIT 1), 14 ) as reorder_days, COALESCE( -- Try category+vendor specific (SELECT overstock_days FROM stock_thresholds st JOIN product_categories pc ON st.category_id = pc.category_id WHERE pc.product_id = p.product_id AND st.vendor = p.vendor LIMIT 1), -- Try category specific (SELECT overstock_days FROM stock_thresholds st JOIN product_categories pc ON st.category_id = pc.category_id WHERE pc.product_id = p.product_id AND st.vendor IS NULL LIMIT 1), -- Try vendor specific (SELECT overstock_days FROM stock_thresholds st WHERE st.category_id IS NULL AND st.vendor = p.vendor LIMIT 1), -- Fall back to default (SELECT overstock_days FROM stock_thresholds st WHERE st.category_id IS NULL AND st.vendor IS NULL LIMIT 1), 90 ) as overstock_days FROM products p ) SELECT p.product_id, p.SKU, p.title, p.stock_quantity, COALESCE(pm.daily_sales_avg, 0) as daily_sales_avg, COALESCE(pm.days_of_inventory, 0) as days_of_inventory, COALESCE(pm.reorder_point, 0) as reorder_point, COALESCE(pm.safety_stock, 0) as safety_stock, CASE WHEN pm.daily_sales_avg = 0 THEN 'New' WHEN p.stock_quantity <= CEIL(pm.daily_sales_avg * pt.critical_days) THEN 'Critical' WHEN p.stock_quantity <= CEIL(pm.daily_sales_avg * pt.reorder_days) THEN 'Reorder' WHEN p.stock_quantity > (pm.daily_sales_avg * pt.overstock_days) THEN 'Overstocked' ELSE 'Healthy' END as stock_status FROM products p LEFT JOIN product_metrics pm ON p.product_id = pm.product_id LEFT JOIN product_thresholds pt ON p.product_id = pt.product_id 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 c.id as category_id, c.name, c.description, c.parent_category, c.status, cm.product_count, cm.active_products, cm.total_value, cm.avg_margin, cm.turnover_rate, cm.growth_rate, CASE WHEN cm.growth_rate >= 20 THEN 'High Growth' WHEN cm.growth_rate >= 5 THEN 'Growing' WHEN cm.growth_rate >= -5 THEN 'Stable' ELSE 'Declining' END as performance_rating FROM categories c LEFT JOIN category_metrics cm ON c.id = cm.category_id;