Improve and debug calculate metrics script
This commit is contained in:
@@ -30,6 +30,10 @@ CREATE TABLE IF NOT EXISTS product_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,
|
||||
@@ -38,6 +42,7 @@ CREATE TABLE IF NOT EXISTS product_metrics (
|
||||
-- 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,
|
||||
@@ -46,7 +51,8 @@ CREATE TABLE IF NOT EXISTS product_metrics (
|
||||
abc_class CHAR(1),
|
||||
stock_status VARCHAR(20),
|
||||
PRIMARY KEY (product_id),
|
||||
FOREIGN KEY (product_id) REFERENCES products(product_id) ON DELETE CASCADE
|
||||
FOREIGN KEY (product_id) REFERENCES products(product_id) ON DELETE CASCADE,
|
||||
INDEX idx_metrics_revenue (total_revenue)
|
||||
);
|
||||
|
||||
-- New table for time-based aggregates
|
||||
@@ -82,11 +88,103 @@ CREATE TABLE IF NOT EXISTS vendor_metrics (
|
||||
PRIMARY KEY (vendor)
|
||||
);
|
||||
|
||||
-- New table for stock threshold configurations
|
||||
CREATE TABLE IF NOT EXISTS stock_thresholds (
|
||||
id INT NOT NULL, -- Changed from AUTO_INCREMENT to explicitly set ID
|
||||
category_id BIGINT, -- NULL means default/global threshold
|
||||
vendor VARCHAR(100), -- NULL means applies to all vendors
|
||||
critical_days INT NOT NULL DEFAULT 7,
|
||||
reorder_days INT NOT NULL DEFAULT 14,
|
||||
overstock_days INT NOT NULL DEFAULT 90,
|
||||
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
||||
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
|
||||
PRIMARY KEY (id),
|
||||
FOREIGN KEY (category_id) REFERENCES categories(id) ON DELETE CASCADE,
|
||||
UNIQUE KEY unique_category_vendor (category_id, vendor),
|
||||
INDEX idx_thresholds_category_vendor (category_id, vendor)
|
||||
);
|
||||
|
||||
-- Insert default thresholds with ID=1
|
||||
INSERT INTO stock_thresholds (id, category_id, vendor, critical_days, reorder_days, overstock_days)
|
||||
VALUES (1, NULL, NULL, 7, 14, 90)
|
||||
ON DUPLICATE KEY UPDATE
|
||||
critical_days = VALUES(critical_days),
|
||||
reorder_days = VALUES(reorder_days),
|
||||
overstock_days = VALUES(overstock_days);
|
||||
|
||||
-- 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,
|
||||
@@ -97,15 +195,18 @@ SELECT
|
||||
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'
|
||||
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;
|
||||
|
||||
|
||||
17
inventory-server/db/migrations/add_metrics_indexes.sql
Normal file
17
inventory-server/db/migrations/add_metrics_indexes.sql
Normal file
@@ -0,0 +1,17 @@
|
||||
-- Indexes for orders table
|
||||
CREATE INDEX IF NOT EXISTS idx_orders_product_date ON orders(product_id, date);
|
||||
CREATE INDEX IF NOT EXISTS idx_orders_date ON orders(date);
|
||||
|
||||
-- Indexes for purchase_orders table
|
||||
CREATE INDEX IF NOT EXISTS idx_po_product_date ON purchase_orders(product_id, date);
|
||||
CREATE INDEX IF NOT EXISTS idx_po_product_status ON purchase_orders(product_id, status);
|
||||
CREATE INDEX IF NOT EXISTS idx_po_vendor ON purchase_orders(vendor);
|
||||
|
||||
-- Indexes for product_metrics table
|
||||
CREATE INDEX IF NOT EXISTS idx_metrics_revenue ON product_metrics(total_revenue);
|
||||
|
||||
-- Indexes for stock_thresholds table
|
||||
CREATE INDEX IF NOT EXISTS idx_thresholds_category_vendor ON stock_thresholds(category_id, vendor);
|
||||
|
||||
-- Indexes for product_categories table
|
||||
CREATE INDEX IF NOT EXISTS idx_product_categories_both ON product_categories(product_id, category_id);
|
||||
@@ -50,7 +50,8 @@ CREATE TABLE product_categories (
|
||||
FOREIGN KEY (product_id) REFERENCES products(product_id) ON DELETE CASCADE,
|
||||
FOREIGN KEY (category_id) REFERENCES categories(id) ON DELETE CASCADE,
|
||||
INDEX idx_category (category_id),
|
||||
INDEX idx_product (product_id)
|
||||
INDEX idx_product (product_id),
|
||||
INDEX idx_product_categories_both (product_id, category_id)
|
||||
) ENGINE=InnoDB;
|
||||
|
||||
-- Create orders table with its indexes
|
||||
@@ -80,6 +81,7 @@ CREATE TABLE orders (
|
||||
INDEX idx_date (date),
|
||||
INDEX idx_status (status),
|
||||
INDEX idx_orders_metrics (product_id, date, canceled, quantity, price),
|
||||
INDEX idx_orders_product_date (product_id, date),
|
||||
UNIQUE KEY unique_order_product (order_number, product_id)
|
||||
) ENGINE=InnoDB;
|
||||
|
||||
@@ -104,6 +106,8 @@ CREATE TABLE purchase_orders (
|
||||
INDEX idx_vendor (vendor),
|
||||
INDEX idx_status (status),
|
||||
INDEX idx_purchase_orders_metrics (product_id, date, status, ordered, received),
|
||||
INDEX idx_po_product_date (product_id, date),
|
||||
INDEX idx_po_product_status (product_id, status),
|
||||
UNIQUE KEY unique_po_product (po_id, product_id)
|
||||
) ENGINE=InnoDB;
|
||||
|
||||
|
||||
Reference in New Issue
Block a user