-- Drop the broken JSONB-based rollback function DROP FUNCTION IF EXISTS public.rollback_to_version(TEXT, UUID, UUID, UUID, TEXT); -- Create new relational rollback function with moderator-only access 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_entity_id_col TEXT; v_new_version_id UUID; v_version_data RECORD; BEGIN -- CRITICAL: Check authorization FIRST IF NOT is_moderator(p_changed_by) THEN RAISE EXCEPTION 'Only moderators can rollback versions' USING ERRCODE = '42501'; -- insufficient_privilege END IF; -- Validate entity type IF p_entity_type NOT IN ('park', 'ride', 'company', 'ride_model') THEN RAISE EXCEPTION 'Invalid entity type: %', p_entity_type; END IF; -- Determine table names v_version_table := p_entity_type || '_versions'; v_entity_id_col := p_entity_type || '_id'; v_entity_table := CASE p_entity_type WHEN 'park' THEN 'parks' WHEN 'ride' THEN 'rides' WHEN 'company' THEN 'companies' WHEN 'ride_model' THEN 'ride_models' END; -- Get the target version data EXECUTE format('SELECT * FROM %I WHERE version_id = $1', v_version_table) INTO v_version_data USING p_target_version_id; IF v_version_data IS NULL THEN RAISE EXCEPTION 'Version not found: %', p_target_version_id; END IF; -- Set session variables for trigger PERFORM set_config('app.current_user_id', p_changed_by::text, true); PERFORM set_config('app.submission_id', '', true); -- Restore entity data based on type IF p_entity_type = 'park' THEN UPDATE parks SET name = v_version_data.name, slug = v_version_data.slug, description = v_version_data.description, park_type = v_version_data.park_type, status = v_version_data.status, location_id = v_version_data.location_id, operator_id = v_version_data.operator_id, property_owner_id = v_version_data.property_owner_id, opening_date = v_version_data.opening_date, closing_date = v_version_data.closing_date, opening_date_precision = v_version_data.opening_date_precision, closing_date_precision = v_version_data.closing_date_precision, website_url = v_version_data.website_url, phone = v_version_data.phone, email = v_version_data.email, banner_image_url = v_version_data.banner_image_url, banner_image_id = v_version_data.banner_image_id, card_image_url = v_version_data.card_image_url, card_image_id = v_version_data.card_image_id, updated_at = NOW() WHERE id = p_entity_id; ELSIF p_entity_type = 'ride' THEN UPDATE rides SET name = v_version_data.name, slug = v_version_data.slug, description = v_version_data.description, category = v_version_data.category, status = v_version_data.status, park_id = v_version_data.park_id, manufacturer_id = v_version_data.manufacturer_id, designer_id = v_version_data.designer_id, ride_model_id = v_version_data.ride_model_id, opening_date = v_version_data.opening_date, closing_date = v_version_data.closing_date, opening_date_precision = v_version_data.opening_date_precision, closing_date_precision = v_version_data.closing_date_precision, height_requirement = v_version_data.height_requirement_cm, age_requirement = v_version_data.age_requirement, max_speed_kmh = v_version_data.max_speed_kmh, duration_seconds = v_version_data.duration_seconds, capacity_per_hour = v_version_data.capacity_per_hour, max_g_force = v_version_data.gforce_max, inversions = v_version_data.inversions_count, length_meters = v_version_data.length_meters, max_height_meters = v_version_data.height_meters, drop_height_meters = v_version_data.drop_meters, banner_image_url = v_version_data.banner_image_url, banner_image_id = v_version_data.banner_image_id, card_image_url = v_version_data.card_image_url, card_image_id = v_version_data.card_image_id, image_url = v_version_data.image_url, ride_sub_type = v_version_data.ride_sub_type, coaster_type = v_version_data.coaster_type, seating_type = v_version_data.seating_type, intensity_level = v_version_data.intensity_level, track_material = v_version_data.track_material, support_material = v_version_data.support_material, propulsion_method = v_version_data.propulsion_method, water_depth_cm = v_version_data.water_depth_cm, splash_height_meters = v_version_data.splash_height_meters, wetness_level = v_version_data.wetness_level, flume_type = v_version_data.flume_type, boat_capacity = v_version_data.boat_capacity, theme_name = v_version_data.theme_name, story_description = v_version_data.story_description, show_duration_seconds = v_version_data.show_duration_seconds, animatronics_count = v_version_data.animatronics_count, projection_type = v_version_data.projection_type, ride_system = v_version_data.ride_system, scenes_count = v_version_data.scenes_count, rotation_type = v_version_data.rotation_type, motion_pattern = v_version_data.motion_pattern, platform_count = v_version_data.platform_count, swing_angle_degrees = v_version_data.swing_angle_degrees, rotation_speed_rpm = v_version_data.rotation_speed_rpm, arm_length_meters = v_version_data.arm_length_meters, max_height_reached_meters = v_version_data.max_height_reached_meters, min_age = v_version_data.min_age, max_age = v_version_data.max_age, educational_theme = v_version_data.educational_theme, character_theme = v_version_data.character_theme, transport_type = v_version_data.transport_type, route_length_meters = v_version_data.route_length_meters, stations_count = v_version_data.stations_count, vehicle_capacity = v_version_data.vehicle_capacity, vehicles_count = v_version_data.vehicles_count, round_trip_duration_seconds = v_version_data.round_trip_duration_seconds, updated_at = NOW() WHERE id = p_entity_id; ELSIF p_entity_type = 'company' THEN UPDATE companies SET name = v_version_data.name, slug = v_version_data.slug, description = v_version_data.description, company_type = v_version_data.company_type, person_type = v_version_data.person_type, founded_year = v_version_data.founded_year, founded_date = v_version_data.founded_date, founded_date_precision = v_version_data.founded_date_precision, headquarters_location = v_version_data.headquarters_location, website_url = v_version_data.website_url, logo_url = v_version_data.logo_url, banner_image_url = v_version_data.banner_image_url, banner_image_id = v_version_data.banner_image_id, card_image_url = v_version_data.card_image_url, card_image_id = v_version_data.card_image_id, updated_at = NOW() WHERE id = p_entity_id; ELSIF p_entity_type = 'ride_model' THEN UPDATE ride_models SET name = v_version_data.name, slug = v_version_data.slug, manufacturer_id = v_version_data.manufacturer_id, category = v_version_data.category, ride_type = v_version_data.ride_type, description = v_version_data.description, banner_image_url = v_version_data.banner_image_url, banner_image_id = v_version_data.banner_image_id, card_image_url = v_version_data.card_image_url, card_image_id = v_version_data.card_image_id, updated_at = NOW() WHERE id = p_entity_id; END IF; -- Update the newly created version with restored change type and reason EXECUTE format(' UPDATE %I SET change_type = $1, change_reason = $2 WHERE %I = $3 AND is_current = true RETURNING version_id ', v_version_table, v_entity_id_col) INTO v_new_version_id USING 'restored'::version_change_type, 'Restored to version ' || v_version_data.version_number || ': ' || p_reason, p_entity_id; RETURN v_new_version_id; END; $$;