mirror of https://github.com/postgres/postgres
parent
81631ac435
commit
a02780ffd0
@ -0,0 +1,202 @@ |
||||
\connect dblink_test_slave |
||||
create table foo(f1 int, f2 text, f3 text[], primary key (f1,f2)); |
||||
NOTICE: CREATE TABLE / PRIMARY KEY will create implicit index 'foo_pkey' for table 'foo' |
||||
insert into foo values(0,'a','{"a0","b0","c0"}'); |
||||
insert into foo values(1,'b','{"a1","b1","c1"}'); |
||||
insert into foo values(2,'c','{"a2","b2","c2"}'); |
||||
insert into foo values(3,'d','{"a3","b3","c3"}'); |
||||
insert into foo values(4,'e','{"a4","b4","c4"}'); |
||||
insert into foo values(5,'f','{"a5","b5","c5"}'); |
||||
insert into foo values(6,'g','{"a6","b6","c6"}'); |
||||
insert into foo values(7,'h','{"a7","b7","c7"}'); |
||||
insert into foo values(8,'i','{"a8","b8","c8"}'); |
||||
insert into foo values(9,'j','{"a9","b9","c9"}'); |
||||
\connect dblink_test_master |
||||
-- regular old dblink |
||||
select * from dblink('dbname=dblink_test_slave','select * from foo') as t(a int, b text, c text[]) where t.a > 7; |
||||
a | b | c |
||||
---+---+------------ |
||||
8 | i | {a8,b8,c8} |
||||
9 | j | {a9,b9,c9} |
||||
(2 rows) |
||||
|
||||
-- should generate "no connection available" error |
||||
select * from dblink('select * from foo') as t(a int, b text, c text[]) where t.a > 7; |
||||
ERROR: dblink: no connection available |
||||
-- create a persistent connection |
||||
select dblink_connect('dbname=dblink_test_slave'); |
||||
dblink_connect |
||||
---------------- |
||||
OK |
||||
(1 row) |
||||
|
||||
-- use the persistent connection |
||||
select * from dblink('select * from foo') as t(a int, b text, c text[]) where t.a > 7; |
||||
a | b | c |
||||
---+---+------------ |
||||
8 | i | {a8,b8,c8} |
||||
9 | j | {a9,b9,c9} |
||||
(2 rows) |
||||
|
||||
-- open a cursor |
||||
select dblink_open('rmt_foo_cursor','select * from foo'); |
||||
dblink_open |
||||
------------- |
||||
OK |
||||
(1 row) |
||||
|
||||
-- fetch some data |
||||
select * from dblink_fetch('rmt_foo_cursor',4) as t(a int, b text, c text[]); |
||||
a | b | c |
||||
---+---+------------ |
||||
0 | a | {a0,b0,c0} |
||||
1 | b | {a1,b1,c1} |
||||
2 | c | {a2,b2,c2} |
||||
3 | d | {a3,b3,c3} |
||||
(4 rows) |
||||
|
||||
select * from dblink_fetch('rmt_foo_cursor',4) as t(a int, b text, c text[]); |
||||
a | b | c |
||||
---+---+------------ |
||||
4 | e | {a4,b4,c4} |
||||
5 | f | {a5,b5,c5} |
||||
6 | g | {a6,b6,c6} |
||||
7 | h | {a7,b7,c7} |
||||
(4 rows) |
||||
|
||||
-- this one only finds two rows left |
||||
select * from dblink_fetch('rmt_foo_cursor',4) as t(a int, b text, c text[]); |
||||
a | b | c |
||||
---+---+------------ |
||||
8 | i | {a8,b8,c8} |
||||
9 | j | {a9,b9,c9} |
||||
(2 rows) |
||||
|
||||
-- close the cursor |
||||
select dblink_close('rmt_foo_cursor'); |
||||
dblink_close |
||||
-------------- |
||||
OK |
||||
(1 row) |
||||
|
||||
-- should generate "cursor rmt_foo_cursor does not exist" error |
||||
select * from dblink_fetch('rmt_foo_cursor',4) as t(a int, b text, c text[]); |
||||
ERROR: dblink_fetch: cursor rmt_foo_cursor does not exist |
||||
-- close the persistent connection |
||||
select dblink_disconnect(); |
||||
dblink_disconnect |
||||
------------------- |
||||
OK |
||||
(1 row) |
||||
|
||||
-- should generate "no connection available" error |
||||
select * from dblink('select * from foo') as t(a int, b text, c text[]) where t.a > 7; |
||||
ERROR: dblink: no connection available |
||||
-- put more data into our slave table, first using arbitrary connection syntax |
||||
-- but truncate the actual return value so we can use diff to check for success |
||||
select substr(dblink_exec('dbname=dblink_test_slave','insert into foo values(10,''k'',''{"a10","b10","c10"}'')'),1,6); |
||||
substr |
||||
-------- |
||||
INSERT |
||||
(1 row) |
||||
|
||||
-- create a persistent connection |
||||
select dblink_connect('dbname=dblink_test_slave'); |
||||
dblink_connect |
||||
---------------- |
||||
OK |
||||
(1 row) |
||||
|
||||
-- put more data into our slave table, using persistent connection syntax |
||||
-- but truncate the actual return value so we can use diff to check for success |
||||
select substr(dblink_exec('insert into foo values(11,''l'',''{"a11","b11","c11"}'')'),1,6); |
||||
substr |
||||
-------- |
||||
INSERT |
||||
(1 row) |
||||
|
||||
-- let's see it |
||||
select * from dblink('select * from foo') as t(a int, b text, c text[]); |
||||
a | b | c |
||||
----+---+--------------- |
||||
0 | a | {a0,b0,c0} |
||||
1 | b | {a1,b1,c1} |
||||
2 | c | {a2,b2,c2} |
||||
3 | d | {a3,b3,c3} |
||||
4 | e | {a4,b4,c4} |
||||
5 | f | {a5,b5,c5} |
||||
6 | g | {a6,b6,c6} |
||||
7 | h | {a7,b7,c7} |
||||
8 | i | {a8,b8,c8} |
||||
9 | j | {a9,b9,c9} |
||||
10 | k | {a10,b10,c10} |
||||
11 | l | {a11,b11,c11} |
||||
(12 rows) |
||||
|
||||
-- change some data |
||||
select dblink_exec('update foo set f3[2] = ''b99'' where f1 = 11'); |
||||
dblink_exec |
||||
------------- |
||||
UPDATE 1 |
||||
(1 row) |
||||
|
||||
-- let's see it |
||||
select * from dblink('select * from foo') as t(a int, b text, c text[]) where a = 11; |
||||
a | b | c |
||||
----+---+--------------- |
||||
11 | l | {a11,b99,c11} |
||||
(1 row) |
||||
|
||||
-- delete some data |
||||
select dblink_exec('delete from foo where f1 = 11'); |
||||
dblink_exec |
||||
------------- |
||||
DELETE 1 |
||||
(1 row) |
||||
|
||||
-- let's see it |
||||
select * from dblink('select * from foo') as t(a int, b text, c text[]) where a = 11; |
||||
a | b | c |
||||
---+---+--- |
||||
(0 rows) |
||||
|
||||
-- misc utilities |
||||
\connect dblink_test_slave |
||||
-- show the currently executing query |
||||
select 'hello' as hello, dblink_current_query() as query; |
||||
hello | query |
||||
-------+----------------------------------------------------------- |
||||
hello | select 'hello' as hello, dblink_current_query() as query; |
||||
(1 row) |
||||
|
||||
-- list the primary key fields |
||||
select * from dblink_get_pkey('foo'); |
||||
position | colname |
||||
----------+--------- |
||||
1 | f1 |
||||
2 | f2 |
||||
(2 rows) |
||||
|
||||
-- build an insert statement based on a local tuple, |
||||
-- replacing the primary key values with new ones |
||||
select dblink_build_sql_insert('foo','1 2',2,'{"0", "a"}','{"99", "xyz"}'); |
||||
dblink_build_sql_insert |
||||
----------------------------------------------------------- |
||||
INSERT INTO foo(f1,f2,f3) VALUES('99','xyz','{a0,b0,c0}') |
||||
(1 row) |
||||
|
||||
-- build an update statement based on a local tuple, |
||||
-- replacing the primary key values with new ones |
||||
select dblink_build_sql_update('foo','1 2',2,'{"0", "a"}','{"99", "xyz"}'); |
||||
dblink_build_sql_update |
||||
---------------------------------------------------------------------------------------- |
||||
UPDATE foo SET f1 = '99', f2 = 'xyz', f3 = '{a0,b0,c0}' WHERE f1 = '99' AND f2 = 'xyz' |
||||
(1 row) |
||||
|
||||
-- build a delete statement based on a local tuple, |
||||
select dblink_build_sql_delete('foo','1 2',2,'{"0", "a"}'); |
||||
dblink_build_sql_delete |
||||
--------------------------------------------- |
||||
DELETE FROM foo WHERE f1 = '0' AND f2 = 'a' |
||||
(1 row) |
||||
|
||||
@ -0,0 +1,95 @@ |
||||
\connect dblink_test_slave |
||||
|
||||
create table foo(f1 int, f2 text, f3 text[], primary key (f1,f2)); |
||||
insert into foo values(0,'a','{"a0","b0","c0"}'); |
||||
insert into foo values(1,'b','{"a1","b1","c1"}'); |
||||
insert into foo values(2,'c','{"a2","b2","c2"}'); |
||||
insert into foo values(3,'d','{"a3","b3","c3"}'); |
||||
insert into foo values(4,'e','{"a4","b4","c4"}'); |
||||
insert into foo values(5,'f','{"a5","b5","c5"}'); |
||||
insert into foo values(6,'g','{"a6","b6","c6"}'); |
||||
insert into foo values(7,'h','{"a7","b7","c7"}'); |
||||
insert into foo values(8,'i','{"a8","b8","c8"}'); |
||||
insert into foo values(9,'j','{"a9","b9","c9"}'); |
||||
|
||||
\connect dblink_test_master |
||||
|
||||
-- regular old dblink |
||||
select * from dblink('dbname=dblink_test_slave','select * from foo') as t(a int, b text, c text[]) where t.a > 7; |
||||
|
||||
-- should generate "no connection available" error |
||||
select * from dblink('select * from foo') as t(a int, b text, c text[]) where t.a > 7; |
||||
|
||||
-- create a persistent connection |
||||
select dblink_connect('dbname=dblink_test_slave'); |
||||
|
||||
-- use the persistent connection |
||||
select * from dblink('select * from foo') as t(a int, b text, c text[]) where t.a > 7; |
||||
|
||||
-- open a cursor |
||||
select dblink_open('rmt_foo_cursor','select * from foo'); |
||||
|
||||
-- fetch some data |
||||
select * from dblink_fetch('rmt_foo_cursor',4) as t(a int, b text, c text[]); |
||||
select * from dblink_fetch('rmt_foo_cursor',4) as t(a int, b text, c text[]); |
||||
|
||||
-- this one only finds two rows left |
||||
select * from dblink_fetch('rmt_foo_cursor',4) as t(a int, b text, c text[]); |
||||
|
||||
-- close the cursor |
||||
select dblink_close('rmt_foo_cursor'); |
||||
|
||||
-- should generate "cursor rmt_foo_cursor does not exist" error |
||||
select * from dblink_fetch('rmt_foo_cursor',4) as t(a int, b text, c text[]); |
||||
|
||||
-- close the persistent connection |
||||
select dblink_disconnect(); |
||||
|
||||
-- should generate "no connection available" error |
||||
select * from dblink('select * from foo') as t(a int, b text, c text[]) where t.a > 7; |
||||
|
||||
-- put more data into our slave table, first using arbitrary connection syntax |
||||
-- but truncate the actual return value so we can use diff to check for success |
||||
select substr(dblink_exec('dbname=dblink_test_slave','insert into foo values(10,''k'',''{"a10","b10","c10"}'')'),1,6); |
||||
|
||||
-- create a persistent connection |
||||
select dblink_connect('dbname=dblink_test_slave'); |
||||
|
||||
-- put more data into our slave table, using persistent connection syntax |
||||
-- but truncate the actual return value so we can use diff to check for success |
||||
select substr(dblink_exec('insert into foo values(11,''l'',''{"a11","b11","c11"}'')'),1,6); |
||||
|
||||
-- let's see it |
||||
select * from dblink('select * from foo') as t(a int, b text, c text[]); |
||||
|
||||
-- change some data |
||||
select dblink_exec('update foo set f3[2] = ''b99'' where f1 = 11'); |
||||
|
||||
-- let's see it |
||||
select * from dblink('select * from foo') as t(a int, b text, c text[]) where a = 11; |
||||
|
||||
-- delete some data |
||||
select dblink_exec('delete from foo where f1 = 11'); |
||||
|
||||
-- let's see it |
||||
select * from dblink('select * from foo') as t(a int, b text, c text[]) where a = 11; |
||||
|
||||
-- misc utilities |
||||
\connect dblink_test_slave |
||||
|
||||
-- show the currently executing query |
||||
select 'hello' as hello, dblink_current_query() as query; |
||||
|
||||
-- list the primary key fields |
||||
select * from dblink_get_pkey('foo'); |
||||
|
||||
-- build an insert statement based on a local tuple, |
||||
-- replacing the primary key values with new ones |
||||
select dblink_build_sql_insert('foo','1 2',2,'{"0", "a"}','{"99", "xyz"}'); |
||||
|
||||
-- build an update statement based on a local tuple, |
||||
-- replacing the primary key values with new ones |
||||
select dblink_build_sql_update('foo','1 2',2,'{"0", "a"}','{"99", "xyz"}'); |
||||
|
||||
-- build a delete statement based on a local tuple, |
||||
select dblink_build_sql_delete('foo','1 2',2,'{"0", "a"}'); |
||||
@ -0,0 +1,15 @@ |
||||
#!/bin/sh |
||||
|
||||
dropdb -U postgres dblink_test_master |
||||
createdb -U postgres dblink_test_master |
||||
psql -U postgres dblink_test_master < `pwd`/dblink.sql |
||||
|
||||
dropdb -U postgres dblink_test_slave |
||||
createdb -U postgres dblink_test_slave |
||||
psql -U postgres dblink_test_slave < `pwd`/dblink.sql |
||||
|
||||
psql -eaq -U postgres template1 < `pwd`/dblink.test.sql > dblink.test.out 2>&1 |
||||
diff -c ./dblink.test.expected.out `pwd`/dblink.test.out > dblink.test.diff |
||||
ls -l dblink.test.diff |
||||
|
||||
|
||||
@ -0,0 +1,53 @@ |
||||
================================================================== |
||||
Name |
||||
|
||||
dblink_connect -- Opens a persistent connection to a remote database |
||||
|
||||
Synopsis |
||||
|
||||
dblink_connect(text connstr) |
||||
|
||||
Inputs |
||||
|
||||
connstr |
||||
|
||||
standard libpq format connection string, |
||||
e.g. "hostaddr=127.0.0.1 port=5432 dbname=mydb user=postgres password=mypasswd" |
||||
|
||||
Outputs |
||||
|
||||
Returns status = "OK" |
||||
|
||||
Example usage |
||||
|
||||
test=# select dblink_connect('dbname=template1'); |
||||
dblink_connect |
||||
---------------- |
||||
OK |
||||
(1 row) |
||||
|
||||
================================================================== |
||||
Name |
||||
|
||||
dblink_disconnect -- Closes the persistent connection to a remote database |
||||
|
||||
Synopsis |
||||
|
||||
dblink_disconnect() |
||||
|
||||
Inputs |
||||
|
||||
none |
||||
|
||||
Outputs |
||||
|
||||
Returns status = "OK" |
||||
|
||||
Example usage |
||||
|
||||
test=# select dblink_disconnect(); |
||||
dblink_disconnect |
||||
------------------- |
||||
OK |
||||
(1 row) |
||||
|
||||
@ -0,0 +1,159 @@ |
||||
================================================================== |
||||
Name |
||||
|
||||
dblink_open -- Opens a cursor on a remote database |
||||
|
||||
Synopsis |
||||
|
||||
dblink_open(text cursorname, text sql) |
||||
|
||||
Inputs |
||||
|
||||
cursorname |
||||
|
||||
a reference name for the cursor |
||||
|
||||
sql |
||||
|
||||
sql statement that you wish to execute on the remote host |
||||
e.g. "select * from pg_class" |
||||
|
||||
Outputs |
||||
|
||||
Returns status = "OK" |
||||
|
||||
Note |
||||
1) dblink_connect(text connstr) must be executed first |
||||
2) dblink_open starts an explicit transaction. If, after using dblink_open, |
||||
you use dblink_exec to change data, and then an error occurs or you use |
||||
dblink_disconnect without a dblink_close first, your change *will* be |
||||
lost. Also, using dblink_close explicitly ends the transaction and thus |
||||
effectively closes *all* open cursors. |
||||
|
||||
Example usage |
||||
|
||||
test=# select dblink_connect('dbname=template1'); |
||||
dblink_connect |
||||
---------------- |
||||
OK |
||||
(1 row) |
||||
|
||||
test=# select dblink_open('foo','select proname, prosrc from pg_proc'); |
||||
dblink_open |
||||
------------- |
||||
OK |
||||
(1 row) |
||||
|
||||
================================================================== |
||||
Name |
||||
|
||||
dblink_fetch -- Returns a set from an open cursor on a remote database |
||||
|
||||
Synopsis |
||||
|
||||
dblink_fetch(text cursorname, int32 howmany) |
||||
|
||||
Inputs |
||||
|
||||
cursorname |
||||
|
||||
The reference name for the cursor |
||||
|
||||
howmany |
||||
|
||||
Maximum number of rows to retrieve. The next howmany rows are fetched, |
||||
starting at the current cursor position, moving forward. Once the cursor |
||||
has positioned to the end, no more rows are produced. |
||||
|
||||
Outputs |
||||
|
||||
Returns setof record |
||||
|
||||
Example usage |
||||
|
||||
test=# select dblink_connect('dbname=template1'); |
||||
dblink_connect |
||||
---------------- |
||||
OK |
||||
(1 row) |
||||
|
||||
test=# select dblink_open('foo','select proname, prosrc from pg_proc where proname like ''bytea%'''); |
||||
dblink_open |
||||
------------- |
||||
OK |
||||
(1 row) |
||||
|
||||
test=# select * from dblink_fetch('foo',5) as (funcname name, source text); |
||||
funcname | source |
||||
----------+---------- |
||||
byteacat | byteacat |
||||
byteacmp | byteacmp |
||||
byteaeq | byteaeq |
||||
byteage | byteage |
||||
byteagt | byteagt |
||||
(5 rows) |
||||
|
||||
test=# select * from dblink_fetch('foo',5) as (funcname name, source text); |
||||
funcname | source |
||||
-----------+----------- |
||||
byteain | byteain |
||||
byteale | byteale |
||||
bytealike | bytealike |
||||
bytealt | bytealt |
||||
byteane | byteane |
||||
(5 rows) |
||||
|
||||
test=# select * from dblink_fetch('foo',5) as (funcname name, source text); |
||||
funcname | source |
||||
------------+------------ |
||||
byteanlike | byteanlike |
||||
byteaout | byteaout |
||||
(2 rows) |
||||
|
||||
test=# select * from dblink_fetch('foo',5) as (funcname name, source text); |
||||
funcname | source |
||||
----------+-------- |
||||
(0 rows) |
||||
|
||||
================================================================== |
||||
Name |
||||
|
||||
dblink_close -- Closes a cursor on a remote database |
||||
|
||||
Synopsis |
||||
|
||||
dblink_close(text cursorname) |
||||
|
||||
Inputs |
||||
|
||||
cursorname |
||||
|
||||
a reference name for the cursor |
||||
|
||||
Outputs |
||||
|
||||
Returns status = "OK" |
||||
|
||||
Note |
||||
dblink_connect(text connstr) must be executed first. |
||||
|
||||
Example usage |
||||
|
||||
test=# select dblink_connect('dbname=template1'); |
||||
dblink_connect |
||||
---------------- |
||||
OK |
||||
(1 row) |
||||
|
||||
test=# select dblink_open('foo','select proname, prosrc from pg_proc'); |
||||
dblink_open |
||||
------------- |
||||
OK |
||||
(1 row) |
||||
|
||||
test=# select dblink_close('foo'); |
||||
dblink_close |
||||
-------------- |
||||
OK |
||||
(1 row) |
||||
|
||||
@ -0,0 +1,105 @@ |
||||
================================================================== |
||||
Name |
||||
|
||||
*DEPRECATED* use new dblink syntax |
||||
dblink -- Returns a resource id for a data set from a remote database |
||||
|
||||
Synopsis |
||||
|
||||
dblink(text connstr, text sql) |
||||
|
||||
Inputs |
||||
|
||||
connstr |
||||
|
||||
standard libpq format connection srting, |
||||
e.g. "hostaddr=127.0.0.1 port=5432 dbname=mydb user=postgres password=mypasswd" |
||||
|
||||
sql |
||||
|
||||
sql statement that you wish to execute on the remote host |
||||
e.g. "select * from pg_class" |
||||
|
||||
Outputs |
||||
|
||||
Returns setof int (res_id) |
||||
|
||||
Example usage |
||||
|
||||
select dblink('hostaddr=127.0.0.1 port=5432 dbname=mydb user=postgres password=mypasswd' |
||||
,'select f1, f2 from mytable'); |
||||
|
||||
================================================================== |
||||
|
||||
Name |
||||
|
||||
*DEPRECATED* use new dblink syntax |
||||
dblink_tok -- Returns individual select field results from a dblink remote query |
||||
|
||||
Synopsis |
||||
|
||||
dblink_tok(int res_id, int fnumber) |
||||
|
||||
Inputs |
||||
|
||||
res_id |
||||
|
||||
a resource id returned by a call to dblink() |
||||
|
||||
fnumber |
||||
|
||||
the ordinal position (zero based) of the field to be returned from the dblink result set |
||||
|
||||
Outputs |
||||
|
||||
Returns text |
||||
|
||||
Example usage |
||||
|
||||
select dblink_tok(t1.dblink_p,0) as f1, dblink_tok(t1.dblink_p,1) as f2 |
||||
from (select dblink('hostaddr=127.0.0.1 port=5432 dbname=mydb user=postgres password=mypasswd' |
||||
,'select f1, f2 from mytable') as dblink_p) as t1; |
||||
|
||||
|
||||
================================================================== |
||||
*DEPRECATED* use new dblink syntax |
||||
A more convenient way to use dblink may be to create a view: |
||||
|
||||
create view myremotetable as |
||||
select dblink_tok(t1.dblink_p,0) as f1, dblink_tok(t1.dblink_p,1) as f2 |
||||
from (select dblink('hostaddr=127.0.0.1 port=5432 dbname=template1 user=postgres password=postgres' |
||||
,'select proname, prosrc from pg_proc') as dblink_p) as t1; |
||||
|
||||
Then you can simply write: |
||||
|
||||
select f1, f2 from myremotetable where f1 like 'bytea%'; |
||||
|
||||
================================================================== |
||||
Name |
||||
*DEPRECATED* use new dblink_exec syntax |
||||
dblink_last_oid -- Returns last inserted oid |
||||
|
||||
Synopsis |
||||
|
||||
dblink_last_oid(int res_id) RETURNS oid |
||||
|
||||
Inputs |
||||
|
||||
res_id |
||||
|
||||
any resource id returned by dblink function; |
||||
|
||||
Outputs |
||||
|
||||
Returns oid of last inserted tuple |
||||
|
||||
Example usage |
||||
|
||||
test=# select dblink_last_oid(dblink('hostaddr=127.0.0.1 port=5432 dbname=mydb user=postgres password=mypasswd' |
||||
,'insert into mytable (f1, f2) values (1,2)')); |
||||
|
||||
dblink_last_oid |
||||
---------------- |
||||
16553 |
||||
(1 row) |
||||
|
||||
@ -0,0 +1,49 @@ |
||||
================================================================== |
||||
Name |
||||
|
||||
dblink_exec -- Executes an UPDATE/INSERT/DELETE on a remote database |
||||
|
||||
Synopsis |
||||
|
||||
dblink_exec(text connstr, text sql) |
||||
- or - |
||||
dblink_exec(text sql) |
||||
|
||||
Inputs |
||||
|
||||
connstr |
||||
|
||||
standard libpq format connection string, |
||||
e.g. "hostaddr=127.0.0.1 port=5432 dbname=mydb user=postgres password=mypasswd" |
||||
If the second form is used, then the dblink_connect(text connstr) must be |
||||
executed first. |
||||
|
||||
sql |
||||
|
||||
sql statement that you wish to execute on the remote host, e.g.: |
||||
|
||||
insert into foo values(0,'a','{"a0","b0","c0"}'); |
||||
|
||||
Outputs |
||||
|
||||
Returns status of the command |
||||
|
||||
Notes |
||||
1) dblink_open starts an explicit transaction. If, after using dblink_open, |
||||
you use dblink_exec to change data, and then an error occurs or you use |
||||
dblink_disconnect without a dblink_close first, your change *will* be |
||||
lost. |
||||
|
||||
Example usage |
||||
|
||||
test=# select dblink_connect('dbname=dblink_test_slave'); |
||||
dblink_connect |
||||
---------------- |
||||
OK |
||||
(1 row) |
||||
|
||||
test=# select dblink_exec('insert into foo values(21,''z'',''{"a0","b0","c0"}'');'); |
||||
dblink_exec |
||||
----------------- |
||||
INSERT 943366 1 |
||||
(1 row) |
||||
@ -0,0 +1,140 @@ |
||||
================================================================== |
||||
Name |
||||
|
||||
dblink_current_query -- returns the current query string |
||||
|
||||
Synopsis |
||||
|
||||
dblink_current_query () RETURNS text |
||||
|
||||
Inputs |
||||
|
||||
None |
||||
|
||||
Outputs |
||||
|
||||
Returns text -- a copy of the currently executing query |
||||
|
||||
Example usage |
||||
|
||||
test=# select dblink_current_query() from (select dblink('dbname=template1','select oid, proname from pg_proc where proname = ''byteacat''') as f1) as t1; |
||||
dblink_current_query |
||||
----------------------------------------------------------------------------------------------------------------------------------------------------- |
||||
select dblink_current_query() from (select dblink('dbname=template1','select oid, proname from pg_proc where proname = ''byteacat''') as f1) as t1; |
||||
(1 row) |
||||
|
||||
================================================================== |
||||
Name |
||||
|
||||
dblink_get_pkey -- returns the position and field names of a relation's |
||||
primary key fields |
||||
|
||||
Synopsis |
||||
|
||||
dblink_get_pkey(text relname) RETURNS setof dblink_pkey_results |
||||
|
||||
Inputs |
||||
|
||||
relname |
||||
|
||||
any relation name; |
||||
e.g. 'foobar' |
||||
|
||||
Outputs |
||||
|
||||
Returns setof dblink_pkey_results -- one row for each primary key field, |
||||
in order of position in the key. dblink_pkey_results is defined as follows: |
||||
CREATE TYPE dblink_pkey_results AS (position int4, colname text); |
||||
|
||||
Example usage |
||||
|
||||
test=# select * from dblink_get_pkey('foobar'); |
||||
position | colname |
||||
----------+--------- |
||||
1 | f1 |
||||
2 | f2 |
||||
3 | f3 |
||||
4 | f4 |
||||
5 | f5 |
||||
|
||||
================================================================== |
||||
Name |
||||
|
||||
dblink_build_sql_insert -- builds an insert statement using a local |
||||
tuple, replacing the selection key field |
||||
values with alternate supplied values |
||||
dblink_build_sql_delete -- builds a delete statement using supplied |
||||
values for selection key field values |
||||
dblink_build_sql_update -- builds an update statement using a local |
||||
tuple, replacing the selection key field |
||||
values with alternate supplied values |
||||
|
||||
|
||||
Synopsis |
||||
|
||||
dblink_build_sql_insert(text relname |
||||
,int2vector primary_key_attnums |
||||
,int2 num_primary_key_atts |
||||
,_text src_pk_att_vals_array |
||||
,_text tgt_pk_att_vals_array) RETURNS text |
||||
dblink_build_sql_delete(text relname |
||||
,int2vector primary_key_attnums |
||||
,int2 num_primary_key_atts |
||||
,_text tgt_pk_att_vals_array) RETURNS text |
||||
dblink_build_sql_update(text relname |
||||
,int2vector primary_key_attnums |
||||
,int2 num_primary_key_atts |
||||
,_text src_pk_att_vals_array |
||||
,_text tgt_pk_att_vals_array) RETURNS text |
||||
|
||||
Inputs |
||||
|
||||
relname |
||||
|
||||
any relation name; |
||||
e.g. 'foobar' |
||||
|
||||
primary_key_attnums |
||||
|
||||
vector of primary key attnums (1 based, see pg_index.indkey); |
||||
e.g. '1 2' |
||||
|
||||
num_primary_key_atts |
||||
|
||||
number of primary key attnums in the vector; e.g. 2 |
||||
|
||||
src_pk_att_vals_array |
||||
|
||||
array of primary key values, used to look up the local matching |
||||
tuple, the values of which are then used to construct the SQL |
||||
statement |
||||
|
||||
tgt_pk_att_vals_array |
||||
|
||||
array of primary key values, used to replace the local tuple |
||||
values in the SQL statement |
||||
|
||||
Outputs |
||||
|
||||
Returns text -- requested SQL statement |
||||
|
||||
Example usage |
||||
|
||||
test=# select dblink_build_sql_insert('foo','1 2',2,'{"1", "a"}','{"1", "b''a"}'); |
||||
dblink_build_sql_insert |
||||
-------------------------------------------------- |
||||
INSERT INTO foo(f1,f2,f3) VALUES('1','b''a','1') |
||||
(1 row) |
||||
|
||||
test=# select dblink_build_sql_delete('MyFoo','1 2',2,'{"1", "b"}'); |
||||
dblink_build_sql_delete |
||||
--------------------------------------------- |
||||
DELETE FROM "MyFoo" WHERE f1='1' AND f2='b' |
||||
(1 row) |
||||
|
||||
test=# select dblink_build_sql_update('foo','1 2',2,'{"1", "a"}','{"1", "b"}'); |
||||
dblink_build_sql_update |
||||
------------------------------------------------------------- |
||||
UPDATE foo SET f1='1',f2='b',f3='1' WHERE f1='1' AND f2='b' |
||||
(1 row) |
||||
|
||||
@ -0,0 +1,85 @@ |
||||
================================================================== |
||||
Name |
||||
|
||||
dblink -- Returns a set from a remote database |
||||
|
||||
Synopsis |
||||
|
||||
dblink(text connstr, text sql) |
||||
- or - |
||||
dblink(text sql) |
||||
|
||||
Inputs |
||||
|
||||
connstr |
||||
|
||||
standard libpq format connection string, |
||||
e.g. "hostaddr=127.0.0.1 port=5432 dbname=mydb user=postgres password=mypasswd" |
||||
If the second form is used, then the dblink_connect(text connstr) must be |
||||
executed first. |
||||
|
||||
sql |
||||
|
||||
sql statement that you wish to execute on the remote host |
||||
e.g. "select * from pg_class" |
||||
|
||||
Outputs |
||||
|
||||
Returns setof record |
||||
|
||||
Example usage |
||||
|
||||
test=# select * from dblink('dbname=template1','select proname, prosrc from pg_proc') |
||||
as t1(proname name, prosrc text) where proname like 'bytea%'; |
||||
proname | prosrc |
||||
------------+------------ |
||||
byteacat | byteacat |
||||
byteaeq | byteaeq |
||||
bytealt | bytealt |
||||
byteale | byteale |
||||
byteagt | byteagt |
||||
byteage | byteage |
||||
byteane | byteane |
||||
byteacmp | byteacmp |
||||
bytealike | bytealike |
||||
byteanlike | byteanlike |
||||
byteain | byteain |
||||
byteaout | byteaout |
||||
(12 rows) |
||||
|
||||
test=# select dblink_connect('dbname=template1'); |
||||
dblink_connect |
||||
---------------- |
||||
OK |
||||
(1 row) |
||||
|
||||
test=# select * from dblink('select proname, prosrc from pg_proc') |
||||
as t1(proname name, prosrc text) where proname like 'bytea%'; |
||||
proname | prosrc |
||||
------------+------------ |
||||
byteacat | byteacat |
||||
byteaeq | byteaeq |
||||
bytealt | bytealt |
||||
byteale | byteale |
||||
byteagt | byteagt |
||||
byteage | byteage |
||||
byteane | byteane |
||||
byteacmp | byteacmp |
||||
bytealike | bytealike |
||||
byteanlike | byteanlike |
||||
byteain | byteain |
||||
byteaout | byteaout |
||||
(12 rows) |
||||
|
||||
================================================================== |
||||
A more convenient way to use dblink may be to create a view: |
||||
|
||||
create view myremote_pg_proc as |
||||
select * |
||||
from dblink('dbname=template1','select proname, prosrc from pg_proc') |
||||
as t1(proname name, prosrc text); |
||||
|
||||
Then you can simply write: |
||||
|
||||
select * from myremote_pg_proc where proname like 'bytea%'; |
||||
|
||||
Loading…
Reference in new issue