Add more tables to db and processing to import script, add error logging to import, add test data snapshots (untested)
This commit is contained in:
@@ -30,6 +30,67 @@ CREATE TABLE IF NOT EXISTS products (
|
||||
INDEX idx_brand (brand)
|
||||
);
|
||||
|
||||
-- New table for product metrics
|
||||
CREATE TABLE IF NOT EXISTS product_metrics (
|
||||
product_id BIGINT NOT NULL,
|
||||
last_calculated_at TIMESTAMP NOT NULL,
|
||||
-- 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),
|
||||
FOREIGN KEY (vendor) REFERENCES products(vendor) ON DELETE CASCADE
|
||||
);
|
||||
|
||||
CREATE TABLE IF NOT EXISTS orders (
|
||||
id BIGINT AUTO_INCREMENT PRIMARY KEY,
|
||||
order_number VARCHAR(50) NOT NULL,
|
||||
@@ -97,4 +158,48 @@ CREATE TABLE IF NOT EXISTS product_categories (
|
||||
FOREIGN KEY (category_id) REFERENCES categories(id) ON DELETE CASCADE,
|
||||
INDEX idx_category (category_id),
|
||||
INDEX idx_product (product_id)
|
||||
);
|
||||
);
|
||||
|
||||
-- Create views for common calculations
|
||||
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 inventory health
|
||||
CREATE OR REPLACE VIEW inventory_health AS
|
||||
SELECT
|
||||
p.product_id,
|
||||
p.SKU,
|
||||
p.title,
|
||||
p.stock_quantity,
|
||||
pm.daily_sales_avg,
|
||||
pm.days_of_inventory,
|
||||
pm.reorder_point,
|
||||
pm.safety_stock,
|
||||
CASE
|
||||
WHEN p.stock_quantity <= pm.safety_stock THEN 'Critical'
|
||||
WHEN p.stock_quantity <= pm.reorder_point THEN 'Reorder'
|
||||
WHEN p.stock_quantity > (pm.daily_sales_avg * 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;
|
||||
Reference in New Issue
Block a user