-- ═══════════════════════════════════════════════════════════════════ -- PHASE 3D: Standardize Submission Table Names (Final) -- ═══════════════════════════════════════════════════════════════════ CREATE TABLE public.ride_submission_coaster_statistics ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), ride_submission_id UUID NOT NULL, stat_name TEXT NOT NULL, stat_value NUMERIC NOT NULL, unit TEXT, category TEXT, created_at TIMESTAMPTZ NOT NULL DEFAULT now() ); CREATE TABLE public.ride_submission_name_history ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), ride_submission_id UUID NOT NULL, former_name TEXT NOT NULL, date_changed DATE, reason TEXT, order_index INTEGER DEFAULT 0, created_at TIMESTAMPTZ NOT NULL DEFAULT now() ); CREATE TABLE public.ride_submission_technical_specifications ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), ride_submission_id UUID NOT NULL, spec_name TEXT NOT NULL, spec_value TEXT NOT NULL, spec_type TEXT NOT NULL, unit TEXT, category TEXT, display_order INTEGER DEFAULT 0, created_at TIMESTAMPTZ NOT NULL DEFAULT now() ); -- Migrate data INSERT INTO public.ride_submission_coaster_statistics (id, ride_submission_id, stat_name, stat_value, unit, category, created_at) SELECT id, ride_submission_id, stat_name, stat_value, unit, category, created_at FROM public.ride_coaster_stats; INSERT INTO public.ride_submission_name_history (id, ride_submission_id, former_name, date_changed, reason, order_index, created_at) SELECT id, ride_submission_id, former_name, date_changed, reason, order_index, created_at FROM public.ride_former_names; INSERT INTO public.ride_submission_technical_specifications (id, ride_submission_id, spec_name, spec_value, spec_type, unit, category, created_at) SELECT id, ride_submission_id, spec_name, spec_value, spec_type, unit, category, created_at FROM public.ride_technical_specs; -- Create constraints ALTER TABLE public.ride_submission_coaster_statistics ADD CONSTRAINT fk_ride_submission_coaster_statistics_ride_submission_id FOREIGN KEY (ride_submission_id) REFERENCES public.ride_submissions(id) ON DELETE CASCADE; ALTER TABLE public.ride_submission_name_history ADD CONSTRAINT fk_ride_submission_name_history_ride_submission_id FOREIGN KEY (ride_submission_id) REFERENCES public.ride_submissions(id) ON DELETE CASCADE; ALTER TABLE public.ride_submission_technical_specifications ADD CONSTRAINT fk_ride_submission_technical_specifications_ride_submission_id FOREIGN KEY (ride_submission_id) REFERENCES public.ride_submissions(id) ON DELETE CASCADE; -- Create indexes CREATE INDEX idx_ride_submission_coaster_statistics_ride_submission_id ON public.ride_submission_coaster_statistics(ride_submission_id); CREATE INDEX idx_ride_submission_name_history_ride_submission_id ON public.ride_submission_name_history(ride_submission_id); CREATE INDEX idx_ride_submission_technical_specifications_ride_submission_id ON public.ride_submission_technical_specifications(ride_submission_id); -- Enable RLS ALTER TABLE public.ride_submission_coaster_statistics ENABLE ROW LEVEL SECURITY; ALTER TABLE public.ride_submission_name_history ENABLE ROW LEVEL SECURITY; ALTER TABLE public.ride_submission_technical_specifications ENABLE ROW LEVEL SECURITY; -- Create policies CREATE POLICY "Moderators can manage ride submission coaster statistics" ON public.ride_submission_coaster_statistics FOR ALL USING (is_moderator(auth.uid())); CREATE POLICY "Users can insert stats for their own ride submissions" ON public.ride_submission_coaster_statistics FOR INSERT WITH CHECK ( EXISTS ( SELECT 1 FROM ride_submissions rs JOIN content_submissions cs ON cs.id = rs.submission_id WHERE rs.id = ride_submission_coaster_statistics.ride_submission_id AND cs.user_id = auth.uid() ) ); CREATE POLICY "Users can view stats for their own ride submissions" ON public.ride_submission_coaster_statistics FOR SELECT USING ( is_moderator(auth.uid()) OR EXISTS ( SELECT 1 FROM ride_submissions rs JOIN content_submissions cs ON cs.id = rs.submission_id WHERE rs.id = ride_submission_coaster_statistics.ride_submission_id AND cs.user_id = auth.uid() ) ); CREATE POLICY "Moderators can manage ride submission name history" ON public.ride_submission_name_history FOR ALL USING (is_moderator(auth.uid())); CREATE POLICY "Users can insert former names for their own ride submissions" ON public.ride_submission_name_history FOR INSERT WITH CHECK ( EXISTS ( SELECT 1 FROM ride_submissions rs JOIN content_submissions cs ON cs.id = rs.submission_id WHERE rs.id = ride_submission_name_history.ride_submission_id AND cs.user_id = auth.uid() ) ); CREATE POLICY "Users can view former names for their own ride submissions" ON public.ride_submission_name_history FOR SELECT USING ( is_moderator(auth.uid()) OR EXISTS ( SELECT 1 FROM ride_submissions rs JOIN content_submissions cs ON cs.id = rs.submission_id WHERE rs.id = ride_submission_name_history.ride_submission_id AND cs.user_id = auth.uid() ) ); CREATE POLICY "Moderators can manage ride submission technical specifications" ON public.ride_submission_technical_specifications FOR ALL USING (is_moderator(auth.uid())); CREATE POLICY "Users can insert specs for their own ride submissions" ON public.ride_submission_technical_specifications FOR INSERT WITH CHECK ( EXISTS ( SELECT 1 FROM ride_submissions rs JOIN content_submissions cs ON cs.id = rs.submission_id WHERE rs.id = ride_submission_technical_specifications.ride_submission_id AND cs.user_id = auth.uid() ) ); CREATE POLICY "Users can view specs for their own ride submissions" ON public.ride_submission_technical_specifications FOR SELECT USING ( is_moderator(auth.uid()) OR EXISTS ( SELECT 1 FROM ride_submissions rs JOIN content_submissions cs ON cs.id = rs.submission_id WHERE rs.id = ride_submission_technical_specifications.ride_submission_id AND cs.user_id = auth.uid() ) ); -- Verify data integrity DO $$ DECLARE old_count INT; new_count INT; BEGIN SELECT COUNT(*) INTO old_count FROM public.ride_coaster_stats; SELECT COUNT(*) INTO new_count FROM public.ride_submission_coaster_statistics; IF old_count != new_count THEN RAISE EXCEPTION 'Coaster stats migration failed: old=%, new=%', old_count, new_count; END IF; SELECT COUNT(*) INTO old_count FROM public.ride_former_names; SELECT COUNT(*) INTO new_count FROM public.ride_submission_name_history; IF old_count != new_count THEN RAISE EXCEPTION 'Name history migration failed: old=%, new=%', old_count, new_count; END IF; SELECT COUNT(*) INTO old_count FROM public.ride_technical_specs; SELECT COUNT(*) INTO new_count FROM public.ride_submission_technical_specifications; IF old_count != new_count THEN RAISE EXCEPTION 'Technical specs migration failed: old=%, new=%', old_count, new_count; END IF; RAISE NOTICE 'Data integrity verified successfully'; END $$; -- Drop old tables DROP TABLE public.ride_coaster_stats CASCADE; DROP TABLE public.ride_former_names CASCADE; DROP TABLE public.ride_technical_specs CASCADE; -- Add documentation COMMENT ON TABLE public.ride_submission_coaster_statistics IS 'Coaster statistics for ride submissions (renamed from ride_coaster_stats)'; COMMENT ON TABLE public.ride_submission_name_history IS 'Name change history for ride submissions (renamed from ride_former_names)'; COMMENT ON TABLE public.ride_submission_technical_specifications IS 'Technical specifications for ride submissions (renamed from ride_technical_specs)';