前往小程序,Get更优阅读体验!
立即前往
首页
学习
活动
专区
工具
TVP
发布
社区首页 >专栏 >使用MySQL 8的递归CTE遍历树

使用MySQL 8的递归CTE遍历树

作者头像
用户1148526
发布2022-11-07 14:59:49
7680
发布2022-11-07 14:59:49
举报
文章被收录于专栏:Hadoop数据仓库

目录

1. 从根遍历到叶

2. 从叶遍历到根

3. 确定叶子节点、分支节点和根节点

(1)使用相关子查询

(2)更高效的写法(一次外连接)


表数据:

代码语言:javascript
复制
mysql> select * from t1;
+------+------+
| id   | pid  |
+------+------+
| 7788 | 7566 |
| 7902 | 7566 |
| 7499 | 7698 |
| 7521 | 7698 |
| 7900 | 7698 |
| 7844 | 7698 |
| 7654 | 7698 |
| 7934 | 7782 |
| 7876 | 7788 |
| 7566 | 7839 |
| 7782 | 7839 |
| 7698 | 7839 |
| 7369 | 7902 |
| 7839 | NULL |
+------+------+
14 rows in set (0.00 sec)

1. 从根遍历到叶

代码语言:javascript
复制
mysql> with recursive x (sid,id,pid)
    ->       as (
    ->   select cast(id as char(100)), id,pid
    ->     from t1
    ->    where pid is null
    ->    union all
    ->   select concat(x.sid,'-->',e.id), e.id,e.pid
    ->     from t1 e, x
    ->    where x.id = e.pid
    ->   )
    ->   select sid
    ->     from x order by 1;
+---------------------------+
| sid                       |
+---------------------------+
| 7839                      |
| 7839-->7566               |
| 7839-->7566-->7788        |
| 7839-->7566-->7788-->7876 |
| 7839-->7566-->7902        |
| 7839-->7566-->7902-->7369 |
| 7839-->7698               |
| 7839-->7698-->7499        |
| 7839-->7698-->7521        |
| 7839-->7698-->7654        |
| 7839-->7698-->7844        |
| 7839-->7698-->7900        |
| 7839-->7782               |
| 7839-->7782-->7934        |
+---------------------------+
14 rows in set (0.00 sec)

另一种显示(缩进):

代码语言:javascript
复制
mysql> with recursive x (sid,id,pid,ss,level)
    ->            as (
    ->        select cast(id as char(100)), id,pid,concat('..',id),1
    ->          from t1
    ->         where pid is null
    ->         union all
    ->        select concat(x.sid,'-->',e.id), e.id,e.pid,concat(lpad('.',2*(level+1),'.'),e.id),x.level + 1
    ->          from t1 e, x
    ->         where x.id = e.pid
    ->        )
    ->        select ss
    ->          from x order by sid;
+--------------+
| ss           |
+--------------+
| ..7839       |
| ....7566     |
| ......7788   |
| ........7876 |
| ......7902   |
| ........7369 |
| ....7698     |
| ......7499   |
| ......7521   |
| ......7654   |
| ......7844   |
| ......7900   |
| ....7782     |
| ......7934   |
+--------------+
14 rows in set (0.00 sec)

2. 从叶遍历到根

代码语言:javascript
复制
mysql>     with recursive x (sid,id,pid)
    ->       as (
    ->   select cast(id as char(100)), id,pid
    ->     from t1
    ->    -- where pid is null
    ->    union all
    ->   select concat(x.sid,'-->',e.id), e.id,e.pid
    ->     from t1 e, x
    ->    where x.pid = e.id
    ->   )
    ->   select sid
    ->     from x where pid is null order by 1;
+---------------------------+
| sid                       |
+---------------------------+
| 7369-->7902-->7566-->7839 |
| 7499-->7698-->7839        |
| 7521-->7698-->7839        |
| 7566-->7839               |
| 7654-->7698-->7839        |
| 7698-->7839               |
| 7782-->7839               |
| 7788-->7566-->7839        |
| 7839                      |
| 7844-->7698-->7839        |
| 7876-->7788-->7566-->7839 |
| 7900-->7698-->7839        |
| 7902-->7566-->7839        |
| 7934-->7782-->7839        |
+---------------------------+
14 rows in set (0.00 sec)

