Chinaunix首页 | 论坛 | 博客
  • 博客访问: 4184008
  • 博文数量: 240
  • 博客积分: 11504
  • 博客等级: 上将
  • 技术积分: 4277
  • 用 户 组: 普通用户
  • 注册时间: 2006-12-28 14:24
文章分类

全部博文(240)

分类: Mysql/postgreSQL

2014-11-05 12:32:50

昨天我用MySQL来实现了ORACLE的递归语句CONNECT BY, 看起来稍复杂些。今天来看看POSTGRESQL如何实现ORACLE的CONNECT BY。
还是用昨天同样的表以及数据。POSTGRESQL自诩最像ORACLE的数据库,所以大部分语句也就都可以简单而且变相的实现了。
在这点上可以用他自己带的WITH递归功能,还可以用第三方扩展带来的类似connect by 函数。


先来看第一点,用递归的WITH来展现这棵树的路径。

点击(此处)折叠或打开

  1. t_girl=# with recursive tmp_country(id,path) as
  2. t_girl-# (
  3. t_girl(# select a.id,'/'||b.name as "path" from country_relation as a inner join country as b on (a.id = b.id) where a.parentid is null
  4. t_girl(# union all
  5. t_girl(# select a.id,q.path||'/'||b.name as "path" from country_relation as a inner join tmp_country as q on (q.id = a.parentid)
  6. t_girl(# inner join country as b on (a.id = b.id)
  7. t_girl(# )
  8. t_girl-# select a.path from tmp_country as a;
  9.                      path
  10. -----------------------------------------------
  11.  /Earth
  12.  /Earth/North America
  13.  /Earth/South America
  14.  /Earth/Europe
  15.  /Earth/Asia
  16.  /Earth/Africa
  17.  /Earth/Australia
  18.  /Earth/North America/Canada
  19.  /Earth/North America/Central America
  20.  /Earth/North America/Island Nations
  21.  /Earth/North America/United States
  22.  /Earth/North America/United States/Alabama
  23.  /Earth/North America/United States/Alaska
  24.  /Earth/North America/United States/Arizona
  25.  /Earth/North America/United States/Arkansas
  26.  /Earth/North America/United States/California
  27. (16 rows)


  28. Time: 3.260 ms




还可以用tablefunc扩展带来的CONNECT BY函数把这棵树遍历出来。
由于昨天设计的两张表通过ID来关联,这个扩展自带的函数要把名字展现出来比较麻烦,索性这里我就用了一张临时表保存我想要的结果。



点击(此处)折叠或打开

  1. t_girl=# CREATE TEMPORARY TABLE tmp_country_relation as SELECT b.id,a.name,b.parentid,''::text as parentname FROM country AS a,country_relation AS b WHERE a.id = b.id;
  2. SELECT 16
  3. Time: 11.773 ms
  4. t_girl=#




这里更新了对应的ID为NAME。

点击(此处)折叠或打开

  1. t_girl=# update tmp_country_relation set parentname = a.name from country as a where parentid = a.id;
  2. UPDATE 15
  3. Time: 1.829 ms



我用TABLEFUNC扩展带来的CONNECT BY 实现这棵树的遍历。

点击(此处)折叠或打开

  1. t_girl=# select path from connectby('tmp_country_relation as a','a.name','a.parentname','Earth',0,'/') as g(id text,parentid text,level int,path text) order by level;
  2.                      path
  3. ----------------------------------------------
  4.  Earth
  5.  Earth/Australia
  6.  Earth/North America
  7.  Earth/Africa
  8.  Earth/South America
  9.  Earth/Europe
  10.  Earth/Asia
  11.  Earth/North America/Island Nations
  12.  Earth/North America/Canada
  13.  Earth/North America/Central America
  14.  Earth/North America/United States
  15.  Earth/North America/United States/California
  16.  Earth/North America/United States/Arkansas
  17.  Earth/North America/United States/Alabama
  18.  Earth/North America/United States/Alaska
  19.  Earth/North America/United States/Arizona
  20. (16 rows)


  21. Time: 5.974 ms
  22. t_girl=#


阅读(13008) | 评论(0) | 转发(0) |
给主人留下些什么吧!~~