背景
有用户(sys_user)、角色(sys_role)、用户角色关联(sys_user_role)三张表,现需要根据用户查询出当前用户所有的角色包括关联角色的所有下级角色
DROP TABLE IF EXISTS sys_role;
CREATE TABLE `sys_role` (
`id` int(11) NOT NULL AUTO_INCREMENT,
`idx` int(11) DEFAULT NULL,
`name` varchar(255) DEFAULT NULL,
`parent_id` int(11) DEFAULT NULL,
PRIMARY KEY (`id`)
) ENGINE=InnoDB AUTO_INCREMENT=7 DEFAULT CHARSET=utf8mb4;
Drop table IF exists sys_user;
CREATE TABLE `sys_user` (
`id` int(11) NOT NULL AUTO_INCREMENT,
`name` varchar(255) DEFAULT NULL,
`password` varchar(255) DEFAULT NULL,
`username` varchar(255) DEFAULT NULL,
PRIMARY KEY (`id`)
) ENGINE=InnoDB AUTO_INCREMENT=5 DEFAULT CHARSET=utf8mb4;
DROP table IF exists sys_user_role;
CREATE TABLE `sys_user_role` (
`id` int(11) NOT NULL AUTO_INCREMENT,
`user_id` int(11) DEFAULT NULL,
`role_id` int(11) DEFAULT NULL,
PRIMARY KEY (`id`)
) ENGINE=InnoDB AUTO_INCREMENT=5 DEFAULT CHARSET=utf8mb4;
INSERT INTO `test`.`sys_role` (`id`, `idx`, `name`, `parent_id`) VALUES ('1', '1', '超级管理员', NULL);
INSERT INTO `test`.`sys_role` (`id`, `idx`, `name`, `parent_id`) VALUES ('2', '2', 'A一级管理员', '1');
INSERT INTO `test`.`sys_role` (`id`, `idx`, `name`, `parent_id`) VALUES ('3', '3', 'A二级管理员', '2');
INSERT INTO `test`.`sys_role` (`id`, `idx`, `name`, `parent_id`) VALUES ('4', '4', 'B一级管理员', '1');
INSERT INTO `test`.`sys_role` (`id`, `idx`, `name`, `parent_id`) VALUES ('5', '5', 'B二级管理员', '4');
INSERT INTO `test`.`sys_role` (`id`, `idx`, `name`, `parent_id`) VALUES ('6', '6', 'A员工', '3');
INSERT INTO `test`.`sys_user` (`id`, `name`, `password`, `username`) VALUES ('1', '超级管理员', '123456', '');
INSERT INTO `test`.`sys_user` (`id`, `name`, `password`, `username`) VALUES ('2', '张三', '123456', NULL);
INSERT INTO `test`.`sys_user` (`id`, `name`, `password`, `username`) VALUES ('3', '李四', '123456', NULL);
INSERT INTO `test`.`sys_user` (`id`, `name`, `password`, `username`) VALUES ('4', '王五', '123456', NULL);
INSERT INTO `test`.`sys_user_role` (`id`, `user_id`, `role_id`) VALUES ('1', '1', '1');
INSERT INTO `test`.`sys_user_role` (`id`, `user_id`, `role_id`) VALUES ('2', '2', '2');
INSERT INTO `test`.`sys_user_role` (`id`, `user_id`, `role_id`) VALUES ('3', '3', '3');
INSERT INTO `test`.`sys_user_role` (`id`, `user_id`, `role_id`) VALUES ('4', '4', '6');
方案
使用mysql存储过程解决
CREATE DEFINER=`root`@`%` PROCEDURE `getChildListProcessByUserId`(IN `userId` int)
BEGIN
DECLARE childList VARCHAR(2000);
DECLARE tempChild VARCHAR(2000);
DECLARE selfRole VARCHAR(1000);
select GROUP_CONCAT(ref.role_id) INTO selfRole from sys_user u LEFT JOIN sys_user_role ref on u.id = ref.user_id where u.id = userId;
SET childList = '';
SET tempChild = selfRole;
WHILE tempChild is not null DO
SET childList = CONCAT(childList,',',tempChild);
SELECT CAST(GROUP_CONCAT(id) AS CHAR)INTO tempChild FROM sys_role where FIND_IN_SET(parent_id,tempChild) > 0;
END WHILE;
select * from sys_role where FIND_IN_SET(parent_id,childList) >0 or FIND_IN_SET(id,selfRole);
END
调用
call getChildListProcessByUserId(1);
call getChildListProcessByUserId(2);
|