Add forecasting page

This commit is contained in:
2025-01-15 22:08:52 -05:00
parent e5f97ab836
commit c8c3d323a4
15 changed files with 893 additions and 94 deletions

View File

@@ -18,6 +18,7 @@ CREATE TABLE IF NOT EXISTS temp_purchase_metrics (
product_id BIGINT NOT NULL,
avg_lead_time_days INT,
last_purchase_date DATE,
first_received_date DATE,
last_received_date DATE,
PRIMARY KEY (product_id)
);
@@ -51,6 +52,7 @@ CREATE TABLE IF NOT EXISTS product_metrics (
-- Purchase metrics
avg_lead_time_days INT,
last_purchase_date DATE,
first_received_date DATE,
last_received_date DATE,
-- Classification
abc_class CHAR(1),
@@ -107,6 +109,23 @@ CREATE TABLE IF NOT EXISTS vendor_metrics (
INDEX idx_vendor_performance (on_time_delivery_rate)
);
-- 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(id) ON DELETE CASCADE,
INDEX idx_category_brand (category_id, brand),
INDEX idx_period (period_start, period_end)
);
-- Re-enable foreign key checks
SET FOREIGN_KEY_CHECKS = 1;
@@ -223,4 +242,27 @@ LEFT JOIN
WHERE
o.canceled = false
GROUP BY
p.product_id, p.SKU, p.title;
p.product_id, p.SKU, p.title;
-- Create view for category sales trends
CREATE OR REPLACE VIEW category_sales_trends AS
SELECT
c.id as category_id,
c.name as category_name,
p.brand,
COUNT(DISTINCT p.product_id) as num_products,
COALESCE(AVG(o.quantity), 0) as avg_daily_sales,
COALESCE(SUM(o.quantity), 0) as total_sold,
COALESCE(AVG(o.price), 0) as avg_price,
MIN(o.date) as first_sale_date,
MAX(o.date) as last_sale_date
FROM
categories c
JOIN
product_categories pc ON c.id = pc.category_id
JOIN
products p ON pc.product_id = p.product_id
LEFT JOIN
orders o ON p.product_id = o.product_id AND o.canceled = false
GROUP BY
c.id, c.name, p.brand;