-- Database Migration SQL Script -- Run this with a database user that has CREATE privilege -- Command: psql -U postgres -d church_songlyric -f migration.sql -- OR connect as the database owner: -- psql -U songlyric_user -d church_songlyric -f migration.sql BEGIN; -- Add indexes for performance (10-100x faster queries) CREATE INDEX IF NOT EXISTS idx_profile_name ON profiles(name); CREATE INDEX IF NOT EXISTS idx_song_title ON songs(title); CREATE INDEX IF NOT EXISTS idx_song_artist ON songs(artist); CREATE INDEX IF NOT EXISTS idx_song_band ON songs(band); CREATE INDEX IF NOT EXISTS idx_plan_date ON plans(date); CREATE INDEX IF NOT EXISTS idx_plan_profile ON plans(profile_id); CREATE INDEX IF NOT EXISTS idx_plan_songs_plan ON plan_songs(plan_id); CREATE INDEX IF NOT EXISTS idx_plan_songs_order ON plan_songs(plan_id, order_index); CREATE INDEX IF NOT EXISTS idx_profile_songs_profile ON profile_songs(profile_id); CREATE INDEX IF NOT EXISTS idx_profile_song_keys ON profile_song_keys(profile_id, song_id); -- Add unique constraints to prevent duplicates -- Note: These will fail if duplicate data exists - clean data first -- Check for duplicates first: -- SELECT plan_id, song_id, COUNT(*) FROM plan_songs GROUP BY plan_id, song_id HAVING COUNT(*) > 1; -- SELECT profile_id, song_id, COUNT(*) FROM profile_songs GROUP BY profile_id, song_id HAVING COUNT(*) > 1; -- SELECT profile_id, song_id, COUNT(*) FROM profile_song_keys GROUP BY profile_id, song_id HAVING COUNT(*) > 1; DO $$ BEGIN IF NOT EXISTS ( SELECT 1 FROM pg_constraint WHERE conname = 'uq_plan_song' ) THEN ALTER TABLE plan_songs ADD CONSTRAINT uq_plan_song UNIQUE (plan_id, song_id); END IF; END $$; DO $$ BEGIN IF NOT EXISTS ( SELECT 1 FROM pg_constraint WHERE conname = 'uq_profile_song' ) THEN ALTER TABLE profile_songs ADD CONSTRAINT uq_profile_song UNIQUE (profile_id, song_id); END IF; END $$; DO $$ BEGIN IF NOT EXISTS ( SELECT 1 FROM pg_constraint WHERE conname = 'uq_profile_song_key' ) THEN ALTER TABLE profile_song_keys ADD CONSTRAINT uq_profile_song_key UNIQUE (profile_id, song_id); END IF; END $$; COMMIT; -- Verify indexes were created SELECT schemaname, tablename, indexname FROM pg_indexes WHERE tablename IN ('profiles', 'songs', 'plans', 'plan_songs', 'profile_songs', 'profile_song_keys') ORDER BY tablename, indexname; -- Verify constraints were created SELECT conname, contype, conrelid::regclass AS table_name FROM pg_constraint WHERE conname IN ('uq_plan_song', 'uq_profile_song', 'uq_profile_song_key');