Skip to content

Commit 71a1b8f

Browse files
committed
recursive
1 parent b2884f6 commit 71a1b8f

File tree

16 files changed

+2092
-13
lines changed

16 files changed

+2092
-13
lines changed

201104/20110427_01.md

Lines changed: 109 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,109 @@
1+
## PostgreSQL : WITH Queries use case
2+
3+
### 作者
4+
digoal
5+
6+
### 日期
7+
2011-04-27
8+
9+
### 标签
10+
PostgreSQL , 递归查询 , group by , order by , cursor , 性能优化 , with recursive
11+
12+
----
13+
14+
## 背景
15+
一位同事有一个这样的需求,不知道怎么写SQL ,
16+
17+
两张表如下
18+
19+
```
20+
table1
21+
22+
id1 int fk reference (table2.id)
23+
id2 int fk reference (table2.id)
24+
25+
table2
26+
27+
id PK
28+
name
29+
```
30+
31+
需要查询如下结果 :
32+
33+
```
34+
t1.id1, t1.id2, id1_name, id2_name where id1=? and id2=?
35+
```
36+
37+
从结果上来看,table1和table2需要关联两次才能匹配到id1对应的name和id2对应的name
38+
39+
这里使用了WITH来实现要查询的结果 :
40+
41+
```
42+
with
43+
a1 as (select a.id1,a.id2,b.name id1_name from table1 a,table2 b where a.id1=b.id and a.id1=?),
44+
a2 as (select a.id1,a.id2,b,name id2_name from table1 a,table2 b where a.id2=b.id and a.id2=?)
45+
select a1.id1,a2.id2,a1.id1_name,a2.id2_name from a1,a2 where a1.id1=a2.id1 and a1.id2=a2.id2;
46+
```
47+
48+
创建三个索引
49+
50+
```
51+
table1.id1
52+
table1.id2
53+
table2.id
54+
```
55+
56+
如下:
57+
58+
```
59+
digoal=> create table table1 (id1 int,id2 int);
60+
digoal=> create table table2 (id int,name name);
61+
digoal=> alter table table2 add constraint uk_table2_id unique (id);
62+
digoal=> alter table table1 add constraint fk_id1 foreign key (id1) references table2 (id);
63+
digoal=> alter table table1 add constraint fk_id2 foreign key (id2) references table2 (id);
64+
digoal=> create index idx_table1_id1 on table1(id1);
65+
digoal=> create index idx_table1_id2 on table1(id2);
66+
digoal=> insert into table2 select generate_series(1,100100),'digoal_'||generate_series(1,100100);
67+
INSERT 0 100100
68+
digoal=> insert into table1 select generate_series(1,100000),generate_series(101,100100);
69+
INSERT 0 100000
70+
71+
72+
73+
digoal=> \d table2
74+
Table "digoal.table2"
75+
Column | Type | Modifiers
76+
--------+---------+-----------
77+
id | integer |
78+
name | name |
79+
Indexes:
80+
"uk_table2_id" UNIQUE, btree (id)
81+
Referenced by:
82+
TABLE "table1" CONSTRAINT "fk_id1" FOREIGN KEY (id1) REFERENCES table2(id)
83+
TABLE "table1" CONSTRAINT "fk_id2" FOREIGN KEY (id2) REFERENCES table2(id)
84+
85+
86+
digoal=> \d table1
87+
Table "digoal.table1"
88+
Column | Type | Modifiers
89+
--------+---------+-----------
90+
id1 | integer |
91+
id2 | integer |
92+
Indexes:
93+
"idx_table1_id1" btree (id1)
94+
"idx_table1_id2" btree (id2)
95+
Foreign-key constraints:
96+
"fk_id1" FOREIGN KEY (id1) REFERENCES table2(id)
97+
"fk_id2" FOREIGN KEY (id2) REFERENCES table2(id)
98+
99+
100+
digoal=> with a1 as (select a.id1,a.id2,b.name id1_name from table1 a,table2 b where a.id1=b.id and a.id1=1),
101+
digoal-> a2 as (select a.id1,a.id2,b,name id2_name from table1 a,table2 b where a.id2=b.id and a.id2=101)
102+
digoal-> select a1.id1,a2.id2,a1.id1_name,a2.id2_name from a1,a2 where a1.id1=a2.id1 and a1.id2=a2.id2;
103+
id1 | id2 | id1_name | id2_name
104+
-----+-----+----------+------------
105+
1 | 101 | digoal_1 | digoal_101
106+
(1 row)
107+
108+
Time: 0.678 ms
109+
```

