Files
java-servers/sql/20251115/数据迁移SQL脚本.sql
2025-11-04 15:09:42 +08:00

216 lines
6.9 KiB
SQL
Raw Blame History

This file contains ambiguous Unicode characters
This file contains Unicode characters that might be confused with other characters. If you think that this is intentional, you can safely ignore this warning. Use the Escape button to reveal them.
-- 数据迁移SQL项目与报名
-- 执行顺序:
-- 1.1 查看项目数据量
-- 1.2 预览项目数据
-- 1.3 迁移项目信息
-- 1.4 验证项目迁移结果
-- 2.1 查看报名数据量按项目ID
-- 2.2 预览报名数据
-- 2.3 获取新项目ID
-- 2.4 写入报名数据使用新项目ID
-- 2.5 验证报名迁移结果
-- 任务1项目数据迁移eln_boe_mixture_project -> boe_new.project_info条件is_deleted='0' AND program_name='社招新员工在线入职学习'
-- 步骤1.1:查看符合条件的数据量(执行前验证)
SELECT COUNT(*) AS data_count
FROM elearninglms.eln_boe_mixture_project
WHERE is_deleted = '0'
AND program_name = '社招新员工在线入职学习';
-- 步骤1.2:查看要迁移的数据详情(执行前验证)
SELECT *
FROM elearninglms.eln_boe_mixture_project
WHERE is_deleted = '0'
AND program_name = '社招新员工在线入职学习';
-- 步骤1.3执行数据迁移INSERT INTO ... SELECT
INSERT INTO boe_new.project_info (
name,
pic_url,
type,
begin_time,
end_time,
manager_id,
remark,
status,
num_value,
introduction,
new_type,
deleted,
unlock_mode,
rank_flag,
attach_switch,
bpm_flag,
load_flag,
create_time,
create_id,
update_time,
update_id
)
SELECT
p.program_name AS name,
p.theme_url AS pic_url,
1 AS type, -- 项目类别固定为1
CASE
WHEN p.open_start_time IS NOT NULL AND p.open_start_time > 0
THEN FROM_UNIXTIME(p.open_start_time)
WHEN p.start_time IS NOT NULL AND p.start_time > 0
THEN FROM_UNIXTIME(p.start_time)
ELSE NULL
END AS begin_time,
CASE
WHEN p.open_end_time IS NOT NULL AND p.open_end_time > 0
THEN FROM_UNIXTIME(p.open_end_time)
WHEN p.end_time IS NOT NULL AND p.end_time > 0
THEN FROM_UNIXTIME(p.end_time)
ELSE NULL
END AS end_time,
p.project_manager_id AS manager_id,
COALESCE(p.program_desc, p.program_desc_nohtml, '') AS remark,
CASE
WHEN p.status = '0' THEN 0 -- 临时 → 草稿
WHEN p.status = '1' THEN 1 -- 正常 → 已发布
WHEN p.status = '2' THEN -1 -- 停用 → 已结束
ELSE 0
END AS status,
p.program_code AS num_value,
COALESCE(p.program_desc_nohtml, p.program_desc, '') AS introduction,
2 AS new_type, -- 学习项目
0 AS deleted, -- 未删除
1 AS unlock_mode, -- 自由模式
0 AS rank_flag, -- 不显示积分排行榜
1 AS attach_switch, -- 共享文档开启
0 AS bpm_flag, -- 报名审批关闭
0 AS load_flag, -- 下载成绩关闭
FROM_UNIXTIME(p.created_at) AS create_time,
CAST(p.created_by AS UNSIGNED) AS create_id,
FROM_UNIXTIME(COALESCE(p.updated_at, p.created_at)) AS update_time,
CAST(COALESCE(p.updated_by, p.created_by) AS UNSIGNED) AS update_id
FROM elearninglms.eln_boe_mixture_project p
WHERE p.is_deleted = '0'
AND p.program_name = '社招新员工在线入职学习'
AND NOT EXISTS (
-- 防止重复插入:如果项目名称已存在则跳过
SELECT 1
FROM boe_new.project_info pi
WHERE pi.name = p.program_name
AND pi.deleted = 0
);
-- 步骤1.4:验证迁移结果
SELECT
COUNT(*) AS migrated_count,
name,
status,
begin_time,
end_time
FROM boe_new.project_info
WHERE name = '社招新员工在线入职学习'
AND deleted = 0
GROUP BY name, status, begin_time, end_time;
-- 任务2项目报名数据迁移eln_boe_mixture_project_enroll -> boe_base.boe_study_course
-- 迁移全部报名数据(包括已删除记录,按 is_deleted 映射状态)
-- 步骤2.1:查看符合条件的数据量(执行前验证)
-- 注意:需要先将 '123xxx' 替换为实际的项目IDkid
SELECT COUNT(*) AS enroll_count
FROM elearninglms.eln_boe_mixture_project_enroll
WHERE program_id = '123xxx'; -- 请替换为实际的项目IDkid
-- 步骤2.2:查看要迁移的数据详情(执行前验证)
SELECT *
FROM elearninglms.eln_boe_mixture_project_enroll
WHERE program_id = '123xxx' -- 请替换为实际的项目IDkid
LIMIT 100;
-- 步骤2.3获取新项目ID
SET @new_project_id = (
SELECT id FROM boe_new.project_info
WHERE name = '社招新员工在线入职学习' AND deleted = 0
ORDER BY id DESC LIMIT 1
);
-- 步骤2.4写入报名数据使用新项目ID
INSERT INTO boe_base.boe_study_course (
course_id,
course_type,
course_name,
aid,
aname,
source,
add_time,
start_time,
last_score,
status,
progress,
remark
)
SELECT
pi.id AS course_id, -- 使用新项目表的自增ID
90 AS course_type,
COALESCE(pi.name, p.program_name, '') AS course_name,
e.user_id AS aid,
COALESCE(u.real_name, '') AS aname,
CASE
WHEN e.enroll_method = 'self' THEN 1
WHEN e.enroll_method = 'admin' THEN 2
WHEN e.enroll_method = 'manager' THEN 3
ELSE 1
END AS source,
FROM_UNIXTIME(e.enroll_time) AS add_time,
FROM_UNIXTIME(e.enroll_time) AS start_time,
NULL AS last_score,
CASE
WHEN e.enroll_type = '1' AND e.approved_state = '1' AND e.is_deleted = '0' THEN 2
WHEN e.enroll_type = '3' THEN 8
WHEN e.cancel_state = '1' THEN 8
WHEN e.is_deleted = '1' THEN 8
ELSE 1
END AS status,
0 AS progress,
CONCAT('迁移自项目报名表报名ID', e.kid) AS remark
FROM elearninglms.eln_boe_mixture_project_enroll e
LEFT JOIN elearninglms.eln_boe_mixture_project p
ON e.program_id = p.kid
LEFT JOIN boe_new.project_info pi
ON p.program_name = pi.name AND pi.deleted = 0
LEFT JOIN elearninglms.eln_fw_user u
ON e.user_id = u.kid
WHERE e.program_id = '123xxx' -- 请替换为实际的项目IDkid
AND pi.id = @new_project_id -- 使用新项目ID
AND NOT EXISTS (
SELECT 1
FROM boe_base.boe_study_course sc
WHERE sc.course_id = @new_project_id
AND sc.aid = e.user_id
);
-- 步骤2.5:验证迁移结果
SELECT
COUNT(*) AS migrated_count,
status,
COUNT(CASE WHEN last_score IS NOT NULL THEN 1 END) AS has_score_count
FROM boe_base.boe_study_course
WHERE course_id = @new_project_id
GROUP BY status;
-- 回滚SQL
-- 回滚步骤R1确认新项目ID如变量丢失可重新获取
--SET @new_project_id = (
-- SELECT id FROM boe_new.project_info
-- WHERE name = '社招新员工在线入职学习' AND deleted = 0
-- ORDER BY id DESC LIMIT 1
--);
--
---- 回滚步骤R2回滚报名数据按备注标记仅删除本次迁移写入的数据
--DELETE FROM boe_base.boe_study_course
--WHERE course_id = @new_project_id
-- AND remark LIKE '迁移自项目报名表%';
--
---- 回滚步骤R3回滚项目信息谨慎执行确认仅影响本次迁移记录
--DELETE FROM boe_new.project_info
--WHERE id = @new_project_id
-- AND name = '社招新员工在线入职学习'
-- AND deleted = 0;