mirror of
https://github.com/pacnpal/thrilltrack-explorer.git
synced 2025-12-20 06:31:13 -05:00
463 lines
18 KiB
PL/PgSQL
463 lines
18 KiB
PL/PgSQL
-- ============================================================================
|
|
-- UNIVERSAL RELATIONAL VERSIONING SYSTEM
|
|
-- Eliminates JSONB storage, uses pure relational structure
|
|
-- Automatic trigger-based versioning with full type safety
|
|
-- ============================================================================
|
|
|
|
-- ============================================================================
|
|
-- STEP 1: Create Version Tables (Pure Relational, No JSONB)
|
|
-- ============================================================================
|
|
|
|
-- Park Versions Table
|
|
CREATE TABLE IF NOT EXISTS public.park_versions (
|
|
-- Version metadata
|
|
version_id uuid PRIMARY KEY DEFAULT gen_random_uuid(),
|
|
park_id uuid NOT NULL REFERENCES public.parks(id) ON DELETE CASCADE,
|
|
version_number integer NOT NULL,
|
|
created_at timestamptz NOT NULL DEFAULT now(),
|
|
created_by uuid,
|
|
change_type version_change_type NOT NULL DEFAULT 'updated',
|
|
change_reason text,
|
|
submission_id uuid REFERENCES public.content_submissions(id) ON DELETE SET NULL,
|
|
is_current boolean NOT NULL DEFAULT true,
|
|
|
|
-- Exact mirror of parks table structure (all fields, no computed columns)
|
|
name text NOT NULL,
|
|
slug text NOT NULL,
|
|
description text,
|
|
park_type text NOT NULL,
|
|
status text NOT NULL,
|
|
location_id uuid REFERENCES public.locations(id) ON DELETE SET NULL,
|
|
operator_id uuid REFERENCES public.companies(id) ON DELETE SET NULL,
|
|
property_owner_id uuid REFERENCES public.companies(id) ON DELETE SET NULL,
|
|
opening_date date,
|
|
closing_date date,
|
|
opening_date_precision text,
|
|
closing_date_precision text,
|
|
website_url text,
|
|
phone text,
|
|
email text,
|
|
banner_image_url text,
|
|
banner_image_id text,
|
|
card_image_url text,
|
|
card_image_id text,
|
|
|
|
-- Constraints
|
|
UNIQUE(park_id, version_number)
|
|
);
|
|
|
|
-- Ride Versions Table
|
|
CREATE TABLE IF NOT EXISTS public.ride_versions (
|
|
-- Version metadata
|
|
version_id uuid PRIMARY KEY DEFAULT gen_random_uuid(),
|
|
ride_id uuid NOT NULL REFERENCES public.rides(id) ON DELETE CASCADE,
|
|
version_number integer NOT NULL,
|
|
created_at timestamptz NOT NULL DEFAULT now(),
|
|
created_by uuid,
|
|
change_type version_change_type NOT NULL DEFAULT 'updated',
|
|
change_reason text,
|
|
submission_id uuid REFERENCES public.content_submissions(id) ON DELETE SET NULL,
|
|
is_current boolean NOT NULL DEFAULT true,
|
|
|
|
-- Mirror of rides table structure
|
|
name text NOT NULL,
|
|
slug text NOT NULL,
|
|
description text,
|
|
category text NOT NULL,
|
|
status text NOT NULL,
|
|
park_id uuid REFERENCES public.parks(id) ON DELETE SET NULL,
|
|
manufacturer_id uuid REFERENCES public.companies(id) ON DELETE SET NULL,
|
|
designer_id uuid REFERENCES public.companies(id) ON DELETE SET NULL,
|
|
ride_model_id uuid,
|
|
opening_date date,
|
|
closing_date date,
|
|
opening_date_precision text,
|
|
closing_date_precision text,
|
|
height_requirement_cm integer,
|
|
max_speed_kmh numeric(6,2),
|
|
duration_seconds integer,
|
|
capacity_per_hour integer,
|
|
gforce_max numeric(4,2),
|
|
inversions_count integer,
|
|
length_meters numeric(10,2),
|
|
height_meters numeric(10,2),
|
|
drop_meters numeric(10,2),
|
|
angle_degrees numeric(5,2),
|
|
former_names jsonb DEFAULT '[]'::jsonb,
|
|
banner_image_url text,
|
|
banner_image_id text,
|
|
card_image_url text,
|
|
card_image_id text,
|
|
|
|
UNIQUE(ride_id, version_number)
|
|
);
|
|
|
|
-- Company Versions Table
|
|
CREATE TABLE IF NOT EXISTS public.company_versions (
|
|
-- Version metadata
|
|
version_id uuid PRIMARY KEY DEFAULT gen_random_uuid(),
|
|
company_id uuid NOT NULL REFERENCES public.companies(id) ON DELETE CASCADE,
|
|
version_number integer NOT NULL,
|
|
created_at timestamptz NOT NULL DEFAULT now(),
|
|
created_by uuid,
|
|
change_type version_change_type NOT NULL DEFAULT 'updated',
|
|
change_reason text,
|
|
submission_id uuid REFERENCES public.content_submissions(id) ON DELETE SET NULL,
|
|
is_current boolean NOT NULL DEFAULT true,
|
|
|
|
-- Mirror of companies table structure
|
|
name text NOT NULL,
|
|
slug text NOT NULL,
|
|
description text,
|
|
company_type text NOT NULL,
|
|
person_type text DEFAULT 'company',
|
|
founded_year integer,
|
|
founded_date date,
|
|
founded_date_precision text,
|
|
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,
|
|
|
|
UNIQUE(company_id, version_number)
|
|
);
|
|
|
|
-- Ride Model Versions Table
|
|
CREATE TABLE IF NOT EXISTS public.ride_model_versions (
|
|
-- Version metadata
|
|
version_id uuid PRIMARY KEY DEFAULT gen_random_uuid(),
|
|
ride_model_id uuid NOT NULL REFERENCES public.ride_models(id) ON DELETE CASCADE,
|
|
version_number integer NOT NULL,
|
|
created_at timestamptz NOT NULL DEFAULT now(),
|
|
created_by uuid,
|
|
change_type version_change_type NOT NULL DEFAULT 'updated',
|
|
change_reason text,
|
|
submission_id uuid REFERENCES public.content_submissions(id) ON DELETE SET NULL,
|
|
is_current boolean NOT NULL DEFAULT true,
|
|
|
|
-- Mirror of ride_models table structure
|
|
name text NOT NULL,
|
|
slug text NOT NULL,
|
|
manufacturer_id uuid REFERENCES public.companies(id) ON DELETE SET NULL,
|
|
category text NOT NULL,
|
|
description text,
|
|
technical_specs jsonb DEFAULT '{}'::jsonb,
|
|
|
|
UNIQUE(ride_model_id, version_number)
|
|
);
|
|
|
|
-- ============================================================================
|
|
-- STEP 2: Create Indexes for Performance
|
|
-- ============================================================================
|
|
|
|
-- Park Versions Indexes
|
|
CREATE INDEX IF NOT EXISTS idx_park_versions_park_id ON public.park_versions(park_id);
|
|
CREATE INDEX IF NOT EXISTS idx_park_versions_created_at ON public.park_versions(created_at DESC);
|
|
CREATE INDEX IF NOT EXISTS idx_park_versions_current ON public.park_versions(park_id, is_current) WHERE is_current = true;
|
|
CREATE INDEX IF NOT EXISTS idx_park_versions_created_by ON public.park_versions(created_by) WHERE created_by IS NOT NULL;
|
|
CREATE INDEX IF NOT EXISTS idx_park_versions_submission_id ON public.park_versions(submission_id) WHERE submission_id IS NOT NULL;
|
|
|
|
-- Ride Versions Indexes
|
|
CREATE INDEX IF NOT EXISTS idx_ride_versions_ride_id ON public.ride_versions(ride_id);
|
|
CREATE INDEX IF NOT EXISTS idx_ride_versions_created_at ON public.ride_versions(created_at DESC);
|
|
CREATE INDEX IF NOT EXISTS idx_ride_versions_current ON public.ride_versions(ride_id, is_current) WHERE is_current = true;
|
|
CREATE INDEX IF NOT EXISTS idx_ride_versions_created_by ON public.ride_versions(created_by) WHERE created_by IS NOT NULL;
|
|
CREATE INDEX IF NOT EXISTS idx_ride_versions_submission_id ON public.ride_versions(submission_id) WHERE submission_id IS NOT NULL;
|
|
|
|
-- Company Versions Indexes
|
|
CREATE INDEX IF NOT EXISTS idx_company_versions_company_id ON public.company_versions(company_id);
|
|
CREATE INDEX IF NOT EXISTS idx_company_versions_created_at ON public.company_versions(created_at DESC);
|
|
CREATE INDEX IF NOT EXISTS idx_company_versions_current ON public.company_versions(company_id, is_current) WHERE is_current = true;
|
|
CREATE INDEX IF NOT EXISTS idx_company_versions_created_by ON public.company_versions(created_by) WHERE created_by IS NOT NULL;
|
|
|
|
-- Ride Model Versions Indexes
|
|
CREATE INDEX IF NOT EXISTS idx_ride_model_versions_model_id ON public.ride_model_versions(ride_model_id);
|
|
CREATE INDEX IF NOT EXISTS idx_ride_model_versions_created_at ON public.ride_model_versions(created_at DESC);
|
|
CREATE INDEX IF NOT EXISTS idx_ride_model_versions_current ON public.ride_model_versions(ride_model_id, is_current) WHERE is_current = true;
|
|
|
|
-- ============================================================================
|
|
-- STEP 3: Create Universal Versioning Trigger Function
|
|
-- ============================================================================
|
|
|
|
CREATE OR REPLACE FUNCTION public.create_relational_version()
|
|
RETURNS trigger
|
|
LANGUAGE plpgsql
|
|
SECURITY DEFINER
|
|
SET search_path = public
|
|
AS $$
|
|
DECLARE
|
|
v_version_number integer;
|
|
v_created_by uuid;
|
|
v_change_type version_change_type;
|
|
v_submission_id uuid;
|
|
v_version_table text;
|
|
v_entity_id_col text;
|
|
BEGIN
|
|
-- Determine version table name
|
|
v_version_table := TG_TABLE_NAME || '_versions';
|
|
v_entity_id_col := TG_TABLE_NAME || '_id';
|
|
|
|
-- Get user from session config (set by edge function)
|
|
BEGIN
|
|
v_created_by := current_setting('app.current_user_id', true)::uuid;
|
|
EXCEPTION WHEN OTHERS THEN
|
|
v_created_by := auth.uid();
|
|
END;
|
|
|
|
-- Get submission ID if available
|
|
BEGIN
|
|
v_submission_id := current_setting('app.submission_id', true)::uuid;
|
|
EXCEPTION WHEN OTHERS THEN
|
|
v_submission_id := NULL;
|
|
END;
|
|
|
|
-- Determine change type
|
|
IF TG_OP = 'INSERT' THEN
|
|
v_change_type := 'created';
|
|
v_version_number := 1;
|
|
ELSIF TG_OP = 'UPDATE' THEN
|
|
-- Only version if data actually changed (ignore updated_at, view counts, ratings)
|
|
IF (OLD.name, OLD.slug, OLD.description, OLD.status) IS NOT DISTINCT FROM
|
|
(NEW.name, NEW.slug, NEW.description, NEW.status) THEN
|
|
RETURN NEW;
|
|
END IF;
|
|
|
|
v_change_type := 'updated';
|
|
|
|
-- Mark previous 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 version record based on table type
|
|
IF TG_TABLE_NAME = 'parks' THEN
|
|
INSERT INTO public.park_versions (
|
|
park_id, version_number, created_by, change_type, submission_id,
|
|
name, slug, description, park_type, status, location_id, operator_id, property_owner_id,
|
|
opening_date, closing_date, opening_date_precision, closing_date_precision,
|
|
website_url, phone, email, banner_image_url, banner_image_id, card_image_url, card_image_id
|
|
) VALUES (
|
|
NEW.id, v_version_number, v_created_by, v_change_type, v_submission_id,
|
|
NEW.name, NEW.slug, NEW.description, NEW.park_type, NEW.status, NEW.location_id, NEW.operator_id, NEW.property_owner_id,
|
|
NEW.opening_date, NEW.closing_date, NEW.opening_date_precision, NEW.closing_date_precision,
|
|
NEW.website_url, NEW.phone, NEW.email, NEW.banner_image_url, NEW.banner_image_id, NEW.card_image_url, NEW.card_image_id
|
|
);
|
|
|
|
ELSIF TG_TABLE_NAME = 'rides' THEN
|
|
INSERT INTO public.ride_versions (
|
|
ride_id, version_number, created_by, change_type, submission_id,
|
|
name, slug, description, category, status, park_id, manufacturer_id, designer_id, ride_model_id,
|
|
opening_date, closing_date, opening_date_precision, closing_date_precision,
|
|
height_requirement_cm, max_speed_kmh, duration_seconds, capacity_per_hour, gforce_max,
|
|
inversions_count, length_meters, height_meters, drop_meters, angle_degrees, former_names,
|
|
banner_image_url, banner_image_id, card_image_url, card_image_id
|
|
) VALUES (
|
|
NEW.id, v_version_number, v_created_by, v_change_type, v_submission_id,
|
|
NEW.name, NEW.slug, NEW.description, NEW.category, NEW.status, NEW.park_id, NEW.manufacturer_id, NEW.designer_id, NEW.ride_model_id,
|
|
NEW.opening_date, NEW.closing_date, NEW.opening_date_precision, NEW.closing_date_precision,
|
|
NEW.height_requirement_cm, NEW.max_speed_kmh, NEW.duration_seconds, NEW.capacity_per_hour, NEW.gforce_max,
|
|
NEW.inversions_count, NEW.length_meters, NEW.height_meters, NEW.drop_meters, NEW.angle_degrees, NEW.former_names,
|
|
NEW.banner_image_url, NEW.banner_image_id, NEW.card_image_url, NEW.card_image_id
|
|
);
|
|
|
|
ELSIF TG_TABLE_NAME = 'companies' THEN
|
|
INSERT INTO public.company_versions (
|
|
company_id, version_number, created_by, change_type, submission_id,
|
|
name, slug, description, company_type, person_type, founded_year, founded_date, founded_date_precision,
|
|
headquarters_location, website_url, logo_url, banner_image_url, banner_image_id, card_image_url, card_image_id
|
|
) VALUES (
|
|
NEW.id, v_version_number, v_created_by, v_change_type, v_submission_id,
|
|
NEW.name, NEW.slug, NEW.description, NEW.company_type, NEW.person_type, NEW.founded_year, NEW.founded_date, NEW.founded_date_precision,
|
|
NEW.headquarters_location, NEW.website_url, NEW.logo_url, NEW.banner_image_url, NEW.banner_image_id, NEW.card_image_url, NEW.card_image_id
|
|
);
|
|
|
|
ELSIF TG_TABLE_NAME = 'ride_models' THEN
|
|
INSERT INTO public.ride_model_versions (
|
|
ride_model_id, version_number, created_by, change_type, submission_id,
|
|
name, slug, manufacturer_id, category, description, technical_specs
|
|
) VALUES (
|
|
NEW.id, v_version_number, v_created_by, v_change_type, v_submission_id,
|
|
NEW.name, NEW.slug, NEW.manufacturer_id, NEW.category, NEW.description, NEW.technical_specs
|
|
);
|
|
END IF;
|
|
|
|
RETURN NEW;
|
|
END;
|
|
$$;
|
|
|
|
-- ============================================================================
|
|
-- STEP 4: Attach Triggers to Entity Tables
|
|
-- ============================================================================
|
|
|
|
DROP TRIGGER IF EXISTS create_park_version_on_change ON public.parks;
|
|
CREATE TRIGGER create_park_version_on_change
|
|
AFTER INSERT OR UPDATE ON public.parks
|
|
FOR EACH ROW
|
|
EXECUTE FUNCTION public.create_relational_version();
|
|
|
|
DROP TRIGGER IF EXISTS create_ride_version_on_change ON public.rides;
|
|
CREATE TRIGGER create_ride_version_on_change
|
|
AFTER INSERT OR UPDATE ON public.rides
|
|
FOR EACH ROW
|
|
EXECUTE FUNCTION public.create_relational_version();
|
|
|
|
DROP TRIGGER IF EXISTS create_company_version_on_change ON public.companies;
|
|
CREATE TRIGGER create_company_version_on_change
|
|
AFTER INSERT OR UPDATE ON public.companies
|
|
FOR EACH ROW
|
|
EXECUTE FUNCTION public.create_relational_version();
|
|
|
|
DROP TRIGGER IF EXISTS create_ride_model_version_on_change ON public.ride_models;
|
|
CREATE TRIGGER create_ride_model_version_on_change
|
|
AFTER INSERT OR UPDATE ON public.ride_models
|
|
FOR EACH ROW
|
|
EXECUTE FUNCTION public.create_relational_version();
|
|
|
|
-- ============================================================================
|
|
-- STEP 5: Create RLS Policies
|
|
-- ============================================================================
|
|
|
|
-- Enable RLS on version tables
|
|
ALTER TABLE public.park_versions ENABLE ROW LEVEL SECURITY;
|
|
ALTER TABLE public.ride_versions ENABLE ROW LEVEL SECURITY;
|
|
ALTER TABLE public.company_versions ENABLE ROW LEVEL SECURITY;
|
|
ALTER TABLE public.ride_model_versions ENABLE ROW LEVEL SECURITY;
|
|
|
|
-- Public can view current versions
|
|
CREATE POLICY "Public can view current park versions"
|
|
ON public.park_versions FOR SELECT
|
|
USING (is_current = true);
|
|
|
|
CREATE POLICY "Public can view current ride versions"
|
|
ON public.ride_versions FOR SELECT
|
|
USING (is_current = true);
|
|
|
|
CREATE POLICY "Public can view current company versions"
|
|
ON public.company_versions FOR SELECT
|
|
USING (is_current = true);
|
|
|
|
CREATE POLICY "Public can view current ride model versions"
|
|
ON public.ride_model_versions FOR SELECT
|
|
USING (is_current = true);
|
|
|
|
-- Moderators can view all versions
|
|
CREATE POLICY "Moderators can view all park versions"
|
|
ON public.park_versions FOR SELECT
|
|
USING (is_moderator(auth.uid()));
|
|
|
|
CREATE POLICY "Moderators can view all ride versions"
|
|
ON public.ride_versions FOR SELECT
|
|
USING (is_moderator(auth.uid()));
|
|
|
|
CREATE POLICY "Moderators can view all company versions"
|
|
ON public.company_versions FOR SELECT
|
|
USING (is_moderator(auth.uid()));
|
|
|
|
CREATE POLICY "Moderators can view all ride model versions"
|
|
ON public.ride_model_versions FOR SELECT
|
|
USING (is_moderator(auth.uid()));
|
|
|
|
-- Users can view their own submitted versions
|
|
CREATE POLICY "Users can view their own park versions"
|
|
ON public.park_versions FOR SELECT
|
|
USING (created_by = auth.uid());
|
|
|
|
CREATE POLICY "Users can view their own ride versions"
|
|
ON public.ride_versions FOR SELECT
|
|
USING (created_by = auth.uid());
|
|
|
|
CREATE POLICY "Users can view their own company versions"
|
|
ON public.company_versions FOR SELECT
|
|
USING (created_by = auth.uid());
|
|
|
|
-- ============================================================================
|
|
-- STEP 6: Create Utility Functions
|
|
-- ============================================================================
|
|
|
|
-- Function to clean up old versions (keep last N versions per entity)
|
|
CREATE OR REPLACE FUNCTION public.cleanup_old_versions(
|
|
entity_type text,
|
|
keep_versions integer DEFAULT 50
|
|
)
|
|
RETURNS integer
|
|
LANGUAGE plpgsql
|
|
SECURITY DEFINER
|
|
SET search_path = public
|
|
AS $$
|
|
DECLARE
|
|
deleted_count integer := 0;
|
|
versions_table text;
|
|
entity_id_col text;
|
|
BEGIN
|
|
versions_table := entity_type || '_versions';
|
|
entity_id_col := entity_type || '_id';
|
|
|
|
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
|
|
)
|
|
', versions_table, entity_id_col, versions_table)
|
|
USING keep_versions;
|
|
|
|
GET DIAGNOSTICS deleted_count = ROW_COUNT;
|
|
|
|
RETURN deleted_count;
|
|
END;
|
|
$$;
|
|
|
|
-- Function to get version comparison
|
|
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
|
|
STABLE SECURITY DEFINER
|
|
SET search_path = public
|
|
AS $$
|
|
DECLARE
|
|
v_table text;
|
|
v_from_record jsonb;
|
|
v_to_record jsonb;
|
|
v_diff jsonb := '{}'::jsonb;
|
|
BEGIN
|
|
v_table := p_entity_type || '_versions';
|
|
|
|
-- Fetch both versions as JSONB for comparison
|
|
EXECUTE format('SELECT row_to_json(t)::jsonb FROM %I t WHERE version_id = $1', v_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_table)
|
|
INTO v_to_record
|
|
USING p_to_version_id;
|
|
|
|
-- Build diff object (simplified - just show changed fields)
|
|
SELECT jsonb_object_agg(key, jsonb_build_object('from', v_from_record->key, 'to', v_to_record->key))
|
|
INTO v_diff
|
|
FROM jsonb_each(v_to_record)
|
|
WHERE key NOT IN ('version_id', 'version_number', 'created_at', 'created_by', 'is_current', 'change_type', 'change_reason', 'submission_id')
|
|
AND v_from_record->key IS DISTINCT FROM v_to_record->key;
|
|
|
|
RETURN COALESCE(v_diff, '{}'::jsonb);
|
|
END;
|
|
$$; |