Files
geo/api/scripts/orga/fix_fk_constraints_safe.sql
Pierre 0687900564 fix: Récupérer l'opération active depuis la table operations
- Corrige l'erreur SQL 'Unknown column fk_operation in users'
- L'opération active est récupérée depuis operations.chk_active = 1
- Jointure avec users pour filtrer par entité de l'admin créateur
- Query: SELECT o.id FROM operations o INNER JOIN users u ON u.fk_entite = o.fk_entite WHERE u.id = ? AND o.chk_active = 1
2026-01-26 16:57:08 +01:00

122 lines
4.2 KiB
SQL
Executable File

-- ================================================================================
-- Script de migration SÉCURISÉ : Correction des contraintes FK pour isolation par opération
-- ================================================================================
--
-- Ce script modifie les contraintes de clés étrangères pour que :
-- - ope_users_sectors.fk_user → pointe vers ope_users.id (au lieu de users.id)
-- - ope_pass.fk_user → pointe vers ope_users.id (au lieu de users.id)
--
-- Version SÉCURISÉE : Vérifie l'existence des contraintes avant de les supprimer
--
-- ================================================================================
USE dva_geo;
-- ================================================================================
-- Afficher les contraintes FK actuelles
-- ================================================================================
SELECT
TABLE_NAME,
COLUMN_NAME,
CONSTRAINT_NAME,
REFERENCED_TABLE_NAME,
REFERENCED_COLUMN_NAME
FROM information_schema.KEY_COLUMN_USAGE
WHERE TABLE_SCHEMA = 'dva_geo'
AND TABLE_NAME IN ('ope_users_sectors', 'ope_pass')
AND COLUMN_NAME = 'fk_user'
ORDER BY TABLE_NAME;
-- ================================================================================
-- 1. Modification de ope_users_sectors.fk_user
-- ================================================================================
-- Supprimer l'ancienne contrainte FK si elle existe
SET @constraint_exists = (
SELECT COUNT(*)
FROM information_schema.KEY_COLUMN_USAGE
WHERE TABLE_SCHEMA = 'dva_geo'
AND TABLE_NAME = 'ope_users_sectors'
AND COLUMN_NAME = 'fk_user'
AND CONSTRAINT_NAME LIKE '%ibfk%'
);
SET @sql = IF(@constraint_exists > 0,
CONCAT('ALTER TABLE ope_users_sectors DROP FOREIGN KEY ',
(SELECT CONSTRAINT_NAME
FROM information_schema.KEY_COLUMN_USAGE
WHERE TABLE_SCHEMA = 'dva_geo'
AND TABLE_NAME = 'ope_users_sectors'
AND COLUMN_NAME = 'fk_user'
AND CONSTRAINT_NAME LIKE '%ibfk%'
LIMIT 1)),
'SELECT "Aucune contrainte FK à supprimer sur ope_users_sectors" AS message'
);
PREPARE stmt FROM @sql;
EXECUTE stmt;
DEALLOCATE PREPARE stmt;
-- Recréer la contrainte FK vers ope_users.id
ALTER TABLE ope_users_sectors
ADD CONSTRAINT ope_users_sectors_ibfk_2
FOREIGN KEY (fk_user) REFERENCES ope_users (id) ON DELETE CASCADE ON UPDATE CASCADE;
-- ================================================================================
-- 2. Modification de ope_pass.fk_user
-- ================================================================================
-- Supprimer l'ancienne contrainte FK si elle existe
SET @constraint_exists = (
SELECT COUNT(*)
FROM information_schema.KEY_COLUMN_USAGE
WHERE TABLE_SCHEMA = 'dva_geo'
AND TABLE_NAME = 'ope_pass'
AND COLUMN_NAME = 'fk_user'
AND CONSTRAINT_NAME LIKE '%ibfk%'
);
SET @sql = IF(@constraint_exists > 0,
CONCAT('ALTER TABLE ope_pass DROP FOREIGN KEY ',
(SELECT CONSTRAINT_NAME
FROM information_schema.KEY_COLUMN_USAGE
WHERE TABLE_SCHEMA = 'dva_geo'
AND TABLE_NAME = 'ope_pass'
AND COLUMN_NAME = 'fk_user'
AND CONSTRAINT_NAME LIKE '%ibfk%'
LIMIT 1)),
'SELECT "Aucune contrainte FK à supprimer sur ope_pass" AS message'
);
PREPARE stmt FROM @sql;
EXECUTE stmt;
DEALLOCATE PREPARE stmt;
-- Recréer la contrainte FK vers ope_users.id
ALTER TABLE ope_pass
ADD CONSTRAINT ope_pass_ibfk_3
FOREIGN KEY (fk_user) REFERENCES ope_users (id) ON DELETE CASCADE ON UPDATE CASCADE;
-- ================================================================================
-- Vérification finale
-- ================================================================================
SELECT
TABLE_NAME,
COLUMN_NAME,
CONSTRAINT_NAME,
REFERENCED_TABLE_NAME,
REFERENCED_COLUMN_NAME
FROM information_schema.KEY_COLUMN_USAGE
WHERE TABLE_SCHEMA = 'dva_geo'
AND TABLE_NAME IN ('ope_users_sectors', 'ope_pass')
AND COLUMN_NAME = 'fk_user'
ORDER BY TABLE_NAME;
-- Résultat attendu :
-- ope_pass | fk_user | ope_pass_ibfk_3 | ope_users | id
-- ope_users_sectors | fk_user | ope_users_sectors_ibfk_2 | ope_users | id
SELECT '✓ Contraintes FK modifiées avec succès !' AS status;