Some checks failed
continuous-integration/drone/push Build is failing
- 后端: 新增 user_levels, exp_history, badge_definitions, user_badges, level_configs 表 - 后端: 新增 LevelService 和 BadgeService 服务 - 后端: 新增等级/奖章/签到/排行榜 API 端点 - 后端: 考试/练习/陪练完成时触发经验值和奖章检查 - 前端: 新增 LevelBadge, ExpProgress, BadgeCard, LevelUpDialog 组件 - 前端: 新增排行榜页面 - 前端: 成长路径页面集成真实等级数据 - 数据库: 包含迁移脚本和初始数据
193 lines
11 KiB
SQL
193 lines
11 KiB
SQL
-- =====================================================
|
||
-- 等级与奖章系统数据库迁移脚本
|
||
-- 版本: 1.0.0
|
||
-- 创建时间: 2026-01-29
|
||
-- 说明: 添加用户等级系统和奖章系统相关表
|
||
-- =====================================================
|
||
|
||
-- 使用事务确保原子性
|
||
START TRANSACTION;
|
||
|
||
-- =====================================================
|
||
-- 1. 用户等级表 (user_levels)
|
||
-- 存储用户的等级和经验值信息
|
||
-- =====================================================
|
||
CREATE TABLE IF NOT EXISTS user_levels (
|
||
id INT AUTO_INCREMENT PRIMARY KEY,
|
||
user_id INT NOT NULL COMMENT '用户ID',
|
||
level INT NOT NULL DEFAULT 1 COMMENT '当前等级',
|
||
exp INT NOT NULL DEFAULT 0 COMMENT '当前经验值',
|
||
total_exp INT NOT NULL DEFAULT 0 COMMENT '累计获得经验值',
|
||
login_streak INT NOT NULL DEFAULT 0 COMMENT '连续登录天数',
|
||
max_login_streak INT NOT NULL DEFAULT 0 COMMENT '历史最长连续登录天数',
|
||
last_login_date DATE NULL COMMENT '最后登录日期(用于计算连续登录)',
|
||
last_checkin_at DATETIME NULL COMMENT '最后签到时间',
|
||
created_at DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
||
updated_at DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
|
||
UNIQUE KEY uk_user_id (user_id),
|
||
INDEX idx_level (level),
|
||
INDEX idx_total_exp (total_exp),
|
||
FOREIGN KEY (user_id) REFERENCES users(id) ON DELETE CASCADE
|
||
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='用户等级表';
|
||
|
||
-- =====================================================
|
||
-- 2. 经验值历史表 (exp_history)
|
||
-- 记录每次经验值变化的详细信息
|
||
-- =====================================================
|
||
CREATE TABLE IF NOT EXISTS exp_history (
|
||
id INT AUTO_INCREMENT PRIMARY KEY,
|
||
user_id INT NOT NULL COMMENT '用户ID',
|
||
exp_change INT NOT NULL COMMENT '经验值变化(正为获得,负为扣除)',
|
||
exp_type VARCHAR(50) NOT NULL COMMENT '类型:exam/practice/training/task/login/badge/other',
|
||
source_id INT NULL COMMENT '来源记录ID(如考试ID、练习ID等)',
|
||
description VARCHAR(255) NOT NULL COMMENT '描述',
|
||
level_before INT NULL COMMENT '变化前等级',
|
||
level_after INT NULL COMMENT '变化后等级',
|
||
created_at DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
||
INDEX idx_user_id (user_id),
|
||
INDEX idx_exp_type (exp_type),
|
||
INDEX idx_created_at (created_at),
|
||
FOREIGN KEY (user_id) REFERENCES users(id) ON DELETE CASCADE
|
||
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='经验值历史表';
|
||
|
||
-- =====================================================
|
||
-- 3. 奖章定义表 (badge_definitions)
|
||
-- 定义所有可获得的奖章及其解锁条件
|
||
-- =====================================================
|
||
CREATE TABLE IF NOT EXISTS badge_definitions (
|
||
id INT AUTO_INCREMENT PRIMARY KEY,
|
||
code VARCHAR(50) NOT NULL COMMENT '奖章编码(唯一标识)',
|
||
name VARCHAR(100) NOT NULL COMMENT '奖章名称',
|
||
description VARCHAR(255) NOT NULL COMMENT '奖章描述',
|
||
icon VARCHAR(100) NOT NULL DEFAULT 'Medal' COMMENT '图标名称(Element Plus 图标)',
|
||
category VARCHAR(50) NOT NULL COMMENT '分类:learning/exam/practice/streak/special',
|
||
condition_type VARCHAR(50) NOT NULL COMMENT '条件类型:count/score/streak/level/duration',
|
||
condition_field VARCHAR(100) NULL COMMENT '条件字段(用于复杂条件)',
|
||
condition_value INT NOT NULL DEFAULT 1 COMMENT '条件数值',
|
||
exp_reward INT NOT NULL DEFAULT 0 COMMENT '解锁奖励经验值',
|
||
sort_order INT NOT NULL DEFAULT 0 COMMENT '排序顺序',
|
||
is_active TINYINT(1) NOT NULL DEFAULT 1 COMMENT '是否启用',
|
||
created_at DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
||
updated_at DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
|
||
UNIQUE KEY uk_code (code),
|
||
INDEX idx_category (category),
|
||
INDEX idx_is_active (is_active)
|
||
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='奖章定义表';
|
||
|
||
-- =====================================================
|
||
-- 4. 用户奖章表 (user_badges)
|
||
-- 记录用户已解锁的奖章
|
||
-- =====================================================
|
||
CREATE TABLE IF NOT EXISTS user_badges (
|
||
id INT AUTO_INCREMENT PRIMARY KEY,
|
||
user_id INT NOT NULL COMMENT '用户ID',
|
||
badge_id INT NOT NULL COMMENT '奖章ID',
|
||
unlocked_at DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP COMMENT '解锁时间',
|
||
is_notified TINYINT(1) NOT NULL DEFAULT 0 COMMENT '是否已通知用户',
|
||
notified_at DATETIME NULL COMMENT '通知时间',
|
||
created_at DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
||
UNIQUE KEY uk_user_badge (user_id, badge_id),
|
||
INDEX idx_user_id (user_id),
|
||
INDEX idx_badge_id (badge_id),
|
||
INDEX idx_unlocked_at (unlocked_at),
|
||
FOREIGN KEY (user_id) REFERENCES users(id) ON DELETE CASCADE,
|
||
FOREIGN KEY (badge_id) REFERENCES badge_definitions(id) ON DELETE CASCADE
|
||
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='用户奖章表';
|
||
|
||
-- =====================================================
|
||
-- 5. 等级配置表 (level_configs)
|
||
-- 定义每个等级所需的经验值和称号
|
||
-- =====================================================
|
||
CREATE TABLE IF NOT EXISTS level_configs (
|
||
id INT AUTO_INCREMENT PRIMARY KEY,
|
||
level INT NOT NULL COMMENT '等级',
|
||
exp_required INT NOT NULL COMMENT '升到此级所需经验值',
|
||
total_exp_required INT NOT NULL COMMENT '累计所需经验值',
|
||
title VARCHAR(50) NOT NULL COMMENT '等级称号',
|
||
color VARCHAR(20) NULL COMMENT '等级颜色(十六进制)',
|
||
created_at DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
||
UNIQUE KEY uk_level (level)
|
||
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='等级配置表';
|
||
|
||
-- =====================================================
|
||
-- 6. 插入等级配置数据
|
||
-- =====================================================
|
||
INSERT INTO level_configs (level, exp_required, total_exp_required, title, color) VALUES
|
||
(1, 0, 0, '初学者', '#909399'),
|
||
(2, 100, 100, '入门学徒', '#67C23A'),
|
||
(3, 200, 300, '勤奋学员', '#67C23A'),
|
||
(4, 400, 700, '进阶学员', '#409EFF'),
|
||
(5, 600, 1300, '优秀学员', '#409EFF'),
|
||
(6, 1000, 2300, '精英学员', '#E6A23C'),
|
||
(7, 1500, 3800, '资深学员', '#E6A23C'),
|
||
(8, 2000, 5800, '学习达人', '#F56C6C'),
|
||
(9, 3000, 8800, '学霸', '#F56C6C'),
|
||
(10, 5000, 13800, '大师', '#9B59B6');
|
||
|
||
-- =====================================================
|
||
-- 7. 插入奖章定义数据
|
||
-- =====================================================
|
||
|
||
-- 7.1 学习进度类奖章
|
||
INSERT INTO badge_definitions (code, name, description, icon, category, condition_type, condition_field, condition_value, exp_reward, sort_order) VALUES
|
||
('first_login', '初来乍到', '首次登录系统', 'Star', 'learning', 'count', 'login_count', 1, 10, 101),
|
||
('course_1', '求知若渴', '完成1门课程学习', 'Reading', 'learning', 'count', 'course_completed', 1, 30, 102),
|
||
('course_5', '博学多才', '完成5门课程学习', 'Collection', 'learning', 'count', 'course_completed', 5, 100, 103),
|
||
('course_10', '学识渊博', '完成10门课程学习', 'Files', 'learning', 'count', 'course_completed', 10, 200, 104);
|
||
|
||
-- 7.2 考试成绩类奖章
|
||
INSERT INTO badge_definitions (code, name, description, icon, category, condition_type, condition_field, condition_value, exp_reward, sort_order) VALUES
|
||
('exam_pass_1', '初试牛刀', '通过1次考试', 'Select', 'exam', 'count', 'exam_passed', 1, 20, 201),
|
||
('exam_pass_10', '身经百战', '通过10次考试', 'Finished', 'exam', 'count', 'exam_passed', 10, 100, 202),
|
||
('exam_pass_50', '考试达人', '通过50次考试', 'Trophy', 'exam', 'count', 'exam_passed', 50, 300, 203),
|
||
('exam_perfect', '完美答卷', '考试获得满分', 'Medal', 'exam', 'score', 'exam_perfect_count', 1, 150, 204),
|
||
('exam_excellent_10', '学霸之路', '10次考试90分以上', 'TrendCharts', 'exam', 'count', 'exam_excellent', 10, 200, 205);
|
||
|
||
-- 7.3 练习时长类奖章
|
||
INSERT INTO badge_definitions (code, name, description, icon, category, condition_type, condition_field, condition_value, exp_reward, sort_order) VALUES
|
||
('practice_1h', '初窥门径', '累计练习1小时', 'Clock', 'practice', 'duration', 'practice_hours', 1, 30, 301),
|
||
('practice_10h', '勤学苦练', '累计练习10小时', 'Timer', 'practice', 'duration', 'practice_hours', 10, 100, 302),
|
||
('practice_50h', '炉火纯青', '累计练习50小时', 'Stopwatch', 'practice', 'duration', 'practice_hours', 50, 300, 303),
|
||
('practice_100', '练习狂人', '完成100次练习', 'Operation', 'practice', 'count', 'practice_count', 100, 200, 304);
|
||
|
||
-- 7.4 连续打卡类奖章
|
||
INSERT INTO badge_definitions (code, name, description, icon, category, condition_type, condition_field, condition_value, exp_reward, sort_order) VALUES
|
||
('streak_3', '小试身手', '连续登录3天', 'Calendar', 'streak', 'streak', 'login_streak', 3, 20, 401),
|
||
('streak_7', '坚持一周', '连续登录7天', 'Calendar', 'streak', 'streak', 'login_streak', 7, 50, 402),
|
||
('streak_30', '持之以恒', '连续登录30天', 'Calendar', 'streak', 'streak', 'login_streak', 30, 200, 403),
|
||
('streak_100', '百日不懈', '连续登录100天', 'Calendar', 'streak', 'streak', 'login_streak', 100, 500, 404);
|
||
|
||
-- 7.5 特殊成就类奖章
|
||
INSERT INTO badge_definitions (code, name, description, icon, category, condition_type, condition_field, condition_value, exp_reward, sort_order) VALUES
|
||
('level_5', '初露锋芒', '达到5级', 'Rank', 'special', 'level', 'user_level', 5, 100, 501),
|
||
('level_10', '登峰造极', '达到满级', 'Crown', 'special', 'level', 'user_level', 10, 500, 502),
|
||
('training_master', '陪练大师', '完成50次陪练', 'Headset', 'special', 'count', 'training_count', 50, 300, 503),
|
||
('first_perfect_practice', '首次完美', '陪练首次获得90分以上', 'StarFilled', 'special', 'score', 'first_practice_90', 1, 100, 504);
|
||
|
||
-- =====================================================
|
||
-- 8. 为现有用户初始化等级数据
|
||
-- =====================================================
|
||
INSERT INTO user_levels (user_id, level, exp, total_exp, login_streak, last_login_date)
|
||
SELECT
|
||
id as user_id,
|
||
1 as level,
|
||
0 as exp,
|
||
0 as total_exp,
|
||
0 as login_streak,
|
||
NULL as last_login_date
|
||
FROM users
|
||
WHERE is_deleted = 0
|
||
ON DUPLICATE KEY UPDATE updated_at = CURRENT_TIMESTAMP;
|
||
|
||
-- 提交事务
|
||
COMMIT;
|
||
|
||
-- =====================================================
|
||
-- 回滚脚本(如需回滚,执行以下语句)
|
||
-- =====================================================
|
||
-- DROP TABLE IF EXISTS user_badges;
|
||
-- DROP TABLE IF EXISTS badge_definitions;
|
||
-- DROP TABLE IF EXISTS exp_history;
|
||
-- DROP TABLE IF EXISTS level_configs;
|
||
-- DROP TABLE IF EXISTS user_levels;
|