feat: 初始化考培练系统项目
- 从服务器拉取完整代码 - 按框架规范整理项目结构 - 配置 Drone CI 测试环境部署 - 包含后端(FastAPI)、前端(Vue3)、管理端 技术栈: Vue3 + TypeScript + FastAPI + MySQL
This commit is contained in:
207
backend/scripts/seed_statistics_demo_data_v2.sql
Normal file
207
backend/scripts/seed_statistics_demo_data_v2.sql
Normal file
@@ -0,0 +1,207 @@
|
||||
-- 为统计分析页面生成轻医美场景的模拟数据(简化版)
|
||||
-- 使用方法: docker-compose -f docker-compose.dev.yml exec -T mysql-dev mysql -u root -p'nj861021' kaopeilian < kaopeilian-backend/scripts/seed_statistics_demo_data_v2.sql
|
||||
|
||||
SET NAMES utf8mb4;
|
||||
SET FOREIGN_KEY_CHECKS = 0;
|
||||
|
||||
-- ============================================
|
||||
-- 1. 获取用户ID(使用admin用户)
|
||||
-- ============================================
|
||||
SET @user_id = (SELECT id FROM users WHERE username = 'admin' LIMIT 1);
|
||||
SET @user_id = IFNULL(@user_id, (SELECT id FROM users WHERE role = 'trainee' LIMIT 1));
|
||||
SET @user_id = IFNULL(@user_id, 1);
|
||||
|
||||
SELECT CONCAT('✓ 使用用户: ', (SELECT username FROM users WHERE id = @user_id), ' (ID: ', @user_id, ')') AS '';
|
||||
|
||||
-- ============================================
|
||||
-- 2. 清理旧数据
|
||||
-- ============================================
|
||||
DELETE FROM exam_mistakes WHERE user_id = @user_id;
|
||||
DELETE FROM exams WHERE user_id = @user_id;
|
||||
DELETE FROM practice_dialogues WHERE session_id IN (
|
||||
SELECT session_id FROM practice_sessions WHERE user_id = @user_id
|
||||
);
|
||||
DELETE FROM practice_reports WHERE session_id IN (
|
||||
SELECT session_id FROM practice_sessions WHERE user_id = @user_id
|
||||
);
|
||||
DELETE FROM practice_sessions WHERE user_id = @user_id;
|
||||
|
||||
SELECT '✓ 旧数据清理完成' AS '';
|
||||
|
||||
-- ============================================
|
||||
-- 3. 生成考试记录(过去60天,呈现进步趋势)
|
||||
-- ============================================
|
||||
-- 使用临时表生成日期序列
|
||||
DROP TEMPORARY TABLE IF EXISTS date_series;
|
||||
CREATE TEMPORARY TABLE date_series (
|
||||
day_offset INT,
|
||||
exam_date DATETIME,
|
||||
progress_factor DECIMAL(5,2)
|
||||
);
|
||||
|
||||
-- 生成60天的日期,30%的天数有考试
|
||||
INSERT INTO date_series (day_offset, exam_date, progress_factor)
|
||||
SELECT
|
||||
n.day_offset,
|
||||
DATE_SUB(NOW(), INTERVAL n.day_offset DAY) + INTERVAL FLOOR(RAND() * 43200) SECOND AS exam_date,
|
||||
(60 - n.day_offset) / 60 AS progress_factor
|
||||
FROM (
|
||||
SELECT 1 AS day_offset UNION ALL SELECT 3 UNION ALL SELECT 5 UNION ALL SELECT 7 UNION ALL SELECT 9
|
||||
UNION ALL SELECT 11 UNION ALL SELECT 13 UNION ALL SELECT 15 UNION ALL SELECT 17 UNION ALL SELECT 19
|
||||
UNION ALL SELECT 21 UNION ALL SELECT 23 UNION ALL SELECT 25 UNION ALL SELECT 27 UNION ALL SELECT 29
|
||||
UNION ALL SELECT 31 UNION ALL SELECT 33 UNION ALL SELECT 35 UNION ALL SELECT 37 UNION ALL SELECT 39
|
||||
UNION ALL SELECT 41 UNION ALL SELECT 43 UNION ALL SELECT 45 UNION ALL SELECT 47 UNION ALL SELECT 49
|
||||
UNION ALL SELECT 51 UNION ALL SELECT 53 UNION ALL SELECT 55 UNION ALL SELECT 57 UNION ALL SELECT 59
|
||||
) AS n;
|
||||
|
||||
-- 生成考试记录
|
||||
INSERT INTO exams (
|
||||
user_id, course_id, exam_name, question_count, total_score, pass_score,
|
||||
start_time, end_time, duration_minutes, round1_score, score, is_passed, status,
|
||||
created_at, updated_at
|
||||
)
|
||||
SELECT
|
||||
@user_id,
|
||||
c.id,
|
||||
CONCAT(c.name, '测试'),
|
||||
10,
|
||||
100.0,
|
||||
60.0,
|
||||
ds.exam_date,
|
||||
DATE_ADD(ds.exam_date, INTERVAL (20 + FLOOR(RAND() * 25)) MINUTE),
|
||||
20 + FLOOR(RAND() * 25),
|
||||
-- 分数呈现进步趋势:基础分60分,根据时间进度增加0-35分
|
||||
ROUND(60 + (ds.progress_factor * 20) + (RAND() * 15), 1) AS round1_score,
|
||||
ROUND(60 + (ds.progress_factor * 20) + (RAND() * 15), 1) AS score,
|
||||
TRUE,
|
||||
'submitted',
|
||||
ds.exam_date,
|
||||
ds.exam_date
|
||||
FROM date_series ds
|
||||
CROSS JOIN courses c
|
||||
WHERE c.is_deleted = FALSE AND c.status = 'published'
|
||||
ORDER BY RAND()
|
||||
LIMIT 50;
|
||||
|
||||
-- 更新is_passed状态
|
||||
UPDATE exams SET is_passed = (round1_score >= pass_score) WHERE user_id = @user_id;
|
||||
|
||||
SELECT CONCAT('✓ 创建了 ', COUNT(*), ' 条考试记录') AS ''
|
||||
FROM exams WHERE user_id = @user_id;
|
||||
|
||||
-- ============================================
|
||||
-- 4. 生成错题记录(增强版 - 确保足够的错题数据)
|
||||
-- ============================================
|
||||
-- 为每个考试生成3-5个错题,不管分数高低
|
||||
-- 这样可以确保有足够的统计样本
|
||||
|
||||
-- 方法:为每个考试生成多个错题
|
||||
INSERT INTO exam_mistakes (
|
||||
user_id, exam_id, question_id, knowledge_point_id,
|
||||
question_content, correct_answer, user_answer, question_type,
|
||||
created_at, updated_at
|
||||
)
|
||||
SELECT
|
||||
e.user_id,
|
||||
e.id,
|
||||
NULL,
|
||||
kp.id,
|
||||
CONCAT('关于"', kp.name, '"的',
|
||||
ELT(1 + FLOOR(RAND() * 3), '概念理解', '实际应用', '综合分析'), '问题'),
|
||||
CONCAT('正确答案:', kp.name, '的标准解释'),
|
||||
CONCAT('错误理解:', '学员对', kp.name, '的误解'),
|
||||
ELT(1 + FLOOR(RAND() * 5), 'single_choice', 'multiple_choice', 'true_false', 'fill_blank', 'essay'),
|
||||
e.start_time,
|
||||
e.start_time
|
||||
FROM exams e
|
||||
CROSS JOIN (
|
||||
SELECT 1 AS mistake_num UNION ALL SELECT 2 UNION ALL SELECT 3 UNION ALL SELECT 4
|
||||
) AS mistake_counts
|
||||
INNER JOIN knowledge_points kp ON kp.course_id = e.course_id
|
||||
WHERE e.user_id = @user_id
|
||||
AND kp.is_deleted = FALSE
|
||||
-- 高分考试(90+)生成1-2个错题
|
||||
AND (
|
||||
(e.round1_score >= 90 AND mistake_counts.mistake_num <= 2 AND RAND() < 0.5)
|
||||
-- 中等分数(80-90)生成2-3个错题
|
||||
OR (e.round1_score >= 80 AND e.round1_score < 90 AND mistake_counts.mistake_num <= 3 AND RAND() < 0.7)
|
||||
-- 一般分数(70-80)生成3-4个错题
|
||||
OR (e.round1_score >= 70 AND e.round1_score < 80 AND mistake_counts.mistake_num <= 4 AND RAND() < 0.8)
|
||||
-- 低分(<70)生成4-5个错题
|
||||
OR (e.round1_score < 70 AND mistake_counts.mistake_num <= 5 AND RAND() < 0.9)
|
||||
)
|
||||
ORDER BY RAND()
|
||||
LIMIT 250;
|
||||
|
||||
SELECT CONCAT('✓ 创建了 ', COUNT(*), ' 条错题记录') AS ''
|
||||
FROM exam_mistakes WHERE user_id = @user_id;
|
||||
|
||||
-- ============================================
|
||||
-- 5. 生成陪练会话记录
|
||||
-- ============================================
|
||||
INSERT INTO practice_sessions (
|
||||
session_id, user_id, scene_id, scene_name, scene_type,
|
||||
start_time, end_time, duration_seconds, turns, status, is_deleted,
|
||||
created_at, updated_at
|
||||
)
|
||||
SELECT
|
||||
CONCAT('session_', @user_id, '_', UNIX_TIMESTAMP(practice_dt)),
|
||||
@user_id,
|
||||
1 + FLOOR(RAND() * 5),
|
||||
ELT(1 + FLOOR(RAND() * 5), '电话销售陪练', '面对面咨询陪练', '客户投诉处理陪练', '售后服务陪练', '产品介绍陪练'),
|
||||
ELT(1 + FLOOR(RAND() * 5), 'phone', 'face', 'complaint', 'after-sales', 'product-intro'),
|
||||
practice_dt,
|
||||
DATE_ADD(practice_dt, INTERVAL duration_sec SECOND),
|
||||
duration_sec,
|
||||
12 + FLOOR(RAND() * 18),
|
||||
'completed',
|
||||
FALSE,
|
||||
practice_dt,
|
||||
practice_dt
|
||||
FROM (
|
||||
SELECT
|
||||
DATE_SUB(NOW(), INTERVAL FLOOR(RAND() * 60) DAY) + INTERVAL FLOOR(RAND() * 43200) SECOND AS practice_dt,
|
||||
900 + FLOOR(RAND() * 900) AS duration_sec
|
||||
FROM (
|
||||
SELECT 1 AS n UNION ALL SELECT 2 UNION ALL SELECT 3 UNION ALL SELECT 4 UNION ALL SELECT 5
|
||||
UNION ALL SELECT 6 UNION ALL SELECT 7 UNION ALL SELECT 8 UNION ALL SELECT 9 UNION ALL SELECT 10
|
||||
UNION ALL SELECT 11 UNION ALL SELECT 12 UNION ALL SELECT 13 UNION ALL SELECT 14 UNION ALL SELECT 15
|
||||
UNION ALL SELECT 16 UNION ALL SELECT 17 UNION ALL SELECT 18
|
||||
) AS numbers
|
||||
) AS practice_dates;
|
||||
|
||||
SELECT CONCAT('✓ 创建了 ', COUNT(*), ' 条陪练会话记录') AS ''
|
||||
FROM practice_sessions WHERE user_id = @user_id;
|
||||
|
||||
-- ============================================
|
||||
-- 6. 统计汇总
|
||||
-- ============================================
|
||||
SELECT '========================================' AS '';
|
||||
SELECT '✅ 数据生成完成!' AS '';
|
||||
SELECT '========================================' AS '';
|
||||
|
||||
SELECT CONCAT('用户: ', username, ' (ID: ', id, ')') AS ''
|
||||
FROM users WHERE id = @user_id;
|
||||
|
||||
SELECT CONCAT('✓ 考试记录: ', COUNT(*), ' 条') AS ''
|
||||
FROM exams WHERE user_id = @user_id;
|
||||
|
||||
SELECT CONCAT('✓ 错题记录: ', COUNT(*), ' 条') AS ''
|
||||
FROM exam_mistakes WHERE user_id = @user_id;
|
||||
|
||||
SELECT CONCAT('✓ 陪练记录: ', COUNT(*), ' 条') AS ''
|
||||
FROM practice_sessions WHERE user_id = @user_id;
|
||||
|
||||
SELECT CONCAT('✓ 知识点数量: ', COUNT(*), ' 个') AS ''
|
||||
FROM knowledge_points WHERE is_deleted = FALSE;
|
||||
|
||||
SELECT '========================================' AS '';
|
||||
SELECT '现在可以访问统计分析页面查看数据:' AS '';
|
||||
SELECT 'http://localhost:5173/analysis/statistics' AS '';
|
||||
SELECT '========================================' AS '';
|
||||
|
||||
-- 清理临时表
|
||||
DROP TEMPORARY TABLE IF EXISTS date_series;
|
||||
|
||||
SET FOREIGN_KEY_CHECKS = 1;
|
||||
|
||||
Reference in New Issue
Block a user