Add new schemas and scripts for calculate
This commit is contained in:
113
inventory-server/db/config-schema-new.sql
Normal file
113
inventory-server/db/config-schema-new.sql
Normal file
@@ -0,0 +1,113 @@
|
||||
-- Drop tables in reverse order of dependency
|
||||
DROP TABLE IF EXISTS public.settings_product CASCADE;
|
||||
DROP TABLE IF EXISTS public.settings_vendor CASCADE;
|
||||
DROP TABLE IF EXISTS public.settings_global CASCADE;
|
||||
|
||||
-- Table Definition: settings_global
|
||||
CREATE TABLE public.settings_global (
|
||||
setting_key VARCHAR PRIMARY KEY,
|
||||
setting_value VARCHAR NOT NULL,
|
||||
description TEXT,
|
||||
updated_at TIMESTAMPTZ NOT NULL DEFAULT CURRENT_TIMESTAMP
|
||||
);
|
||||
|
||||
-- Table Definition: settings_vendor
|
||||
CREATE TABLE public.settings_vendor (
|
||||
vendor VARCHAR PRIMARY KEY, -- Matches products.vendor
|
||||
default_lead_time_days INT,
|
||||
default_days_of_stock INT,
|
||||
updated_at TIMESTAMPTZ NOT NULL DEFAULT CURRENT_TIMESTAMP
|
||||
);
|
||||
-- Index for faster lookups if needed (PK usually sufficient)
|
||||
-- CREATE INDEX idx_settings_vendor_vendor ON public.settings_vendor(vendor);
|
||||
|
||||
-- Table Definition: settings_product
|
||||
CREATE TABLE public.settings_product (
|
||||
pid INT8 PRIMARY KEY,
|
||||
lead_time_days INT, -- Overrides vendor/global
|
||||
days_of_stock INT, -- Overrides vendor/global
|
||||
safety_stock INT DEFAULT 0, -- Minimum desired stock level
|
||||
forecast_method VARCHAR DEFAULT 'standard', -- e.g., 'standard', 'seasonal'
|
||||
exclude_from_forecast BOOLEAN DEFAULT FALSE,
|
||||
updated_at TIMESTAMPTZ NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
||||
CONSTRAINT fk_settings_product_pid FOREIGN KEY (pid) REFERENCES public.products(pid) ON DELETE CASCADE ON UPDATE CASCADE
|
||||
);
|
||||
|
||||
|
||||
-- Description: Inserts or updates standard default global settings.
|
||||
-- Safe to rerun; will update existing keys with these default values.
|
||||
-- Dependencies: `settings_global` table must exist.
|
||||
-- Frequency: Run once initially, or rerun if you want to reset global defaults.
|
||||
|
||||
INSERT INTO public.settings_global (setting_key, setting_value, description) VALUES
|
||||
('abc_revenue_threshold_a', '0.80', 'Revenue percentage for Class A (cumulative)'),
|
||||
('abc_revenue_threshold_b', '0.95', 'Revenue percentage for Class B (cumulative)'),
|
||||
('abc_calculation_basis', 'revenue_30d', 'Metric for ABC calc (revenue_30d, sales_30d, lifetime_revenue)'),
|
||||
('abc_calculation_period', '30', 'Days period for ABC calculation if not lifetime'),
|
||||
('default_forecast_method', 'standard', 'Default forecast method (standard, seasonal)'),
|
||||
('default_lead_time_days', '14', 'Global default lead time in days'),
|
||||
('default_days_of_stock', '30', 'Global default days of stock coverage target'),
|
||||
-- Set default safety stock to 0 units. Can be overridden per product.
|
||||
-- If you wanted safety stock in days, you'd store 'days' here and calculate units later.
|
||||
('default_safety_stock_units', '0', 'Global default safety stock in units')
|
||||
ON CONFLICT (setting_key) DO UPDATE SET
|
||||
setting_value = EXCLUDED.setting_value,
|
||||
description = EXCLUDED.description,
|
||||
updated_at = CURRENT_TIMESTAMP; -- Update timestamp if default value changes
|
||||
|
||||
|
||||
|
||||
-- Description: Creates placeholder rows in `settings_vendor` for each unique vendor
|
||||
-- found in the `products` table. Does NOT set specific overrides.
|
||||
-- Safe to rerun; will NOT overwrite existing vendor settings.
|
||||
-- Dependencies: `settings_vendor` table must exist, `products` table populated.
|
||||
-- Frequency: Run once after initial product load, or periodically if new vendors are added.
|
||||
|
||||
INSERT INTO public.settings_vendor (
|
||||
vendor,
|
||||
default_lead_time_days,
|
||||
default_days_of_stock
|
||||
-- updated_at will use its default CURRENT_TIMESTAMP on insert
|
||||
)
|
||||
SELECT
|
||||
DISTINCT p.vendor,
|
||||
-- Explicitly cast NULL to INTEGER to resolve type mismatch
|
||||
CAST(NULL AS INTEGER),
|
||||
CAST(NULL AS INTEGER)
|
||||
FROM
|
||||
public.products p
|
||||
WHERE
|
||||
p.vendor IS NOT NULL
|
||||
AND p.vendor <> '' -- Exclude blank vendors if necessary
|
||||
|
||||
ON CONFLICT (vendor) DO NOTHING; -- IMPORTANT: Do not overwrite existing vendor settings
|
||||
|
||||
SELECT COUNT(*) FROM public.settings_vendor; -- Verify rows were inserted
|
||||
|
||||
|
||||
-- Description: Creates placeholder rows in `settings_product` for each unique product
|
||||
-- found in the `products` table. Sets basic defaults but no specific overrides.
|
||||
-- Safe to rerun; will NOT overwrite existing product settings.
|
||||
-- Dependencies: `settings_product` table must exist, `products` table populated.
|
||||
-- Frequency: Run once after initial product load, or periodically if new products are added.
|
||||
|
||||
INSERT INTO public.settings_product (
|
||||
pid,
|
||||
lead_time_days, -- NULL = Inherit from Vendor/Global
|
||||
days_of_stock, -- NULL = Inherit from Vendor/Global
|
||||
safety_stock, -- Default to 0 units initially
|
||||
forecast_method, -- NULL = Inherit from Global ('standard')
|
||||
exclude_from_forecast -- Default to FALSE
|
||||
-- updated_at will use its default CURRENT_TIMESTAMP on insert
|
||||
)
|
||||
SELECT
|
||||
p.pid,
|
||||
CAST(NULL AS INTEGER), -- Explicitly cast NULL to INTEGER
|
||||
CAST(NULL AS INTEGER), -- Explicitly cast NULL to INTEGER
|
||||
COALESCE((SELECT setting_value::int FROM settings_global WHERE setting_key = 'default_safety_stock_units'), 0), -- Use global default safety stock units
|
||||
CAST(NULL AS VARCHAR), -- Cast NULL to VARCHAR for forecast_method (already varchar, but explicit)
|
||||
FALSE -- Default: Include in forecast
|
||||
FROM
|
||||
public.products p
|
||||
|
||||
ON CONFLICT (pid) DO NOTHING; -- IMPORTANT: Do not overwrite existing product-specific settings
|
||||
Reference in New Issue
Block a user