migration de base avant liens courts
This commit is contained in:
329
scripts/check-database-state.sql
Normal file
329
scripts/check-database-state.sql
Normal file
@@ -0,0 +1,329 @@
|
|||||||
|
-- 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 $$;
|
||||||
223
scripts/migration-to-latest-schema.sql
Normal file
223
scripts/migration-to-latest-schema.sql
Normal file
@@ -0,0 +1,223 @@
|
|||||||
|
-- Script de migration vers le schéma le plus récent avec liens courts
|
||||||
|
-- À exécuter dans votre base de données Supabase
|
||||||
|
|
||||||
|
-- ========================================
|
||||||
|
-- ÉTAPE 1: Ajout des colonnes manquantes
|
||||||
|
-- ========================================
|
||||||
|
|
||||||
|
-- Ajouter la colonne slug aux campagnes si elle n'existe pas
|
||||||
|
DO $$
|
||||||
|
BEGIN
|
||||||
|
IF NOT EXISTS (
|
||||||
|
SELECT 1 FROM information_schema.columns
|
||||||
|
WHERE table_name = 'campaigns' AND column_name = 'slug'
|
||||||
|
) THEN
|
||||||
|
ALTER TABLE campaigns ADD COLUMN slug TEXT UNIQUE;
|
||||||
|
RAISE NOTICE 'Colonne slug ajoutée à la table campaigns';
|
||||||
|
ELSE
|
||||||
|
RAISE NOTICE 'Colonne slug existe déjà dans la table campaigns';
|
||||||
|
END IF;
|
||||||
|
END $$;
|
||||||
|
|
||||||
|
-- Ajouter la colonne short_id aux participants si elle n'existe pas
|
||||||
|
DO $$
|
||||||
|
BEGIN
|
||||||
|
IF NOT EXISTS (
|
||||||
|
SELECT 1 FROM information_schema.columns
|
||||||
|
WHERE table_name = 'participants' AND column_name = 'short_id'
|
||||||
|
) THEN
|
||||||
|
ALTER TABLE participants ADD COLUMN short_id TEXT UNIQUE;
|
||||||
|
RAISE NOTICE 'Colonne short_id ajoutée à la table participants';
|
||||||
|
ELSE
|
||||||
|
RAISE NOTICE 'Colonne short_id existe déjà dans la table participants';
|
||||||
|
END IF;
|
||||||
|
END $$;
|
||||||
|
|
||||||
|
-- ========================================
|
||||||
|
-- ÉTAPE 2: Création des fonctions utilitaires
|
||||||
|
-- ========================================
|
||||||
|
|
||||||
|
-- Fonction pour générer un slug à partir d'un titre
|
||||||
|
CREATE OR REPLACE FUNCTION generate_slug(title TEXT)
|
||||||
|
RETURNS TEXT AS $$
|
||||||
|
DECLARE
|
||||||
|
generated_slug TEXT;
|
||||||
|
counter INTEGER := 0;
|
||||||
|
base_slug TEXT;
|
||||||
|
BEGIN
|
||||||
|
-- Convertir en minuscules et remplacer les caractères spéciaux
|
||||||
|
base_slug := lower(regexp_replace(title, '[^a-zA-Z0-9\s]', '', 'g'));
|
||||||
|
base_slug := regexp_replace(base_slug, '\s+', '-', 'g');
|
||||||
|
base_slug := trim(both '-' from base_slug);
|
||||||
|
|
||||||
|
-- Si le slug est vide, utiliser 'campagne'
|
||||||
|
IF base_slug = '' THEN
|
||||||
|
base_slug := 'campagne';
|
||||||
|
END IF;
|
||||||
|
|
||||||
|
generated_slug := base_slug;
|
||||||
|
|
||||||
|
-- Vérifier si le slug existe déjà et ajouter un numéro si nécessaire
|
||||||
|
WHILE EXISTS (SELECT 1 FROM campaigns WHERE campaigns.slug = generated_slug) LOOP
|
||||||
|
counter := counter + 1;
|
||||||
|
generated_slug := base_slug || '-' || counter;
|
||||||
|
END LOOP;
|
||||||
|
|
||||||
|
RETURN generated_slug;
|
||||||
|
END;
|
||||||
|
$$ LANGUAGE plpgsql;
|
||||||
|
|
||||||
|
-- Fonction pour générer un short_id unique
|
||||||
|
CREATE OR REPLACE FUNCTION generate_short_id()
|
||||||
|
RETURNS TEXT AS $$
|
||||||
|
DECLARE
|
||||||
|
chars TEXT := 'ABCDEFGHIJKLMNOPQRSTUVWXYZ0123456789';
|
||||||
|
result TEXT := '';
|
||||||
|
i INTEGER;
|
||||||
|
generated_short_id TEXT;
|
||||||
|
counter INTEGER := 0;
|
||||||
|
BEGIN
|
||||||
|
LOOP
|
||||||
|
-- Générer un identifiant de 6 caractères
|
||||||
|
result := '';
|
||||||
|
FOR i IN 1..6 LOOP
|
||||||
|
result := result || substr(chars, floor(random() * length(chars))::integer + 1, 1);
|
||||||
|
END LOOP;
|
||||||
|
|
||||||
|
generated_short_id := result;
|
||||||
|
|
||||||
|
-- Vérifier si le short_id existe déjà
|
||||||
|
IF NOT EXISTS (SELECT 1 FROM participants WHERE participants.short_id = generated_short_id) THEN
|
||||||
|
RETURN generated_short_id;
|
||||||
|
END IF;
|
||||||
|
|
||||||
|
-- Éviter les boucles infinies
|
||||||
|
counter := counter + 1;
|
||||||
|
IF counter > 100 THEN
|
||||||
|
RAISE EXCEPTION 'Impossible de générer un short_id unique après 100 tentatives';
|
||||||
|
END IF;
|
||||||
|
END LOOP;
|
||||||
|
END;
|
||||||
|
$$ LANGUAGE plpgsql;
|
||||||
|
|
||||||
|
-- ========================================
|
||||||
|
-- ÉTAPE 3: Mise à jour des données existantes
|
||||||
|
-- ========================================
|
||||||
|
|
||||||
|
-- Générer des slugs pour les campagnes qui n'en ont pas
|
||||||
|
UPDATE campaigns
|
||||||
|
SET slug = generate_slug(title)
|
||||||
|
WHERE slug IS NULL;
|
||||||
|
|
||||||
|
-- Générer des short_ids pour les participants qui n'en ont pas
|
||||||
|
UPDATE participants
|
||||||
|
SET short_id = generate_short_id()
|
||||||
|
WHERE short_id IS NULL;
|
||||||
|
|
||||||
|
-- ========================================
|
||||||
|
-- ÉTAPE 4: Création des index manquants
|
||||||
|
-- ========================================
|
||||||
|
|
||||||
|
-- Index pour les slugs de campagnes
|
||||||
|
DO $$
|
||||||
|
BEGIN
|
||||||
|
IF NOT EXISTS (
|
||||||
|
SELECT 1 FROM pg_indexes
|
||||||
|
WHERE indexname = 'idx_campaigns_slug'
|
||||||
|
) THEN
|
||||||
|
CREATE INDEX idx_campaigns_slug ON campaigns(slug);
|
||||||
|
RAISE NOTICE 'Index idx_campaigns_slug créé';
|
||||||
|
ELSE
|
||||||
|
RAISE NOTICE 'Index idx_campaigns_slug existe déjà';
|
||||||
|
END IF;
|
||||||
|
END $$;
|
||||||
|
|
||||||
|
-- Index pour les short_ids de participants
|
||||||
|
DO $$
|
||||||
|
BEGIN
|
||||||
|
IF NOT EXISTS (
|
||||||
|
SELECT 1 FROM pg_indexes
|
||||||
|
WHERE indexname = 'idx_participants_short_id'
|
||||||
|
) THEN
|
||||||
|
CREATE INDEX idx_participants_short_id ON participants(short_id);
|
||||||
|
RAISE NOTICE 'Index idx_participants_short_id créé';
|
||||||
|
ELSE
|
||||||
|
RAISE NOTICE 'Index idx_participants_short_id existe déjà';
|
||||||
|
END IF;
|
||||||
|
END $$;
|
||||||
|
|
||||||
|
-- ========================================
|
||||||
|
-- ÉTAPE 5: Fonction pour remplacer les votes
|
||||||
|
-- ========================================
|
||||||
|
|
||||||
|
-- Fonction pour remplacer tous les votes d'un participant de manière atomique
|
||||||
|
CREATE OR REPLACE FUNCTION replace_participant_votes(
|
||||||
|
p_campaign_id UUID,
|
||||||
|
p_participant_id UUID,
|
||||||
|
p_votes JSONB
|
||||||
|
)
|
||||||
|
RETURNS VOID AS $$
|
||||||
|
DECLARE
|
||||||
|
vote_record RECORD;
|
||||||
|
BEGIN
|
||||||
|
-- Commencer une transaction
|
||||||
|
BEGIN
|
||||||
|
-- Supprimer tous les votes existants pour ce participant dans cette campagne
|
||||||
|
DELETE FROM votes
|
||||||
|
WHERE campaign_id = p_campaign_id
|
||||||
|
AND participant_id = p_participant_id;
|
||||||
|
|
||||||
|
-- Insérer les nouveaux votes
|
||||||
|
FOR vote_record IN
|
||||||
|
SELECT * FROM jsonb_array_elements(p_votes)
|
||||||
|
LOOP
|
||||||
|
INSERT INTO votes (campaign_id, participant_id, proposition_id, amount)
|
||||||
|
VALUES (
|
||||||
|
p_campaign_id,
|
||||||
|
p_participant_id,
|
||||||
|
(vote_record.value->>'proposition_id')::UUID,
|
||||||
|
(vote_record.value->>'amount')::INTEGER
|
||||||
|
);
|
||||||
|
END LOOP;
|
||||||
|
|
||||||
|
-- La transaction sera automatiquement commitée si tout va bien
|
||||||
|
EXCEPTION
|
||||||
|
WHEN OTHERS THEN
|
||||||
|
-- En cas d'erreur, la transaction sera automatiquement rollbackée
|
||||||
|
RAISE EXCEPTION 'Erreur lors du remplacement des votes: %', SQLERRM;
|
||||||
|
END;
|
||||||
|
END;
|
||||||
|
$$ LANGUAGE plpgsql SECURITY DEFINER;
|
||||||
|
|
||||||
|
-- ========================================
|
||||||
|
-- ÉTAPE 6: Vérification et rapport
|
||||||
|
-- ========================================
|
||||||
|
|
||||||
|
-- Afficher un rapport de la migration
|
||||||
|
DO $$
|
||||||
|
DECLARE
|
||||||
|
campaign_count INTEGER;
|
||||||
|
participant_count INTEGER;
|
||||||
|
campaign_with_slug INTEGER;
|
||||||
|
participant_with_short_id INTEGER;
|
||||||
|
BEGIN
|
||||||
|
-- Compter les campagnes
|
||||||
|
SELECT COUNT(*) INTO campaign_count FROM campaigns;
|
||||||
|
SELECT COUNT(*) INTO campaign_with_slug FROM campaigns WHERE slug IS NOT NULL;
|
||||||
|
|
||||||
|
-- Compter les participants
|
||||||
|
SELECT COUNT(*) INTO participant_count FROM participants;
|
||||||
|
SELECT COUNT(*) INTO participant_with_short_id FROM participants WHERE short_id IS NOT NULL;
|
||||||
|
|
||||||
|
RAISE NOTICE '=== RAPPORT DE MIGRATION ===';
|
||||||
|
RAISE NOTICE 'Campagnes totales: %', campaign_count;
|
||||||
|
RAISE NOTICE 'Campagnes avec slug: %', campaign_with_slug;
|
||||||
|
RAISE NOTICE 'Participants totaux: %', participant_count;
|
||||||
|
RAISE NOTICE 'Participants avec short_id: %', participant_with_short_id;
|
||||||
|
|
||||||
|
IF campaign_count = campaign_with_slug AND participant_count = participant_with_short_id THEN
|
||||||
|
RAISE NOTICE '✅ Migration réussie ! Toutes les données ont été migrées.';
|
||||||
|
ELSE
|
||||||
|
RAISE NOTICE '⚠️ Attention: Certaines données n''ont pas été migrées.';
|
||||||
|
END IF;
|
||||||
|
END $$;
|
||||||
Reference in New Issue
Block a user