-- ============================================= -- 角色权限迁移脚本 -- 将 yz_role_menus 表中的权限数据迁移到 yz_roles 表的 menu_ids 字段(JSON数组) -- 执行时间: 2025 -- ============================================= SET NAMES utf8mb4; -- ============================================= -- 步骤1: 在 yz_roles 表中添加 menu_ids 字段(JSON类型存储菜单ID数组) -- ============================================= -- 检查字段是否已存在 SET @exist := (SELECT COUNT(*) FROM information_schema.columns WHERE table_schema = DATABASE() AND table_name = 'yz_roles' AND column_name = 'menu_ids'); SET @sqlstmt := IF(@exist = 0, 'ALTER TABLE yz_roles ADD COLUMN menu_ids JSON NULL COMMENT "菜单权限ID数组,JSON格式存储" AFTER description', 'SELECT "字段 menu_ids 已存在" AS message'); PREPARE stmt FROM @sqlstmt; EXECUTE stmt; DEALLOCATE PREPARE stmt; -- ============================================= -- 步骤2: 从 yz_role_menus 表迁移数据到 yz_roles.menu_ids -- ============================================= -- 使用临时存储过程迁移数据 DELIMITER $$ DROP PROCEDURE IF EXISTS migrate_role_permissions$$ CREATE PROCEDURE migrate_role_permissions() BEGIN DECLARE done INT DEFAULT FALSE; DECLARE v_role_id INT; DECLARE v_menu_ids JSON; DECLARE cur CURSOR FOR SELECT role_id, JSON_ARRAYAGG(menu_id ORDER BY menu_id) as menu_ids FROM yz_role_menus GROUP BY role_id; DECLARE CONTINUE HANDLER FOR NOT FOUND SET done = TRUE; OPEN cur; read_loop: LOOP FETCH cur INTO v_role_id, v_menu_ids; IF done THEN LEAVE read_loop; END IF; -- 更新角色表的 menu_ids 字段 UPDATE yz_roles SET menu_ids = v_menu_ids WHERE role_id = v_role_id; END LOOP; CLOSE cur; -- 对于没有权限的角色,设置为空数组 UPDATE yz_roles SET menu_ids = JSON_ARRAY() WHERE menu_ids IS NULL; SELECT '数据迁移完成' AS message; END$$ DELIMITER ; -- 执行迁移 CALL migrate_role_permissions(); -- 删除临时存储过程 DROP PROCEDURE IF EXISTS migrate_role_permissions; -- ============================================= -- 步骤3: 验证迁移结果 -- ============================================= -- 查看迁移后的数据 SELECT r.role_id, r.role_name, r.menu_ids, JSON_LENGTH(r.menu_ids) as menu_count, (SELECT COUNT(*) FROM yz_role_menus WHERE role_id = r.role_id) as old_count FROM yz_roles r WHERE r.delete_time IS NULL ORDER BY r.role_id; -- ============================================= -- 步骤4: 备份旧表(可选,建议先备份) -- ============================================= -- 创建备份表 CREATE TABLE IF NOT EXISTS yz_role_menus_backup AS SELECT * FROM yz_role_menus; SELECT '备份表 yz_role_menus_backup 创建完成' AS message; -- ============================================= -- 注意:迁移完成后,需要确认数据正确,然后可以删除 yz_role_menus 表 -- 删除命令:DROP TABLE IF EXISTS yz_role_menus; -- =============================================