Files
inventory/inventory-server/db/config-schema.sql

225 lines
8.6 KiB
SQL

-- Configuration tables schema
-- Stock threshold configurations
CREATE TABLE stock_thresholds (
id INTEGER NOT NULL,
category_id BIGINT, -- NULL means default/global threshold
vendor VARCHAR(100), -- NULL means applies to all vendors
critical_days INTEGER NOT NULL DEFAULT 7,
reorder_days INTEGER NOT NULL DEFAULT 14,
overstock_days INTEGER NOT NULL DEFAULT 90,
low_stock_threshold INTEGER NOT NULL DEFAULT 5,
min_reorder_quantity INTEGER NOT NULL DEFAULT 1,
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
PRIMARY KEY (id),
FOREIGN KEY (category_id) REFERENCES categories(cat_id) ON DELETE CASCADE,
UNIQUE (category_id, vendor)
);
CREATE INDEX idx_st_metrics ON stock_thresholds(category_id, vendor);
-- Lead time threshold configurations
CREATE TABLE lead_time_thresholds (
id INTEGER NOT NULL,
category_id BIGINT, -- NULL means default/global threshold
vendor VARCHAR(100), -- NULL means applies to all vendors
target_days INTEGER NOT NULL DEFAULT 14,
warning_days INTEGER NOT NULL DEFAULT 21,
critical_days INTEGER NOT NULL DEFAULT 30,
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
PRIMARY KEY (id),
FOREIGN KEY (category_id) REFERENCES categories(cat_id) ON DELETE CASCADE,
UNIQUE (category_id, vendor)
);
-- Sales velocity window configurations
CREATE TABLE sales_velocity_config (
id INTEGER NOT NULL,
category_id BIGINT, -- NULL means default/global threshold
vendor VARCHAR(100), -- NULL means applies to all vendors
daily_window_days INTEGER NOT NULL DEFAULT 30,
weekly_window_days INTEGER NOT NULL DEFAULT 7,
monthly_window_days INTEGER NOT NULL DEFAULT 90,
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
PRIMARY KEY (id),
FOREIGN KEY (category_id) REFERENCES categories(cat_id) ON DELETE CASCADE,
UNIQUE (category_id, vendor)
);
CREATE INDEX idx_sv_metrics ON sales_velocity_config(category_id, vendor);
-- ABC Classification configurations
CREATE TABLE abc_classification_config (
id INTEGER 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 INTEGER NOT NULL DEFAULT 90,
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP
);
-- Safety stock configurations
CREATE TABLE safety_stock_config (
id INTEGER NOT NULL,
category_id BIGINT, -- NULL means default/global threshold
vendor VARCHAR(100), -- NULL means applies to all vendors
coverage_days INTEGER 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,
PRIMARY KEY (id),
FOREIGN KEY (category_id) REFERENCES categories(cat_id) ON DELETE CASCADE,
UNIQUE (category_id, vendor)
);
CREATE INDEX idx_ss_metrics ON safety_stock_config(category_id, vendor);
-- Turnover rate configurations
CREATE TABLE turnover_config (
id INTEGER NOT NULL,
category_id BIGINT, -- NULL means default/global threshold
vendor VARCHAR(100), -- NULL means applies to all vendors
calculation_period_days INTEGER 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,
PRIMARY KEY (id),
FOREIGN KEY (category_id) REFERENCES categories(cat_id) ON DELETE CASCADE,
UNIQUE (category_id, vendor)
);
-- Create table for sales seasonality factors
CREATE TABLE sales_seasonality (
month INTEGER NOT NULL,
seasonality_factor DECIMAL(5,3) DEFAULT 0,
last_updated TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
PRIMARY KEY (month),
CONSTRAINT month_range CHECK (month BETWEEN 1 AND 12),
CONSTRAINT seasonality_range CHECK (seasonality_factor BETWEEN -1.0 AND 1.0)
);
-- Insert default global thresholds
INSERT INTO stock_thresholds (id, category_id, vendor, critical_days, reorder_days, overstock_days)
VALUES (1, NULL, NULL, 7, 14, 90)
ON CONFLICT (id) DO UPDATE SET
critical_days = EXCLUDED.critical_days,
reorder_days = EXCLUDED.reorder_days,
overstock_days = EXCLUDED.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 CONFLICT (id) DO UPDATE SET
target_days = EXCLUDED.target_days,
warning_days = EXCLUDED.warning_days,
critical_days = EXCLUDED.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 CONFLICT (id) DO UPDATE SET
daily_window_days = EXCLUDED.daily_window_days,
weekly_window_days = EXCLUDED.weekly_window_days,
monthly_window_days = EXCLUDED.monthly_window_days;
INSERT INTO abc_classification_config (id, a_threshold, b_threshold, classification_period_days)
VALUES (1, 20.0, 50.0, 90)
ON CONFLICT (id) DO UPDATE SET
a_threshold = EXCLUDED.a_threshold,
b_threshold = EXCLUDED.b_threshold,
classification_period_days = EXCLUDED.classification_period_days;
INSERT INTO safety_stock_config (id, category_id, vendor, coverage_days, service_level)
VALUES (1, NULL, NULL, 14, 95.0)
ON CONFLICT (id) DO UPDATE SET
coverage_days = EXCLUDED.coverage_days,
service_level = EXCLUDED.service_level;
INSERT INTO turnover_config (id, category_id, vendor, calculation_period_days, target_rate)
VALUES (1, NULL, NULL, 30, 1.0)
ON CONFLICT (id) DO UPDATE SET
calculation_period_days = EXCLUDED.calculation_period_days,
target_rate = EXCLUDED.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 CONFLICT (month) DO UPDATE SET
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 'Vendor: ' || st.vendor
WHEN st.vendor IS NULL THEN 'Category: ' || c.name
ELSE '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;
-- History and status tables
CREATE TABLE IF NOT EXISTS calculate_history (
id BIGSERIAL PRIMARY KEY,
start_time TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
end_time TIMESTAMP NULL,
duration_seconds INTEGER,
duration_minutes DECIMAL(10,2) GENERATED ALWAYS AS (duration_seconds::decimal / 60.0) STORED,
total_products INTEGER DEFAULT 0,
total_orders INTEGER DEFAULT 0,
total_purchase_orders INTEGER DEFAULT 0,
processed_products INTEGER DEFAULT 0,
processed_orders INTEGER DEFAULT 0,
processed_purchase_orders INTEGER DEFAULT 0,
status calculation_status DEFAULT 'running',
error_message TEXT,
additional_info JSONB
);
CREATE TABLE IF NOT EXISTS calculate_status (
module_name module_name PRIMARY KEY,
last_calculation_timestamp TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP
);
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
);
CREATE TABLE IF NOT EXISTS import_history (
id BIGSERIAL PRIMARY KEY,
table_name VARCHAR(50) NOT NULL,
start_time TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
end_time TIMESTAMP NULL,
duration_seconds INTEGER,
duration_minutes DECIMAL(10,2) GENERATED ALWAYS AS (duration_seconds::decimal / 60.0) STORED,
records_added INTEGER DEFAULT 0,
records_updated INTEGER DEFAULT 0,
is_incremental BOOLEAN DEFAULT FALSE,
status calculation_status DEFAULT 'running',
error_message TEXT,
additional_info JSONB
);
-- Create all indexes after tables are fully created
CREATE INDEX IF NOT EXISTS idx_last_calc ON calculate_status(last_calculation_timestamp);
CREATE INDEX IF NOT EXISTS idx_last_sync ON sync_status(last_sync_timestamp);
CREATE INDEX IF NOT EXISTS idx_table_time ON import_history(table_name, start_time);