207 lines
7.1 KiB
SQL
207 lines
7.1 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),
|
|
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,
|
|
-- Financial metrics
|
|
avg_margin_percent DECIMAL(10,3),
|
|
total_revenue DECIMAL(10,3),
|
|
inventory_value 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,
|
|
INDEX idx_metrics_revenue (total_revenue)
|
|
);
|
|
|
|
-- 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
|
|
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; |