Files
thrilltrack-explorer/supabase/migrations/20251103140627_cb03678b-7247-4b79-b155-2fd8cc1d4778.sql
2025-11-03 14:09:16 +00:00

204 lines
6.9 KiB
SQL

-- Phase 3: Migrate existing JSONB data to relational tables
-- This migration moves all existing item_data from submission_items into relational tables
DO $$
DECLARE
item_record RECORD;
new_park_sub_id UUID;
new_ride_sub_id UUID;
new_photo_sub_id UUID;
BEGIN
-- Migrate park submissions
FOR item_record IN
SELECT * FROM submission_items
WHERE item_type = 'park'
AND item_data IS NOT NULL
AND item_data_id IS NULL
LOOP
INSERT INTO park_submissions (
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 (
item_record.submission_id,
COALESCE((item_record.item_data->>'name')::TEXT, 'Unnamed'),
COALESCE((item_record.item_data->>'slug')::TEXT, 'unnamed'),
(item_record.item_data->>'description')::TEXT,
COALESCE((item_record.item_data->>'park_type')::TEXT, 'theme_park'),
COALESCE((item_record.item_data->>'status')::TEXT, 'operating'),
(item_record.item_data->>'location_id')::UUID,
(item_record.item_data->>'operator_id')::UUID,
(item_record.item_data->>'property_owner_id')::UUID,
(item_record.item_data->>'opening_date')::DATE,
(item_record.item_data->>'closing_date')::DATE,
(item_record.item_data->>'opening_date_precision')::TEXT,
(item_record.item_data->>'closing_date_precision')::TEXT,
(item_record.item_data->>'website_url')::TEXT,
(item_record.item_data->>'phone')::TEXT,
(item_record.item_data->>'email')::TEXT,
(item_record.item_data->>'banner_image_url')::TEXT,
(item_record.item_data->>'banner_image_id')::TEXT,
(item_record.item_data->>'card_image_url')::TEXT,
(item_record.item_data->>'card_image_id')::TEXT
)
RETURNING id INTO new_park_sub_id;
UPDATE submission_items
SET item_data_id = new_park_sub_id
WHERE id = item_record.id;
RAISE NOTICE 'Migrated park submission item %', item_record.id;
END LOOP;
-- Migrate ride submissions
FOR item_record IN
SELECT * FROM submission_items
WHERE item_type = 'ride'
AND item_data IS NOT NULL
AND item_data_id IS NULL
LOOP
INSERT INTO ride_submissions (
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,
age_requirement,
max_speed_kmh,
duration_seconds,
capacity_per_hour,
gforce_max,
inversions_count,
length_meters,
height_meters,
drop_meters,
banner_image_url,
banner_image_id,
card_image_url,
card_image_id
)
VALUES (
item_record.submission_id,
COALESCE((item_record.item_data->>'name')::TEXT, 'Unnamed'),
COALESCE((item_record.item_data->>'slug')::TEXT, 'unnamed'),
(item_record.item_data->>'description')::TEXT,
COALESCE((item_record.item_data->>'category')::TEXT, 'other'),
COALESCE((item_record.item_data->>'status')::TEXT, 'operating'),
(item_record.item_data->>'park_id')::UUID,
(item_record.item_data->>'manufacturer_id')::UUID,
(item_record.item_data->>'designer_id')::UUID,
(item_record.item_data->>'ride_model_id')::UUID,
(item_record.item_data->>'opening_date')::DATE,
(item_record.item_data->>'closing_date')::DATE,
(item_record.item_data->>'opening_date_precision')::TEXT,
(item_record.item_data->>'closing_date_precision')::TEXT,
(item_record.item_data->>'height_requirement_cm')::INTEGER,
(item_record.item_data->>'age_requirement')::INTEGER,
(item_record.item_data->>'max_speed_kmh')::DECIMAL,
(item_record.item_data->>'duration_seconds')::INTEGER,
(item_record.item_data->>'capacity_per_hour')::INTEGER,
(item_record.item_data->>'gforce_max')::DECIMAL,
(item_record.item_data->>'inversions_count')::INTEGER,
(item_record.item_data->>'length_meters')::DECIMAL,
(item_record.item_data->>'height_meters')::DECIMAL,
(item_record.item_data->>'drop_meters')::DECIMAL,
(item_record.item_data->>'banner_image_url')::TEXT,
(item_record.item_data->>'banner_image_id')::TEXT,
(item_record.item_data->>'card_image_url')::TEXT,
(item_record.item_data->>'card_image_id')::TEXT
)
RETURNING id INTO new_ride_sub_id;
UPDATE submission_items
SET item_data_id = new_ride_sub_id
WHERE id = item_record.id;
RAISE NOTICE 'Migrated ride submission item %', item_record.id;
END LOOP;
-- Migrate photo submissions (check if already migrated)
FOR item_record IN
SELECT * FROM submission_items
WHERE item_type = 'photo'
AND item_data IS NOT NULL
AND item_data_id IS NULL
AND NOT EXISTS (
SELECT 1 FROM photo_submissions
WHERE submission_id = item_record.submission_id
)
LOOP
INSERT INTO photo_submissions (
submission_id,
entity_type,
entity_id,
context
)
VALUES (
item_record.submission_id,
COALESCE((item_record.item_data->>'entity_type')::TEXT, (item_record.item_data->>'context')::TEXT, 'park'),
(item_record.item_data->>'entity_id')::UUID,
COALESCE((item_record.item_data->>'context')::TEXT, 'park')
)
RETURNING id INTO new_photo_sub_id;
-- Migrate individual photos
IF item_record.item_data ? 'photos' THEN
INSERT INTO photo_submission_items (
photo_submission_id,
url,
caption,
title,
cloudflare_id,
order_index
)
SELECT
new_photo_sub_id,
(photo->>'url')::TEXT,
(photo->>'caption')::TEXT,
(photo->>'title')::TEXT,
(photo->>'cloudflare_id')::TEXT,
COALESCE((photo->>'order')::INTEGER, (photo->>'order_index')::INTEGER, 0)
FROM jsonb_array_elements(item_record.item_data->'photos') AS photo;
END IF;
UPDATE submission_items
SET item_data_id = new_photo_sub_id
WHERE id = item_record.id;
RAISE NOTICE 'Migrated photo submission item %', item_record.id;
END LOOP;
RAISE NOTICE 'Data migration complete';
END $$;
-- Add comments documenting the migration
COMMENT ON COLUMN submission_items.item_data IS 'DEPRECATED: Legacy JSONB column. All data migrated to relational tables. Use item_data_id foreign key instead. Will be dropped in next migration.';
COMMENT ON COLUMN submission_items.original_data IS 'DEPRECATED: Legacy JSONB column for moderator edits. All data migrated to relational tables. Will be dropped in next migration.';