-- JSONB Elimination - Final Cleanup and Relational Data Handler -- Ensures all relational tables exist with proper RLS policies -- ============================================================================ -- 1. ENSURE RELATIONAL TABLES EXIST -- ============================================================================ -- Ride Technical Specifications (already exists, ensure RLS) DO $$ BEGIN IF NOT EXISTS ( SELECT 1 FROM pg_tables WHERE schemaname = 'public' AND tablename = 'ride_technical_specifications' ) THEN CREATE TABLE public.ride_technical_specifications ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), ride_id UUID NOT NULL REFERENCES public.rides(id) ON DELETE CASCADE, spec_name TEXT NOT NULL, spec_value TEXT NOT NULL, spec_unit TEXT, category TEXT, display_order INTEGER DEFAULT 0, created_at TIMESTAMPTZ DEFAULT NOW(), CONSTRAINT ride_technical_specifications_unique UNIQUE(ride_id, spec_name) ); CREATE INDEX idx_ride_technical_specifications_ride_id ON public.ride_technical_specifications(ride_id); END IF; END $$; -- Ride Model Technical Specifications (already exists, ensure RLS) DO $$ BEGIN IF NOT EXISTS ( SELECT 1 FROM pg_tables WHERE schemaname = 'public' AND tablename = 'ride_model_technical_specifications' ) THEN CREATE TABLE public.ride_model_technical_specifications ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), ride_model_id UUID NOT NULL REFERENCES public.ride_models(id) ON DELETE CASCADE, spec_name TEXT NOT NULL, spec_value TEXT NOT NULL, spec_unit TEXT, category TEXT, display_order INTEGER DEFAULT 0, created_at TIMESTAMPTZ DEFAULT NOW(), CONSTRAINT ride_model_technical_specifications_unique UNIQUE(ride_model_id, spec_name) ); CREATE INDEX idx_ride_model_technical_specifications_ride_model_id ON public.ride_model_technical_specifications(ride_model_id); END IF; END $$; -- Ride Coaster Stats (already exists, ensure RLS) DO $$ BEGIN IF NOT EXISTS ( SELECT 1 FROM pg_tables WHERE schemaname = 'public' AND tablename = 'ride_coaster_stats' ) THEN CREATE TABLE public.ride_coaster_stats ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), ride_id UUID NOT NULL REFERENCES public.rides(id) ON DELETE CASCADE, stat_name TEXT NOT NULL, stat_value NUMERIC NOT NULL, unit TEXT, category TEXT, description TEXT, display_order INTEGER DEFAULT 0, created_at TIMESTAMPTZ DEFAULT NOW(), CONSTRAINT ride_coaster_stats_unique UNIQUE(ride_id, stat_name) ); CREATE INDEX idx_ride_coaster_stats_ride_id ON public.ride_coaster_stats(ride_id); END IF; END $$; -- Ride Name History (already exists, ensure RLS) DO $$ BEGIN IF NOT EXISTS ( SELECT 1 FROM pg_tables WHERE schemaname = 'public' AND tablename = 'ride_name_history' ) THEN CREATE TABLE public.ride_name_history ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), ride_id UUID NOT NULL REFERENCES public.rides(id) ON DELETE CASCADE, former_name TEXT NOT NULL, date_changed DATE, reason TEXT, from_year INTEGER, to_year INTEGER, order_index INTEGER DEFAULT 0, created_at TIMESTAMPTZ DEFAULT NOW() ); CREATE INDEX idx_ride_name_history_ride_id ON public.ride_name_history(ride_id); END IF; END $$; -- ============================================================================ -- 2. ENABLE RLS ON ALL RELATIONAL TABLES -- ============================================================================ ALTER TABLE public.ride_technical_specifications ENABLE ROW LEVEL SECURITY; ALTER TABLE public.ride_model_technical_specifications ENABLE ROW LEVEL SECURITY; ALTER TABLE public.ride_coaster_stats ENABLE ROW LEVEL SECURITY; ALTER TABLE public.ride_name_history ENABLE ROW LEVEL SECURITY; -- ============================================================================ -- 3. CREATE RLS POLICIES -- ============================================================================ -- Ride Technical Specifications Policies DROP POLICY IF EXISTS "Public read ride tech specs" ON public.ride_technical_specifications; DROP POLICY IF EXISTS "Moderators manage ride tech specs" ON public.ride_technical_specifications; CREATE POLICY "Public read ride tech specs" ON public.ride_technical_specifications FOR SELECT USING (true); CREATE POLICY "Moderators manage ride tech specs" ON public.ride_technical_specifications FOR ALL USING (is_moderator(auth.uid())); -- Ride Model Technical Specifications Policies DROP POLICY IF EXISTS "Public read model tech specs" ON public.ride_model_technical_specifications; DROP POLICY IF EXISTS "Moderators manage model tech specs" ON public.ride_model_technical_specifications; CREATE POLICY "Public read model tech specs" ON public.ride_model_technical_specifications FOR SELECT USING (true); CREATE POLICY "Moderators manage model tech specs" ON public.ride_model_technical_specifications FOR ALL USING (is_moderator(auth.uid())); -- Ride Coaster Stats Policies DROP POLICY IF EXISTS "Public read coaster stats" ON public.ride_coaster_stats; DROP POLICY IF EXISTS "Moderators manage coaster stats" ON public.ride_coaster_stats; CREATE POLICY "Public read coaster stats" ON public.ride_coaster_stats FOR SELECT USING (true); CREATE POLICY "Moderators manage coaster stats" ON public.ride_coaster_stats FOR ALL USING (is_moderator(auth.uid())); -- Ride Name History Policies DROP POLICY IF EXISTS "Public read name history" ON public.ride_name_history; DROP POLICY IF EXISTS "Moderators manage name history" ON public.ride_name_history; CREATE POLICY "Public read name history" ON public.ride_name_history FOR SELECT USING (true); CREATE POLICY "Moderators manage name history" ON public.ride_name_history FOR ALL USING (is_moderator(auth.uid())); -- ============================================================================ -- 4. VERIFY JSONB COLUMNS DROPPED -- ============================================================================ -- These should already be dropped, but verify DO $$ BEGIN -- Check rides table IF EXISTS ( SELECT 1 FROM information_schema.columns WHERE table_schema = 'public' AND table_name = 'rides' AND column_name IN ('coaster_stats', 'technical_specs', 'former_names') ) THEN RAISE WARNING 'JSONB columns still exist in rides table - should have been dropped'; END IF; -- Check ride_models table IF EXISTS ( SELECT 1 FROM information_schema.columns WHERE table_schema = 'public' AND table_name = 'ride_models' AND column_name = 'technical_specs' ) THEN RAISE WARNING 'JSONB column still exists in ride_models table - should have been dropped'; END IF; -- Check user_top_lists table IF EXISTS ( SELECT 1 FROM information_schema.columns WHERE table_schema = 'public' AND table_name = 'user_top_lists' AND column_name = 'items' ) THEN RAISE WARNING 'JSONB column still exists in user_top_lists table - should have been dropped'; END IF; END $$; -- ============================================================================ -- SUCCESS VERIFICATION -- ============================================================================ DO $$ BEGIN RAISE NOTICE 'JSONB Elimination Complete!'; RAISE NOTICE '✅ All relational tables created'; RAISE NOTICE '✅ RLS policies enabled'; RAISE NOTICE '✅ JSONB columns verified dropped'; RAISE NOTICE '✅ Ready for relational data insertion'; END $$;