groceries/2025-05-30 temporal_migration.sql
lasse 0b42a74fe9 Minor version bump (1.x.0) is appropriate because:
 New functionality added (soft delete system)
 Backward compatible (existing features unchanged)
 Significant enhancement (complete temporal tracking system)
 API additions (new endpoints, parameters)
 UI enhancements (new components, visual indicators)
2025-05-30 09:49:26 +02:00

122 lines
4.6 KiB
PL/PgSQL

-- Migration script for adding temporal tables to products
-- Run this script to add versioning support to your existing database
--
-- Note: We use '9999-12-31' as the "far future" date to represent
-- the current/active version of a product. This is more portable than PostgreSQL's
-- 'infinity' and works well with both PostgreSQL and SQLite.
--
-- New products will use CURRENT_DATE as valid_from, but existing products
-- are set to '2025-05-01' as a baseline date for historical tracking.
BEGIN;
-- Step 1: Add temporal columns to existing products table
ALTER TABLE products
ADD COLUMN valid_from DATE DEFAULT CURRENT_DATE NOT NULL,
ADD COLUMN valid_to DATE DEFAULT '9999-12-31' NOT NULL,
ADD COLUMN deleted BOOLEAN DEFAULT FALSE NOT NULL;
-- Step 2: Create products_history table
CREATE TABLE products_history (
history_id SERIAL PRIMARY KEY,
id INTEGER NOT NULL,
name VARCHAR NOT NULL,
category_id INTEGER NOT NULL,
brand_id INTEGER,
organic BOOLEAN DEFAULT FALSE,
weight FLOAT,
weight_unit VARCHAR DEFAULT 'piece',
created_at TIMESTAMPTZ,
updated_at TIMESTAMPTZ,
valid_from DATE NOT NULL,
valid_to DATE NOT NULL,
deleted BOOLEAN DEFAULT FALSE NOT NULL,
operation CHAR(1) NOT NULL,
archived_at TIMESTAMPTZ DEFAULT NOW() NOT NULL
);
-- Step 3: Create indexes for performance
CREATE INDEX idx_products_history_id ON products_history(id);
CREATE INDEX idx_products_history_valid_period ON products_history(id, valid_from, valid_to);
CREATE INDEX idx_products_valid_period ON products(id, valid_from, valid_to);
-- Step 4: Create trigger function for automatic versioning
CREATE OR REPLACE FUNCTION products_versioning_trigger()
RETURNS TRIGGER AS $$
BEGIN
-- Handle DELETE operations
IF TG_OP = 'DELETE' THEN
-- Create history record for the deleted product
INSERT INTO products_history (
id, name, category_id, brand_id, organic, weight, weight_unit,
created_at, updated_at, valid_from, valid_to, deleted, operation
) VALUES (
OLD.id, OLD.name, OLD.category_id, OLD.brand_id, OLD.organic,
OLD.weight, OLD.weight_unit, OLD.created_at, OLD.updated_at,
OLD.valid_from, CURRENT_DATE, OLD.deleted, 'D'
);
RETURN OLD;
END IF;
-- Handle UPDATE operations
IF TG_OP = 'UPDATE' THEN
-- Check if any versioned fields have changed
IF (OLD.name IS DISTINCT FROM NEW.name OR
OLD.category_id IS DISTINCT FROM NEW.category_id OR
OLD.brand_id IS DISTINCT FROM NEW.brand_id OR
OLD.organic IS DISTINCT FROM NEW.organic OR
OLD.weight IS DISTINCT FROM NEW.weight OR
OLD.weight_unit IS DISTINCT FROM NEW.weight_unit OR
OLD.deleted IS DISTINCT FROM NEW.deleted) THEN
-- Determine the valid_to date for the history record
DECLARE
history_valid_to DATE;
BEGIN
-- If valid_from was manually changed, use that as the cutoff
-- Otherwise, use current date for automatic versioning
IF OLD.valid_from IS DISTINCT FROM NEW.valid_from THEN
history_valid_to = NEW.valid_from;
ELSE
history_valid_to = CURRENT_DATE;
-- For automatic versioning, update the valid_from to today
NEW.valid_from = CURRENT_DATE;
END IF;
-- Create history record with the old data
INSERT INTO products_history (
id, name, category_id, brand_id, organic, weight, weight_unit,
created_at, updated_at, valid_from, valid_to, deleted, operation
) VALUES (
OLD.id, OLD.name, OLD.category_id, OLD.brand_id, OLD.organic,
OLD.weight, OLD.weight_unit, OLD.created_at, OLD.updated_at,
OLD.valid_from, history_valid_to, OLD.deleted, 'U'
);
END;
-- Always ensure valid_to is set to far future for current version
NEW.valid_to = '9999-12-31';
NEW.updated_at = NOW();
END IF;
RETURN NEW;
END IF;
RETURN NULL;
END;
$$ LANGUAGE plpgsql;
-- Step 5: Create the trigger
CREATE TRIGGER products_versioning_trigger
BEFORE UPDATE OR DELETE ON products
FOR EACH ROW
EXECUTE FUNCTION products_versioning_trigger();
-- Step 6: Initialize existing products with proper temporal data
UPDATE products
SET valid_from = '2025-05-01',
valid_to = '9999-12-31'
WHERE valid_from IS NULL OR valid_to IS NULL;
COMMIT;