3. 确定叶子节点、分支节点和根节点

(1)使用相关子查询

代码语言:javascript
复制
mysql>  select id,
    ->         (select 1 - sign(count(*)) from t1 d
    ->           -- 有子节点          
    ->           where d.pid = e.id) as is_leaf,
    ->         (select sign(count(*)) from t1 d
    ->           -- 有子节点并且有父节点
    ->           where d.pid = e.id and e.pid is not null) as is_branch,
    ->         (select sign(count(*)) from t1 d
    ->           -- 没有父节点
    ->           where d.id = e.id and d.pid is null) as is_root
    ->    from t1 e
    ->  order by 4 desc,3 desc,id;
+------+---------+-----------+---------+
| id   | is_leaf | is_branch | is_root |
+------+---------+-----------+---------+
| 7839 |       0 |         0 |       1 |
| 7566 |       0 |         1 |       0 |
| 7698 |       0 |         1 |       0 |
| 7782 |       0 |         1 |       0 |
| 7788 |       0 |         1 |       0 |
| 7902 |       0 |         1 |       0 |
| 7369 |       1 |         0 |       0 |
| 7499 |       1 |         0 |       0 |
| 7521 |       1 |         0 |       0 |
| 7654 |       1 |         0 |       0 |
| 7844 |       1 |         0 |       0 |
| 7876 |       1 |         0 |       0 |
| 7900 |       1 |         0 |       0 |
| 7934 |       1 |         0 |       0 |
+------+---------+-----------+---------+
14 rows in set (0.00 sec)

(2)更高效的写法(一次外连接)

代码语言:javascript
复制
mysql> select distinct id,
    ->        case when flag = 'is_leaf' then 1 else 0 end is_leaf,
    ->        case when flag = 'is_branch' then 1 else 0 end is_branch,
    ->        case when flag = 'is_root' then 1 else 0 end is_root
    ->   from (select t2.id,
    ->                case when t1.id is null then 'is_leaf' 
    ->                     when t2.pid is null then 'is_root' 
    ->                     else 'is_branch' end flag
    ->          from t1 right join t1 t2 on t1.pid=t2.id) t
    ->  order by 4 desc,3 desc,id;
+------+---------+-----------+---------+
| id   | is_leaf | is_branch | is_root |
+------+---------+-----------+---------+
| 7839 |       0 |         0 |       1 |
| 7566 |       0 |         1 |       0 |
| 7698 |       0 |         1 |       0 |
| 7782 |       0 |         1 |       0 |
| 7788 |       0 |         1 |       0 |
| 7902 |       0 |         1 |       0 |
| 7369 |       1 |         0 |       0 |
| 7499 |       1 |         0 |       0 |
| 7521 |       1 |         0 |       0 |
| 7654 |       1 |         0 |       0 |
| 7844 |       1 |         0 |       0 |
| 7876 |       1 |         0 |       0 |
| 7900 |       1 |         0 |       0 |
| 7934 |       1 |         0 |       0 |
+------+---------+-----------+---------+
14 rows in set (0.00 sec)
本文参与 腾讯云自媒体同步曝光计划,分享自作者个人站点/博客。
原始发表:2022-10-27,如有侵权请联系 cloudcommunity@tencent.com 删除

本文分享自 作者个人站点/博客 前往查看

如有侵权,请联系 cloudcommunity@tencent.com 删除。

本文参与 腾讯云自媒体同步曝光计划  ,欢迎热爱写作的你一起参与!

评论
登录后参与评论
0 条评论
热度
最新
推荐阅读
目录
  • 1. 从根遍历到叶
  • 2. 从叶遍历到根
  • 3. 确定叶子节点、分支节点和根节点
    • (1)使用相关子查询
      • (2)更高效的写法(一次外连接)
      领券
      问题归档专栏文章快讯文章归档关键词归档开发者手册归档开发者手册 Section 归档