-- ================================================================ -- 用户课程学习进度表迁移脚本 -- 创建日期: 2026-01-30 -- 功能: 添加用户课程进度追踪表和用户资料进度追踪表 -- ================================================================ -- 事务开始 START TRANSACTION; -- ================================================================ -- 1. 创建用户课程进度表 -- ================================================================ CREATE TABLE IF NOT EXISTS user_course_progress ( id INT PRIMARY KEY AUTO_INCREMENT, user_id INT NOT NULL COMMENT '用户ID', course_id INT NOT NULL COMMENT '课程ID', status VARCHAR(20) NOT NULL DEFAULT 'not_started' COMMENT '学习状态:not_started/in_progress/completed', progress_percent FLOAT NOT NULL DEFAULT 0 COMMENT '完成百分比(0-100)', completed_materials INT NOT NULL DEFAULT 0 COMMENT '已完成资料数', total_materials INT NOT NULL DEFAULT 0 COMMENT '总资料数', total_study_time INT NOT NULL DEFAULT 0 COMMENT '总学习时长(秒)', first_accessed_at DATETIME COMMENT '首次访问时间', last_accessed_at DATETIME COMMENT '最后访问时间', completed_at DATETIME COMMENT '完成时间', created_at DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP, updated_at DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP, UNIQUE KEY uq_user_course (user_id, course_id), INDEX idx_user_course_progress_user (user_id), INDEX idx_user_course_progress_course (course_id), INDEX idx_user_course_progress_status (status), FOREIGN KEY (user_id) REFERENCES users(id) ON DELETE CASCADE, FOREIGN KEY (course_id) REFERENCES courses(id) ON DELETE CASCADE ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='用户课程进度表'; -- ================================================================ -- 2. 创建用户资料进度表 -- ================================================================ CREATE TABLE IF NOT EXISTS user_material_progress ( id INT PRIMARY KEY AUTO_INCREMENT, user_id INT NOT NULL COMMENT '用户ID', material_id INT NOT NULL COMMENT '资料ID', course_id INT NOT NULL COMMENT '课程ID(冗余字段)', is_completed BOOLEAN NOT NULL DEFAULT FALSE COMMENT '是否已完成', progress_percent FLOAT NOT NULL DEFAULT 0 COMMENT '阅读/播放进度百分比(0-100)', last_position INT NOT NULL DEFAULT 0 COMMENT '上次播放位置(秒)', total_duration INT NOT NULL DEFAULT 0 COMMENT '媒体总时长(秒)', study_time INT NOT NULL DEFAULT 0 COMMENT '学习时长(秒)', first_accessed_at DATETIME COMMENT '首次访问时间', last_accessed_at DATETIME COMMENT '最后访问时间', completed_at DATETIME COMMENT '完成时间', created_at DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP, updated_at DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP, UNIQUE KEY uq_user_material (user_id, material_id), INDEX idx_user_material_progress_user (user_id), INDEX idx_user_material_progress_material (material_id), FOREIGN KEY (user_id) REFERENCES users(id) ON DELETE CASCADE, FOREIGN KEY (material_id) REFERENCES course_materials(id) ON DELETE CASCADE, FOREIGN KEY (course_id) REFERENCES courses(id) ON DELETE CASCADE ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='用户资料进度表'; -- 提交事务 COMMIT; -- ================================================================ -- 验证表创建 -- ================================================================ SELECT 'user_course_progress' as table_name, COUNT(*) as count FROM information_schema.tables WHERE table_schema = DATABASE() AND table_name = 'user_course_progress' UNION ALL SELECT 'user_material_progress' as table_name, COUNT(*) as count FROM information_schema.tables WHERE table_schema = DATABASE() AND table_name = 'user_material_progress';