Files
inventory/inventory-server/db/config-schema.sql
2025-02-02 20:41:23 -05:00

222 lines
8.9 KiB
SQL

-- Configuration tables schema
-- Stock threshold configurations
CREATE TABLE IF NOT EXISTS stock_thresholds (
id INT NOT NULL,
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,
low_stock_threshold INT NOT NULL DEFAULT 5,
min_reorder_quantity INT NOT NULL DEFAULT 1,
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(cat_id) ON DELETE CASCADE,
UNIQUE KEY unique_category_vendor (category_id, vendor),
INDEX idx_st_metrics (category_id, vendor)
);
-- Lead time threshold configurations
CREATE TABLE IF NOT EXISTS lead_time_thresholds (
id INT NOT NULL,
category_id BIGINT, -- NULL means default/global threshold
vendor VARCHAR(100), -- NULL means applies to all vendors
target_days INT NOT NULL DEFAULT 14,
warning_days INT NOT NULL DEFAULT 21,
critical_days INT NOT NULL DEFAULT 30,
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(cat_id) ON DELETE CASCADE,
UNIQUE KEY unique_category_vendor (category_id, vendor)
);
-- Sales velocity window configurations
CREATE TABLE IF NOT EXISTS sales_velocity_config (
id INT NOT NULL,
category_id BIGINT, -- NULL means default/global threshold
vendor VARCHAR(100), -- NULL means applies to all vendors
daily_window_days INT NOT NULL DEFAULT 30,
weekly_window_days INT NOT NULL DEFAULT 7,
monthly_window_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(cat_id) ON DELETE CASCADE,
UNIQUE KEY unique_category_vendor (category_id, vendor),
INDEX idx_sv_metrics (category_id, vendor)
);
-- ABC Classification configurations
CREATE TABLE IF NOT EXISTS abc_classification_config (
id INT NOT NULL PRIMARY KEY,
a_threshold DECIMAL(5,2) NOT NULL DEFAULT 20.0,
b_threshold DECIMAL(5,2) NOT NULL DEFAULT 50.0,
classification_period_days INT NOT NULL DEFAULT 90,
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP
);
-- Safety stock configurations
CREATE TABLE IF NOT EXISTS safety_stock_config (
id INT NOT NULL,
category_id BIGINT, -- NULL means default/global threshold
vendor VARCHAR(100), -- NULL means applies to all vendors
coverage_days INT NOT NULL DEFAULT 14,
service_level DECIMAL(5,2) NOT NULL DEFAULT 95.0,
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(cat_id) ON DELETE CASCADE,
UNIQUE KEY unique_category_vendor (category_id, vendor),
INDEX idx_ss_metrics (category_id, vendor)
);
-- Turnover rate configurations
CREATE TABLE IF NOT EXISTS turnover_config (
id INT NOT NULL,
category_id BIGINT, -- NULL means default/global threshold
vendor VARCHAR(100), -- NULL means applies to all vendors
calculation_period_days INT NOT NULL DEFAULT 30,
target_rate DECIMAL(10,2) NOT NULL DEFAULT 1.0,
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(cat_id) ON DELETE CASCADE,
UNIQUE KEY unique_category_vendor (category_id, vendor)
);
-- Create table for sales seasonality factors
CREATE TABLE IF NOT EXISTS sales_seasonality (
month INT NOT NULL,
seasonality_factor DECIMAL(5,3) DEFAULT 0,
last_updated TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
PRIMARY KEY (month),
CHECK (month BETWEEN 1 AND 12),
CHECK (seasonality_factor BETWEEN -1.0 AND 1.0)
);
-- Insert default global thresholds if not exists
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);
INSERT INTO lead_time_thresholds (id, category_id, vendor, target_days, warning_days, critical_days)
VALUES (1, NULL, NULL, 14, 21, 30)
ON DUPLICATE KEY UPDATE
target_days = VALUES(target_days),
warning_days = VALUES(warning_days),
critical_days = VALUES(critical_days);
INSERT INTO sales_velocity_config (id, category_id, vendor, daily_window_days, weekly_window_days, monthly_window_days)
VALUES (1, NULL, NULL, 30, 7, 90)
ON DUPLICATE KEY UPDATE
daily_window_days = VALUES(daily_window_days),
weekly_window_days = VALUES(weekly_window_days),
monthly_window_days = VALUES(monthly_window_days);
INSERT INTO abc_classification_config (id, a_threshold, b_threshold, classification_period_days)
VALUES (1, 20.0, 50.0, 90)
ON DUPLICATE KEY UPDATE
a_threshold = VALUES(a_threshold),
b_threshold = VALUES(b_threshold),
classification_period_days = VALUES(classification_period_days);
INSERT INTO safety_stock_config (id, category_id, vendor, coverage_days, service_level)
VALUES (1, NULL, NULL, 14, 95.0)
ON DUPLICATE KEY UPDATE
coverage_days = VALUES(coverage_days),
service_level = VALUES(service_level);
INSERT INTO turnover_config (id, category_id, vendor, calculation_period_days, target_rate)
VALUES (1, NULL, NULL, 30, 1.0)
ON DUPLICATE KEY UPDATE
calculation_period_days = VALUES(calculation_period_days),
target_rate = VALUES(target_rate);
-- Insert default seasonality factors (neutral)
INSERT INTO sales_seasonality (month, seasonality_factor)
VALUES
(1, 0), (2, 0), (3, 0), (4, 0), (5, 0), (6, 0),
(7, 0), (8, 0), (9, 0), (10, 0), (11, 0), (12, 0)
ON DUPLICATE KEY UPDATE last_updated = CURRENT_TIMESTAMP;
-- View to show thresholds with category names
CREATE OR REPLACE VIEW stock_thresholds_view AS
SELECT
st.*,
c.name as category_name,
CASE
WHEN st.category_id IS NULL AND st.vendor IS NULL THEN 'Global Default'
WHEN st.category_id IS NULL THEN CONCAT('Vendor: ', st.vendor)
WHEN st.vendor IS NULL THEN CONCAT('Category: ', c.name)
ELSE CONCAT('Category: ', c.name, ' / Vendor: ', st.vendor)
END as threshold_scope
FROM
stock_thresholds st
LEFT JOIN
categories c ON st.category_id = c.cat_id
ORDER BY
CASE
WHEN st.category_id IS NULL AND st.vendor IS NULL THEN 1
WHEN st.category_id IS NULL THEN 2
WHEN st.vendor IS NULL THEN 3
ELSE 4
END,
c.name,
st.vendor;
-- Update calculate_history table to track all record types
ALTER TABLE calculate_history
ADD COLUMN total_orders INT DEFAULT 0 AFTER total_products,
ADD COLUMN total_purchase_orders INT DEFAULT 0 AFTER total_orders,
CHANGE COLUMN products_processed processed_products INT DEFAULT 0,
ADD COLUMN processed_orders INT DEFAULT 0 AFTER processed_products,
ADD COLUMN processed_purchase_orders INT DEFAULT 0 AFTER processed_orders;
CREATE TABLE IF NOT EXISTS calculate_history (
id BIGINT AUTO_INCREMENT PRIMARY KEY,
start_time TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
end_time TIMESTAMP NULL,
duration_seconds INT,
duration_minutes DECIMAL(10,2) GENERATED ALWAYS AS (duration_seconds / 60.0) STORED,
total_products INT DEFAULT 0,
total_orders INT DEFAULT 0,
total_purchase_orders INT DEFAULT 0,
processed_products INT DEFAULT 0,
processed_orders INT DEFAULT 0,
processed_purchase_orders INT DEFAULT 0,
status ENUM('running', 'completed', 'failed', 'cancelled') DEFAULT 'running',
error_message TEXT,
additional_info JSON,
INDEX idx_status_time (status, start_time)
);
CREATE TABLE IF NOT EXISTS sync_status (
table_name VARCHAR(50) PRIMARY KEY,
last_sync_timestamp TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
last_sync_id BIGINT,
INDEX idx_last_sync (last_sync_timestamp)
);
CREATE TABLE IF NOT EXISTS import_history (
id BIGINT AUTO_INCREMENT PRIMARY KEY,
table_name VARCHAR(50) NOT NULL,
start_time TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
end_time TIMESTAMP NULL,
duration_seconds INT,
duration_minutes DECIMAL(10,2) GENERATED ALWAYS AS (duration_seconds / 60.0) STORED,
records_added INT DEFAULT 0,
records_updated INT DEFAULT 0,
is_incremental BOOLEAN DEFAULT FALSE,
status ENUM('running', 'completed', 'failed', 'cancelled') DEFAULT 'running',
error_message TEXT,
additional_info JSON,
INDEX idx_table_time (table_name, start_time),
INDEX idx_status (status)
);