Skip to content

Commit fa5f932

Browse files
committed
new doc
1 parent 2353d25 commit fa5f932

File tree

6 files changed

+116
-0
lines changed

6 files changed

+116
-0
lines changed

201708/20170825_01.md

Lines changed: 114 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,114 @@
1+
## 通过空间思想理解GiST索引的构造
2+
3+
### 作者
4+
digoal
5+
6+
### 日期
7+
2017-08-25
8+
9+
### 标签
10+
PostgreSQL , GIS , PostGIS , Greenplum , 空间检索 , GiST , B-Tree , geohash
11+
12+
----
13+
14+
## 背景
15+
可以支持空间检索的GiST索引的数据结果到底是什么样的呢?
16+
17+
本文为以下两篇文档的增补:
18+
19+
[《Greenplum 空间(GIS)数据检索 B-Tree & GiST 索引实践 - 阿里云HybridDB for PostgreSQL最佳实践》](../201708/20170824_02.md)
20+
21+
[《PostGIS空间索引(GiST、BRIN、R-Tree)选择、优化 - 阿里云RDS PostgreSQL最佳实践》](../201708/20170820_01.md)
22+
23+
## GiST索引的构造
24+
我们可以用空间的思想来理解它,比如我在这篇文档中讲解了为什么我们需要通过数据规整来提高geohash b-tree的检索效率。
25+
26+
[《Greenplum 空间(GIS)数据检索 B-Tree & GiST 索引实践 - 阿里云HybridDB for PostgreSQL最佳实践》](../201708/20170824_02.md)
27+
28+
因为这样可以让每个heap block的bound box(包含这个HEAP BLOCK中所有空间的最小BOX, 平面对象。如果是多维对象,使用多维对象的立体BOX或者多维BOX表示。)尽量的缩小,同时让不同heap block之间的边界更加的清晰,重叠少。从而提高空间数据检索的过滤性。
29+
30+
实际上GiST索引思想与之类似,只不过它不是通过编排HEAP BLOCK来实现这一的划清边界的,而是通过R-Tree结构来表示的。这一的话,用户在写入数据时,对应的空间对象写到哪个GiST索引分支就非常的明朗。(当然,GiST索引和其他索引一样,随着数据的写入会出现SPLIT的需求。)
31+
32+
![pic](20170825_01_pic_001.jpg)
33+
34+
## GiST索引对写入性能的影响(时间越小越好)
35+
36+
```
37+
postgres=# create unlogged table test_gist (pos geometry);
38+
CREATE TABLE
39+
40+
postgres=# create index idx_test_gist_1 on test_gist using gist (pos);
41+
CREATE INDEX
42+
43+
postgres=# insert into test_gist select st_setsrid(st_makepoint(random()*360-180, random()*180-90), 4326) from generate_series(1,5000000);
44+
INSERT 0 5000000
45+
Time: 67127.758 ms
46+
47+
postgres=# drop index idx_test_gist_1 ;
48+
DROP INDEX
49+
Time: 1056.465 ms
50+
51+
postgres=# create index idx_test_gist_1 on test_gist using gist (pos);
52+
CREATE INDEX
53+
Time: 58945.677 ms
54+
```
55+
56+
## B-Tree索引对写入的性能影响(时间越小越好)
57+
58+
```
59+
postgres=# create unlogged table test_btree (pos geometry);
60+
CREATE TABLE
61+
62+
postgres=# create index idx_test_btree_1 on test_btree using btree(st_geohash(pos,11));
63+
CREATE INDEX
64+
65+
postgres=# insert into test_btree select st_setsrid(st_makepoint(random()*360-180, random()*180-90), 4326) from generate_series(1,5000000);
66+
INSERT 0 5000000
67+
Time: 30199.098 ms
68+
69+
postgres=# drop index idx_test_btree_1 ;
70+
DROP INDEX
71+
Time: 50.565 ms
72+
73+
postgres=# create index idx_test_btree_1 on test_btree using btree(st_geohash(pos,11));
74+
CREATE INDEX
75+
Time: 7746.942 ms
76+
```
77+
78+
## BRIN索引对写入性能的影响(时间越小越好)
79+
80+
```
81+
postgres=# create unlogged table test_brin (pos geometry);
82+
CREATE TABLE
83+
84+
postgres=# create index idx_test_brin_1 on test_brin using brin(pos);
85+
CREATE INDEX
86+
87+
postgres=# insert into test_brin select st_setsrid(st_makepoint(random()*360-180, random()*180-90), 4326) from generate_series(1,5000000);
88+
INSERT 0 5000000
89+
Time: 7476.996 ms
90+
91+
postgres=# drop index idx_test_brin_1 ;
92+
DROP INDEX
93+
Time: 1.604 ms
94+
95+
postgres=# create index idx_test_brin_1 on test_brin using brin(pos);
96+
CREATE INDEX
97+
Time: 1697.741 ms
98+
```
99+
100+
## GiST实际上是一个通用的索引框架,支持多种数据类型
101+
102+
不仅仅空间类型,更多复杂的类型GiST或者SP-GiST索引也支持。
103+
104+
![pic](20170825_01_pic_002.jpg)
105+
106+
## 参考
107+
108+
[《Greenplum 空间(GIS)数据检索 B-Tree & GiST 索引实践 - 阿里云HybridDB for PostgreSQL最佳实践》](../201708/20170824_02.md)
109+
110+
[《PostGIS空间索引(GiST、BRIN、R-Tree)选择、优化 - 阿里云RDS PostgreSQL最佳实践》](../201708/20170820_01.md)
111+
112+
[Flexible Indexing with Postgres](20170825_01_pdf_001.pdf)
113+
114+

201708/20170825_01_pdf_001.pdf

418 KB
Binary file not shown.

201708/20170825_01_pic_001.jpg

43.8 KB
Loading

201708/20170825_01_pic_002.jpg

49.5 KB
Loading

201708/readme.md

Lines changed: 1 addition & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -1,5 +1,6 @@
11
### 文章列表
22
----
3+
##### 20170825_01.md [《通过空间思想理解GiST索引的构造》](20170825_01.md)
34
##### 20170824_02.md [《Greenplum 空间(GIS)数据检索 b-tree & GiST 索引实践 - 阿里云HybridDB for PostgreSQL最佳实践》](20170824_02.md)
45
##### 20170824_01.md [《PostgreSQL BRIN索引的pages_per_range选项优化与内核代码优化思考》](20170824_01.md)
56
##### 20170823_03.md [《PostgreSQL 增量备份集的有效恢复位点》](20170823_03.md)

README.md

Lines changed: 1 addition & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -29,6 +29,7 @@ digoal's|PostgreSQL|文章|归类
2929

3030
### 未归类文档如下
3131
----
32+
##### 201708/20170825_01.md [《通过空间思想理解GiST索引的构造》](201708/20170825_01.md)
3233
##### 201708/20170824_02.md [《Greenplum 空间(GIS)数据检索 b-tree & GiST 索引实践 - 阿里云HybridDB for PostgreSQL最佳实践》](201708/20170824_02.md)
3334
##### 201708/20170824_01.md [《PostgreSQL BRIN索引的pages_per_range选项优化与内核代码优化思考》](201708/20170824_01.md)
3435
##### 201708/20170823_03.md [《PostgreSQL 增量备份集的有效恢复位点》](201708/20170823_03.md)

0 commit comments

Comments
 (0)