-- Script de vérification de l'état de la base de données -- À exécuter AVANT la migration pour diagnostiquer l'état actuel -- ======================================== -- VÉRIFICATION DES COLONNES -- ======================================== -- Vérifier si les colonnes de liens courts existent SELECT 'campaigns.slug' as column_name, CASE WHEN EXISTS ( SELECT 1 FROM information_schema.columns WHERE table_name = 'campaigns' AND column_name = 'slug' ) THEN '✅ Existe' ELSE '❌ Manquante' END as status UNION ALL SELECT 'participants.short_id' as column_name, CASE WHEN EXISTS ( SELECT 1 FROM information_schema.columns WHERE table_name = 'participants' AND column_name = 'short_id' ) THEN '✅ Existe' ELSE '❌ Manquante' END as status; -- ======================================== -- VÉRIFICATION DES FONCTIONS -- ======================================== -- Vérifier si les fonctions utilitaires existent SELECT 'generate_slug' as function_name, CASE WHEN EXISTS ( SELECT 1 FROM pg_proc p JOIN pg_namespace n ON p.pronamespace = n.oid WHERE p.proname = 'generate_slug' AND n.nspname = 'public' ) THEN '✅ Existe' ELSE '❌ Manquante' END as status UNION ALL SELECT 'generate_short_id' as function_name, CASE WHEN EXISTS ( SELECT 1 FROM pg_proc p JOIN pg_namespace n ON p.pronamespace = n.oid WHERE p.proname = 'generate_short_id' AND n.nspname = 'public' ) THEN '✅ Existe' ELSE '❌ Manquante' END as status UNION ALL SELECT 'replace_participant_votes' as function_name, CASE WHEN EXISTS ( SELECT 1 FROM pg_proc p JOIN pg_namespace n ON p.pronamespace = n.oid WHERE p.proname = 'replace_participant_votes' AND n.nspname = 'public' ) THEN '✅ Existe' ELSE '❌ Manquante' END as status; -- ======================================== -- VÉRIFICATION DES INDEX -- ======================================== -- Vérifier si les index de performance existent SELECT 'idx_campaigns_slug' as index_name, CASE WHEN EXISTS ( SELECT 1 FROM pg_indexes WHERE indexname = 'idx_campaigns_slug' ) THEN '✅ Existe' ELSE '❌ Manquant' END as status UNION ALL SELECT 'idx_participants_short_id' as index_name, CASE WHEN EXISTS ( SELECT 1 FROM pg_indexes WHERE indexname = 'idx_participants_short_id' ) THEN '✅ Existe' ELSE '❌ Manquant' END as status; -- ======================================== -- ANALYSE DES DONNÉES EXISTANTES -- ======================================== -- Compter les campagnes et leur état (version sécurisée) DO $$ DECLARE campaigns_total INTEGER; campaigns_with_slug INTEGER := 0; participants_total INTEGER; participants_with_short_id INTEGER := 0; slug_exists BOOLEAN; short_id_exists BOOLEAN; BEGIN -- Vérifier si les colonnes existent SELECT EXISTS ( SELECT 1 FROM information_schema.columns WHERE table_name = 'campaigns' AND column_name = 'slug' ) INTO slug_exists; SELECT EXISTS ( SELECT 1 FROM information_schema.columns WHERE table_name = 'participants' AND column_name = 'short_id' ) INTO short_id_exists; -- Compter les campagnes SELECT COUNT(*) INTO campaigns_total FROM campaigns; -- Compter les participants SELECT COUNT(*) INTO participants_total FROM participants; -- Compter les campagnes avec slug si la colonne existe IF slug_exists THEN SELECT COUNT(*) INTO campaigns_with_slug FROM campaigns WHERE slug IS NOT NULL; END IF; -- Compter les participants avec short_id si la colonne existe IF short_id_exists THEN SELECT COUNT(*) INTO participants_with_short_id FROM participants WHERE short_id IS NOT NULL; END IF; -- Afficher les résultats RAISE NOTICE '=== ANALYSE DES DONNÉES ==='; RAISE NOTICE 'Campagnes totales: %', campaigns_total; IF slug_exists THEN RAISE NOTICE 'Campagnes avec slug: %', campaigns_with_slug; RAISE NOTICE 'Campagnes sans slug: %', campaigns_total - campaigns_with_slug; ELSE RAISE NOTICE 'Colonne slug: ❌ N''existe pas encore'; END IF; RAISE NOTICE 'Participants totaux: %', participants_total; IF short_id_exists THEN RAISE NOTICE 'Participants avec short_id: %', participants_with_short_id; RAISE NOTICE 'Participants sans short_id: %', participants_total - participants_with_short_id; ELSE RAISE NOTICE 'Colonne short_id: ❌ N''existe pas encore'; END IF; END $$; -- ======================================== -- EXEMPLES DE DONNÉES EXISTANTES -- ======================================== -- Afficher quelques exemples de campagnes (version sécurisée) DO $$ DECLARE slug_exists BOOLEAN; r RECORD; BEGIN -- Vérifier si la colonne slug existe SELECT EXISTS ( SELECT 1 FROM information_schema.columns WHERE table_name = 'campaigns' AND column_name = 'slug' ) INTO slug_exists; IF slug_exists THEN RAISE NOTICE '=== EXEMPLES DE CAMPAGNES ==='; FOR r IN SELECT id, title, slug, CASE WHEN slug IS NULL THEN '❌ Besoin de migration' ELSE '✅ OK' END as status FROM campaigns ORDER BY created_at DESC LIMIT 5 LOOP RAISE NOTICE 'ID: %, Titre: %, Slug: %, Status: %', r.id, r.title, r.slug, r.status; END LOOP; ELSE RAISE NOTICE '=== EXEMPLES DE CAMPAGNES ==='; FOR r IN SELECT id, title FROM campaigns ORDER BY created_at DESC LIMIT 5 LOOP RAISE NOTICE 'ID: %, Titre: %, Slug: ❌ Colonne inexistante', r.id, r.title; END LOOP; END IF; END $$; -- Afficher quelques exemples de participants (version sécurisée) DO $$ DECLARE short_id_exists BOOLEAN; r RECORD; BEGIN -- Vérifier si la colonne short_id existe SELECT EXISTS ( SELECT 1 FROM information_schema.columns WHERE table_name = 'participants' AND column_name = 'short_id' ) INTO short_id_exists; IF short_id_exists THEN RAISE NOTICE '=== EXEMPLES DE PARTICIPANTS ==='; FOR r IN SELECT id, first_name, last_name, short_id, CASE WHEN short_id IS NULL THEN '❌ Besoin de migration' ELSE '✅ OK' END as status FROM participants ORDER BY created_at DESC LIMIT 5 LOOP RAISE NOTICE 'ID: %, Nom: % %, Short ID: %, Status: %', r.id, r.first_name, r.last_name, r.short_id, r.status; END LOOP; ELSE RAISE NOTICE '=== EXEMPLES DE PARTICIPANTS ==='; FOR r IN SELECT id, first_name, last_name FROM participants ORDER BY created_at DESC LIMIT 5 LOOP RAISE NOTICE 'ID: %, Nom: % %, Short ID: ❌ Colonne inexistante', r.id, r.first_name, r.last_name; END LOOP; END IF; END $$; -- ======================================== -- RECOMMANDATIONS -- ======================================== DO $$ DECLARE missing_slug_count INTEGER := 0; missing_short_id_count INTEGER := 0; missing_functions INTEGER; missing_indexes INTEGER; slug_exists BOOLEAN; short_id_exists BOOLEAN; BEGIN -- Vérifier si les colonnes existent SELECT EXISTS ( SELECT 1 FROM information_schema.columns WHERE table_name = 'campaigns' AND column_name = 'slug' ) INTO slug_exists; SELECT EXISTS ( SELECT 1 FROM information_schema.columns WHERE table_name = 'participants' AND column_name = 'short_id' ) INTO short_id_exists; -- Compter les éléments manquants seulement si les colonnes existent IF slug_exists THEN SELECT COUNT(*) INTO missing_slug_count FROM campaigns WHERE slug IS NULL; ELSE SELECT COUNT(*) INTO missing_slug_count FROM campaigns; END IF; IF short_id_exists THEN SELECT COUNT(*) INTO missing_short_id_count FROM participants WHERE short_id IS NULL; ELSE SELECT COUNT(*) INTO missing_short_id_count FROM participants; END IF; SELECT COUNT(*) INTO missing_functions FROM ( SELECT 'generate_slug' as func UNION ALL SELECT 'generate_short_id' UNION ALL SELECT 'replace_participant_votes' ) f WHERE NOT EXISTS ( SELECT 1 FROM pg_proc p JOIN pg_namespace n ON p.pronamespace = n.oid WHERE p.proname = f.func AND n.nspname = 'public' ); SELECT COUNT(*) INTO missing_indexes FROM ( SELECT 'idx_campaigns_slug' as idx UNION ALL SELECT 'idx_participants_short_id' ) i WHERE NOT EXISTS ( SELECT 1 FROM pg_indexes WHERE indexname = i.idx ); RAISE NOTICE '=== RECOMMANDATIONS ==='; IF missing_slug_count > 0 OR missing_short_id_count > 0 OR missing_functions > 0 OR missing_indexes > 0 THEN RAISE NOTICE '🔄 Migration nécessaire !'; IF missing_slug_count > 0 THEN IF slug_exists THEN RAISE NOTICE ' - % campagnes ont besoin d''un slug', missing_slug_count; ELSE RAISE NOTICE ' - % campagnes ont besoin de la colonne slug + génération', missing_slug_count; END IF; END IF; IF missing_short_id_count > 0 THEN IF short_id_exists THEN RAISE NOTICE ' - % participants ont besoin d''un short_id', missing_short_id_count; ELSE RAISE NOTICE ' - % participants ont besoin de la colonne short_id + génération', missing_short_id_count; END IF; END IF; IF missing_functions > 0 THEN RAISE NOTICE ' - % fonctions utilitaires manquantes', missing_functions; END IF; IF missing_indexes > 0 THEN RAISE NOTICE ' - % index de performance manquants', missing_indexes; END IF; RAISE NOTICE ' → Exécutez le script migration-to-latest-schema.sql'; ELSE RAISE NOTICE '✅ Base de données à jour ! Aucune migration nécessaire.'; END IF; END $$;