-- ===================================================== -- 自定义挑战功能数据库迁移脚本 -- 创建时间: 2025-01-25 -- 说明: 添加用户自定义挑战功能所需的字段和索引 -- ===================================================== -- 1. 扩展 t_challenges 表,添加自定义挑战相关字段 ALTER TABLE `t_challenges` ADD COLUMN `source` ENUM('system', 'custom') NOT NULL DEFAULT 'system' COMMENT '挑战来源:system=系统预设, custom=用户创建' AFTER `type`, ADD COLUMN `creator_id` VARCHAR(64) NULL COMMENT '创建者用户ID,仅custom类型有值' AFTER `source`, ADD COLUMN `share_code` VARCHAR(12) NULL COMMENT '分享码,6-12位字符,用于加入挑战' AFTER `creator_id`, ADD COLUMN `is_public` BOOLEAN NOT NULL DEFAULT TRUE COMMENT '是否公开:true=任何人可通过分享码加入, false=仅邀请' AFTER `share_code`, ADD COLUMN `max_participants` INT NULL COMMENT '最大参与人数限制,null表示无限制' AFTER `is_public`, ADD COLUMN `challenge_state` ENUM('draft', 'active', 'archived') NOT NULL DEFAULT 'active' COMMENT '挑战状态:draft=草稿, active=活跃, archived=已归档' AFTER `max_participants`; -- 2. 创建索引以提升查询性能 ALTER TABLE `t_challenges` ADD UNIQUE INDEX `idx_share_code` (`share_code`), ADD INDEX `idx_creator_id` (`creator_id`), ADD INDEX `idx_source_state` (`source`, `challenge_state`); -- 3. 更新现有数据,标记为系统挑战 UPDATE `t_challenges` SET `source` = 'system', `challenge_state` = 'active' WHERE `source` IS NULL OR `source` = ''; -- 4. 验证数据迁移 SELECT COUNT(*) as total_challenges, SUM(CASE WHEN source = 'system' THEN 1 ELSE 0 END) as system_challenges, SUM(CASE WHEN source = 'custom' THEN 1 ELSE 0 END) as custom_challenges, SUM(CASE WHEN challenge_state = 'active' THEN 1 ELSE 0 END) as active_challenges, SUM(CASE WHEN challenge_state = 'draft' THEN 1 ELSE 0 END) as draft_challenges, SUM(CASE WHEN challenge_state = 'archived' THEN 1 ELSE 0 END) as archived_challenges FROM `t_challenges`; -- ===================================================== -- 迁移完成说明: -- 1. 所有现有挑战已标记为系统挑战 (source='system') -- 2. 所有现有挑战已标记为活跃状态 (challenge_state='active') -- 3. 已创建必要的索引以提升查询性能 -- 4. share_code 字段有唯一索引,确保分享码唯一性 -- =====================================================