前言:
关于多级别菜单栏或者权限系统中部门上下级的树形遍历,oracle中有connect by来实现,mysql没有这样的便捷途径,所以mysql遍历数据表是我们经常会遇到的头痛问题,下面通过存储过程来实现。
1,建立测试表和数据:
drop table if exists csdn.channel;
create table csdn.channel (
id int(11) not null auto_increment,
cname varchar(200) default null,
parent_id int(11) default null,
primary key (id)
) engine=innodb default charset=utf8;
insert into channel(id,cname,parent_id)
values (13,'首页',-1),
(14,'tv580',-1),
(15,'生活580',-1),
(16,'左上幻灯片',13),
(17,'帮忙',14),
(18,'栏目简介',17);
drop table if exists channel;
2,利用临时表和递归过程实现树的遍历(mysql的udf不能递归调用):
2.1,从某节点向下遍历子节点,递归生成临时表数据
-- pro_cre_childlist
delimiter $$
drop procedure if exists csdn.pro_cre_childlist$$
create procedure csdn.pro_cre_childlist(in rootid int,in ndepth int)
begin
declare done int default 0;
declare b int;
declare cur1 cursor for select id from channel where parent_id=rootid;
declare continue handler for not found set done = 1;
set max_sp_recursion_depth=12;
insert into tmplst values (null,rootid,ndepth);
open cur1;
fetch cur1 into b;
while done=0 do
call pro_cre_childlist(b,ndepth+1);
fetch cur1 into b;
end while;
close cur1;
end$$
2.2,从某节点向上追溯根节点,递归生成临时表数据
-- pro_cre_parentlist
delimiter $$
drop procedure if exists csdn.pro_cre_parentlist$$
create procedure csdn.pro_cre_parentlist(in rootid int,in ndepth int)
begin
declare done int default 0;
declare b int;
declare cur1 cursor for select parent_id from channel where id=rootid;
declare continue handler for not found set done = 1;
set max_sp_recursion_depth=12;
insert into tmplst values (null,rootid,ndepth);
open cur1;
fetch cur1 into b;
while done=0 do
call pro_cre_parentlist(b,ndepth+1);
fetch cur1 into b;
end while;
close cur1;
end$$
2.3,实现类似oracle sys_connect_by_path的功能,递归过程输出某节点id路径
-- pro_cre_pathlist
delimiter $$
use csdn$$
drop procedure if exists pro_cre_pathlist$$
create procedure pro_cre_pathlist(in nid int,in delimit varchar(10),inout pathstr varchar(1000))
begin
declare done int default 0;
declare parentid int default 0;
declare cur1 cursor for
select t.parent_id,concat(cast(t.parent_id as char),delimit,pathstr)
from channel as t where t.id = nid;
declare continue handler for not found set done = 1;
set max_sp_recursion_depth=12;
open cur1;
fetch cur1 into parentid,pathstr;
while done=0 do
call pro_cre_pathlist(parentid,delimit,pathstr);
fetch cur1 into parentid,pathstr;
end while;
close cur1;
end$$
delimiter ;
2.4,递归过程输出某节点name路径
-- pro_cre_pnlist
delimiter $$
use csdn$$
drop procedure if exists pro_cre_pnlist$$
create procedure pro_cre_pnlist(in nid int,in delimit varchar(10),inout pathstr varchar(1000))
begin
declare done int default 0;
declare parentid int default 0;
declare cur1 cursor for
select t.parent_id,concat(t.cname,delimit,pathstr)
from channel as t where t.id = nid;
declare continue handler for not found set done = 1;
set max_sp_recursion_depth=12;
open cur1;
fetch cur1 into parentid,pathstr;
while done=0 do
call pro_cre_pnlist(parentid,delimit,pathstr);
fetch cur1 into parentid,pathstr;
end while;
close cur1;
end$$
delimiter ;
2.5,调用函数输出id路径
-- fn_tree_path
delimiter $$
drop function if exists csdn.fn_tree_path$$
create function csdn.fn_tree_path(nid int,delimit varchar(10)) returns varchar(2000) charset utf8
begin
declare pathid varchar(1000);
set @pathid=cast(nid as char);
call pro_cre_pathlist(nid,delimit,@pathid);
return @pathid;
end$$
2.6,调用函数输出name路径
-- fn_tree_pathname
-- 调用函数输出name路径
delimiter $$
drop function if exists csdn.fn_tree_pathname$$
create function csdn.fn_tree_pathname(nid int,delimit varchar(10)) returns varchar(2000) charset utf8
begin
declare pathid varchar(1000);
set @pathid='';
call pro_cre_pnlist(nid,delimit,@pathid);
return @pathid;
end$$
delimiter ;
2.7,调用过程输出子节点
-- pro_show_childlst
delimiter $$
-- 调用过程输出子节点
drop procedure if exists pro_show_childlst$$
create procedure pro_show_childlst(in rootid int)
begin
drop temporary table if exists tmplst;
create temporary table if not exists tmplst
(sno int primary key auto_increment,id int,depth int);
call pro_cre_childlist(rootid,0);
select channel.id,concat(space(tmplst.depth*2),'--',channel.cname) name,channel.parent_id,tmplst.depth,fn_tree_path(channel.id,'/') path,
fn_tree_pathname(channel.id,'/') pathname
from tmplst,channel where tmplst.id=channel.id order by tmplst.sno;
end$$
2.8,调用过程输出父节点
-- pro_show_parentlst
delimiter $$
-- 调用过程输出父节点
drop procedure if exists `pro_show_parentlst`$$
create procedure `pro_show_parentlst`(in rootid int)
begin
drop temporary table if exists tmplst;
create temporary table if not exists tmplst
(sno int primary key auto_increment,id int,depth int);
call pro_cre_parentlist(rootid,0);
select channel.id,concat(space(tmplst.depth*2),'--',channel.cname) name,channel.parent_id,tmplst.depth,
fn_tree_path(channel.id,'/') path,fn_tree_pathname(channel.id,'/') pathname
from tmplst,channel where tmplst.id=channel.id order by tmplst.sno;
end$$
3,开始测试:
3.1,从根节点开始显示,显示子节点集合:
mysql> call pro_show_childlst(-1);
+----+-----------------------+-----------+-------+-------------+----------------------------+
| id | name | parent_id | depth | path | pathname |
+----+-----------------------+-----------+-------+-------------+----------------------------+
| 13 | --首页 | -1 | 1 | -1/13 | 首页/ |
| 16 | --左上幻灯片 | 13 | 2 | -1/13/16 | 首页/左上幻灯片/ |
| 14 | --tv580 | -1 | 1 | -1/14 | tv580/ |
| 17 | --帮忙 | 14 | 2 | -1/14/17 | tv580/帮忙/ |
| 18 | --栏目简介 | 17 | 3 | -1/14/17/18 | tv580/帮忙/栏目简介/ |
| 15 | --生活580 | -1 | 1 | -1/15 | 生活580/ |
+----+-----------------------+-----------+-------+-------------+----------------------------+
6 rows in set (0.05 sec)
query ok, 0 rows affected (0.05 sec)
3.2,显示首页下面的子节点
call pro_show_childlst(13);
mysql> call pro_show_childlst(13);
+----+---------------------+-----------+-------+----------+-------------------------+
| id | name | parent_id | depth | path | pathname |
+----+---------------------+-----------+-------+----------+-------------------------+
| 13 | --首页 | -1 | 0 | -1/13 | 首页/ |
| 16 | --左上幻灯片 | 13 | 1 | -1/13/16 | 首页/左上幻灯片/ |
+----+---------------------+-----------+-------+----------+-------------------------+
2 rows in set (0.02 sec)
query ok, 0 rows affected (0.02 sec)
mysql>
3.3,显示tv580下面的所有子节点
call pro_show_childlst(14);
mysql> call pro_show_childlst(14);
+----+--------------------+-----------+-------+-------------+----------------------------+
| id | name | parent_id | depth | path | pathname |
+----+--------------------+-----------+-------+-------------+----------------------------+
| 14 | --tv580 | -1 | 0 | -1/14 | tv580/ |
| 17 | --帮忙 | 14 | 1 | -1/14/17 | tv580/帮忙/ |
| 18 | --栏目简介 | 17 | 2 | -1/14/17/18 | tv580/帮忙/栏目简介/ |
+----+--------------------+-----------+-------+-------------+----------------------------+
3 rows in set (0.02 sec)
query ok, 0 rows affected (0.02 sec)
mysql>
3.4,“帮忙”节点有一个子节点,显示出来:
call pro_show_childlst(17);
mysql> call pro_show_childlst(17);
+----+------------------+-----------+-------+-------------+----------------------------+
| id | name | parent_id | depth | path | pathname |
+----+------------------+-----------+-------+-------------+----------------------------+
| 17 | --帮忙 | 14 | 0 | -1/14/17 | tv580/帮忙/ |
| 18 | --栏目简介 | 17 | 1 | -1/14/17/18 | tv580/帮忙/栏目简介/ |
+----+------------------+-----------+-------+-------------+----------------------------+
2 rows in set (0.03 sec)
query ok, 0 rows affected (0.03 sec)
mysql>
3.5,“栏目简介”没有子节点,所以只显示最终节点:
mysql> call pro_show_childlst(18);
+----+----------------+-----------+-------+-------------+----------------------------+
| id | name | parent_id | depth | path | pathname |
+----+----------------+-----------+-------+-------------+----------------------------+
| 18 | --栏目简介 | 17 | 0 | -1/14/17/18 | tv580/帮忙/栏目简介/ |
+----+----------------+-----------+-------+-------------+----------------------------+
1 row in set (0.36 sec)
query ok, 0 rows affected (0.36 sec)
mysql>
3.6,显示根节点的父节点
call pro_show_parentlst(-1);
mysql> call pro_show_parentlst(-1);
empty set (0.01 sec)
query ok, 0 rows affected (0.01 sec)
mysql>
3.7,显示“首页”的父节点
call pro_show_parentlst(13);
mysql> call pro_show_parentlst(13);
+----+----------+-----------+-------+-------+----------+
| id | name | parent_id | depth | path | pathname |
+----+----------+-----------+-------+-------+----------+
| 13 | --首页 | -1 | 0 | -1/13 | 首页/ |
+----+----------+-----------+-------+-------+----------+
1 row in set (0.02 sec)
query ok, 0 rows affected (0.02 sec)
mysql>
3.8,显示“tv580”的父节点,parent_id为-1
call pro_show_parentlst(14);
mysql> call pro_show_parentlst(14);
+----+---------+-----------+-------+-------+----------+
| id | name | parent_id | depth | path | pathname |
+----+---------+-----------+-------+-------+----------+
| 14 | --tv580 | -1 | 0 | -1/14 | tv580/ |
+----+---------+-----------+-------+-------+----------+
1 row in set (0.02 sec)
query ok, 0 rows affected (0.02 sec)
3.9,显示“帮忙”节点的父节点
mysql>
call pro_show_parentlst(17);
mysql> call pro_show_parentlst(17);
+----+-----------+-----------+-------+----------+---------------+
| id | name | parent_id | depth | path | pathname |
+----+-----------+-----------+-------+----------+---------------+
| 17 | --帮忙 | 14 | 0 | -1/14/17 | tv580/帮忙/ |
| 14 | --tv580 | -1 | 1 | -1/14 | tv580/ |
+----+-----------+-----------+-------+----------+---------------+
2 rows in set (0.02 sec)
query ok, 0 rows affected (0.02 sec)
mysql>
3.10,显示最低层节点“栏目简介”的父节点
call pro_show_parentlst(18);
mysql> call pro_show_parentlst(18);
+----+----------------+-----------+-------+-------------+----------------------------+
| id | name | parent_id | depth | path | pathname |
+----+----------------+-----------+-------+-------------+----------------------------+
| 18 | --栏目简介 | 17 | 0 | -1/14/17/18 | tv580/帮忙/栏目简介/ |
| 17 | --帮忙 | 14 | 1 | -1/14/17 | tv580/帮忙/ |
| 14 | --tv580 | -1 | 2 | -1/14 | tv580/ |
+----+----------------+-----------+-------+-------------+----------------------------+
3 rows in set (0.02 sec)
query ok, 0 rows affected (0.02 sec)
mysql>
以上就是mysql 实现树形的遍历(关于多级菜单栏以及多级上下部门的查询问题) 的内容。