430 lines
15 KiB
SQL
430 lines
15 KiB
SQL
-- Disable foreign key checks
|
|
SET FOREIGN_KEY_CHECKS = 0;
|
|
|
|
-- Temporary tables for batch metrics processing
|
|
CREATE TABLE IF NOT EXISTS 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 IF NOT EXISTS temp_purchase_metrics (
|
|
pid BIGINT NOT NULL,
|
|
avg_lead_time_days INT,
|
|
last_purchase_date DATE,
|
|
first_received_date DATE,
|
|
last_received_date DATE,
|
|
PRIMARY KEY (pid)
|
|
);
|
|
|
|
-- New table for product metrics
|
|
CREATE TABLE IF NOT EXISTS 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 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 metrics
|
|
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),
|
|
-- 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,
|
|
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),
|
|
INDEX idx_metrics_forecast (forecast_accuracy, forecast_bias)
|
|
);
|
|
|
|
-- New table for time-based aggregates
|
|
CREATE TABLE IF NOT EXISTS product_time_aggregates (
|
|
pid 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 (pid, year, month),
|
|
FOREIGN KEY (pid) REFERENCES products(pid) ON DELETE CASCADE,
|
|
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,
|
|
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(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,
|
|
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(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,
|
|
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(cat_id) ON DELETE CASCADE,
|
|
INDEX idx_category_brand (category_id, brand),
|
|
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(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),
|
|
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(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,
|
|
PRIMARY KEY (brand, year, month),
|
|
INDEX idx_brand_date (year, month)
|
|
);
|
|
|
|
-- New table for sales forecasts
|
|
CREATE TABLE IF NOT EXISTS sales_forecasts (
|
|
pid 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 (pid, forecast_date),
|
|
FOREIGN KEY (pid) REFERENCES products(pid) 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(cat_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
|
|
CREATE OR REPLACE VIEW inventory_health AS
|
|
WITH product_thresholds AS (
|
|
SELECT
|
|
p.pid,
|
|
COALESCE(
|
|
-- Try category+vendor specific
|
|
(SELECT critical_days FROM stock_thresholds st
|
|
JOIN product_categories pc ON st.category_id = pc.cat_id
|
|
WHERE pc.pid = p.pid
|
|
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.cat_id
|
|
WHERE pc.pid = p.pid
|
|
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.cat_id
|
|
WHERE pc.pid = p.pid
|
|
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.cat_id
|
|
WHERE pc.pid = p.pid
|
|
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.cat_id
|
|
WHERE pc.pid = p.pid
|
|
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.cat_id
|
|
WHERE pc.pid = p.pid
|
|
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.pid,
|
|
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.pid = pm.pid
|
|
LEFT JOIN
|
|
product_thresholds pt ON p.pid = pt.pid
|
|
WHERE
|
|
p.managing_stock = true;
|
|
|
|
-- Create view for category performance trends
|
|
CREATE OR REPLACE VIEW category_performance_trends AS
|
|
SELECT
|
|
c.cat_id as category_id,
|
|
c.name,
|
|
c.description,
|
|
p.name as parent_name,
|
|
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
|
|
categories p ON c.parent_id = p.cat_id
|
|
LEFT JOIN
|
|
category_metrics cm ON c.cat_id = cm.category_id; |