-- Script de création des tables pour le module Chat -- Date : 2025-01-17 -- Version : 1.0 -- Tables préfixées "chat_" pour le module de messagerie -- ============================================ -- SUPPRESSION DES TABLES EXISTANTES -- ============================================ -- Attention : Ceci supprimera toutes les données existantes du chat ! -- Désactiver temporairement les contraintes de clés étrangères SET FOREIGN_KEY_CHECKS = 0; -- Supprimer la vue si elle existe DROP VIEW IF EXISTS chat_rooms_with_last_message; -- Supprimer les tables dans l'ordre inverse des dépendances DROP TABLE IF EXISTS `chat_read_receipts`; DROP TABLE IF EXISTS `chat_participants`; DROP TABLE IF EXISTS `chat_messages`; DROP TABLE IF EXISTS `chat_rooms`; -- Supprimer toute autre table commençant par chat_ qui pourrait exister -- Note : Cette procédure supprime dynamiquement toutes les tables avec le préfixe chat_ DELIMITER $$ DROP PROCEDURE IF EXISTS drop_chat_tables$$ CREATE PROCEDURE drop_chat_tables() BEGIN DECLARE done INT DEFAULT FALSE; DECLARE tableName VARCHAR(255); DECLARE cur CURSOR FOR SELECT table_name FROM information_schema.tables WHERE table_schema = DATABASE() AND table_name LIKE 'chat_%'; DECLARE CONTINUE HANDLER FOR NOT FOUND SET done = TRUE; OPEN cur; read_loop: LOOP FETCH cur INTO tableName; IF done THEN LEAVE read_loop; END IF; SET @sql = CONCAT('DROP TABLE IF EXISTS `', tableName, '`'); PREPARE stmt FROM @sql; EXECUTE stmt; DEALLOCATE PREPARE stmt; END LOOP; CLOSE cur; END$$ DELIMITER ; -- Exécuter la procédure CALL drop_chat_tables(); -- Supprimer la procédure après utilisation DROP PROCEDURE IF EXISTS drop_chat_tables; -- Réactiver les contraintes de clés étrangères SET FOREIGN_KEY_CHECKS = 1; -- ============================================ -- CRÉATION DES NOUVELLES TABLES -- ============================================ -- Table des salles de conversation CREATE TABLE IF NOT EXISTS `chat_rooms` ( `id` VARCHAR(36) NOT NULL PRIMARY KEY COMMENT 'UUID de la salle', `title` VARCHAR(255) DEFAULT NULL COMMENT 'Titre de la conversation', `type` ENUM('private', 'group', 'broadcast') NOT NULL DEFAULT 'private' COMMENT 'Type de conversation', `created_at` TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP COMMENT 'Date de création', `created_by` INT(11) UNSIGNED NOT NULL COMMENT 'ID du créateur', `updated_at` TIMESTAMP NULL DEFAULT NULL ON UPDATE CURRENT_TIMESTAMP COMMENT 'Dernière modification', `is_active` TINYINT(1) NOT NULL DEFAULT 1 COMMENT 'Conversation active', KEY `idx_created_by` (`created_by`), KEY `idx_type` (`type`), KEY `idx_created_at` (`created_at`), CONSTRAINT `fk_chat_rooms_creator` FOREIGN KEY (`created_by`) REFERENCES `users` (`id`) ON DELETE CASCADE ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='Salles de conversation'; -- Table des messages CREATE TABLE IF NOT EXISTS `chat_messages` ( `id` VARCHAR(36) NOT NULL PRIMARY KEY COMMENT 'UUID du message', `room_id` VARCHAR(36) NOT NULL COMMENT 'ID de la salle', `content` TEXT NOT NULL COMMENT 'Contenu du message', `sender_id` INT(11) UNSIGNED NOT NULL COMMENT 'ID de l\'expéditeur', `sent_at` TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP COMMENT 'Date d\'envoi', `edited_at` TIMESTAMP NULL DEFAULT NULL COMMENT 'Date de modification', `is_deleted` TINYINT(1) NOT NULL DEFAULT 0 COMMENT 'Message supprimé', KEY `idx_room_id` (`room_id`), KEY `idx_sender_id` (`sender_id`), KEY `idx_sent_at` (`sent_at`), KEY `idx_room_sent` (`room_id`, `sent_at`), CONSTRAINT `fk_chat_messages_room` FOREIGN KEY (`room_id`) REFERENCES `chat_rooms` (`id`) ON DELETE CASCADE, CONSTRAINT `fk_chat_messages_sender` FOREIGN KEY (`sender_id`) REFERENCES `users` (`id`) ON DELETE CASCADE ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='Messages du chat'; -- Table des participants CREATE TABLE IF NOT EXISTS `chat_participants` ( `room_id` VARCHAR(36) NOT NULL COMMENT 'ID de la salle', `user_id` INT(11) UNSIGNED NOT NULL COMMENT 'ID de l\'utilisateur', `role` INT(11) DEFAULT NULL COMMENT 'Rôle de l\'utilisateur (fk_role)', `entite_id` INT(11) UNSIGNED DEFAULT NULL COMMENT 'ID de l\'entité', `joined_at` TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP COMMENT 'Date d\'adhésion', `left_at` TIMESTAMP NULL DEFAULT NULL COMMENT 'Date de départ', `is_admin` TINYINT(1) NOT NULL DEFAULT 0 COMMENT 'Admin de la salle', `last_read_at` TIMESTAMP NULL DEFAULT NULL COMMENT 'Dernière lecture', PRIMARY KEY (`room_id`, `user_id`), KEY `idx_user_id` (`user_id`), KEY `idx_entite_id` (`entite_id`), KEY `idx_joined_at` (`joined_at`), CONSTRAINT `fk_chat_participants_room` FOREIGN KEY (`room_id`) REFERENCES `chat_rooms` (`id`) ON DELETE CASCADE, CONSTRAINT `fk_chat_participants_user` FOREIGN KEY (`user_id`) REFERENCES `users` (`id`) ON DELETE CASCADE, CONSTRAINT `fk_chat_participants_entite` FOREIGN KEY (`entite_id`) REFERENCES `entites` (`id`) ON DELETE SET NULL ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='Participants aux conversations'; -- Table des accusés de lecture CREATE TABLE IF NOT EXISTS `chat_read_receipts` ( `message_id` VARCHAR(36) NOT NULL COMMENT 'ID du message', `user_id` INT(11) UNSIGNED NOT NULL COMMENT 'ID de l\'utilisateur', `read_at` TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP COMMENT 'Date de lecture', PRIMARY KEY (`message_id`, `user_id`), KEY `idx_user_id` (`user_id`), KEY `idx_read_at` (`read_at`), CONSTRAINT `fk_chat_read_message` FOREIGN KEY (`message_id`) REFERENCES `chat_messages` (`id`) ON DELETE CASCADE, CONSTRAINT `fk_chat_read_user` FOREIGN KEY (`user_id`) REFERENCES `users` (`id`) ON DELETE CASCADE ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='Accusés de lecture'; -- Index supplémentaires pour les performances CREATE INDEX idx_chat_active_rooms ON chat_rooms(is_active, created_at DESC); CREATE INDEX idx_chat_user_rooms ON chat_participants(user_id, left_at, joined_at DESC); CREATE INDEX idx_chat_unread ON chat_messages(room_id, sent_at) WHERE id NOT IN (SELECT message_id FROM chat_read_receipts); -- Vue pour faciliter la récupération des conversations avec le dernier message CREATE OR REPLACE VIEW chat_rooms_with_last_message AS SELECT r.*, m.content as last_message_content, m.sender_id as last_message_sender, m.sent_at as last_message_at, u.encrypted_name as last_message_sender_name FROM chat_rooms r LEFT JOIN ( SELECT m1.* FROM chat_messages m1 INNER JOIN ( SELECT room_id, MAX(sent_at) as max_sent_at FROM chat_messages WHERE is_deleted = 0 GROUP BY room_id ) m2 ON m1.room_id = m2.room_id AND m1.sent_at = m2.max_sent_at ) m ON r.id = m.room_id LEFT JOIN users u ON m.sender_id = u.id WHERE r.is_active = 1;