contrib/dblink GRANTs and regression test fix - Mailing list pgsql-patches

From Joe Conway
Subject contrib/dblink GRANTs and regression test fix
Date
Msg-id 3D826D63.3030702@joeconway.com
Whole thread Raw
Responses Re: contrib/dblink GRANTs and regression test fix  (Tom Lane <tgl@sss.pgh.pa.us>)
List pgsql-patches
The attached adds GRANTs to PUBLIC for dblink functions, removes the
non-standard regression test, and adds standard installcheck regression test
support.

The test creates a second database (regression_slave) and drops it again, in
order to avoid the cheesy-ness of connecting back to the same database ;-)

Please apply.

Thanks,

Joe


Index: contrib/dblink/Makefile
===================================================================
RCS file: /opt/src/cvs/pgsql-server/contrib/dblink/Makefile,v
retrieving revision 1.6
diff -c -r1.6 Makefile
*** contrib/dblink/Makefile    3 Sep 2002 04:01:05 -0000    1.6
--- contrib/dblink/Makefile    13 Sep 2002 21:43:57 -0000
***************
*** 11,16 ****
--- 11,17 ----

  DATA_built = dblink.sql
  DOCS = README.dblink
+ REGRESS = dblink

  EXTRA_CLEAN = dblink.test.out dblink.test.diff

Index: contrib/dblink/dblink.sql.in
===================================================================
RCS file: /opt/src/cvs/pgsql-server/contrib/dblink/dblink.sql.in,v
retrieving revision 1.4
diff -c -r1.4 dblink.sql.in
*** contrib/dblink/dblink.sql.in    2 Sep 2002 06:13:31 -0000    1.4
--- contrib/dblink/dblink.sql.in    13 Sep 2002 22:27:30 -0000
***************
*** 29,38 ****
    AS 'MODULE_PATHNAME','dblink_close' LANGUAGE 'c'
    WITH (isstrict);

! -- Note: if this is a first time install of dblink, the following DROP
! -- FUNCTION line is expected to fail.
! -- Comment out the following 4 lines if the DEPRECATED functions are used.
! DROP FUNCTION dblink (text,text);
  CREATE OR REPLACE FUNCTION dblink (text,text) RETURNS setof record
    AS 'MODULE_PATHNAME','dblink_record' LANGUAGE 'c'
    WITH (isstrict);
--- 29,40 ----
    AS 'MODULE_PATHNAME','dblink_close' LANGUAGE 'c'
    WITH (isstrict);

! -- Note: if this is not a first time install of dblink, uncomment the
! -- following DROP which prepares the database for the new, non-deprecated
! -- version.
! --DROP FUNCTION dblink (text,text);
!
! -- Comment out the following 3 lines if the DEPRECATED functions are used.
  CREATE OR REPLACE FUNCTION dblink (text,text) RETURNS setof record
    AS 'MODULE_PATHNAME','dblink_record' LANGUAGE 'c'
    WITH (isstrict);
***************
*** 69,71 ****
--- 71,89 ----

  CREATE OR REPLACE FUNCTION dblink_current_query () RETURNS text
    AS 'MODULE_PATHNAME','dblink_current_query' LANGUAGE 'c';
