-- ========================================================== -- 04_fk_policies.sql : normalisation des politiques ON DELETE -- A exécuter après 01_init.sql et 03_checks.sql -- ========================================================== -- Helper: Drop FK d'une table/colonne si elle existe (par son/leurs noms de colonne) -- puis recrée la contrainte avec la clause fournie -- Utilise information_schema pour retrouver le nom de contrainte auto-généré -- NB: schema = public -- ========== messages.id_expediteur -> utilisateurs.id : SET NULL (au lieu de CASCADE) DO $$ DECLARE conname text; BEGIN SELECT tc.constraint_name INTO conname FROM information_schema.table_constraints tc JOIN information_schema.key_column_usage kcu ON tc.constraint_name = kcu.constraint_name AND tc.table_schema = kcu.table_schema WHERE tc.table_schema='public' AND tc.table_name='messages' AND tc.constraint_type='FOREIGN KEY' AND kcu.column_name='id_expediteur'; IF conname IS NOT NULL THEN EXECUTE format('ALTER TABLE public.messages DROP CONSTRAINT %I', conname); END IF; EXECUTE $sql$ ALTER TABLE public.messages ADD CONSTRAINT fk_messages_id_expediteur FOREIGN KEY (id_expediteur) REFERENCES public.utilisateurs(id) ON DELETE SET NULL $sql$; END $$; -- ========== parents.id_co_parent -> utilisateurs.id : SET NULL DO $$ DECLARE conname text; BEGIN SELECT tc.constraint_name INTO conname FROM information_schema.table_constraints tc JOIN information_schema.key_column_usage kcu ON tc.constraint_name = kcu.constraint_name AND tc.table_schema = kcu.table_schema WHERE tc.table_schema='public' AND tc.table_name='parents' AND tc.constraint_type='FOREIGN KEY' AND kcu.column_name='id_co_parent'; IF conname IS NOT NULL THEN EXECUTE format('ALTER TABLE public.parents DROP CONSTRAINT %I', conname); END IF; EXECUTE $sql$ ALTER TABLE public.parents ADD CONSTRAINT fk_parents_id_co_parent FOREIGN KEY (id_co_parent) REFERENCES public.utilisateurs(id) ON DELETE SET NULL $sql$; END $$; -- ========== avenants_contrats.initie_par -> utilisateurs.id : SET NULL DO $$ DECLARE conname text; BEGIN SELECT tc.constraint_name INTO conname FROM information_schema.table_constraints tc JOIN information_schema.key_column_usage kcu ON tc.constraint_name = kcu.constraint_name AND tc.table_schema = kcu.table_schema WHERE tc.table_schema='public' AND tc.table_name='avenants_contrats' AND tc.constraint_type='FOREIGN KEY' AND kcu.column_name='initie_par'; IF conname IS NOT NULL THEN EXECUTE format('ALTER TABLE public.avenants_contrats DROP CONSTRAINT %I', conname); END IF; EXECUTE $sql$ ALTER TABLE public.avenants_contrats ADD CONSTRAINT fk_avenants_contrats_initie_par FOREIGN KEY (initie_par) REFERENCES public.utilisateurs(id) ON DELETE SET NULL $sql$; END $$; -- ========== evenements.id_am -> utilisateurs.id : SET NULL DO $$ DECLARE conname text; BEGIN SELECT tc.constraint_name INTO conname FROM information_schema.table_constraints tc JOIN information_schema.key_column_usage kcu ON tc.constraint_name = kcu.constraint_name AND tc.table_schema = kcu.table_schema WHERE tc.table_schema='public' AND tc.table_name='evenements' AND tc.constraint_type='FOREIGN KEY' AND kcu.column_name='id_am'; IF conname IS NOT NULL THEN EXECUTE format('ALTER TABLE public.evenements DROP CONSTRAINT %I', conname); END IF; EXECUTE $sql$ ALTER TABLE public.evenements ADD CONSTRAINT fk_evenements_id_am FOREIGN KEY (id_am) REFERENCES public.utilisateurs(id) ON DELETE SET NULL $sql$; END $$; -- ========== evenements.id_parent -> parents.id_utilisateur : SET NULL DO $$ DECLARE conname text; BEGIN SELECT tc.constraint_name INTO conname FROM information_schema.table_constraints tc JOIN information_schema.key_column_usage kcu ON tc.constraint_name = kcu.constraint_name AND tc.table_schema = kcu.table_schema WHERE tc.table_schema='public' AND tc.table_name='evenements' AND tc.constraint_type='FOREIGN KEY' AND kcu.column_name='id_parent'; IF conname IS NOT NULL THEN EXECUTE format('ALTER TABLE public.evenements DROP CONSTRAINT %I', conname); END IF; EXECUTE $sql$ ALTER TABLE public.evenements ADD CONSTRAINT fk_evenements_id_parent FOREIGN KEY (id_parent) REFERENCES public.parents(id_utilisateur) ON DELETE SET NULL $sql$; END $$; -- ========== evenements.cree_par -> utilisateurs.id : SET NULL DO $$ DECLARE conname text; BEGIN SELECT tc.constraint_name INTO conname FROM information_schema.table_constraints tc JOIN information_schema.key_column_usage kcu ON tc.constraint_name = kcu.constraint_name AND tc.table_schema = kcu.table_schema WHERE tc.table_schema='public' AND tc.table_name='evenements' AND tc.constraint_type='FOREIGN KEY' AND kcu.column_name='cree_par'; IF conname IS NOT NULL THEN EXECUTE format('ALTER TABLE public.evenements DROP CONSTRAINT %I', conname); END IF; EXECUTE $sql$ ALTER TABLE public.evenements ADD CONSTRAINT fk_evenements_cree_par FOREIGN KEY (cree_par) REFERENCES public.utilisateurs(id) ON DELETE SET NULL $sql$; END $$; -- ========== signalements_bugs.id_utilisateur -> utilisateurs.id : SET NULL DO $$ DECLARE conname text; BEGIN SELECT tc.constraint_name INTO conname FROM information_schema.table_constraints tc JOIN information_schema.key_column_usage kcu ON tc.constraint_name = kcu.constraint_name AND tc.table_schema = kcu.table_schema WHERE tc.table_schema='public' AND tc.table_name='signalements_bugs' AND tc.constraint_type='FOREIGN KEY' AND kcu.column_name='id_utilisateur'; IF conname IS NOT NULL THEN EXECUTE format('ALTER TABLE public.signalements_bugs DROP CONSTRAINT %I', conname); END IF; EXECUTE $sql$ ALTER TABLE public.signalements_bugs ADD CONSTRAINT fk_signalements_bugs_id_utilisateur FOREIGN KEY (id_utilisateur) REFERENCES public.utilisateurs(id) ON DELETE SET NULL $sql$; END $$; -- ========== validations.id_utilisateur -> utilisateurs.id : SET NULL DO $$ DECLARE conname text; BEGIN SELECT tc.constraint_name INTO conname FROM information_schema.table_constraints tc JOIN information_schema.key_column_usage kcu ON tc.constraint_name = kcu.constraint_name AND tc.table_schema = kcu.table_schema WHERE tc.table_schema='public' AND tc.table_name='validations' AND tc.constraint_type='FOREIGN KEY' AND kcu.column_name='id_utilisateur'; IF conname IS NOT NULL THEN EXECUTE format('ALTER TABLE public.validations DROP CONSTRAINT %I', conname); END IF; EXECUTE $sql$ ALTER TABLE public.validations ADD CONSTRAINT fk_validations_id_utilisateur FOREIGN KEY (id_utilisateur) REFERENCES public.utilisateurs(id) ON DELETE SET NULL $sql$; END $$; -- NB: -- D'autres FK déjà correctes : CASCADE (assistantes_maternelles, parents, enfants_parents, dossiers, messages.id_dossier, contrats, avenants_contrats.id_contrat, evenements.id_enfant), SET NULL (uploads). -- On laisse ON UPDATE par défaut (NO ACTION), car les UUID ne changent pas.