Add backend changes and update scripts
This commit is contained in:
@@ -94,19 +94,86 @@ CREATE TABLE IF NOT EXISTS product_time_aggregates (
|
||||
INDEX idx_date (year, month)
|
||||
);
|
||||
|
||||
-- New table for vendor performance
|
||||
-- New table for vendor metrics
|
||||
CREATE TABLE IF NOT EXISTS vendor_metrics (
|
||||
vendor VARCHAR(100) NOT NULL,
|
||||
last_calculated_at TIMESTAMP 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,
|
||||
total_late_orders INT,
|
||||
total_purchase_value DECIMAL(10,3),
|
||||
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),
|
||||
INDEX idx_vendor_performance (on_time_delivery_rate)
|
||||
FOREIGN KEY (vendor) REFERENCES vendor_details(vendor) ON DELETE CASCADE,
|
||||
INDEX idx_vendor_performance (on_time_delivery_rate),
|
||||
INDEX idx_vendor_status (status)
|
||||
);
|
||||
|
||||
-- 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(10,3) DEFAULT 0,
|
||||
avg_margin DECIMAL(5,2),
|
||||
turnover_rate DECIMAL(10,3),
|
||||
growth_rate DECIMAL(5,2),
|
||||
-- Status
|
||||
status VARCHAR(20) DEFAULT 'active',
|
||||
PRIMARY KEY (category_id),
|
||||
FOREIGN KEY (category_id) REFERENCES categories(id) ON DELETE CASCADE,
|
||||
INDEX idx_category_status (status),
|
||||
INDEX idx_category_growth (growth_rate)
|
||||
);
|
||||
|
||||
-- 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(10,3) DEFAULT 0,
|
||||
total_revenue DECIMAL(10,3) DEFAULT 0,
|
||||
avg_margin DECIMAL(5,2),
|
||||
turnover_rate DECIMAL(10,3),
|
||||
PRIMARY KEY (category_id, year, month),
|
||||
FOREIGN KEY (category_id) REFERENCES categories(id) ON DELETE CASCADE,
|
||||
INDEX idx_category_date (year, month)
|
||||
);
|
||||
|
||||
-- New table for category-based sales metrics
|
||||
@@ -265,4 +332,57 @@ JOIN
|
||||
LEFT JOIN
|
||||
orders o ON p.product_id = o.product_id AND o.canceled = false
|
||||
GROUP BY
|
||||
c.id, c.name, p.brand;
|
||||
c.id, c.name, p.brand;
|
||||
|
||||
-- Create view for vendor performance trends
|
||||
CREATE OR REPLACE VIEW vendor_performance_trends AS
|
||||
SELECT
|
||||
v.vendor,
|
||||
v.contact_name,
|
||||
v.status,
|
||||
vm.avg_lead_time_days,
|
||||
vm.on_time_delivery_rate,
|
||||
vm.order_fill_rate,
|
||||
vm.total_orders,
|
||||
vm.total_late_orders,
|
||||
vm.total_purchase_value,
|
||||
vm.avg_order_value,
|
||||
vm.active_products,
|
||||
vm.total_products,
|
||||
vm.total_revenue,
|
||||
vm.avg_margin_percent,
|
||||
CASE
|
||||
WHEN vm.order_fill_rate >= 95 THEN 'Excellent'
|
||||
WHEN vm.order_fill_rate >= 85 THEN 'Good'
|
||||
WHEN vm.order_fill_rate >= 75 THEN 'Fair'
|
||||
ELSE 'Poor'
|
||||
END as performance_rating
|
||||
FROM
|
||||
vendor_details v
|
||||
LEFT JOIN
|
||||
vendor_metrics vm ON v.vendor = vm.vendor;
|
||||
|
||||
-- Create view for category performance trends
|
||||
CREATE OR REPLACE VIEW category_performance_trends AS
|
||||
SELECT
|
||||
c.id as category_id,
|
||||
c.name,
|
||||
c.description,
|
||||
c.parent_category,
|
||||
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
|
||||
category_metrics cm ON c.id = cm.category_id;
|
||||
Reference in New Issue
Block a user