+
+ GRANT EXECUTE ON FUNCTION dblink_connect (text) TO PUBLIC;
+ GRANT EXECUTE ON FUNCTION dblink_disconnect () TO PUBLIC;
+ GRANT EXECUTE ON FUNCTION dblink_open (text,text) TO PUBLIC;
+ GRANT EXECUTE ON FUNCTION dblink_fetch (text,int) TO PUBLIC;
+ GRANT EXECUTE ON FUNCTION dblink_close (text) TO PUBLIC;
+ GRANT EXECUTE ON FUNCTION dblink (text,text) TO PUBLIC;
+ GRANT EXECUTE ON FUNCTION dblink (text) TO PUBLIC;
+ GRANT EXECUTE ON FUNCTION dblink_exec (text,text) TO PUBLIC;
+ GRANT EXECUTE ON FUNCTION dblink_exec (text) TO PUBLIC;
+ GRANT EXECUTE ON FUNCTION dblink_get_pkey (text) TO PUBLIC;
+ GRANT EXECUTE ON FUNCTION dblink_build_sql_insert (text, int2vector, int2, _text, _text) TO PUBLIC;
+ GRANT EXECUTE ON FUNCTION dblink_build_sql_delete (text, int2vector, int2, _text) TO PUBLIC;
+ GRANT EXECUTE ON FUNCTION dblink_build_sql_update (text, int2vector, int2, _text, _text) TO PUBLIC;
+ GRANT EXECUTE ON FUNCTION dblink_current_query () TO PUBLIC;
+
Index: contrib/dblink/dblink.test.expected.out
===================================================================
RCS file: contrib/dblink/dblink.test.expected.out
diff -N contrib/dblink/dblink.test.expected.out
*** contrib/dblink/dblink.test.expected.out    2 Sep 2002 06:32:41 -0000    1.1
--- /dev/null    1 Jan 1970 00:00:00 -0000
***************
*** 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 ----
Index: contrib/dblink/dblink.test.sql
===================================================================
RCS file: contrib/dblink/dblink.test.sql
diff -N contrib/dblink/dblink.test.sql
*** contrib/dblink/dblink.test.sql    2 Sep 2002 06:32:41 -0000    1.1
--- /dev/null    1 Jan 1970 00:00:00 -0000
***************
*** 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 ----
Index: contrib/dblink/dblink_check.sh
===================================================================
RCS file: contrib/dblink/dblink_check.sh
diff -N contrib/dblink/dblink_check.sh
*** contrib/dblink/dblink_check.sh    2 Sep 2002 06:32:41 -0000    1.1
--- /dev/null    1 Jan 1970 00:00:00 -0000
***************
*** 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 ----
Index: contrib/dblink/expected/dblink.out
===================================================================
RCS file: contrib/dblink/expected/dblink.out
diff -N contrib/dblink/expected/dblink.out
*** /dev/null    1 Jan 1970 00:00:00 -0000
--- contrib/dblink/expected/dblink.out    13 Sep 2002 22:17:27 -0000
***************
*** 0 ****
--- 1,259 ----
+ --
+ -- First, create a slave database and define the functions.
+ -- Turn off echoing so that expected file does not depend on
+ -- contents of dblink.sql.
+ --
+ CREATE DATABASE regression_slave;
+ \connect regression_slave
+ \set ECHO none
+ 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"}');
+ -- misc utilities
+ -- 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)
+
+ --
+ -- Connect back to the regression database and define the functions.
+ -- Turn off echoing so that expected file does not depend on
+ -- contents of dblink.sql.
+ --
+ \connect regression
+ \set ECHO none
+ -- regular old dblink
+ select * from dblink('dbname=regression_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=regression_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=regression_slave','insert into foo values(10,''k'',''{"a10","b10","c10"}'')'),1,6);
+  substr
+ --------
+  INSERT
+ (1 row)
+
+ -- create a persistent connection
+ select dblink_connect('dbname=regression_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)
+
+ -- close the persistent connection
+ select dblink_disconnect();
+  dblink_disconnect
+ -------------------
+  OK
+ (1 row)
+
+ -- now wait for the connection to the slave to be cleared before
+ -- we try to drop the database
+ CREATE FUNCTION wait() RETURNS TEXT AS '
+ DECLARE
+     rec           record;
+     cntr          int;
+ BEGIN
+     cntr = 0;
+
+     select into rec d.datname
+     from pg_database d,
+         (select pg_stat_get_backend_dbid(pg_stat_get_backend_idset()) AS dbid) b
+     where d.oid = b.dbid and d.datname = ''regression_slave'';
+
+     WHILE FOUND LOOP
+         cntr = cntr + 1;
+
+         select into rec d.datname
+         from pg_database d,
+             (select pg_stat_get_backend_dbid(pg_stat_get_backend_idset()) AS dbid) b
+         where d.oid = b.dbid and d.datname = ''regression_slave'';
+
+         -- safety valve
+         if cntr > 1000 THEN
+             EXIT;
+         end if;
+     END LOOP;
+     RETURN ''OK'';
+ END;
+ ' LANGUAGE 'plpgsql';
+ SELECT wait();
+  wait
+ ------
+  OK
+ (1 row)
+
+ -- OK, safe to drop the slave
+ DROP DATABASE regression_slave;
Index: contrib/dblink/sql/dblink.sql
===================================================================
RCS file: contrib/dblink/sql/dblink.sql
diff -N contrib/dblink/sql/dblink.sql
*** /dev/null    1 Jan 1970 00:00:00 -0000
--- contrib/dblink/sql/dblink.sql    13 Sep 2002 22:17:18 -0000
***************
*** 0 ****
--- 1,149 ----
+ --
+ -- First, create a slave database and define the functions.
+ -- Turn off echoing so that expected file does not depend on
+ -- contents of dblink.sql.
+ --
+ CREATE DATABASE regression_slave;
+ \connect regression_slave
+ \set ECHO none
+ \i dblink.sql
+ \set ECHO all
+
+ 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"}');
+
+ -- misc utilities
+
+ -- 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"}');
+
+ --
+ -- Connect back to the regression database and define the functions.
+ -- Turn off echoing so that expected file does not depend on
+ -- contents of dblink.sql.
+ --
+ \connect regression
+ \set ECHO none
+ \i dblink.sql
+ \set ECHO all
+
+ -- regular old dblink
+ select * from dblink('dbname=regression_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=regression_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=regression_slave','insert into foo values(10,''k'',''{"a10","b10","c10"}'')'),1,6);
+
+ -- create a persistent connection
+ select dblink_connect('dbname=regression_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;
+
+ -- close the persistent connection
+ select dblink_disconnect();
+
+ -- now wait for the connection to the slave to be cleared before
+ -- we try to drop the database
+ CREATE FUNCTION wait() RETURNS TEXT AS '
+ DECLARE
+     rec           record;
+     cntr          int;
+ BEGIN
+     cntr = 0;
+
+     select into rec d.datname
+     from pg_database d,
+         (select pg_stat_get_backend_dbid(pg_stat_get_backend_idset()) AS dbid) b
+     where d.oid = b.dbid and d.datname = ''regression_slave'';
+
+     WHILE FOUND LOOP
+         cntr = cntr + 1;
+
+         select into rec d.datname
+         from pg_database d,
+             (select pg_stat_get_backend_dbid(pg_stat_get_backend_idset()) AS dbid) b
+         where d.oid = b.dbid and d.datname = ''regression_slave'';
+
+         -- safety value
+         if cntr > 1000 THEN
+             EXIT;
+         end if;
+     END LOOP;
+     RETURN ''OK'';
+ END;
+ ' LANGUAGE 'plpgsql';
+ SELECT wait();
+
+ -- OK, safe to drop the slave
+ DROP DATABASE regression_slave;

pgsql-patches by date:

Previous
From: Neil Conway
Date:
Subject: improve PL/PgSQL documentation
Next
From: Joe Conway
Date:
Subject: contrib/cube & contrib/seg regression fixes