Files
thrilltrack-explorer/supabase/migrations/20251030132028_dbb807b7-d635-4074-ba43-a7306a9c1444.sql
2025-10-30 13:20:57 +00:00

209 lines
12 KiB
PL/PgSQL

-- Add category-specific fields to ride_versions table for complete version tracking
-- Water Ride Fields
ALTER TABLE public.ride_versions ADD COLUMN water_depth_cm INTEGER;
ALTER TABLE public.ride_versions ADD COLUMN splash_height_meters NUMERIC(5,2);
ALTER TABLE public.ride_versions ADD COLUMN wetness_level TEXT;
ALTER TABLE public.ride_versions ADD COLUMN flume_type TEXT;
ALTER TABLE public.ride_versions ADD COLUMN boat_capacity INTEGER;
-- Dark Ride Fields
ALTER TABLE public.ride_versions ADD COLUMN theme_name TEXT;
ALTER TABLE public.ride_versions ADD COLUMN story_description TEXT;
ALTER TABLE public.ride_versions ADD COLUMN show_duration_seconds INTEGER;
ALTER TABLE public.ride_versions ADD COLUMN animatronics_count INTEGER;
ALTER TABLE public.ride_versions ADD COLUMN projection_type TEXT;
ALTER TABLE public.ride_versions ADD COLUMN ride_system TEXT;
ALTER TABLE public.ride_versions ADD COLUMN scenes_count INTEGER;
-- Flat Ride Fields
ALTER TABLE public.ride_versions ADD COLUMN rotation_type TEXT;
ALTER TABLE public.ride_versions ADD COLUMN motion_pattern TEXT;
ALTER TABLE public.ride_versions ADD COLUMN platform_count INTEGER;
ALTER TABLE public.ride_versions ADD COLUMN swing_angle_degrees INTEGER;
ALTER TABLE public.ride_versions ADD COLUMN rotation_speed_rpm INTEGER;
ALTER TABLE public.ride_versions ADD COLUMN arm_length_meters NUMERIC(5,2);
ALTER TABLE public.ride_versions ADD COLUMN max_height_reached_meters NUMERIC(5,2);
-- Kiddie Ride Fields
ALTER TABLE public.ride_versions ADD COLUMN min_age INTEGER;
ALTER TABLE public.ride_versions ADD COLUMN max_age INTEGER;
ALTER TABLE public.ride_versions ADD COLUMN educational_theme TEXT;
ALTER TABLE public.ride_versions ADD COLUMN character_theme TEXT;
-- Transportation Fields
ALTER TABLE public.ride_versions ADD COLUMN transport_type TEXT;
ALTER TABLE public.ride_versions ADD COLUMN route_length_meters NUMERIC(8,2);
ALTER TABLE public.ride_versions ADD COLUMN stations_count INTEGER;
ALTER TABLE public.ride_versions ADD COLUMN vehicle_capacity INTEGER;
ALTER TABLE public.ride_versions ADD COLUMN vehicles_count INTEGER;
ALTER TABLE public.ride_versions ADD COLUMN round_trip_duration_seconds INTEGER;
-- Add check constraints matching rides table
ALTER TABLE public.ride_versions ADD CONSTRAINT ride_versions_wetness_level_check
CHECK (wetness_level IS NULL OR wetness_level IN ('none', 'light', 'moderate', 'heavy', 'soaking'));
ALTER TABLE public.ride_versions ADD CONSTRAINT ride_versions_rotation_type_check
CHECK (rotation_type IS NULL OR rotation_type IN ('spinning', 'swinging', 'rotating', 'tilting', 'orbiting', 'none'));
ALTER TABLE public.ride_versions ADD CONSTRAINT ride_versions_transport_type_check
CHECK (transport_type IS NULL OR transport_type IN ('monorail', 'train', 'skyride', 'chairlift', 'people_mover', 'tram', 'ferry', 'other'));
-- Add comments for documentation
COMMENT ON COLUMN public.ride_versions.water_depth_cm IS 'Water depth in centimeters (water rides)';
COMMENT ON COLUMN public.ride_versions.splash_height_meters IS 'Maximum splash height in meters (water rides)';
COMMENT ON COLUMN public.ride_versions.wetness_level IS 'Expected wetness level: none, light, moderate, heavy, soaking';
COMMENT ON COLUMN public.ride_versions.flume_type IS 'Type of flume/channel (water rides)';
COMMENT ON COLUMN public.ride_versions.boat_capacity IS 'Passengers per boat/log (water rides)';
COMMENT ON COLUMN public.ride_versions.theme_name IS 'Name of the theme/story (dark rides)';
COMMENT ON COLUMN public.ride_versions.story_description IS 'Description of the story/narrative (dark rides)';
COMMENT ON COLUMN public.ride_versions.show_duration_seconds IS 'Duration of show elements in seconds (dark rides)';
COMMENT ON COLUMN public.ride_versions.animatronics_count IS 'Number of animatronic figures (dark rides)';
COMMENT ON COLUMN public.ride_versions.projection_type IS 'Type of projection technology used (dark rides)';
COMMENT ON COLUMN public.ride_versions.ride_system IS 'Type of ride system/track (dark rides)';
COMMENT ON COLUMN public.ride_versions.scenes_count IS 'Number of distinct scenes (dark rides)';
COMMENT ON COLUMN public.ride_versions.rotation_type IS 'Type of rotation: spinning, swinging, rotating, tilting, orbiting, none';
COMMENT ON COLUMN public.ride_versions.motion_pattern IS 'Description of motion pattern (flat rides)';
COMMENT ON COLUMN public.ride_versions.platform_count IS 'Number of platforms/arms (flat rides)';
COMMENT ON COLUMN public.ride_versions.swing_angle_degrees IS 'Maximum swing angle in degrees (flat rides)';
COMMENT ON COLUMN public.ride_versions.rotation_speed_rpm IS 'Rotation speed in RPM (flat rides)';
COMMENT ON COLUMN public.ride_versions.arm_length_meters IS 'Length of ride arms in meters (flat rides)';
COMMENT ON COLUMN public.ride_versions.max_height_reached_meters IS 'Maximum height reached during ride cycle (flat rides)';
COMMENT ON COLUMN public.ride_versions.min_age IS 'Minimum recommended age (kiddie rides)';
COMMENT ON COLUMN public.ride_versions.max_age IS 'Maximum recommended age (kiddie rides)';
COMMENT ON COLUMN public.ride_versions.educational_theme IS 'Educational theme/purpose (kiddie rides)';
COMMENT ON COLUMN public.ride_versions.character_theme IS 'Character or IP theme (kiddie rides)';
COMMENT ON COLUMN public.ride_versions.transport_type IS 'Type of transportation: monorail, train, skyride, chairlift, people_mover, tram, ferry, other';
COMMENT ON COLUMN public.ride_versions.route_length_meters IS 'Length of the route in meters (transportation)';
COMMENT ON COLUMN public.ride_versions.stations_count IS 'Number of stations/stops (transportation)';
COMMENT ON COLUMN public.ride_versions.vehicle_capacity IS 'Capacity per vehicle (transportation)';
COMMENT ON COLUMN public.ride_versions.vehicles_count IS 'Total number of vehicles in operation (transportation)';
COMMENT ON COLUMN public.ride_versions.round_trip_duration_seconds IS 'Duration of complete round trip in seconds (transportation)';
-- Update the create_relational_version function to include all new fields
CREATE OR REPLACE FUNCTION public.create_relational_version()
RETURNS TRIGGER
LANGUAGE plpgsql
SECURITY DEFINER
SET search_path = public
AS $function$
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,
water_depth_cm, splash_height_meters, wetness_level, flume_type, boat_capacity,
theme_name, story_description, show_duration_seconds, animatronics_count, projection_type, ride_system, scenes_count,
rotation_type, motion_pattern, platform_count, swing_angle_degrees, rotation_speed_rpm, arm_length_meters, max_height_reached_meters,
min_age, max_age, educational_theme, character_theme,
transport_type, route_length_meters, stations_count, vehicle_capacity, vehicles_count, round_trip_duration_seconds
) 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,
NEW.water_depth_cm, NEW.splash_height_meters, NEW.wetness_level, NEW.flume_type, NEW.boat_capacity,
NEW.theme_name, NEW.story_description, NEW.show_duration_seconds, NEW.animatronics_count, NEW.projection_type, NEW.ride_system, NEW.scenes_count,
NEW.rotation_type, NEW.motion_pattern, NEW.platform_count, NEW.swing_angle_degrees, NEW.rotation_speed_rpm, NEW.arm_length_meters, NEW.max_height_reached_meters,
NEW.min_age, NEW.max_age, NEW.educational_theme, NEW.character_theme,
NEW.transport_type, NEW.route_length_meters, NEW.stations_count, NEW.vehicle_capacity, NEW.vehicles_count, NEW.round_trip_duration_seconds
);
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;
$function$;