-- Disable foreign key checks SET session_replication_role = 'replica'; -- Temporary tables for batch metrics processing CREATE TABLE temp_sales_metrics ( pid 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 (pid) ); CREATE TABLE temp_purchase_metrics ( pid BIGINT NOT NULL, avg_lead_time_days INTEGER, last_purchase_date DATE, first_received_date DATE, last_received_date DATE, PRIMARY KEY (pid) ); -- New table for product metrics CREATE TABLE product_metrics ( pid 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 INTEGER, first_sale_date DATE, last_sale_date DATE, -- Stock metrics days_of_inventory INTEGER, weeks_of_inventory INTEGER, reorder_point INTEGER, safety_stock INTEGER, reorder_qty INTEGER DEFAULT 0, overstocked_amt INTEGER 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 INTEGER, last_purchase_date DATE, first_received_date DATE, last_received_date DATE, -- Classification metrics abc_class CHAR(1), stock_status VARCHAR(20), -- Turnover metrics turnover_rate DECIMAL(12,3), -- Lead time metrics current_lead_time INTEGER, target_lead_time INTEGER, 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 (pid), FOREIGN KEY (pid) REFERENCES products(pid) ON DELETE CASCADE ); CREATE INDEX idx_metrics_revenue ON product_metrics(total_revenue); CREATE INDEX idx_metrics_stock_status ON product_metrics(stock_status); CREATE INDEX idx_metrics_lead_time ON product_metrics(lead_time_status); CREATE INDEX idx_metrics_turnover ON product_metrics(turnover_rate); CREATE INDEX idx_metrics_last_calculated ON product_metrics(last_calculated_at); CREATE INDEX idx_metrics_abc ON product_metrics(abc_class); CREATE INDEX idx_metrics_sales ON product_metrics(daily_sales_avg, weekly_sales_avg, monthly_sales_avg); CREATE INDEX idx_metrics_forecast ON product_metrics(forecast_accuracy, forecast_bias); -- New table for time-based aggregates CREATE TABLE product_time_aggregates ( pid BIGINT NOT NULL, year INTEGER NOT NULL, month INTEGER NOT NULL, -- Sales metrics total_quantity_sold INTEGER DEFAULT 0, total_revenue DECIMAL(10,3) DEFAULT 0, total_cost DECIMAL(10,3) DEFAULT 0, order_count INTEGER DEFAULT 0, -- Stock changes stock_received INTEGER DEFAULT 0, stock_ordered INTEGER 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 (pid, year, month), FOREIGN KEY (pid) REFERENCES products(pid) ON DELETE CASCADE ); CREATE INDEX idx_date ON product_time_aggregates(year, month); -- Create vendor_details table CREATE TABLE vendor_details ( vendor VARCHAR(100) PRIMARY KEY, contact_name VARCHAR(100), email VARCHAR(255), phone VARCHAR(50), status VARCHAR(20) DEFAULT 'active', created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ); CREATE INDEX idx_vendor_details_status ON vendor_details(status); -- New table for vendor metrics CREATE TABLE 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 INTEGER DEFAULT 0, total_late_orders INTEGER DEFAULT 0, total_purchase_value DECIMAL(10,3) DEFAULT 0, avg_order_value DECIMAL(10,3), -- Product metrics active_products INTEGER DEFAULT 0, total_products INTEGER 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 ); CREATE INDEX idx_vendor_performance ON vendor_metrics(on_time_delivery_rate); CREATE INDEX idx_vendor_status ON vendor_metrics(status); CREATE INDEX idx_vendor_metrics_last_calculated ON vendor_metrics(last_calculated_at); CREATE INDEX idx_vendor_metrics_orders ON vendor_metrics(total_orders, total_late_orders); -- New table for category metrics CREATE TABLE category_metrics ( category_id BIGINT NOT NULL, last_calculated_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP, -- Product metrics product_count INTEGER DEFAULT 0, active_products INTEGER DEFAULT 0, -- Financial metrics total_value DECIMAL(15,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(cat_id) ON DELETE CASCADE ); CREATE INDEX idx_category_status ON category_metrics(status); CREATE INDEX idx_category_growth ON category_metrics(growth_rate); CREATE INDEX idx_metrics_last_calculated_cat ON category_metrics(last_calculated_at); CREATE INDEX idx_category_metrics_products ON category_metrics(product_count, active_products); -- New table for vendor time-based metrics CREATE TABLE vendor_time_metrics ( vendor VARCHAR(100) NOT NULL, year INTEGER NOT NULL, month INTEGER NOT NULL, -- Order metrics total_orders INTEGER DEFAULT 0, late_orders INTEGER 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 ); CREATE INDEX idx_vendor_date ON vendor_time_metrics(year, month); -- New table for category time-based metrics CREATE TABLE category_time_metrics ( category_id BIGINT NOT NULL, year INTEGER NOT NULL, month INTEGER NOT NULL, -- Product metrics product_count INTEGER DEFAULT 0, active_products INTEGER DEFAULT 0, -- Financial metrics total_value DECIMAL(15,3) DEFAULT 0, total_revenue DECIMAL(15,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(cat_id) ON DELETE CASCADE ); CREATE INDEX idx_category_date ON category_time_metrics(year, month); -- New table for category-based sales metrics CREATE TABLE 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 INTEGER DEFAULT 0, num_products INTEGER 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(cat_id) ON DELETE CASCADE ); CREATE INDEX idx_category_brand ON category_sales_metrics(category_id, brand); CREATE INDEX idx_period ON category_sales_metrics(period_start, period_end); -- New table for brand metrics CREATE TABLE brand_metrics ( brand VARCHAR(100) NOT NULL, last_calculated_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP, -- Product metrics product_count INTEGER DEFAULT 0, active_products INTEGER DEFAULT 0, -- Stock metrics total_stock_units INTEGER DEFAULT 0, total_stock_cost DECIMAL(15,2) DEFAULT 0, total_stock_retail DECIMAL(15,2) DEFAULT 0, -- Sales metrics total_revenue DECIMAL(15,2) DEFAULT 0, avg_margin DECIMAL(5,2) DEFAULT 0, growth_rate DECIMAL(5,2) DEFAULT 0, PRIMARY KEY (brand) ); CREATE INDEX idx_brand_metrics_last_calculated ON brand_metrics(last_calculated_at); CREATE INDEX idx_brand_metrics_revenue ON brand_metrics(total_revenue); CREATE INDEX idx_brand_metrics_growth ON brand_metrics(growth_rate); -- New table for brand time-based metrics CREATE TABLE brand_time_metrics ( brand VARCHAR(100) NOT NULL, year INTEGER NOT NULL, month INTEGER NOT NULL, -- Product metrics product_count INTEGER DEFAULT 0, active_products INTEGER DEFAULT 0, -- Stock metrics total_stock_units INTEGER DEFAULT 0, total_stock_cost DECIMAL(15,2) DEFAULT 0, total_stock_retail DECIMAL(15,2) DEFAULT 0, -- Sales metrics total_revenue DECIMAL(15,2) DEFAULT 0, avg_margin DECIMAL(5,2) DEFAULT 0, growth_rate DECIMAL(5,2) DEFAULT 0, PRIMARY KEY (brand, year, month) ); CREATE INDEX idx_brand_time_date ON brand_time_metrics(year, month); -- New table for sales forecasts CREATE TABLE sales_forecasts ( pid BIGINT NOT NULL, forecast_date DATE NOT NULL, forecast_quantity INTEGER, confidence_level DECIMAL(5,2), created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP, PRIMARY KEY (pid, forecast_date), FOREIGN KEY (pid) REFERENCES products(pid) ON DELETE CASCADE ); CREATE INDEX idx_forecast_date ON sales_forecasts(forecast_date); -- New table for category forecasts CREATE TABLE category_forecasts ( category_id BIGINT NOT NULL, forecast_date DATE NOT NULL, forecast_revenue DECIMAL(15,2), forecast_units INTEGER, confidence_level DECIMAL(5,2), created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP, PRIMARY KEY (category_id, forecast_date), FOREIGN KEY (category_id) REFERENCES categories(cat_id) ON DELETE CASCADE ); CREATE INDEX idx_cat_forecast_date ON category_forecasts(forecast_date); -- Create views for common calculations CREATE OR REPLACE VIEW inventory_health AS WITH stock_levels AS ( SELECT p.pid, p.title, p.SKU, p.stock_quantity, p.preorder_count, pm.daily_sales_avg, pm.weekly_sales_avg, pm.monthly_sales_avg, pm.reorder_point, pm.safety_stock, pm.days_of_inventory, pm.weeks_of_inventory, pm.stock_status, pm.abc_class, pm.turnover_rate, pm.avg_lead_time_days, pm.current_lead_time, pm.target_lead_time, pm.lead_time_status, p.cost_price, p.price, pm.inventory_value, pm.gmroi FROM products p LEFT JOIN product_metrics pm ON p.pid = pm.pid WHERE p.managing_stock = true AND p.visible = true ) SELECT *, CASE WHEN stock_quantity <= safety_stock THEN 'Critical' WHEN stock_quantity <= reorder_point THEN 'Low' WHEN stock_quantity > (reorder_point * 3) THEN 'Excess' ELSE 'Healthy' END as inventory_status, CASE WHEN lead_time_status = 'delayed' AND stock_status = 'low' THEN 'High' WHEN lead_time_status = 'delayed' OR stock_status = 'low' THEN 'Medium' ELSE 'Low' END as risk_level FROM stock_levels; -- Create view for category performance trends CREATE OR REPLACE VIEW category_performance_trends AS WITH monthly_trends AS ( SELECT c.cat_id, c.name as category_name, ctm.year, ctm.month, ctm.product_count, ctm.active_products, ctm.total_value, ctm.total_revenue, ctm.avg_margin, ctm.turnover_rate, LAG(ctm.total_revenue) OVER (PARTITION BY c.cat_id ORDER BY ctm.year, ctm.month) as prev_month_revenue, LAG(ctm.turnover_rate) OVER (PARTITION BY c.cat_id ORDER BY ctm.year, ctm.month) as prev_month_turnover FROM categories c JOIN category_time_metrics ctm ON c.cat_id = ctm.category_id ) SELECT *, CASE WHEN prev_month_revenue IS NULL THEN 0 ELSE ((total_revenue - prev_month_revenue) / prev_month_revenue) * 100 END as revenue_growth_percent, CASE WHEN prev_month_turnover IS NULL THEN 0 ELSE ((turnover_rate - prev_month_turnover) / prev_month_turnover) * 100 END as turnover_growth_percent FROM monthly_trends; SET session_replication_role = 'origin';