-- Script de création des tables chat pour MariaDB -- Compatible avec le module chat GEOSECTOR -- Création des tables pour le système de chat -- Table des salles de discussion DROP TABLE IF EXISTS `chat_rooms`; CREATE TABLE `chat_rooms` ( `id` varchar(50) NOT NULL, `type` enum('privee', 'groupe', 'liste_diffusion', 'broadcast', 'announcement') NOT NULL, `title` varchar(100) DEFAULT NULL, `date_creation` timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP, `fk_user` int unsigned NOT NULL, `fk_entite` int unsigned DEFAULT NULL, `statut` enum('active', 'archive') NOT NULL DEFAULT 'active', `description` text, `reply_permission` enum('all', 'admins_only', 'sender_only', 'none') NOT NULL DEFAULT 'all', `is_pinned` tinyint(1) unsigned NOT NULL DEFAULT 0, `expiry_date` timestamp NULL DEFAULT NULL, `updated_at` timestamp NULL DEFAULT NULL ON UPDATE CURRENT_TIMESTAMP, PRIMARY KEY (`id`), KEY `idx_user` (`fk_user`), KEY `idx_entite` (`fk_entite`), KEY `idx_type` (`type`), KEY `idx_statut` (`statut`) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci; -- Table des participants aux salles de discussion DROP TABLE IF EXISTS `chat_participants`; CREATE TABLE `chat_participants` ( `id` int unsigned NOT NULL AUTO_INCREMENT, `id_room` varchar(50) NOT NULL, `id_user` int unsigned DEFAULT NULL, `anonymous_id` varchar(50) DEFAULT NULL, `role` enum('administrateur', 'participant', 'en_lecture_seule') NOT NULL DEFAULT 'participant', `date_ajout` timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP, `notification_activee` tinyint(1) unsigned NOT NULL DEFAULT 1, `last_read_message_id` varchar(50) DEFAULT NULL, `via_target` tinyint(1) unsigned NOT NULL DEFAULT 0, `can_reply` tinyint(1) unsigned DEFAULT NULL, PRIMARY KEY (`id`), KEY `idx_room` (`id_room`), KEY `idx_user` (`id_user`), KEY `idx_anonymous_id` (`anonymous_id`), CONSTRAINT `fk_chat_participants_room` FOREIGN KEY (`id_room`) REFERENCES `chat_rooms` (`id`) ON DELETE CASCADE, CONSTRAINT `uc_room_user` UNIQUE (`id_room`, `id_user`) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci; -- Table des messages DROP TABLE IF EXISTS `chat_messages`; CREATE TABLE `chat_messages` ( `id` varchar(50) NOT NULL, `fk_room` varchar(50) NOT NULL, `fk_user` int unsigned DEFAULT NULL, `sender_type` enum('user', 'anonymous', 'system') NOT NULL DEFAULT 'user', `content` text, `content_type` enum('text', 'image', 'file') NOT NULL DEFAULT 'text', `date_sent` timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP, `date_delivered` timestamp NULL DEFAULT NULL, `date_read` timestamp NULL DEFAULT NULL, `statut` enum('envoye', 'livre', 'lu', 'error') NOT NULL DEFAULT 'envoye', `is_announcement` tinyint(1) unsigned NOT NULL DEFAULT 0, PRIMARY KEY (`id`), KEY `idx_room` (`fk_room`), KEY `idx_user` (`fk_user`), KEY `idx_date` (`date_sent`), KEY `idx_status` (`statut`), CONSTRAINT `fk_chat_messages_room` FOREIGN KEY (`fk_room`) REFERENCES `chat_rooms` (`id`) ON DELETE CASCADE ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci; -- Table des cibles d'audience DROP TABLE IF EXISTS `chat_audience_targets`; CREATE TABLE `chat_audience_targets` ( `id` int unsigned NOT NULL AUTO_INCREMENT, `fk_room` varchar(50) NOT NULL, `target_type` enum('role', 'entity', 'all', 'combined') NOT NULL DEFAULT 'all', `target_id` varchar(50) DEFAULT NULL, `role_filter` varchar(20) DEFAULT NULL, `entity_filter` varchar(50) DEFAULT NULL, `date_creation` timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP, PRIMARY KEY (`id`), KEY `idx_room` (`fk_room`), KEY `idx_type` (`target_type`), CONSTRAINT `fk_chat_audience_targets_room` FOREIGN KEY (`fk_room`) REFERENCES `chat_rooms` (`id`) ON DELETE CASCADE ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci; -- Table des listes de diffusion DROP TABLE IF EXISTS `chat_broadcast_lists`; CREATE TABLE `chat_broadcast_lists` ( `id` int unsigned NOT NULL AUTO_INCREMENT, `fk_room` varchar(50) NOT NULL, `name` varchar(100) NOT NULL, `description` text, `fk_user_creator` int unsigned NOT NULL, `date_creation` timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP, PRIMARY KEY (`id`), KEY `idx_room` (`fk_room`), KEY `idx_user_creator` (`fk_user_creator`), CONSTRAINT `fk_chat_broadcast_lists_room` FOREIGN KEY (`fk_room`) REFERENCES `chat_rooms` (`id`) ON DELETE CASCADE ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci; -- Table pour suivre la lecture des messages DROP TABLE IF EXISTS `chat_read_messages`; CREATE TABLE `chat_read_messages` ( `id` bigint unsigned NOT NULL AUTO_INCREMENT, `fk_message` varchar(50) NOT NULL, `fk_user` int unsigned NOT NULL, `date_read` timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP, PRIMARY KEY (`id`), KEY `idx_message` (`fk_message`), KEY `idx_user` (`fk_user`), CONSTRAINT `uc_message_user` UNIQUE (`fk_message`, `fk_user`), CONSTRAINT `fk_chat_read_messages_message` FOREIGN KEY (`fk_message`) REFERENCES `chat_messages` (`id`) ON DELETE CASCADE ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci; -- Table des notifications DROP TABLE IF EXISTS `chat_notifications`; CREATE TABLE `chat_notifications` ( `id` bigint unsigned NOT NULL AUTO_INCREMENT, `fk_user` int unsigned NOT NULL, `fk_message` varchar(50) DEFAULT NULL, `fk_room` varchar(50) DEFAULT NULL, `type` varchar(50) NOT NULL, `contenu` text, `date_creation` timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP, `date_lecture` timestamp NULL DEFAULT NULL, `statut` enum('non_lue', 'lue') NOT NULL DEFAULT 'non_lue', PRIMARY KEY (`id`), KEY `idx_user` (`fk_user`), KEY `idx_message` (`fk_message`), KEY `idx_room` (`fk_room`), KEY `idx_statut` (`statut`), CONSTRAINT `fk_chat_notifications_message` FOREIGN KEY (`fk_message`) REFERENCES `chat_messages` (`id`) ON DELETE SET NULL, CONSTRAINT `fk_chat_notifications_room` FOREIGN KEY (`fk_room`) REFERENCES `chat_rooms` (`id`) ON DELETE SET NULL ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci; -- Table des utilisateurs anonymes (pour Resalice) DROP TABLE IF EXISTS `chat_anonymous_users`; CREATE TABLE `chat_anonymous_users` ( `id` varchar(50) NOT NULL, `device_id` varchar(100) NOT NULL, `name` varchar(100) DEFAULT NULL, `email` varchar(100) DEFAULT NULL, `created_at` timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP, `converted_to_user_id` int unsigned DEFAULT NULL, `metadata` json DEFAULT NULL, PRIMARY KEY (`id`), KEY `idx_device_id` (`device_id`), KEY `idx_converted_user` (`converted_to_user_id`) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci; -- Table pour la file d'attente hors ligne DROP TABLE IF EXISTS `chat_offline_queue`; CREATE TABLE `chat_offline_queue` ( `id` bigint unsigned NOT NULL AUTO_INCREMENT, `user_id` int unsigned NOT NULL, `operation_type` varchar(50) NOT NULL, `operation_data` json NOT NULL, `created_at` timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP, `processed_at` timestamp NULL DEFAULT NULL, `status` enum('pending', 'processing', 'completed', 'failed') NOT NULL DEFAULT 'pending', `error_message` text, PRIMARY KEY (`id`), KEY `idx_user_id` (`user_id`), KEY `idx_status` (`status`), KEY `idx_created_at` (`created_at`) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci; -- Table pour les pièces jointes DROP TABLE IF EXISTS `chat_attachments`; CREATE TABLE `chat_attachments` ( `id` varchar(50) NOT NULL, `fk_message` varchar(50) NOT NULL, `file_name` varchar(255) NOT NULL, `file_path` varchar(500) NOT NULL, `file_type` varchar(100) NOT NULL, `file_size` int unsigned NOT NULL, `created_at` timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP, PRIMARY KEY (`id`), KEY `idx_message` (`fk_message`), CONSTRAINT `fk_chat_attachments_message` FOREIGN KEY (`fk_message`) REFERENCES `chat_messages` (`id`) ON DELETE CASCADE ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci; -- Vues utiles -- Vue des messages avec informations utilisateur CREATE OR REPLACE VIEW `chat_messages_with_users` AS SELECT m.*, u.name as sender_name, u.username as sender_username, u.fk_entite as sender_entity_id FROM chat_messages m LEFT JOIN users u ON m.fk_user = u.id; -- Vue des conversations avec compte de messages non lus CREATE OR REPLACE VIEW `chat_conversations_unread` AS SELECT r.*, COUNT(DISTINCT m.id) as total_messages, COUNT(DISTINCT rm.id) as read_messages, COUNT(DISTINCT m.id) - COUNT(DISTINCT rm.id) as unread_messages, (SELECT date_sent FROM chat_messages WHERE fk_room = r.id ORDER BY date_sent DESC LIMIT 1) as last_message_date FROM chat_rooms r LEFT JOIN chat_messages m ON r.id = m.fk_room LEFT JOIN chat_read_messages rm ON m.id = rm.fk_message GROUP BY r.id; -- Index supplémentaires pour les performances CREATE INDEX idx_messages_unread ON chat_messages(fk_room, statut); CREATE INDEX idx_participants_active ON chat_participants(id_room, id_user, notification_activee); CREATE INDEX idx_notifications_unread ON chat_notifications(fk_user, statut);