Skip to content

Commit b8a6505

Browse files
committed
new doc
1 parent b075e5c commit b8a6505

26 files changed

+1264
-0
lines changed

201303/20130319_01.md

Lines changed: 328 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,328 @@
1+
## PostgreSQL FDW mongo_fdw usage
2+
3+
### 作者
4+
digoal
5+
6+
### 日期
7+
2013-03-19
8+
9+
### 标签
10+
PostgreSQL , width_bucket , mongo , fdw , 外部表
11+
12+
----
13+
14+
## 背景
15+
https://wiki.postgresql.org/wiki/Foreign_data_wrappers
16+
17+
mongo_fdw是PostgreSQL众多FDW中的一个, 显而易见是连接mongoDB的.
18+
19+
最近在看CitusDB的时候, 文档中提到了mongo_fdw, 实际上在CitusDB中并没有发挥这个extension的distribute query特性.
20+
21+
用在PostgreSQL单节点的环境当然也是可以的.
22+
23+
目前mongo_fdw由EDB在维护,建议用户使用EDB的版本。本文成文太早,还没有EDB版本的MONGO_FDW。
24+
25+
https://github.com/EnterpriseDB/mongo_fdw
26+
27+
下面介绍一下mongo_fdw在PostgreSQL数据库环境中的安装和用法.
28+
29+
## 1. 安装
30+
下载
31+
32+
```
33+
ocz@db-172-16-3-150-> wget --no-check-certificate https://github.com/citusdata/mongo_fdw/archive/master.zip
34+
ocz@db-172-16-3-150-> unzip master
35+
ocz@db-172-16-3-150-> mv mongo_fdw-master postgresql-9.2.1/contrib/
36+
```
37+
38+
编译
39+
40+
```
41+
su - root
42+
[root@db-172-16-3-150 ~]# . /home/ocz/.bash_profile
43+
root@db-172-16-3-150-> which pg_config
44+
/home/ocz/pgsql9.2.1/bin/pg_config
45+
root@db-172-16-3-150-> cd /home/ocz/postgresql-9.2.1/contrib/mongo_fdw-master/
46+
root@db-172-16-3-150-> make clean
47+
root@db-172-16-3-150-> make
48+
root@db-172-16-3-150-> make install
49+
```
50+
51+
## 2. 创建extension
52+
53+
```
54+
root@db-172-16-3-150-> su - ocz
55+
ocz@db-172-16-3-150-> psql
56+
psql (9.2.1)
57+
Type "help" for help.
58+
postgres=# \c digoal postgres
59+
digoal=# create extension mongo_fdw;
60+
CREATE EXTENSION
61+
```
62+
63+
## 3. 创建mongoDB测试环境
64+
65+
```
66+
[root@db-172-16-3-150 ~]# wget http://fastdl.mongodb.org/linux/mongodb-linux-x86_64-2.2.3.tgz
67+
[root@db-172-16-3-150 ~]# tar -zxvf mongodb-linux-x86_64-2.2.3.tgz
68+
[root@db-172-16-3-150 ~]# mv mongodb-linux-x86_64-2.2.3 /opt/
69+
70+
[root@db-172-16-3-150 ~]# useradd mongo
71+
[root@db-172-16-3-150 ~]# chown -R mongo:mongo /opt/mongodb-linux-x86_64-2.2.3
72+
73+
[root@db-172-16-3-150 ~]# su - mongo
74+
mongo@db-172-16-3-150-> vi .bash_profile
75+
export MONGO_HOME=/opt/mongodb-linux-x86_64-2.2.3
76+
export PATH=$MONGO_HOME/bin:$PATH:.
77+
umask 022
78+
alias rm='rm -i'
79+
alias ll='ls -lh'
80+
81+
su - root
82+
[root@db-172-16-3-150 data03]# mkdir -p /data03/mongodata
83+
[root@db-172-16-3-150 data03]# chown -R mongo:mongo /data03/mongodata
84+
85+
[root@db-172-16-3-150 data03]# vi /opt/mongodb-linux-x86_64-2.2.3/mongo11111.conf
86+
logpath = /data03/mongodata/mongod_5281.log
87+
logappend = true
88+
fork = true
89+
port = 11111
90+
noauth = true
91+
bind_ip = 0.0.0.0
92+
dbpath = /data03/mongodata/
93+
maxConns = 20000
94+
pidfilepath = /data03/mongodata/mongod_11111.pid
95+
nounixsocket = true
96+
directoryperdb = true
97+
journal = true
98+
journalCommitInterval = 40
99+
profile = 0
100+
nohttpinterface = true
101+
nssize = 2000
102+
oplogSize = 31280
103+
[root@db-172-16-3-150 mongodb-linux-x86_64-2.2.3]# chown mongo:mongo /opt/mongodb-linux-x86_64-2.2.3/mongo11111.conf
104+
```
105+
106+
## 4. 启动mongodb数据库
107+
108+
```
109+
su - mongo
110+
mongo@db-172-16-3-150-> mongod -f /opt/mongodb-linux-x86_64-2.2.3/mongo11111.conf
111+
mongo@db-172-16-3-150-> mongo 127.0.0.1:11111/admin
112+
MongoDB shell version: 2.2.3
113+
connecting to: 127.0.0.1:11111/admin
114+
Welcome to the MongoDB shell.
115+
For interactive help, type "help".
116+
For more comprehensive documentation, see
117+
http://docs.mongodb.org/
118+
Questions? Try the support group
119+
http://groups.google.com/group/mongodb-user
120+
> show dbsshow dbs
121+
local (empty)
122+
```
123+
124+
## 5. 创建外部表
125+
126+
```
127+
[root@db-172-16-3-150 ~]# su - ocz
128+
ocz@db-172-16-3-150-> psql digoal digoal
129+
psql (9.2.1)
130+
Type "help" for help.
131+
digoal=> \c digoal postgres
132+
You are now connected to database "digoal" as user "postgres".
133+
digoal=# \dx
134+
List of installed extensions
135+
Name | Version | Schema | Description
136+
-----------+---------+------------+--------------------------------------------------------------
137+
dblink | 1.0 | public | connect to other PostgreSQL databases from within a database
138+
hll | 1.0 | public | type for storing hyperloglog data
139+
mongo_fdw | 1.0 | public | foreign data wrapper for MongoDB access
140+
plcoffee | 1.3.0 | pg_catalog | PL/CoffeeScript (v8) trusted procedural language
141+
plls | 1.3.0 | pg_catalog | PL/LiveScript (v8) trusted procedural language
142+
plpgsql | 1.0 | pg_catalog | PL/pgSQL procedural language
143+
plv8 | 1.3.0 | pg_catalog | PL/JavaScript (v8) trusted procedural language
144+
(7 rows)
145+
146+
digoal=# CREATE SERVER mongo_server FOREIGN DATA WRAPPER mongo_fdw
147+
OPTIONS (address '127.0.0.1', port '11111');
148+
149+
digoal=# CREATE FOREIGN TABLE customer_reviews
150+
(
151+
customer_id TEXT,
152+
review_date TIMESTAMP,
153+
review_rating INTEGER,
154+
product_id CHAR(10),
155+
product_title TEXT,
156+
product_group TEXT,
157+
product_category TEXT,
158+
similar_product_ids CHAR(10)[]
159+
)
160+
SERVER mongo_server
161+
OPTIONS (database 'test', collection 'customer_reviews');
162+
```
163+
164+
## 6. 查询外部表
165+
166+
```
167+
digoal=# select * from customer_reviews ;
168+
customer_id | review_date | review_rating | product_id | product_title | product_group | product_category | similar_product_ids
169+
-------------+-------------+---------------+------------+---------------+---------------+------------------+---------------------
170+
(0 rows)
171+
> show dbsshow dbs
172+
local (empty)
173+
test (empty)
174+
```
175+
176+
## 7. 下载测试数据
177+
178+
```
179+
[root@db-172-16-3-150 ~]# wget http://examples.citusdata.com/customer_reviews_1998.json.gz
180+
[root@db-172-16-3-150 ~]# wget http://examples.citusdata.com/customer_reviews_1999.json.gz
181+
[root@db-172-16-3-150 ~]# gunzip customer_reviews_1998.json.gz
182+
```
183+
184+
## 8. 导入测试数据
185+
186+
```
187+
[root@db-172-16-3-150 ~]# . /home/mongo/.bash_profile
188+
root@db-172-16-3-150-> which mongo
189+
/opt/mongodb-linux-x86_64-2.2.3/bin/mongo
190+
root@db-172-16-3-150-> mongoimport --port 11111 --db test --collection customer_reviews --type json --file customer_reviews_1998.json
191+
connected to: 127.0.0.1:11111
192+
root@db-172-16-3-150-> mongo 127.0.0.1:11111/test
193+
MongoDB shell version: 2.2.3
194+
connecting to: 127.0.0.1:11111/test
195+
> show collections
196+
customer_reviews
197+
system.indexes
198+
> db.customer_reviews.count()
199+
589859
200+
```
201+
202+
## 9. PostgreSQL 外部表查询
203+
204+
```
205+
digoal=# select * from customer_reviews limit 1;
206+
customer_id | review_date | review_rating | product_id | product_title | product_group | p
207+
roduct_category | similar_product_ids
208+
---------------+---------------------+---------------+------------+--------------------------------------------+---------------+----
209+
------------------+----------------------------------------------------------
210+
AE22YDHSBFYIP | 1970-12-30 00:00:00 | 5 | 1551803542 | Start and Run a Coffee Bar (Start & Run a) | Book | Bus
211+
iness & Investing | {0471136174,0910627312,047112138X,0786883561,0201570483}
212+
(1 row)
213+
digoal=# select count(*) from customer_reviews ;
214+
count
215+
--------
216+
589859
217+
(1 row)
218+
digoal=# SELECT
219+
round(avg(review_rating), 2),
220+
width_bucket(length(product_title), 1, 50, 5) as title_length,
221+
count(*)
222+
FROM
223+
customer_reviews
224+
WHERE
225+
product_group='Book' AND
226+
review_date >= '1998-01-01' AND
227+
review_date < date '1998-01-01' + interval '1 year'
228+
GROUP BY
229+
title_length
230+
ORDER BY
231+
title_length;
232+
round | title_length | count
233+
-------+--------------+--------
234+
4.39 | 1 | 40058
235+
4.29 | 2 | 125688
236+
4.41 | 3 | 76425
237+
4.36 | 4 | 51531
238+
4.30 | 5 | 34974
239+
4.39 | 6 | 30349
240+
(6 rows)
241+
242+
digoal=# explain analyze verbose SELECT
243+
round(avg(review_rating), 2),
244+
width_bucket(length(product_title), 1, 50, 5) as title_length,
245+
count(*)
246+
FROM
247+
customer_reviews
248+
WHERE
249+
product_group='Book' AND
250+
review_date >= '1998-01-01' AND
251+
review_date < date '1998-01-01' + interval '1 year'
252+
GROUP BY
253+
title_length
254+
ORDER BY
255+
title_length;
256+
QUERY PLAN
257+
258+
------------------------------------------------------------------------------------------------------------------------------------
259+
----------------------------------------------------------------------------------------------------------------------
260+
Sort (cost=21457.71..21457.71 rows=1 width=36) (actual time=3221.772..3221.772 rows=6 loops=1)
261+
Output: (round(avg(review_rating), 2)), (width_bucket((length(product_title))::double precision, 1::double precision, 50::double
262+
precision, 5)), (count(*))
263+
Sort Key: (width_bucket((length(customer_reviews.product_title))::double precision, 1::double precision, 50::double precision, 5)
264+
)
265+
Sort Method: quicksort Memory: 25kB
266+
-> HashAggregate (cost=21457.68..21457.70 rows=1 width=36) (actual time=3221.746..3221.754 rows=6 loops=1)
267+
Output: round(avg(review_rating), 2), (width_bucket((length(product_title))::double precision, 1::double precision, 50::dou
268+
ble precision, 5)), count(*)
269+
-> Foreign Scan on public.customer_reviews (cost=5.00..21457.56 rows=15 width=36) (actual time=225.305..3036.528 rows=359
270+
025 loops=1)
271+
Output: width_bucket((length(product_title))::double precision, 1::double precision, 50::double precision, 5), review
272+
_rating
273+
Filter: ((customer_reviews.review_date >= '1998-01-01 00:00:00'::timestamp without time zone) AND (customer_reviews.r
274+
eview_date < '1999-01-01 00:00:00'::timestamp without time zone) AND (customer_reviews.product_group = 'Book'::text))
275+
Foreign Namespace: test.customer_reviews
276+
Total runtime: 3222.184 ms
277+
(11 rows)
278+
```
279+
280+
## 参考
281+
282+
1\. https://github.com/citusdata/mongo_fdw
283+
284+
2\. http://pgxn.org/dist/mongo_fdw
285+
286+
3\. https://github.com/EnterpriseDB/mongo_fdw
287+
288+
## 其他FDW
289+
1\. hive
290+
291+
https://github.com/youngwookim/hive-fdw-for-postgresql
292+
293+
2\. PostgreSQL Foreign Table - pgsql_fdw
294+
295+
http://blog.163.com/digoal@126/blog/static/163877040201231514057303/
296+
297+
3\. PostgreSQL Foreign Table - oracle_fdw 1
298+
299+
http://blog.163.com/digoal@126/blog/static/163877040201181505331588/
300+
301+
4\. PostgreSQL Foreign Table - oracle_fdw 2
302+
303+
http://blog.163.com/digoal@126/blog/static/16387704020118151162340/
304+
305+
5\. PostgreSQL Foreign Table - oracle_fdw 3
306+
307+
http://blog.163.com/digoal@126/blog/static/16387704020118951953408/
308+
309+
6\. PostgreSQL Foreign Table - file_fdw
310+
311+
http://blog.163.com/digoal@126/blog/static/163877040201141641148311/
312+
313+
7\. PostgreSQL Foreign Table - redis_fdw
314+
315+
http://blog.163.com/digoal@126/blog/static/16387704020119181188247/
316+
317+
8\. PostgreSQL Foreign Table - mysql_fdw 1
318+
319+
http://blog.163.com/digoal@126/blog/static/1638770402011111233524987/
320+
321+
9\. PostgreSQL Foreign Table - mysql_fdw 2
322+
323+
http://blog.163.com/digoal@126/blog/static/16387704020121108551698/
324+
325+
10\. PostgreSQL file text array fdw used for unpredictable columns of text file
326+
327+
http://blog.163.com/digoal@126/blog/static/163877040201302410511382/
328+

201303/readme.md

Lines changed: 1 addition & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -3,6 +3,7 @@
33
##### 20130325_01.md [《PostgreSQL 并行逻辑备份与一致性讲解 - PostgreSQL 9.3 parallel pg_dump》](20130325_01.md)
44
##### 20130320_02.md [《PostgreSQL 审计 - PostgreSQL Audit by Database or Role wide parameter》](20130320_02.md)
55
##### 20130320_01.md [《PostgreSQL 审计成功事务 - PostgreSQL Fine-Grained Table,Column,Row Level Audit》](20130320_01.md)
6+
##### 20130319_01.md [《PostgreSQL FDW mongo_fdw usage》](20130319_01.md)
67
##### 20130315_01.md [《PostgreSQL Server Encoding sql_ascii attention》](20130315_01.md)
78
##### 20130313_01.md [《PostgreSQL 事件触发器 - PostgreSQL 9.3 Event Trigger》](20130313_01.md)
89
##### 20130311_03.md [《表级复制(base on trigger) -- PostgreSQL general sync and async multi-master replication trigger function》](20130311_03.md)

0 commit comments

Comments
 (0)