-- ================================================================ -- 赛事编排智能化升级 SQL 脚本 -- 用途:支持智能编排算法(场地容纳人数 + 项目时长限制) -- 日期:2025-12-06 -- ================================================================ -- 1. 创建场地信息表(如果不存在) -- ================================================================ -- 注意:使用 capacity 字段名以匹配现有数据库表结构 CREATE TABLE IF NOT EXISTS `martial_venue` ( `id` bigint(20) NOT NULL AUTO_INCREMENT COMMENT '主键ID', `tenant_id` varchar(12) DEFAULT '000000' COMMENT '租户ID', `competition_id` bigint(20) NOT NULL COMMENT '赛事ID', `venue_name` varchar(100) NOT NULL COMMENT '场地名称', `venue_code` varchar(50) DEFAULT NULL COMMENT '场地编码', `location` varchar(200) DEFAULT NULL COMMENT '位置/地点', `capacity` int(11) DEFAULT 100 COMMENT '容纳人数', `facilities` varchar(500) DEFAULT NULL COMMENT '场地设施', `status` int(2) DEFAULT 1 COMMENT '状态(0-禁用,1-启用)', `create_user` bigint(20) DEFAULT NULL COMMENT '创建人', `create_dept` bigint(20) DEFAULT NULL COMMENT '创建部门', `create_time` datetime DEFAULT CURRENT_TIMESTAMP COMMENT '创建时间', `update_user` bigint(20) DEFAULT NULL COMMENT '修改人', `update_time` datetime DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP COMMENT '修改时间', `is_deleted` int(2) DEFAULT 0 COMMENT '是否已删除', PRIMARY KEY (`id`), KEY `idx_competition_id` (`competition_id`), KEY `idx_tenant_id` (`tenant_id`) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COMMENT='场地信息表'; -- 2. 确保 martial_project 表有 estimated_duration 字段 -- ================================================================ -- 检查字段是否存在,不存在则添加 SET @col_exists = 0; SELECT COUNT(*) INTO @col_exists FROM information_schema.COLUMNS WHERE TABLE_SCHEMA = DATABASE() AND TABLE_NAME = 'martial_project' AND COLUMN_NAME = 'estimated_duration'; SET @sql = IF(@col_exists = 0, 'ALTER TABLE martial_project ADD COLUMN estimated_duration int(11) DEFAULT 5 COMMENT ''预估时长(分钟)'' AFTER max_participants', 'SELECT ''estimated_duration column already exists'' AS info' ); PREPARE stmt FROM @sql; EXECUTE stmt; DEALLOCATE PREPARE stmt; -- 3. 插入测试数据(仅用于开发测试) -- ================================================================ -- 为赛事 ID=100 插入场地数据 INSERT INTO `martial_venue` (`competition_id`, `venue_name`, `venue_code`, `capacity`, `location`, `facilities`) VALUES (100, '一号场地', 'VENUE_01', 50, '体育馆一楼东侧', '主会场,配备专业武术地毯,适合集体项目'), (100, '二号场地', 'VENUE_02', 50, '体育馆一楼西侧', '次会场,配备专业武术地毯,适合集体项目'), (100, '三号场地', 'VENUE_03', 30, '体育馆二楼东侧', '小型场地,适合个人项目'), (100, '四号场地', 'VENUE_04', 30, '体育馆二楼西侧', '小型场地,适合个人项目') ON DUPLICATE KEY UPDATE venue_name = VALUES(venue_name), capacity = VALUES(capacity), location = VALUES(location), facilities = VALUES(facilities); -- 4. 更新现有项目的预估时长(如果为NULL或0) -- ================================================================ UPDATE martial_project SET estimated_duration = CASE WHEN project_name LIKE '%太极%' THEN 5 WHEN project_name LIKE '%长拳%' THEN 5 WHEN project_name LIKE '%剑%' THEN 4 WHEN project_name LIKE '%刀%' THEN 4 WHEN project_name LIKE '%棍%' THEN 6 WHEN project_name LIKE '%枪%' THEN 6 ELSE 5 END WHERE estimated_duration IS NULL OR estimated_duration = 0; -- 5. 创建视图:场地使用统计(可选) -- ================================================================ CREATE OR REPLACE VIEW v_venue_usage_stats AS SELECT v.id AS venue_id, v.competition_id, v.venue_name, v.max_capacity, COUNT(DISTINCT s.group_id) AS assigned_groups, SUM(s.participant_count) AS total_participants, SUM(s.estimated_duration) AS total_duration, v.max_capacity - IFNULL(SUM(s.participant_count), 0) AS remaining_capacity FROM martial_venue v LEFT JOIN ( -- 这里假设将来会有 martial_schedule 表来存储编排结果 SELECT venue_id, group_id, COUNT(*) AS participant_count, SUM(estimated_duration) AS estimated_duration FROM martial_schedule_detail WHERE is_deleted = 0 GROUP BY venue_id, group_id ) s ON v.id = s.venue_id WHERE v.is_deleted = 0 GROUP BY v.id, v.competition_id, v.venue_name, v.max_capacity; -- ================================================================ -- 脚本执行完成 -- ================================================================ -- 说明: -- 1. 场地表已创建,支持最大容纳人数配置 -- 2. 项目表 estimated_duration 字段已确保存在 -- 3. 测试数据已插入(赛事ID=100) -- 4. 现有项目的预估时长已更新为合理默认值 -- ================================================================