180 lines
8.0 KiB
SQL
180 lines
8.0 KiB
SQL
-- =============================================
|
||
-- 赛程编排系统 - 增量升级脚本
|
||
-- =============================================
|
||
-- 说明: 检查并创建缺失的表,不影响现有数据
|
||
-- 版本: v1.1
|
||
-- 日期: 2025-12-09
|
||
-- =============================================
|
||
|
||
USE martial_db;
|
||
|
||
-- 检查当前已有的表
|
||
SELECT
|
||
table_name,
|
||
'已存在' AS status
|
||
FROM information_schema.tables
|
||
WHERE table_schema = 'martial_db'
|
||
AND table_name LIKE 'martial_schedule%';
|
||
|
||
-- =============================================
|
||
-- 创建新表(仅当不存在时)
|
||
-- =============================================
|
||
|
||
-- 1. 赛程编排分组表
|
||
CREATE TABLE IF NOT EXISTS `martial_schedule_group` (
|
||
`id` bigint(20) NOT NULL AUTO_INCREMENT COMMENT '主键ID',
|
||
`competition_id` bigint(20) NOT NULL COMMENT '赛事ID',
|
||
`group_name` varchar(200) NOT NULL COMMENT '分组名称(如:太极拳男组)',
|
||
`project_id` bigint(20) NOT NULL COMMENT '项目ID',
|
||
`project_name` varchar(100) DEFAULT NULL COMMENT '项目名称',
|
||
`category` varchar(50) DEFAULT NULL COMMENT '组别(成年组、少年组等)',
|
||
`project_type` tinyint(1) NOT NULL DEFAULT '1' COMMENT '项目类型(1=个人 2=集体)',
|
||
`display_order` int(11) NOT NULL DEFAULT '0' COMMENT '显示顺序(集体项目优先,数字越小越靠前)',
|
||
`total_participants` int(11) DEFAULT '0' COMMENT '总参赛人数',
|
||
`total_teams` int(11) DEFAULT '0' COMMENT '总队伍数(仅集体项目)',
|
||
`estimated_duration` int(11) DEFAULT '0' COMMENT '预计时长(分钟)',
|
||
`create_user` bigint(20) DEFAULT NULL,
|
||
`create_dept` bigint(20) DEFAULT NULL,
|
||
`create_time` datetime DEFAULT CURRENT_TIMESTAMP,
|
||
`update_user` bigint(20) DEFAULT NULL,
|
||
`update_time` datetime DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
|
||
`status` int(11) DEFAULT '1' COMMENT '状态(1-启用,2-禁用)',
|
||
`is_deleted` int(11) DEFAULT '0',
|
||
`tenant_id` varchar(12) DEFAULT '000000',
|
||
PRIMARY KEY (`id`),
|
||
KEY `idx_competition` (`competition_id`),
|
||
KEY `idx_project` (`project_id`),
|
||
KEY `idx_display_order` (`display_order`),
|
||
KEY `idx_tenant` (`tenant_id`)
|
||
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COMMENT='赛程编排分组表';
|
||
|
||
-- 2. 赛程编排明细表(场地时间段分配)
|
||
CREATE TABLE IF NOT EXISTS `martial_schedule_detail` (
|
||
`id` bigint(20) NOT NULL AUTO_INCREMENT COMMENT '主键ID',
|
||
`schedule_group_id` bigint(20) NOT NULL COMMENT '分组ID',
|
||
`competition_id` bigint(20) NOT NULL COMMENT '赛事ID',
|
||
`venue_id` bigint(20) NOT NULL COMMENT '场地ID',
|
||
`venue_name` varchar(100) DEFAULT NULL COMMENT '场地名称',
|
||
`schedule_date` date NOT NULL COMMENT '比赛日期',
|
||
`time_period` varchar(20) NOT NULL COMMENT '时间段(morning/afternoon)',
|
||
`time_slot` varchar(20) NOT NULL COMMENT '时间点(08:30/13:30)',
|
||
`estimated_start_time` datetime DEFAULT NULL COMMENT '预计开始时间',
|
||
`estimated_end_time` datetime DEFAULT NULL COMMENT '预计结束时间',
|
||
`estimated_duration` int(11) DEFAULT '0' COMMENT '预计时长(分钟)',
|
||
`participant_count` int(11) DEFAULT '0' COMMENT '参赛人数',
|
||
`sort_order` int(11) DEFAULT '0' COMMENT '场内顺序',
|
||
`create_user` bigint(20) DEFAULT NULL,
|
||
`create_dept` bigint(20) DEFAULT NULL,
|
||
`create_time` datetime DEFAULT CURRENT_TIMESTAMP,
|
||
`update_user` bigint(20) DEFAULT NULL,
|
||
`update_time` datetime DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
|
||
`status` int(11) DEFAULT '1' COMMENT '状态(1-未开始,2-进行中,3-已完成)',
|
||
`is_deleted` int(11) DEFAULT '0',
|
||
`tenant_id` varchar(12) DEFAULT '000000',
|
||
PRIMARY KEY (`id`),
|
||
KEY `idx_group` (`schedule_group_id`),
|
||
KEY `idx_competition` (`competition_id`),
|
||
KEY `idx_venue_time` (`venue_id`,`schedule_date`,`time_slot`),
|
||
KEY `idx_tenant` (`tenant_id`)
|
||
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COMMENT='赛程编排明细表(场地时间段分配)';
|
||
|
||
-- 3. 赛程编排参赛者关联表
|
||
CREATE TABLE IF NOT EXISTS `martial_schedule_participant` (
|
||
`id` bigint(20) NOT NULL AUTO_INCREMENT COMMENT '主键ID',
|
||
`schedule_detail_id` bigint(20) NOT NULL COMMENT '编排明细ID',
|
||
`schedule_group_id` bigint(20) NOT NULL COMMENT '分组ID',
|
||
`participant_id` bigint(20) NOT NULL COMMENT '参赛者ID(关联martial_athlete表)',
|
||
`organization` varchar(200) DEFAULT NULL COMMENT '单位名称',
|
||
`player_name` varchar(100) DEFAULT NULL COMMENT '选手姓名',
|
||
`project_name` varchar(100) DEFAULT NULL COMMENT '项目名称',
|
||
`category` varchar(50) DEFAULT NULL COMMENT '组别',
|
||
`performance_order` int(11) DEFAULT '0' COMMENT '出场顺序',
|
||
`create_user` bigint(20) DEFAULT NULL,
|
||
`create_dept` bigint(20) DEFAULT NULL,
|
||
`create_time` datetime DEFAULT CURRENT_TIMESTAMP,
|
||
`update_user` bigint(20) DEFAULT NULL,
|
||
`update_time` datetime DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
|
||
`status` int(11) DEFAULT '1' COMMENT '状态(1-待出场,2-已出场)',
|
||
`is_deleted` int(11) DEFAULT '0',
|
||
`tenant_id` varchar(12) DEFAULT '000000',
|
||
PRIMARY KEY (`id`),
|
||
KEY `idx_detail` (`schedule_detail_id`),
|
||
KEY `idx_group` (`schedule_group_id`),
|
||
KEY `idx_participant` (`participant_id`),
|
||
KEY `idx_tenant` (`tenant_id`)
|
||
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COMMENT='赛程编排参赛者关联表';
|
||
|
||
-- 4. 赛程编排状态表
|
||
CREATE TABLE IF NOT EXISTS `martial_schedule_status` (
|
||
`id` bigint(20) NOT NULL AUTO_INCREMENT COMMENT '主键ID',
|
||
`competition_id` bigint(20) NOT NULL COMMENT '赛事ID(唯一)',
|
||
`schedule_status` tinyint(1) NOT NULL DEFAULT '0' COMMENT '编排状态(0=未编排 1=编排中 2=已保存锁定)',
|
||
`last_auto_schedule_time` datetime DEFAULT NULL COMMENT '最后自动编排时间',
|
||
`locked_time` datetime DEFAULT NULL COMMENT '锁定时间',
|
||
`locked_by` varchar(100) DEFAULT NULL COMMENT '锁定人',
|
||
`total_groups` int(11) DEFAULT '0' COMMENT '总分组数',
|
||
`total_participants` int(11) DEFAULT '0' COMMENT '总参赛人数',
|
||
`create_user` bigint(20) DEFAULT NULL,
|
||
`create_dept` bigint(20) DEFAULT NULL,
|
||
`create_time` datetime DEFAULT CURRENT_TIMESTAMP,
|
||
`update_user` bigint(20) DEFAULT NULL,
|
||
`update_time` datetime DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
|
||
`status` int(11) DEFAULT '1' COMMENT '状态(1-启用,2-禁用)',
|
||
`is_deleted` int(11) DEFAULT '0',
|
||
`tenant_id` varchar(12) DEFAULT '000000',
|
||
PRIMARY KEY (`id`),
|
||
UNIQUE KEY `uk_competition` (`competition_id`),
|
||
KEY `idx_tenant` (`tenant_id`),
|
||
KEY `idx_schedule_status` (`schedule_status`)
|
||
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COMMENT='赛程编排状态表';
|
||
|
||
-- =============================================
|
||
-- 验证结果
|
||
-- =============================================
|
||
|
||
SELECT
|
||
'升级完成' AS message,
|
||
COUNT(*) AS new_tables_count
|
||
FROM information_schema.tables
|
||
WHERE table_schema = 'martial_db'
|
||
AND table_name IN (
|
||
'martial_schedule_group',
|
||
'martial_schedule_detail',
|
||
'martial_schedule_participant',
|
||
'martial_schedule_status'
|
||
);
|
||
|
||
-- 显示所有赛程相关表
|
||
SELECT
|
||
table_name,
|
||
table_comment,
|
||
CASE
|
||
WHEN table_name IN ('martial_schedule_group', 'martial_schedule_detail',
|
||
'martial_schedule_participant', 'martial_schedule_status')
|
||
THEN '新系统'
|
||
ELSE '旧系统'
|
||
END AS system_version
|
||
FROM information_schema.tables
|
||
WHERE table_schema = 'martial_db'
|
||
AND table_name LIKE 'martial_schedule%'
|
||
ORDER BY system_version DESC, table_name;
|
||
|
||
-- =============================================
|
||
-- 说明
|
||
-- =============================================
|
||
--
|
||
-- 执行结果说明:
|
||
-- 1. 如果 new_tables_count = 4,说明4张新表全部创建成功
|
||
-- 2. 如果 new_tables_count < 4,说明部分表已存在或创建失败
|
||
-- 3. 最后一个查询会显示所有赛程相关表及其所属系统版本
|
||
--
|
||
-- 新旧系统对比:
|
||
-- - 旧系统: martial_schedule, martial_schedule_athlete (可能存在)
|
||
-- - 新系统: martial_schedule_group, martial_schedule_detail,
|
||
-- martial_schedule_participant, martial_schedule_status
|
||
--
|
||
-- 两个系统可以共存,不会互相影响
|
||
-- 新系统由后端Service层代码使用
|
||
--
|
||
-- =============================================
|