-- Create function for updating timestamps if it doesn't exist CREATE OR REPLACE FUNCTION update_updated_column() RETURNS TRIGGER AS $$ BEGIN NEW.updated = CURRENT_TIMESTAMP; RETURN NEW; END; $$ language 'plpgsql'; -- Create function for updating updated_at timestamps CREATE OR REPLACE FUNCTION update_updated_at_column() RETURNS TRIGGER AS $$ BEGIN NEW.updated_at = CURRENT_TIMESTAMP; RETURN NEW; END; $$ language 'plpgsql'; -- 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 -- History and status tables CREATE TABLE IF NOT EXISTS calculate_history ( id BIGSERIAL PRIMARY KEY, start_time TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT CURRENT_TIMESTAMP, end_time TIMESTAMP WITH TIME ZONE 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 text PRIMARY KEY, last_calculation_timestamp TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT CURRENT_TIMESTAMP ); CREATE TABLE IF NOT EXISTS sync_status ( table_name TEXT PRIMARY KEY, last_sync_timestamp TIMESTAMP WITH TIME ZONE 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 WITH TIME ZONE NOT NULL DEFAULT CURRENT_TIMESTAMP, end_time TIMESTAMP WITH TIME ZONE 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, records_deleted INTEGER DEFAULT 0, records_skipped INTEGER DEFAULT 0, total_processed 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); CREATE INDEX IF NOT EXISTS idx_import_history_status ON import_history(status); CREATE INDEX IF NOT EXISTS idx_calculate_history_status ON calculate_history(status); -- Add comments for documentation COMMENT ON TABLE import_history IS 'Tracks history of data import operations with detailed statistics'; COMMENT ON COLUMN import_history.records_deleted IS 'Number of records deleted during this import'; COMMENT ON COLUMN import_history.records_skipped IS 'Number of records skipped (e.g., unchanged, invalid)'; COMMENT ON COLUMN import_history.total_processed IS 'Total number of records examined/processed, including skipped'; COMMENT ON TABLE calculate_history IS 'Tracks history of metrics calculation runs with performance data'; COMMENT ON COLUMN calculate_history.duration_seconds IS 'Total duration of the calculation in seconds'; COMMENT ON COLUMN calculate_history.additional_info IS 'JSON object containing step timings, row counts, and other detailed metrics';