-- 成长路径功能数据库迁移脚本 -- 创建时间: 2026-01-30 -- ===================================================== -- 1. 修改 growth_paths 表,添加岗位关联 -- ===================================================== ALTER TABLE growth_paths ADD COLUMN IF NOT EXISTS position_id INT NULL COMMENT '关联岗位ID' AFTER target_role, ADD COLUMN IF NOT EXISTS stages JSON NULL COMMENT '阶段配置[{name, description, order}]' AFTER courses, ADD INDEX idx_position_id (position_id); -- ===================================================== -- 2. 创建成长路径节点表 -- ===================================================== CREATE TABLE IF NOT EXISTS growth_path_nodes ( id INT AUTO_INCREMENT PRIMARY KEY, growth_path_id INT NOT NULL COMMENT '成长路径ID', course_id INT NOT NULL COMMENT '课程ID', stage_name VARCHAR(100) NULL COMMENT '所属阶段名称', title VARCHAR(200) NOT NULL COMMENT '节点标题', description TEXT NULL COMMENT '节点描述', order_num INT DEFAULT 0 NOT NULL COMMENT '排序顺序', is_required BOOLEAN DEFAULT TRUE NOT NULL COMMENT '是否必修', prerequisites JSON NULL COMMENT '前置节点IDs [1, 2, 3]', estimated_days INT DEFAULT 7 COMMENT '预计学习天数', -- 软删除 is_deleted BOOLEAN DEFAULT FALSE NOT NULL, deleted_at DATETIME NULL, -- 时间戳 created_at DATETIME DEFAULT CURRENT_TIMESTAMP NOT NULL, updated_at DATETIME DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP NOT NULL, -- 索引 INDEX idx_growth_path_id (growth_path_id), INDEX idx_course_id (course_id), INDEX idx_stage_name (stage_name), INDEX idx_order_num (order_num), INDEX idx_is_deleted (is_deleted), -- 外键 CONSTRAINT fk_gpn_growth_path FOREIGN KEY (growth_path_id) REFERENCES growth_paths(id) ON DELETE CASCADE, CONSTRAINT fk_gpn_course FOREIGN KEY (course_id) REFERENCES courses(id) ON DELETE CASCADE ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='成长路径节点表'; -- ===================================================== -- 3. 创建用户成长路径进度表 -- ===================================================== CREATE TABLE IF NOT EXISTS user_growth_path_progress ( id INT AUTO_INCREMENT PRIMARY KEY, user_id INT NOT NULL COMMENT '用户ID', growth_path_id INT NOT NULL COMMENT '成长路径ID', current_node_id INT NULL COMMENT '当前学习节点ID', completed_node_ids JSON NULL COMMENT '已完成节点IDs [1, 2, 3]', total_progress DECIMAL(5,2) DEFAULT 0.00 COMMENT '总进度百分比', status VARCHAR(20) DEFAULT 'not_started' NOT NULL COMMENT '状态: not_started/in_progress/completed', -- 时间记录 started_at DATETIME NULL COMMENT '开始时间', completed_at DATETIME NULL COMMENT '完成时间', last_activity_at DATETIME NULL COMMENT '最后活动时间', -- 时间戳 created_at DATETIME DEFAULT CURRENT_TIMESTAMP NOT NULL, updated_at DATETIME DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP NOT NULL, -- 索引 INDEX idx_user_id (user_id), INDEX idx_growth_path_id (growth_path_id), INDEX idx_status (status), UNIQUE KEY uk_user_growth_path (user_id, growth_path_id), -- 外键 CONSTRAINT fk_ugpp_user FOREIGN KEY (user_id) REFERENCES users(id) ON DELETE CASCADE, CONSTRAINT fk_ugpp_growth_path FOREIGN KEY (growth_path_id) REFERENCES growth_paths(id) ON DELETE CASCADE ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='用户成长路径进度表'; -- ===================================================== -- 4. 创建用户节点完成记录表(详细记录每个节点的完成情况) -- ===================================================== CREATE TABLE IF NOT EXISTS user_node_completions ( id INT AUTO_INCREMENT PRIMARY KEY, user_id INT NOT NULL COMMENT '用户ID', growth_path_id INT NOT NULL COMMENT '成长路径ID', node_id INT NOT NULL COMMENT '节点ID', course_progress DECIMAL(5,2) DEFAULT 0.00 COMMENT '课程学习进度', status VARCHAR(20) DEFAULT 'locked' NOT NULL COMMENT '状态: locked/unlocked/in_progress/completed', -- 时间记录 unlocked_at DATETIME NULL COMMENT '解锁时间', started_at DATETIME NULL COMMENT '开始学习时间', completed_at DATETIME NULL COMMENT '完成时间', -- 时间戳 created_at DATETIME DEFAULT CURRENT_TIMESTAMP NOT NULL, updated_at DATETIME DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP NOT NULL, -- 索引 INDEX idx_user_id (user_id), INDEX idx_growth_path_id (growth_path_id), INDEX idx_node_id (node_id), INDEX idx_status (status), UNIQUE KEY uk_user_node (user_id, node_id), -- 外键 CONSTRAINT fk_unc_user FOREIGN KEY (user_id) REFERENCES users(id) ON DELETE CASCADE, CONSTRAINT fk_unc_node FOREIGN KEY (node_id) REFERENCES growth_path_nodes(id) ON DELETE CASCADE ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='用户节点完成记录表';