-- ============================================= -- 角色权限迁移脚本(简化版,不使用存储过程) -- 将 yz_role_menus 表中的权限数据迁移到 yz_roles 表的 menu_ids 字段(JSON数组) -- ============================================= 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 -- ============================================= -- 检查 yz_role_menus 表是否存在 SET @table_exists := (SELECT COUNT(*) FROM information_schema.tables WHERE table_schema = DATABASE() AND table_name = 'yz_role_menus'); -- 如果表存在,执行迁移 -- 注意:需要分步执行,因为PREPARE不能执行多语句 -- 2.1 创建临时表存储每个角色的菜单ID数组 -- 使用 GROUP_CONCAT 和 CONCAT 来构建JSON数组(兼容性更好) -- 处理 NULL 情况:如果 GROUP_CONCAT 返回 NULL,则使用空数组 '[]' SET @sqlstmt := IF(@table_exists > 0, 'CREATE TEMPORARY TABLE temp_role_menu_ids AS SELECT role_id, IFNULL(CONCAT(''['', GROUP_CONCAT(menu_id ORDER BY menu_id SEPARATOR '',''), '']''), ''[]'') as menu_ids_json FROM yz_role_menus GROUP BY role_id', 'SELECT ''表 yz_role_menus 不存在,跳过数据迁移'' AS message'); PREPARE stmt FROM @sqlstmt; EXECUTE stmt; DEALLOCATE PREPARE stmt; -- 2.2 更新 yz_roles 表的 menu_ids 字段 -- 将字符串转换为 JSON 类型 SET @sqlstmt := IF(@table_exists > 0, 'UPDATE yz_roles r INNER JOIN temp_role_menu_ids t ON r.role_id = t.role_id SET r.menu_ids = CAST(t.menu_ids_json AS JSON)', 'SELECT ''跳过更新'' AS message'); PREPARE stmt FROM @sqlstmt; EXECUTE stmt; DEALLOCATE PREPARE stmt; -- 2.3 删除临时表 SET @sqlstmt := IF(@table_exists > 0, 'DROP TEMPORARY TABLE IF EXISTS temp_role_menu_ids', 'SELECT ''跳过删除临时表'' AS message'); PREPARE stmt FROM @sqlstmt; EXECUTE stmt; DEALLOCATE PREPARE stmt; -- 2.4 对于没有权限的角色,确保设置为空数组(如果还没有设置) -- 使用 CAST 将字符串转换为 JSON 类型 UPDATE yz_roles SET menu_ids = CAST('[]' AS JSON) WHERE menu_ids IS NULL; -- ============================================= -- 步骤3: 验证迁移结果 -- ============================================= SELECT r.role_id, r.role_name, r.menu_ids, JSON_LENGTH(COALESCE(r.menu_ids, CAST('[]' AS JSON))) 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: 备份旧表(可选,建议先备份) -- ============================================= -- 检查 yz_role_menus 表是否存在 SET @table_exists := (SELECT COUNT(*) FROM information_schema.tables WHERE table_schema = DATABASE() AND table_name = 'yz_role_menus'); -- 检查备份表是否已存在 SET @backup_exists := (SELECT COUNT(*) FROM information_schema.tables WHERE table_schema = DATABASE() AND table_name = 'yz_role_menus_backup'); -- 如果原表存在且备份表不存在,则创建备份 SET @sqlstmt := IF(@table_exists > 0 AND @backup_exists = 0, 'CREATE TABLE yz_role_menus_backup AS SELECT * FROM yz_role_menus', IF(@backup_exists > 0, 'SELECT ''备份表 yz_role_menus_backup 已存在,跳过备份'' AS message', 'SELECT ''表 yz_role_menus 不存在,无需备份'' AS message')); PREPARE stmt FROM @sqlstmt; EXECUTE stmt; DEALLOCATE PREPARE stmt; -- ============================================= -- 注意:迁移完成后,需要确认数据正确,然后可以删除 yz_role_menus 表 -- 删除命令:DROP TABLE IF EXISTS yz_role_menus; -- =============================================