-- 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, 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) ); -- Insert default thresholds with ID=1 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); -- 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.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;