-- JSONB Elimination Phase 2: Data Migration -- Migrate existing JSONB data to new relational tables -- ============================================================================ -- 1. MIGRATE COASTER_STATS DATA (if any exists) -- ============================================================================ -- Note: This migrates data from rides.coaster_stats JSONB to coaster_stats table -- Handle the migration carefully as JSONB structure may vary DO $$ DECLARE ride_record RECORD; stat_key TEXT; stat_val TEXT; BEGIN -- Check if coaster_stats column still exists before migrating IF EXISTS ( SELECT 1 FROM information_schema.columns WHERE table_schema = 'public' AND table_name = 'rides' AND column_name = 'coaster_stats' ) THEN -- Iterate through rides with coaster_stats FOR ride_record IN SELECT id, coaster_stats FROM public.rides WHERE coaster_stats IS NOT NULL AND jsonb_typeof(coaster_stats) = 'object' LOOP -- Extract each key-value pair from the JSONB object FOR stat_key, stat_val IN SELECT key, value::text FROM jsonb_each_text(ride_record.coaster_stats) LOOP -- Insert into coaster_stats table INSERT INTO public.coaster_stats (ride_id, stat_type, stat_value, display_order) VALUES (ride_record.id, stat_key, stat_val, 0) ON CONFLICT (ride_id, stat_type) DO NOTHING; END LOOP; END LOOP; RAISE NOTICE 'Migrated coaster_stats data successfully'; ELSE RAISE NOTICE 'coaster_stats column does not exist, skipping migration'; END IF; END $$; -- ============================================================================ -- 2. MIGRATE TECHNICAL_SPECS DATA (rides) -- ============================================================================ DO $$ DECLARE ride_record RECORD; spec_key TEXT; spec_val TEXT; BEGIN IF EXISTS ( SELECT 1 FROM information_schema.columns WHERE table_schema = 'public' AND table_name = 'rides' AND column_name = 'technical_specs' ) THEN FOR ride_record IN SELECT id, technical_specs FROM public.rides WHERE technical_specs IS NOT NULL AND jsonb_typeof(technical_specs) = 'object' LOOP FOR spec_key, spec_val IN SELECT key, value::text FROM jsonb_each_text(ride_record.technical_specs) LOOP INSERT INTO public.technical_specifications (entity_type, entity_id, spec_name, spec_value, display_order) VALUES ('ride', ride_record.id, spec_key, spec_val, 0) ON CONFLICT (entity_type, entity_id, spec_name) DO NOTHING; END LOOP; END LOOP; RAISE NOTICE 'Migrated ride technical_specs data successfully'; ELSE RAISE NOTICE 'rides.technical_specs column does not exist, skipping migration'; END IF; END $$; -- ============================================================================ -- 3. MIGRATE TECHNICAL_SPECS DATA (ride_models) -- ============================================================================ DO $$ DECLARE model_record RECORD; spec_key TEXT; spec_val TEXT; BEGIN IF EXISTS ( SELECT 1 FROM information_schema.columns WHERE table_schema = 'public' AND table_name = 'ride_models' AND column_name = 'technical_specs' ) THEN FOR model_record IN SELECT id, technical_specs FROM public.ride_models WHERE technical_specs IS NOT NULL AND jsonb_typeof(technical_specs) = 'object' LOOP FOR spec_key, spec_val IN SELECT key, value::text FROM jsonb_each_text(model_record.technical_specs) LOOP INSERT INTO public.technical_specifications (entity_type, entity_id, spec_name, spec_value, display_order) VALUES ('ride_model', model_record.id, spec_key, spec_val, 0) ON CONFLICT (entity_type, entity_id, spec_name) DO NOTHING; END LOOP; END LOOP; RAISE NOTICE 'Migrated ride_model technical_specs data successfully'; ELSE RAISE NOTICE 'ride_models.technical_specs column does not exist, skipping migration'; END IF; END $$; -- ============================================================================ -- 4. MIGRATE USER_TOP_LISTS ITEMS DATA -- ============================================================================ -- Note: items column should be a JSONB array like: [{"id": "uuid", "position": 1, "notes": "..."}] -- This requires checking if 'items' column exists and has proper structure DO $$ DECLARE list_record RECORD; item_record JSONB; BEGIN IF EXISTS ( SELECT 1 FROM information_schema.columns WHERE table_schema = 'public' AND table_name = 'user_top_lists' AND column_name = 'items' ) THEN FOR list_record IN SELECT id, items, list_type FROM public.user_top_lists WHERE items IS NOT NULL AND jsonb_typeof(items) = 'array' LOOP -- Iterate through array items FOR item_record IN SELECT * FROM jsonb_array_elements(list_record.items) LOOP -- Determine entity_type from list_type INSERT INTO public.list_items ( list_id, entity_type, entity_id, position, notes ) VALUES ( list_record.id, CASE list_record.list_type WHEN 'coasters' THEN 'coaster' WHEN 'rides' THEN 'ride' WHEN 'parks' THEN 'park' ELSE 'ride' END, (item_record->>'id')::UUID, (item_record->>'position')::INTEGER, item_record->>'notes' ) ON CONFLICT (list_id, position) DO NOTHING; END LOOP; END LOOP; RAISE NOTICE 'Migrated user_top_lists items data successfully'; ELSE RAISE NOTICE 'user_top_lists.items column does not exist, skipping migration'; END IF; END $$;