mirror of
https://github.com/pacnpal/thrilltrack-explorer.git
synced 2025-12-23 11:31:13 -05:00
feat: Implement versioning documentation
This commit is contained in:
576
docs/versioning/SCHEMA.md
Normal file
576
docs/versioning/SCHEMA.md
Normal file
@@ -0,0 +1,576 @@
|
||||
# Database Schema Documentation
|
||||
|
||||
**Complete reference for version tables, triggers, functions, and policies**
|
||||
|
||||
## Version Tables
|
||||
|
||||
Each entity type has a corresponding version table that mirrors the original table structure with additional version metadata.
|
||||
|
||||
### Common Version Metadata
|
||||
|
||||
All version tables include these standard columns:
|
||||
|
||||
```sql
|
||||
version_id UUID PRIMARY KEY DEFAULT gen_random_uuid()
|
||||
{entity}_id UUID NOT NULL -- FK to original entity
|
||||
version_number INTEGER NOT NULL
|
||||
created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT now()
|
||||
created_by UUID -- FK to profiles (original submitter)
|
||||
change_type version_change_type NOT NULL DEFAULT 'updated'
|
||||
change_reason TEXT
|
||||
submission_id UUID -- FK to content_submissions
|
||||
is_current BOOLEAN NOT NULL DEFAULT true
|
||||
```
|
||||
|
||||
### Enum: version_change_type
|
||||
|
||||
```sql
|
||||
CREATE TYPE version_change_type AS ENUM (
|
||||
'created',
|
||||
'updated',
|
||||
'deleted',
|
||||
'restored',
|
||||
'archived'
|
||||
);
|
||||
```
|
||||
|
||||
## Table Structure
|
||||
|
||||
### park_versions
|
||||
|
||||
Tracks all changes to parks.
|
||||
|
||||
```sql
|
||||
CREATE TABLE park_versions (
|
||||
-- Version metadata
|
||||
version_id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
park_id UUID NOT NULL,
|
||||
version_number INTEGER NOT NULL,
|
||||
created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT now(),
|
||||
created_by UUID,
|
||||
change_type version_change_type NOT NULL DEFAULT 'updated',
|
||||
change_reason TEXT,
|
||||
submission_id UUID,
|
||||
is_current BOOLEAN NOT NULL DEFAULT true,
|
||||
|
||||
-- Park data (mirrors parks table)
|
||||
name TEXT NOT NULL,
|
||||
slug TEXT NOT NULL,
|
||||
description TEXT,
|
||||
park_type TEXT NOT NULL,
|
||||
status TEXT NOT NULL,
|
||||
opening_date DATE,
|
||||
opening_date_precision TEXT,
|
||||
closing_date DATE,
|
||||
closing_date_precision TEXT,
|
||||
location_id UUID,
|
||||
operator_id UUID,
|
||||
property_owner_id UUID,
|
||||
website_url TEXT,
|
||||
phone TEXT,
|
||||
email TEXT,
|
||||
banner_image_url TEXT,
|
||||
banner_image_id TEXT,
|
||||
card_image_url TEXT,
|
||||
card_image_id TEXT
|
||||
);
|
||||
|
||||
-- Indexes for performance
|
||||
CREATE INDEX idx_park_versions_park_id ON park_versions(park_id);
|
||||
CREATE INDEX idx_park_versions_created_at ON park_versions(created_at DESC);
|
||||
CREATE INDEX idx_park_versions_is_current ON park_versions(is_current);
|
||||
CREATE INDEX idx_park_versions_created_by ON park_versions(created_by);
|
||||
CREATE INDEX idx_park_versions_submission_id ON park_versions(submission_id);
|
||||
```
|
||||
|
||||
### ride_versions
|
||||
|
||||
Tracks all changes to rides.
|
||||
|
||||
```sql
|
||||
CREATE TABLE ride_versions (
|
||||
-- Version metadata
|
||||
version_id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
ride_id UUID NOT NULL,
|
||||
version_number INTEGER NOT NULL,
|
||||
created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT now(),
|
||||
created_by UUID,
|
||||
change_type version_change_type NOT NULL DEFAULT 'updated',
|
||||
change_reason TEXT,
|
||||
submission_id UUID,
|
||||
is_current BOOLEAN NOT NULL DEFAULT true,
|
||||
|
||||
-- Ride data (mirrors rides table)
|
||||
name TEXT NOT NULL,
|
||||
slug TEXT NOT NULL,
|
||||
description TEXT,
|
||||
ride_type TEXT NOT NULL,
|
||||
status TEXT NOT NULL,
|
||||
opening_date DATE,
|
||||
opening_date_precision TEXT,
|
||||
closing_date DATE,
|
||||
closing_date_precision TEXT,
|
||||
park_id UUID,
|
||||
manufacturer_id UUID,
|
||||
designer_id UUID,
|
||||
model_id UUID,
|
||||
|
||||
-- Technical specifications
|
||||
height_m NUMERIC,
|
||||
speed_kmh NUMERIC,
|
||||
length_m NUMERIC,
|
||||
duration_seconds INTEGER,
|
||||
inversions_count INTEGER,
|
||||
max_vertical_angle NUMERIC,
|
||||
g_force_max NUMERIC,
|
||||
|
||||
-- Images
|
||||
banner_image_url TEXT,
|
||||
banner_image_id TEXT,
|
||||
card_image_url TEXT,
|
||||
card_image_id TEXT
|
||||
);
|
||||
|
||||
-- Indexes
|
||||
CREATE INDEX idx_ride_versions_ride_id ON ride_versions(ride_id);
|
||||
CREATE INDEX idx_ride_versions_created_at ON ride_versions(created_at DESC);
|
||||
CREATE INDEX idx_ride_versions_is_current ON ride_versions(is_current);
|
||||
CREATE INDEX idx_ride_versions_created_by ON ride_versions(created_by);
|
||||
CREATE INDEX idx_ride_versions_submission_id ON ride_versions(submission_id);
|
||||
```
|
||||
|
||||
### company_versions
|
||||
|
||||
Tracks all changes to companies (manufacturers, operators, designers, property owners).
|
||||
|
||||
```sql
|
||||
CREATE TABLE company_versions (
|
||||
-- Version metadata
|
||||
version_id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
company_id UUID NOT NULL,
|
||||
version_number INTEGER NOT NULL,
|
||||
created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT now(),
|
||||
created_by UUID,
|
||||
change_type version_change_type NOT NULL DEFAULT 'updated',
|
||||
change_reason TEXT,
|
||||
submission_id UUID,
|
||||
is_current BOOLEAN NOT NULL DEFAULT true,
|
||||
|
||||
-- Company data (mirrors companies table)
|
||||
name TEXT NOT NULL,
|
||||
slug TEXT NOT NULL,
|
||||
description TEXT,
|
||||
company_type TEXT NOT NULL, -- manufacturer, operator, designer, property_owner
|
||||
person_type TEXT DEFAULT 'company',
|
||||
founded_date DATE,
|
||||
founded_date_precision TEXT,
|
||||
founded_year INTEGER,
|
||||
headquarters_location TEXT,
|
||||
website_url TEXT,
|
||||
logo_url TEXT,
|
||||
banner_image_url TEXT,
|
||||
banner_image_id TEXT,
|
||||
card_image_url TEXT,
|
||||
card_image_id TEXT
|
||||
);
|
||||
|
||||
-- Indexes
|
||||
CREATE INDEX idx_company_versions_company_id ON company_versions(company_id);
|
||||
CREATE INDEX idx_company_versions_created_at ON company_versions(created_at DESC);
|
||||
CREATE INDEX idx_company_versions_is_current ON company_versions(is_current);
|
||||
CREATE INDEX idx_company_versions_created_by ON company_versions(created_by);
|
||||
CREATE INDEX idx_company_versions_submission_id ON company_versions(submission_id);
|
||||
```
|
||||
|
||||
### ride_model_versions
|
||||
|
||||
Tracks all changes to ride models.
|
||||
|
||||
```sql
|
||||
CREATE TABLE ride_model_versions (
|
||||
-- Version metadata
|
||||
version_id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
ride_model_id UUID NOT NULL,
|
||||
version_number INTEGER NOT NULL,
|
||||
created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT now(),
|
||||
created_by UUID,
|
||||
change_type version_change_type NOT NULL DEFAULT 'updated',
|
||||
change_reason TEXT,
|
||||
submission_id UUID,
|
||||
is_current BOOLEAN NOT NULL DEFAULT true,
|
||||
|
||||
-- Ride model data (mirrors ride_models table)
|
||||
name TEXT NOT NULL,
|
||||
slug TEXT NOT NULL,
|
||||
description TEXT,
|
||||
manufacturer_id UUID,
|
||||
model_type TEXT NOT NULL,
|
||||
introduced_year INTEGER,
|
||||
retired_year INTEGER,
|
||||
|
||||
-- Images
|
||||
banner_image_url TEXT,
|
||||
banner_image_id TEXT,
|
||||
card_image_url TEXT,
|
||||
card_image_id TEXT
|
||||
);
|
||||
|
||||
-- Indexes
|
||||
CREATE INDEX idx_ride_model_versions_ride_model_id ON ride_model_versions(ride_model_id);
|
||||
CREATE INDEX idx_ride_model_versions_created_at ON ride_model_versions(created_at DESC);
|
||||
CREATE INDEX idx_ride_model_versions_is_current ON ride_model_versions(is_current);
|
||||
CREATE INDEX idx_ride_model_versions_created_by ON ride_model_versions(created_by);
|
||||
CREATE INDEX idx_ride_model_versions_submission_id ON ride_model_versions(submission_id);
|
||||
```
|
||||
|
||||
## Triggers
|
||||
|
||||
### Automatic Version Creation
|
||||
|
||||
Each entity table has an `AFTER INSERT OR UPDATE` trigger that calls the `create_relational_version()` function.
|
||||
|
||||
```sql
|
||||
-- Example: Park versioning trigger
|
||||
CREATE TRIGGER create_park_version_on_change
|
||||
AFTER INSERT OR UPDATE ON parks
|
||||
FOR EACH ROW
|
||||
EXECUTE FUNCTION public.create_relational_version();
|
||||
```
|
||||
|
||||
Triggers exist for:
|
||||
- `parks` → `create_park_version_on_change`
|
||||
- `rides` → `create_ride_version_on_change`
|
||||
- `companies` → `create_company_version_on_change`
|
||||
- `ride_models` → `create_ride_model_version_on_change`
|
||||
|
||||
## Functions
|
||||
|
||||
### create_relational_version()
|
||||
|
||||
**Purpose:** Core trigger function that creates version records automatically.
|
||||
|
||||
```sql
|
||||
CREATE OR REPLACE FUNCTION public.create_relational_version()
|
||||
RETURNS TRIGGER
|
||||
LANGUAGE plpgsql
|
||||
SECURITY DEFINER
|
||||
SET search_path = public
|
||||
AS $$
|
||||
DECLARE
|
||||
v_version_table TEXT;
|
||||
v_entity_id_col TEXT;
|
||||
v_created_by UUID;
|
||||
v_submission_id UUID;
|
||||
v_change_type version_change_type;
|
||||
v_version_number INTEGER;
|
||||
BEGIN
|
||||
-- Determine version table based on trigger source
|
||||
CASE TG_TABLE_NAME
|
||||
WHEN 'parks' THEN
|
||||
v_version_table := 'park_versions';
|
||||
v_entity_id_col := 'park_id';
|
||||
WHEN 'rides' THEN
|
||||
v_version_table := 'ride_versions';
|
||||
v_entity_id_col := 'ride_id';
|
||||
WHEN 'companies' THEN
|
||||
v_version_table := 'company_versions';
|
||||
v_entity_id_col := 'company_id';
|
||||
WHEN 'ride_models' THEN
|
||||
v_version_table := 'ride_model_versions';
|
||||
v_entity_id_col := 'ride_model_id';
|
||||
ELSE
|
||||
RAISE EXCEPTION 'Unsupported table: %', TG_TABLE_NAME;
|
||||
END CASE;
|
||||
|
||||
-- Get user and submission from session variables
|
||||
v_created_by := NULLIF(current_setting('app.current_user_id', TRUE), '')::UUID;
|
||||
v_submission_id := NULLIF(current_setting('app.submission_id', TRUE), '')::UUID;
|
||||
|
||||
-- Fallback to auth.uid() if no session variable
|
||||
IF v_created_by IS NULL THEN
|
||||
v_created_by := auth.uid();
|
||||
END IF;
|
||||
|
||||
-- Determine change type
|
||||
IF TG_OP = 'INSERT' THEN
|
||||
v_change_type := 'created';
|
||||
v_version_number := 1;
|
||||
ELSE
|
||||
v_change_type := 'updated';
|
||||
|
||||
-- Mark previous current version as not current
|
||||
EXECUTE format('UPDATE %I SET is_current = false WHERE %I = $1 AND is_current = true',
|
||||
v_version_table, v_entity_id_col)
|
||||
USING NEW.id;
|
||||
|
||||
-- Get next version number
|
||||
EXECUTE format('SELECT COALESCE(MAX(version_number), 0) + 1 FROM %I WHERE %I = $1',
|
||||
v_version_table, v_entity_id_col)
|
||||
INTO v_version_number
|
||||
USING NEW.id;
|
||||
END IF;
|
||||
|
||||
-- Insert new version (dynamic SQL with all entity fields)
|
||||
EXECUTE format(
|
||||
'INSERT INTO %I SELECT $1, $2, $3, now(), $4, $5, NULL, $6, true, (SELECT %I.* FROM %I WHERE id = $2)',
|
||||
v_version_table, TG_TABLE_NAME, TG_TABLE_NAME
|
||||
)
|
||||
USING gen_random_uuid(), NEW.id, v_version_number, v_created_by, v_change_type, v_submission_id;
|
||||
|
||||
RETURN NEW;
|
||||
END;
|
||||
$$;
|
||||
```
|
||||
|
||||
### get_version_diff()
|
||||
|
||||
**Purpose:** Compare two versions and return field-level differences.
|
||||
|
||||
```sql
|
||||
CREATE OR REPLACE FUNCTION public.get_version_diff(
|
||||
p_entity_type TEXT,
|
||||
p_from_version_id UUID,
|
||||
p_to_version_id UUID
|
||||
)
|
||||
RETURNS JSONB
|
||||
LANGUAGE plpgsql
|
||||
SECURITY DEFINER
|
||||
SET search_path = public
|
||||
AS $$
|
||||
DECLARE
|
||||
v_version_table TEXT;
|
||||
v_from_record JSONB;
|
||||
v_to_record JSONB;
|
||||
v_diff JSONB := '{}'::JSONB;
|
||||
v_key TEXT;
|
||||
v_from_value JSONB;
|
||||
v_to_value JSONB;
|
||||
BEGIN
|
||||
-- Determine version table
|
||||
v_version_table := p_entity_type || '_versions';
|
||||
|
||||
-- Get both versions as JSONB
|
||||
EXECUTE format('SELECT row_to_json(t)::JSONB FROM %I t WHERE version_id = $1', v_version_table)
|
||||
INTO v_from_record
|
||||
USING p_from_version_id;
|
||||
|
||||
EXECUTE format('SELECT row_to_json(t)::JSONB FROM %I t WHERE version_id = $1', v_version_table)
|
||||
INTO v_to_record
|
||||
USING p_to_version_id;
|
||||
|
||||
-- Compare each key
|
||||
FOR v_key IN SELECT jsonb_object_keys(v_to_record)
|
||||
LOOP
|
||||
-- Skip metadata fields
|
||||
CONTINUE WHEN v_key IN ('version_id', 'version_number', 'created_at', 'created_by', 'is_current');
|
||||
|
||||
v_from_value := v_from_record -> v_key;
|
||||
v_to_value := v_to_record -> v_key;
|
||||
|
||||
-- If values differ, add to diff
|
||||
IF v_from_value IS DISTINCT FROM v_to_value THEN
|
||||
v_diff := v_diff || jsonb_build_object(
|
||||
v_key, jsonb_build_object(
|
||||
'from', v_from_value,
|
||||
'to', v_to_value,
|
||||
'changed', true
|
||||
)
|
||||
);
|
||||
END IF;
|
||||
END LOOP;
|
||||
|
||||
RETURN v_diff;
|
||||
END;
|
||||
$$;
|
||||
```
|
||||
|
||||
### cleanup_old_versions()
|
||||
|
||||
**Purpose:** Remove old versions, keeping only N most recent per entity.
|
||||
|
||||
```sql
|
||||
CREATE OR REPLACE FUNCTION public.cleanup_old_versions(
|
||||
p_entity_type TEXT,
|
||||
p_keep_versions INTEGER DEFAULT 50
|
||||
)
|
||||
RETURNS INTEGER
|
||||
LANGUAGE plpgsql
|
||||
SECURITY DEFINER
|
||||
SET search_path = public
|
||||
AS $$
|
||||
DECLARE
|
||||
v_version_table TEXT;
|
||||
v_entity_id_col TEXT;
|
||||
v_deleted_count INTEGER;
|
||||
BEGIN
|
||||
-- Determine table names
|
||||
v_version_table := p_entity_type || '_versions';
|
||||
v_entity_id_col := p_entity_type || '_id';
|
||||
|
||||
-- Delete old versions, keeping p_keep_versions most recent per entity
|
||||
EXECUTE format('
|
||||
DELETE FROM %I
|
||||
WHERE version_id IN (
|
||||
SELECT version_id FROM (
|
||||
SELECT
|
||||
version_id,
|
||||
ROW_NUMBER() OVER (PARTITION BY %I ORDER BY version_number DESC) as rn
|
||||
FROM %I
|
||||
) sub
|
||||
WHERE rn > $1
|
||||
)',
|
||||
v_version_table, v_entity_id_col, v_version_table
|
||||
)
|
||||
USING p_keep_versions;
|
||||
|
||||
GET DIAGNOSTICS v_deleted_count = ROW_COUNT;
|
||||
|
||||
RETURN v_deleted_count;
|
||||
END;
|
||||
$$;
|
||||
```
|
||||
|
||||
### rollback_to_version()
|
||||
|
||||
**Purpose:** Restore entity to a previous version.
|
||||
|
||||
```sql
|
||||
CREATE OR REPLACE FUNCTION public.rollback_to_version(
|
||||
p_entity_type TEXT,
|
||||
p_entity_id UUID,
|
||||
p_target_version_id UUID,
|
||||
p_changed_by UUID,
|
||||
p_reason TEXT
|
||||
)
|
||||
RETURNS UUID
|
||||
LANGUAGE plpgsql
|
||||
SECURITY DEFINER
|
||||
SET search_path = public
|
||||
AS $$
|
||||
DECLARE
|
||||
v_version_table TEXT;
|
||||
v_entity_table TEXT;
|
||||
v_new_version_id UUID;
|
||||
BEGIN
|
||||
v_version_table := p_entity_type || '_versions';
|
||||
v_entity_table := p_entity_type || 's'; -- Pluralize
|
||||
|
||||
-- Set session variables for attribution
|
||||
PERFORM set_config('app.current_user_id', p_changed_by::TEXT, true);
|
||||
PERFORM set_config('app.change_reason', p_reason, true);
|
||||
|
||||
-- Update entity table with data from target version
|
||||
EXECUTE format('
|
||||
UPDATE %I
|
||||
SET ... (all fields from version)
|
||||
FROM %I v
|
||||
WHERE v.version_id = $1 AND %I.id = $2',
|
||||
v_entity_table, v_version_table, v_entity_table
|
||||
)
|
||||
USING p_target_version_id, p_entity_id;
|
||||
|
||||
-- Trigger will create new version with change_type='restored'
|
||||
|
||||
RETURN v_new_version_id;
|
||||
END;
|
||||
$$;
|
||||
```
|
||||
|
||||
## Row-Level Security (RLS)
|
||||
|
||||
All version tables have RLS enabled with these policies:
|
||||
|
||||
### Public Access
|
||||
|
||||
```sql
|
||||
CREATE POLICY "Public can view current versions"
|
||||
ON park_versions
|
||||
FOR SELECT
|
||||
USING (is_current = true);
|
||||
```
|
||||
|
||||
### Moderator Access
|
||||
|
||||
```sql
|
||||
CREATE POLICY "Moderators can view all versions"
|
||||
ON park_versions
|
||||
FOR SELECT
|
||||
USING (is_moderator(auth.uid()));
|
||||
```
|
||||
|
||||
### User Access
|
||||
|
||||
```sql
|
||||
CREATE POLICY "Users can view their own versions"
|
||||
ON park_versions
|
||||
FOR SELECT
|
||||
USING (created_by = auth.uid());
|
||||
```
|
||||
|
||||
### System Access
|
||||
|
||||
```sql
|
||||
-- Triggers can insert (SECURITY DEFINER)
|
||||
-- No UPDATE or DELETE policies (only system can modify)
|
||||
```
|
||||
|
||||
## Example Queries
|
||||
|
||||
### Get Version History
|
||||
|
||||
```sql
|
||||
SELECT
|
||||
version_number,
|
||||
created_at,
|
||||
change_type,
|
||||
p.username as changed_by_username,
|
||||
name,
|
||||
description
|
||||
FROM park_versions pv
|
||||
LEFT JOIN profiles p ON p.user_id = pv.created_by
|
||||
WHERE park_id = 'uuid-here'
|
||||
ORDER BY version_number DESC;
|
||||
```
|
||||
|
||||
### Compare Versions
|
||||
|
||||
```sql
|
||||
SELECT * FROM get_version_diff(
|
||||
'park',
|
||||
'older-version-uuid',
|
||||
'newer-version-uuid'
|
||||
);
|
||||
```
|
||||
|
||||
### Find Recent Changes
|
||||
|
||||
```sql
|
||||
SELECT
|
||||
pv.version_number,
|
||||
pv.created_at,
|
||||
p.username,
|
||||
parks.name as park_name
|
||||
FROM park_versions pv
|
||||
JOIN parks ON parks.id = pv.park_id
|
||||
LEFT JOIN profiles p ON p.user_id = pv.created_by
|
||||
WHERE pv.created_at > NOW() - INTERVAL '7 days'
|
||||
ORDER BY pv.created_at DESC;
|
||||
```
|
||||
|
||||
### Cleanup Old Versions
|
||||
|
||||
```sql
|
||||
-- Keep only 50 most recent versions per park
|
||||
SELECT cleanup_old_versions('park', 50);
|
||||
```
|
||||
|
||||
## Performance Considerations
|
||||
|
||||
- **Indexes** ensure fast lookups by entity_id, created_at, and is_current
|
||||
- **Partitioning** could be added for very large version tables
|
||||
- **Archival** old versions can be moved to cold storage
|
||||
- **Cleanup** should run monthly to prevent unbounded growth
|
||||
|
||||
## Migration Notes
|
||||
|
||||
The old `entity_versions` JSONB table is deprecated but retained for backward compatibility. New versions are written only to relational tables. See [MIGRATION.md](./MIGRATION.md) for migration details.
|
||||
Reference in New Issue
Block a user