-- Challenges feature DDL -- Creates core tables required by the challenge listing, participation, and progress tracking flows. CREATE TABLE IF NOT EXISTS t_challenges ( id CHAR(36) NOT NULL PRIMARY KEY, title VARCHAR(255) NOT NULL COMMENT '挑战标题', image VARCHAR(512) DEFAULT NULL COMMENT '挑战封面图', start_at DATETIME NOT NULL COMMENT '挑战开始时间', end_at DATETIME NOT NULL COMMENT '挑战结束时间', period_label VARCHAR(128) DEFAULT NULL COMMENT '周期标签,例如「21天挑战」', duration_label VARCHAR(128) NOT NULL COMMENT '持续时间标签,例如「持续21天」', requirement_label VARCHAR(255) NOT NULL COMMENT '挑战要求标签,例如「每日练习 1 次」', summary TEXT DEFAULT NULL COMMENT '挑战概要说明', target_value INT NOT NULL COMMENT '挑战目标值(例如需要完成的天数)', progress_unit VARCHAR(64) NOT NULL DEFAULT '天' COMMENT '进度单位,用于展示排行榜指标', ranking_description VARCHAR(255) DEFAULT NULL COMMENT '排行榜描述,例如「连续打卡榜」', highlight_title VARCHAR(255) NOT NULL COMMENT '高亮标题', highlight_subtitle VARCHAR(255) NOT NULL COMMENT '高亮副标题', cta_label VARCHAR(128) NOT NULL COMMENT 'CTA 按钮文字', created_at DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP, updated_at DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci; CREATE TABLE IF NOT EXISTS t_challenge_participants ( id CHAR(36) NOT NULL PRIMARY KEY, challenge_id CHAR(36) NOT NULL COMMENT '挑战 ID', user_id VARCHAR(64) NOT NULL COMMENT '用户 ID', progress_value INT NOT NULL DEFAULT 0 COMMENT '当前进度值', target_value INT NOT NULL COMMENT '目标值,通常与挑战 target_value 相同', status ENUM('active', 'completed', 'left') NOT NULL DEFAULT 'active' COMMENT '参与状态', joined_at DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP COMMENT '加入时间', left_at DATETIME DEFAULT NULL COMMENT '退出时间', last_progress_at DATETIME DEFAULT NULL COMMENT '最近一次更新进度的时间', created_at DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP, updated_at DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP, CONSTRAINT fk_challenge_participant_challenge FOREIGN KEY (challenge_id) REFERENCES t_challenges (id) ON DELETE CASCADE ON UPDATE CASCADE, CONSTRAINT fk_challenge_participant_user FOREIGN KEY (user_id) REFERENCES t_users (id) ON DELETE CASCADE ON UPDATE CASCADE, CONSTRAINT uq_challenge_participant UNIQUE KEY (challenge_id, user_id) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci; CREATE INDEX idx_challenge_participants_status_progress ON t_challenge_participants (challenge_id, status, progress_value DESC, updated_at ASC);