mirror of
https://github.com/pacnpal/thrilltrack-explorer.git
synced 2025-12-20 06:31:13 -05:00
472 lines
14 KiB
PL/PgSQL
472 lines
14 KiB
PL/PgSQL
-- ============================================================================
|
|
-- COMPREHENSIVE VERSIONING SYSTEM
|
|
-- ============================================================================
|
|
|
|
-- Create enum for change types
|
|
CREATE TYPE public.version_change_type AS ENUM ('created', 'updated', 'deleted', 'restored', 'archived');
|
|
|
|
-- ============================================================================
|
|
-- CORE VERSIONING TABLES
|
|
-- ============================================================================
|
|
|
|
-- Master version registry with complete snapshots
|
|
CREATE TABLE public.entity_versions (
|
|
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
|
entity_type TEXT NOT NULL,
|
|
entity_id UUID NOT NULL,
|
|
version_number INTEGER NOT NULL,
|
|
version_data JSONB NOT NULL,
|
|
changed_by UUID REFERENCES auth.users(id),
|
|
changed_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT now(),
|
|
change_reason TEXT,
|
|
change_type public.version_change_type NOT NULL DEFAULT 'updated',
|
|
submission_id UUID REFERENCES public.content_submissions(id),
|
|
is_current BOOLEAN NOT NULL DEFAULT true,
|
|
ip_address_hash TEXT,
|
|
metadata JSONB DEFAULT '{}'::jsonb,
|
|
UNIQUE(entity_type, entity_id, version_number)
|
|
);
|
|
|
|
-- Granular field-level change tracking
|
|
CREATE TABLE public.entity_field_history (
|
|
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
|
version_id UUID NOT NULL REFERENCES public.entity_versions(id) ON DELETE CASCADE,
|
|
field_name TEXT NOT NULL,
|
|
old_value JSONB,
|
|
new_value JSONB,
|
|
change_type TEXT NOT NULL CHECK (change_type IN ('added', 'modified', 'removed')),
|
|
created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT now()
|
|
);
|
|
|
|
-- Relationship change tracking
|
|
CREATE TABLE public.entity_relationships_history (
|
|
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
|
version_id UUID NOT NULL REFERENCES public.entity_versions(id) ON DELETE CASCADE,
|
|
relationship_type TEXT NOT NULL,
|
|
related_entity_type TEXT NOT NULL,
|
|
related_entity_id UUID,
|
|
old_related_entity_id UUID,
|
|
change_type TEXT NOT NULL CHECK (change_type IN ('linked', 'unlinked', 'changed')),
|
|
created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT now()
|
|
);
|
|
|
|
-- Cached version comparisons for performance
|
|
CREATE TABLE public.version_diffs (
|
|
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
|
from_version_id UUID NOT NULL REFERENCES public.entity_versions(id) ON DELETE CASCADE,
|
|
to_version_id UUID NOT NULL REFERENCES public.entity_versions(id) ON DELETE CASCADE,
|
|
diff_data JSONB NOT NULL,
|
|
created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT now(),
|
|
UNIQUE(from_version_id, to_version_id)
|
|
);
|
|
|
|
-- ============================================================================
|
|
-- HISTORICAL STATE TABLES (Real-world lifecycle)
|
|
-- ============================================================================
|
|
|
|
-- Historical parks (closed, demolished, transformed)
|
|
CREATE TABLE public.historical_parks (
|
|
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
|
original_park_id UUID REFERENCES public.parks(id),
|
|
name TEXT NOT NULL,
|
|
slug TEXT NOT NULL,
|
|
operated_from DATE,
|
|
operated_until DATE,
|
|
closure_reason TEXT,
|
|
successor_park_id UUID REFERENCES public.parks(id),
|
|
final_state_data JSONB NOT NULL,
|
|
location_id UUID REFERENCES public.locations(id),
|
|
created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT now()
|
|
);
|
|
|
|
-- Historical rides (removed, relocated, demolished)
|
|
CREATE TABLE public.historical_rides (
|
|
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
|
original_ride_id UUID REFERENCES public.rides(id),
|
|
name TEXT NOT NULL,
|
|
slug TEXT NOT NULL,
|
|
park_id UUID REFERENCES public.parks(id),
|
|
operated_from DATE,
|
|
operated_until DATE,
|
|
removal_reason TEXT,
|
|
relocated_to_park_id UUID REFERENCES public.parks(id),
|
|
successor_ride_id UUID REFERENCES public.rides(id),
|
|
final_state_data JSONB NOT NULL,
|
|
created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT now()
|
|
);
|
|
|
|
-- Park location history (relocations, expansions)
|
|
CREATE TABLE public.park_location_history (
|
|
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
|
park_id UUID NOT NULL REFERENCES public.parks(id) ON DELETE CASCADE,
|
|
old_location_id UUID REFERENCES public.locations(id),
|
|
new_location_id UUID NOT NULL REFERENCES public.locations(id),
|
|
moved_at DATE NOT NULL,
|
|
reason TEXT,
|
|
created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT now()
|
|
);
|
|
|
|
-- ============================================================================
|
|
-- INDEXES FOR PERFORMANCE
|
|
-- ============================================================================
|
|
|
|
-- Lookup indexes
|
|
CREATE INDEX idx_entity_versions_entity ON public.entity_versions(entity_type, entity_id);
|
|
CREATE INDEX idx_entity_versions_changed_by ON public.entity_versions(changed_by);
|
|
CREATE INDEX idx_entity_versions_submission ON public.entity_versions(submission_id) WHERE submission_id IS NOT NULL;
|
|
|
|
-- Timeline index
|
|
CREATE INDEX idx_entity_versions_changed_at ON public.entity_versions(changed_at DESC);
|
|
|
|
-- Current version partial index (performance optimization)
|
|
CREATE INDEX idx_entity_versions_current ON public.entity_versions(entity_type, entity_id) WHERE is_current = true;
|
|
|
|
-- Field history indexes
|
|
CREATE INDEX idx_field_history_version ON public.entity_field_history(version_id);
|
|
CREATE INDEX idx_field_history_field ON public.entity_field_history(field_name);
|
|
|
|
-- Relationship history indexes
|
|
CREATE INDEX idx_relationships_history_version ON public.entity_relationships_history(version_id);
|
|
|
|
-- Historical entities indexes
|
|
CREATE INDEX idx_historical_parks_original ON public.historical_parks(original_park_id);
|
|
CREATE INDEX idx_historical_rides_original ON public.historical_rides(original_ride_id);
|
|
CREATE INDEX idx_historical_rides_park ON public.historical_rides(park_id);
|
|
|
|
-- ============================================================================
|
|
-- CORE VERSIONING FUNCTIONS
|
|
-- ============================================================================
|
|
|
|
-- Create a new entity version
|
|
CREATE OR REPLACE FUNCTION public.create_entity_version(
|
|
p_entity_type TEXT,
|
|
p_entity_id UUID,
|
|
p_version_data JSONB,
|
|
p_changed_by UUID,
|
|
p_change_reason TEXT DEFAULT NULL,
|
|
p_submission_id UUID DEFAULT NULL,
|
|
p_change_type public.version_change_type DEFAULT 'updated'
|
|
)
|
|
RETURNS UUID
|
|
LANGUAGE plpgsql
|
|
SECURITY DEFINER
|
|
SET search_path = public
|
|
AS $$
|
|
DECLARE
|
|
v_version_id UUID;
|
|
v_version_number INTEGER;
|
|
v_old_data JSONB;
|
|
BEGIN
|
|
-- Get the previous version data
|
|
SELECT version_data INTO v_old_data
|
|
FROM public.entity_versions
|
|
WHERE entity_type = p_entity_type
|
|
AND entity_id = p_entity_id
|
|
AND is_current = true;
|
|
|
|
-- Mark previous version as not current
|
|
UPDATE public.entity_versions
|
|
SET is_current = false
|
|
WHERE entity_type = p_entity_type
|
|
AND entity_id = p_entity_id
|
|
AND is_current = true;
|
|
|
|
-- Get next version number
|
|
SELECT COALESCE(MAX(version_number), 0) + 1 INTO v_version_number
|
|
FROM public.entity_versions
|
|
WHERE entity_type = p_entity_type
|
|
AND entity_id = p_entity_id;
|
|
|
|
-- Create new version
|
|
INSERT INTO public.entity_versions (
|
|
entity_type,
|
|
entity_id,
|
|
version_number,
|
|
version_data,
|
|
changed_by,
|
|
change_reason,
|
|
change_type,
|
|
submission_id,
|
|
is_current
|
|
) VALUES (
|
|
p_entity_type,
|
|
p_entity_id,
|
|
v_version_number,
|
|
p_version_data,
|
|
p_changed_by,
|
|
p_change_reason,
|
|
p_change_type,
|
|
p_submission_id,
|
|
true
|
|
)
|
|
RETURNING id INTO v_version_id;
|
|
|
|
-- Create field-level history if there's old data
|
|
IF v_old_data IS NOT NULL THEN
|
|
PERFORM public.create_field_history_entries(v_version_id, v_old_data, p_version_data);
|
|
END IF;
|
|
|
|
RETURN v_version_id;
|
|
END;
|
|
$$;
|
|
|
|
-- Create field history entries by comparing old and new data
|
|
CREATE OR REPLACE FUNCTION public.create_field_history_entries(
|
|
p_version_id UUID,
|
|
p_old_data JSONB,
|
|
p_new_data JSONB
|
|
)
|
|
RETURNS VOID
|
|
LANGUAGE plpgsql
|
|
SECURITY DEFINER
|
|
SET search_path = public
|
|
AS $$
|
|
DECLARE
|
|
v_key TEXT;
|
|
v_old_value JSONB;
|
|
v_new_value JSONB;
|
|
BEGIN
|
|
-- Check for modified and added fields
|
|
FOR v_key IN SELECT jsonb_object_keys(p_new_data)
|
|
LOOP
|
|
v_old_value := p_old_data -> v_key;
|
|
v_new_value := p_new_data -> v_key;
|
|
|
|
IF v_old_value IS NULL THEN
|
|
-- Field was added
|
|
INSERT INTO public.entity_field_history (
|
|
version_id, field_name, old_value, new_value, change_type
|
|
) VALUES (
|
|
p_version_id, v_key, NULL, v_new_value, 'added'
|
|
);
|
|
ELSIF v_old_value IS DISTINCT FROM v_new_value THEN
|
|
-- Field was modified
|
|
INSERT INTO public.entity_field_history (
|
|
version_id, field_name, old_value, new_value, change_type
|
|
) VALUES (
|
|
p_version_id, v_key, v_old_value, v_new_value, 'modified'
|
|
);
|
|
END IF;
|
|
END LOOP;
|
|
|
|
-- Check for removed fields
|
|
FOR v_key IN SELECT jsonb_object_keys(p_old_data)
|
|
LOOP
|
|
IF NOT (p_new_data ? v_key) THEN
|
|
v_old_value := p_old_data -> v_key;
|
|
INSERT INTO public.entity_field_history (
|
|
version_id, field_name, old_value, new_value, change_type
|
|
) VALUES (
|
|
p_version_id, v_key, v_old_value, NULL, 'removed'
|
|
);
|
|
END IF;
|
|
END LOOP;
|
|
END;
|
|
$$;
|
|
|
|
-- Compare two versions and cache the diff
|
|
CREATE OR REPLACE FUNCTION public.compare_versions(
|
|
p_from_version_id UUID,
|
|
p_to_version_id UUID
|
|
)
|
|
RETURNS JSONB
|
|
LANGUAGE plpgsql
|
|
SECURITY DEFINER
|
|
SET search_path = public
|
|
AS $$
|
|
DECLARE
|
|
v_cached_diff JSONB;
|
|
v_from_data JSONB;
|
|
v_to_data JSONB;
|
|
v_diff JSONB;
|
|
BEGIN
|
|
-- Check cache first
|
|
SELECT diff_data INTO v_cached_diff
|
|
FROM public.version_diffs
|
|
WHERE from_version_id = p_from_version_id
|
|
AND to_version_id = p_to_version_id;
|
|
|
|
IF v_cached_diff IS NOT NULL THEN
|
|
RETURN v_cached_diff;
|
|
END IF;
|
|
|
|
-- Get version data
|
|
SELECT version_data INTO v_from_data
|
|
FROM public.entity_versions
|
|
WHERE id = p_from_version_id;
|
|
|
|
SELECT version_data INTO v_to_data
|
|
FROM public.entity_versions
|
|
WHERE id = p_to_version_id;
|
|
|
|
-- Build diff (simple approach - list all changed fields)
|
|
SELECT jsonb_object_agg(
|
|
key,
|
|
jsonb_build_object(
|
|
'from', v_from_data -> key,
|
|
'to', v_to_data -> key
|
|
)
|
|
) INTO v_diff
|
|
FROM (
|
|
SELECT DISTINCT key
|
|
FROM (
|
|
SELECT jsonb_object_keys(v_from_data) AS key
|
|
UNION
|
|
SELECT jsonb_object_keys(v_to_data) AS key
|
|
) keys
|
|
WHERE (v_from_data -> key) IS DISTINCT FROM (v_to_data -> key)
|
|
) changed_keys;
|
|
|
|
-- Cache the diff
|
|
INSERT INTO public.version_diffs (from_version_id, to_version_id, diff_data)
|
|
VALUES (p_from_version_id, p_to_version_id, v_diff)
|
|
ON CONFLICT (from_version_id, to_version_id) DO UPDATE
|
|
SET diff_data = EXCLUDED.diff_data;
|
|
|
|
RETURN v_diff;
|
|
END;
|
|
$$;
|
|
|
|
-- Rollback entity to a previous version
|
|
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_target_data JSONB;
|
|
v_table_name TEXT;
|
|
v_new_version_id UUID;
|
|
BEGIN
|
|
-- Get target version data
|
|
SELECT version_data INTO v_target_data
|
|
FROM public.entity_versions
|
|
WHERE id = p_target_version_id
|
|
AND entity_type = p_entity_type
|
|
AND entity_id = p_entity_id;
|
|
|
|
IF v_target_data IS NULL THEN
|
|
RAISE EXCEPTION 'Target version not found';
|
|
END IF;
|
|
|
|
-- Determine table name from entity type
|
|
v_table_name := CASE p_entity_type
|
|
WHEN 'park' THEN 'parks'
|
|
WHEN 'ride' THEN 'rides'
|
|
WHEN 'company' THEN 'companies'
|
|
WHEN 'ride_model' THEN 'ride_models'
|
|
ELSE p_entity_type || 's'
|
|
END;
|
|
|
|
-- Create new version with restored change type
|
|
v_new_version_id := public.create_entity_version(
|
|
p_entity_type,
|
|
p_entity_id,
|
|
v_target_data,
|
|
p_changed_by,
|
|
'Rolled back: ' || p_reason,
|
|
NULL,
|
|
'restored'
|
|
);
|
|
|
|
-- Update the actual entity table (simplified - in production would need dynamic SQL)
|
|
-- This is a placeholder - actual implementation would use dynamic SQL to update each field
|
|
|
|
RETURN v_new_version_id;
|
|
END;
|
|
$$;
|
|
|
|
-- ============================================================================
|
|
-- RLS POLICIES
|
|
-- ============================================================================
|
|
|
|
-- Enable RLS
|
|
ALTER TABLE public.entity_versions ENABLE ROW LEVEL SECURITY;
|
|
ALTER TABLE public.entity_field_history ENABLE ROW LEVEL SECURITY;
|
|
ALTER TABLE public.entity_relationships_history ENABLE ROW LEVEL SECURITY;
|
|
ALTER TABLE public.version_diffs ENABLE ROW LEVEL SECURITY;
|
|
ALTER TABLE public.historical_parks ENABLE ROW LEVEL SECURITY;
|
|
ALTER TABLE public.historical_rides ENABLE ROW LEVEL SECURITY;
|
|
ALTER TABLE public.park_location_history ENABLE ROW LEVEL SECURITY;
|
|
|
|
-- Version viewing policies
|
|
CREATE POLICY "Public can view current versions"
|
|
ON public.entity_versions FOR SELECT
|
|
USING (is_current = true);
|
|
|
|
CREATE POLICY "Moderators can view all versions"
|
|
ON public.entity_versions FOR SELECT
|
|
USING (is_moderator(auth.uid()));
|
|
|
|
CREATE POLICY "Users can view their own changes"
|
|
ON public.entity_versions FOR SELECT
|
|
USING (changed_by = auth.uid());
|
|
|
|
-- Version creation policies
|
|
CREATE POLICY "System can create versions"
|
|
ON public.entity_versions FOR INSERT
|
|
WITH CHECK (true);
|
|
|
|
-- Moderators can manage versions
|
|
CREATE POLICY "Moderators can update versions"
|
|
ON public.entity_versions FOR UPDATE
|
|
USING (is_moderator(auth.uid()));
|
|
|
|
-- Field history policies
|
|
CREATE POLICY "Moderators view field history"
|
|
ON public.entity_field_history FOR SELECT
|
|
USING (is_moderator(auth.uid()));
|
|
|
|
CREATE POLICY "System can create field history"
|
|
ON public.entity_field_history FOR INSERT
|
|
WITH CHECK (true);
|
|
|
|
-- Relationship history policies
|
|
CREATE POLICY "Moderators view relationship history"
|
|
ON public.entity_relationships_history FOR SELECT
|
|
USING (is_moderator(auth.uid()));
|
|
|
|
CREATE POLICY "System can create relationship history"
|
|
ON public.entity_relationships_history FOR INSERT
|
|
WITH CHECK (true);
|
|
|
|
-- Version diffs policies
|
|
CREATE POLICY "Moderators view diffs"
|
|
ON public.version_diffs FOR SELECT
|
|
USING (is_moderator(auth.uid()));
|
|
|
|
CREATE POLICY "System can create diffs"
|
|
ON public.version_diffs FOR INSERT
|
|
WITH CHECK (true);
|
|
|
|
-- Historical entities policies
|
|
CREATE POLICY "Public read historical parks"
|
|
ON public.historical_parks FOR SELECT
|
|
USING (true);
|
|
|
|
CREATE POLICY "Moderators manage historical parks"
|
|
ON public.historical_parks FOR ALL
|
|
USING (is_moderator(auth.uid()));
|
|
|
|
CREATE POLICY "Public read historical rides"
|
|
ON public.historical_rides FOR SELECT
|
|
USING (true);
|
|
|
|
CREATE POLICY "Moderators manage historical rides"
|
|
ON public.historical_rides FOR ALL
|
|
USING (is_moderator(auth.uid()));
|
|
|
|
CREATE POLICY "Moderators view location history"
|
|
ON public.park_location_history FOR SELECT
|
|
USING (is_moderator(auth.uid()));
|
|
|
|
CREATE POLICY "Moderators manage location history"
|
|
ON public.park_location_history FOR ALL
|
|
USING (is_moderator(auth.uid())); |