201104/readme.md

Lines changed: 3 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,3 @@
1+
### 文章列表
2+
----
3+
##### 20110427_01.md [《PostgreSQL : WITH Queries use case》](20110427_01.md)

201105/20110527_01.md

Lines changed: 198 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,198 @@
1+
## PostgreSQL 树状数据存储与查询(非递归) - Use ltree extension deal tree-like data type
2+
3+
### 作者
4+
digoal
5+
6+
### 日期
7+
2011-05-27
8+
9+
### 标签
10+
PostgreSQL , 递归查询 , 树结构 , ltree
11+
12+
----
13+
14+
## 背景
15+
PostgreSQL 9.1里面的一个ltree extension.
16+
17+
由两位国外PostgreSQL贡献者共同开发
18+
19+
http://www.sai.msu.su/~megera/postgres/gist
20+
21+
这个extension带有四个数据类型,多个函数,支持多样化的操作符。
22+
23+
对于树形结构的数据处理可见一斑。
24+
25+
之前我的一位同事在设计数据结构的时候有用到这种树形数据,当时是用PostgreSQL的递归查询来满足的需求。
26+
27+
文章地址:
28+
29+
http://blog.163.com/digoal@126/blog/static/163877040201132843255911/
30+
31+
如果使用ltree extension的话,会方便很多。
32+
33+
简易模块加载步骤:
34+
35+
1\. 安装PostgreSQL的时候
36+
37+
```
38+
gmake world
39+
gmake install-world
40+
```
41+
42+
2\. 在需要新增此EXTENSION的数据库,使用超级用户新增。
43+
44+
```
45+
digoal=# create extension ltree;
46+
CREATE EXTENSION
47+
48+
digoal=# select * from pg_extension ;
49+
extname | extowner | extnamespace | extrelocatable | extversion | extconfig | extcondition
50+
----------+----------+--------------+----------------+------------+-----------+--------------
51+
plpgsql | 10 | 11 | f | 1.0 | |
52+
file_fdw | 10 | 2200 | t | 1.0 | |
53+
ltree | 10 | 2200 | t | 1.0 | |
54+
(3 rows)
55+
56+
digoal=# \dT+
57+
List of data types
58+
Schema | Name | Internal name | Size | Elements | Description
59+
--------+------------+---------------+------+----------+-------------
60+
public | lquery | lquery | var | |
61+
public | ltree | ltree | var | |
62+
public | ltree_gist | ltree_gist | var | |
63+
public | ltxtquery | ltxtquery | var | |
64+
(4 rows)
65+
```
66+
67+
简单的介绍一下这几个类型 :
68+
69+
1\. ltree (目前只支持A-Z,a-z,0-9,_作为label的合法字符)
70+
71+
树形结构类型,一个ltree被称为一个path,由1或多个LABEL组成,每个label由A-Z,a-z,0-9,_组成。
72+
73+
2\. lquery
74+
75+
规则表达式,用于匹配ltree类型.
76+
77+
具体参考手册,需要注意的是%匹配的不是一个label,而是label里的一个单词(_为单词分隔符
78+
79+
3\. ltxtquery
80+
81+
一般用于全文扫描,注意,只有ltxtquery类型是符号和匹配的内容是可以有空格隔开的,lquery和ltree不支持空格。
82+
83+
操作符介绍:
84+
85+
Table F-12. ltree Operators
86+
87+
88+
Operator| Returns| Description
89+
---|---|---
90+
ltree @> ltree| boolean| is left argument an ancestor of right (or equal)?
91+
ltree <@ ltree| boolean| is left argument a descendant of right (or equal)?
92+
ltree ~ lquery| boolean| does ltree match lquery?
93+
lquery ~ ltree| boolean| does ltree match lquery?
94+
ltree ? lquery[]| boolean| does ltree match any lquery in array?
95+
lquery[] ? ltree| boolean| does ltree match any lquery in array?
96+
ltree @ ltxtquery| boolean| does ltree match ltxtquery?
97+
ltxtquery @ ltree| boolean| does ltree match ltxtquery?
98+
ltree &#124;&#124; ltree| ltree| concatenate ltree paths
99+
ltree &#124;&#124; text| ltree| convert text to ltree and concatenate
100+
text &#124;&#124; ltree| ltree| convert text to ltree and concatenate
101+
ltree[] @> ltree| boolean| does array contain an ancestor of ltree?
102+
ltree <@ ltree[]| boolean| does array contain an ancestor of ltree?
103+
ltree[] <@ ltree| boolean| does array contain a descendant of ltree?
104+
ltree @> ltree[]| boolean| does array contain a descendant of ltree?
105+
ltree[] ~ lquery| boolean| does array contain any path matching lquery?
106+
lquery ~ ltree[]| boolean| does array contain any path matching lquery?
107+
ltree[] ? lquery[]| boolean| does ltree array contain any path matching any lquery?
108+
lquery[] ? ltree[]| boolean| does ltree array contain any path matching any lquery?
109+
ltree[] @ ltxtquery| boolean| does array contain any path matching ltxtquery?
110+
ltxtquery @ ltree[]| boolean| does array contain any path matching ltxtquery?
111+
ltree[] ?@> ltree| ltree| first array entry that is an ancestor of ltree; NULL if none
112+
ltree[] ?<@ ltree| ltree| first array entry that is a descendant of ltree; NULL if none
113+
ltree[] ?~ lquery| ltree| first array entry that matches lquery; NULL if none
114+
ltree[] ?@ ltxtquery| ltree| first array entry that matches ltxtquery; NULL if none
115+
116+
函数简单介绍:
117+
118+
Function| Return Type| Description| Example| Result
119+
---|---|---|---|---
120+
subltree(ltree, int start, int end)| ltree| subpath of ltree from position start to position end-1 (counting from 0)| subltree('Top.Child1.Child2',1,2)| Child1
121+
subpath(ltree, int offset, int len)| ltree| subpath of ltree starting at position offset, length len. If offset is negative, subpath starts that far from the end of the path. If len is negative, leaves that many labels off the end of the path.| subpath('Top.Child1.Child2',0,2)| Top.Child1
122+
subpath(ltree, int offset)| ltree| subpath of ltree starting at position offset, extending to end of path. If offset is negative, subpath starts that far from the end of the path.| subpath('Top.Child1.Child2',1)| Child1.Child2
123+
nlevel(ltree)| integer| number of labels in path| nlevel('Top.Child1.Child2')| 3
124+
index(ltree a, ltree b)| integer| position of first occurrence of b in a; -1 if not found| index('0.1.2.3.5.4.5.6.8.5.6.8','5.6')| 6
125+
index(ltree a, ltree b, int offset)| integer| position of first occurrence of b in a, searching starting at offset; negative offsetmeans start -offset labels from the end of the path| index('0.1.2.3.5.4.5.6.8.5.6.8','5.6',-4)| 9
126+
text2ltree(text)| ltree| cast text to ltree|-|-
127+
ltree2text(ltree)| text| cast ltree to text|-|-
128+
lca(ltree, ltree, ...)| ltree| lowest common ancestor, i.e., longest common prefix of paths (up to 8 arguments supported)| lca('1.2.2.3','1.2.3.4.5.6')| 1.2
129+
lca(ltree[])| ltree| lowest common ancestor, i.e., longest common prefix of paths| lca(array['1.2.2.3'::ltree,'1.2.3'])| 1.2
130+
131+
实例:
132+
133+
```
134+
digoal=> create table tbl_music(id serial4,song ltree not null);
135+
NOTICE: CREATE TABLE will create implicit sequence "tbl_music_id_seq" for serial column "tbl_music.id"
136+
CREATE TABLE
137+
138+
digoal=> insert into tbl_music (song) values ('GangTai.NanGeShou.LiuDeHua.AiNiYiWanNian');
139+
digoal=> insert into tbl_music (song) values ('GangTai.NanGeShou.LiuDeHua.JinTian');
140+
INSERT 0 1
141+
digoal=> insert into tbl_music (song) values ('GangTai.NanGeShou.LiuDeHua.WangQinShui');
142+
INSERT 0 1
143+
digoal=> insert into tbl_music (song) values ('GangTai.NanGeShou.ZhangXueYou.WenBie');
144+
INSERT 0 1
145+
digoal=> insert into tbl_music (song) values ('GangTai.NanGeShou.ZhangXueYou.QingShu');
146+
INSERT 0 1
147+
digoal=> insert into tbl_music (song) values ('GangTai.NvGeShou.ZhenXiuWen.MeiFeiSeWu');
148+
INSERT 0 1
149+
digoal=> insert into tbl_music (song) values ('GangTai.NvGeShou.ZhenXiuWen.ZhongShenMeiLi');
150+
INSERT 0 1
151+
digoal=> insert into tbl_music (song) values ('DaLu.NanGeShou.DaoLang.2002NianDeDiYiChangXue');
152+
INSERT 0 1
153+
digoal=> insert into tbl_music (song) values ('DaLu.NvGeShou.FanBinBin.FeiNiao');
154+
155+
digoal=> select * from tbl_music;
156+
id | song
157+
----+-----------------------------------------------
158+
2 | GangTai.NanGeShou.LiuDeHua.AiNiYiWanNian
159+
3 | GangTai.NanGeShou.LiuDeHua.JinTian
160+
4 | GangTai.NanGeShou.LiuDeHua.WangQinShui
161+
5 | GangTai.NanGeShou.ZhangXueYou.WenBie
162+
6 | GangTai.NanGeShou.ZhangXueYou.QingShu
163+
7 | GangTai.NvGeShou.ZhenXiuWen.MeiFeiSeWu
164+
8 | GangTai.NvGeShou.ZhenXiuWen.ZhongShenMeiLi
165+
9 | DaLu.NanGeShou.DaoLang.2002NianDeDiYiChangXue
166+
10 | DaLu.NvGeShou.FanBinBin.FeiNiao
167+
```
168+
169+
检索刘德华的所有歌曲.
170+
171+
```
172+
digoal=> select subltree(song,3,4) from tbl_music where subltree(song,2,3)='LiuDeHua';
173+
subltree
174+
---------------
175+
AiNiYiWanNian
176+
JinTian
177+
WangQinShui
178+
(3 rows)
179+
```
180+
181+
查找与刘德华同一个区域(港台。男歌手)的歌手。
182+
183+
```
184+
digoal=> select distinct subltree(song,2,3) from tbl_music where song <@ (select subpath(song,0,2) from tbl_music where subltree(song,2,3)='LiuDeHua' limit 1);
185+
subltree
186+
-------------
187+
LiuDeHua
188+
ZhangXueYou
189+
(2 rows)
190+
```
191+
192+
其他不再举例.
193+
194+
## 参考
195+
postgresql-9.1beta1/postgresql-9.1beta1/doc/src/sgml/html/ltree.html
196+
197+
with recursive
198+

201105/readme.md

Lines changed: 1 addition & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -1,4 +1,5 @@
11
### 文章列表
22
----
3+
##### 20110527_01.md [《PostgreSQL 树状数据存储与查询(非递归) - Use ltree extension deal tree-like data type》](20110527_01.md)
34
##### 20110518_01.md [《Use SecureCRT and Chrome & Proxy Switchy! Plugin》](20110518_01.md)
45
##### 20110511_01.md [《PostgreSQL replication monitor》](20110511_01.md)

0 commit comments

Comments
 (0)