110 lines
3.3 KiB
SQL
110 lines
3.3 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 (
|
|
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,
|
|
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),
|
|
-- Stock metrics
|
|
days_of_inventory INT,
|
|
weeks_of_inventory INT,
|
|
reorder_point INT,
|
|
safety_stock INT,
|
|
-- Financial metrics
|
|
avg_margin_percent DECIMAL(10,3),
|
|
total_revenue DECIMAL(10,3),
|
|
-- Purchase metrics
|
|
avg_lead_time_days INT,
|
|
last_purchase_date DATE,
|
|
last_received_date DATE,
|
|
-- Classification
|
|
abc_class CHAR(1),
|
|
stock_status VARCHAR(20),
|
|
PRIMARY KEY (product_id),
|
|
FOREIGN KEY (product_id) REFERENCES products(product_id) ON DELETE CASCADE
|
|
);
|
|
|
|
-- 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),
|
|
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 performance
|
|
CREATE TABLE IF NOT EXISTS vendor_metrics (
|
|
vendor VARCHAR(100) NOT NULL,
|
|
last_calculated_at TIMESTAMP NOT NULL,
|
|
avg_lead_time_days DECIMAL(10,3),
|
|
on_time_delivery_rate DECIMAL(5,2),
|
|
order_fill_rate DECIMAL(5,2),
|
|
total_orders INT,
|
|
total_late_orders INT,
|
|
PRIMARY KEY (vendor)
|
|
);
|
|
|
|
-- 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
|
|
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 p.stock_quantity <= COALESCE(pm.safety_stock, 0) THEN 'Critical'
|
|
WHEN p.stock_quantity <= COALESCE(pm.reorder_point, 0) THEN 'Reorder'
|
|
WHEN p.stock_quantity > (COALESCE(pm.daily_sales_avg, 0) * 90) THEN 'Overstocked'
|
|
ELSE 'Healthy'
|
|
END as stock_status
|
|
FROM
|
|
products p
|
|
LEFT JOIN
|
|
product_metrics pm ON p.product_id = pm.product_id
|
|
WHERE
|
|
p.managing_stock = true; |