Attached is a fairly sizeable update to contrib/dblink. I'd love to get

review/feedback if anyone is interested and can spend the time. But I'd
also love to get this committed and address changes as incremental
patches ;-), so if there are no objections, please apply.

Below I'll give a synopsis of the changes. More detailed descriptions
are now in a new doc directory under contrib/dblink. There is also a new

dblink.test.sql file which will give a pretty good overview of the
functions and their use.

Joe Conway
This commit is contained in:
Bruce Momjian 2002-09-02 06:13:31 +00:00
parent a12b4e279b
commit 7b8eb0b4f1
5 changed files with 965 additions and 717 deletions

View File

@ -48,7 +48,7 @@ dbase -
dblink -
Allows remote query execution
by Joe Conway <joe.conway@mail.com>
by Joe Conway <mail@joeconway.com>
dbmirror -
Replication server
@ -73,7 +73,7 @@ fulltextindex -
fuzzystrmatch -
Levenshtein, metaphone, and soundex fuzzy string matching
by Joe Conway <joseph.conway@home.com>, Joel Burton <jburton@scw.org>
by Joe Conway <mail@joeconway.com>, Joel Burton <jburton@scw.org>
intagg -
Integer aggregator

View File

@ -3,7 +3,9 @@
*
* Functions returning results from a remote database
*
* Copyright (c) Joseph Conway <mail@joeconway.com>, 2001, 2002,
* Joe Conway <mail@joeconway.com>
*
* Copyright (c) 2001, 2002 by PostgreSQL Global Development Group
* ALL RIGHTS RESERVED;
*
* Permission to use, copy, modify, and distribute this software and its
@ -25,13 +27,36 @@
*
*/
Version 0.4 (7 April, 2002):
Functions allowing remote database INSERT/UPDATE/DELETE/SELECT, and
various utility functions.
Tested under Linux (Red Hat 7.2) and PostgreSQL 7.2 and 7.3devel
Version 0.5 (25 August, 2002):
Major overhaul to work with new backend "table function" capability. Removed
dblink_strtok() and dblink_replace() functions because they are now
available as backend functions (split() and replace() respectively).
Tested under Linux (Red Hat 7.3) and PostgreSQL 7.3devel. This version
is no longer backwards portable to PostgreSQL 7.2.
Release Notes:
Version 0.5
- dblink now supports use directly as a table function; this is the new
preferred usage going forward
- Use of dblink_tok is now deprecated; original form of dblink is also
deprecated. They _will_ be removed in the next version.
- dblink_last_oid is also deprecated; use dblink_exec() which returns
the command status as a single row, single column result.
- Original dblink, dblink_tok, and dblink_last_oid are commented out in
dblink.sql; remove the comments to use the deprecated functions.
- dblink_strtok() and dblink_replace() functions were removed. Use
split() and replace() respectively (new backend functions in
PostgreSQL 7.3) instead.
- New functions: dblink_exec() for non-SELECT queries; dblink_connect()
opens connection that persists for duration of a backend;
dblink_disconnect() closes a persistent connection; dblink_open()
opens a cursor; dblink_fetch() fetches results from an open cursor.
dblink_close() closes a cursor.
- New test suite: dblink_check.sh, dblink.test.sql,
dblink.test.expected.out. Execute dblink_check.sh from the same
directory as the other two files. Output is dblink.test.out and
dblink.test.diff. Note that dblink.test.sql is a good source
of example usage.
Version 0.4
- removed cursor wrap around input sql to allow for remote
@ -59,16 +84,48 @@ Installation:
installs following functions into database template1:
dblink(text,text) RETURNS setof int
- returns a resource id for results from remote query
dblink_tok(int,int) RETURNS text
- extracts and returns individual field results
dblink_strtok(text,text,int) RETURNS text
- extracts and returns individual token from delimited text
connection
------------
dblink_connect(text) RETURNS text
- opens a connection that will persist for duration of current
backend or until it is disconnected
dblink_disconnect() RETURNS text
- disconnects a persistent connection
cursor
------------
dblink_open(text,text) RETURNS text
- opens a cursor using connection already opened with dblink_connect()
that will persist for duration of current backend or until it is
closed
dblink_fetch(text, int) RETURNS setof record
- fetches data from an already opened cursor
dblink_close(text) RETURNS text
- closes a cursor
query
------------
dblink(text,text) RETURNS setof record
- returns a set of results from remote SELECT query
(Note: comment out in dblink.sql to use deprecated version)
dblink(text) RETURNS setof record
- returns a set of results from remote SELECT query, using connection
already opened with dblink_connect()
execute
------------
dblink_exec(text, text) RETURNS text
- executes an INSERT/UPDATE/DELETE query remotely
dblink_exec(text) RETURNS text
- executes an INSERT/UPDATE/DELETE query remotely, using connection
already opened with dblink_connect()
misc
------------
dblink_current_query() RETURNS text
- returns the current query string
dblink_get_pkey(text) RETURNS setof text
- returns the field names of a relation's primary key fields
dblink_last_oid(int) RETURNS oid
- returns the last inserted oid
dblink_build_sql_insert(text,int2vector,int2,_text,_text) RETURNS text
- builds an insert statement using a local tuple, replacing the
selection key field values with alternate supplied values
@ -78,338 +135,30 @@ Installation:
dblink_build_sql_update(text,int2vector,int2,_text,_text) RETURNS text
- builds an update statement using a local tuple, replacing the
selection key field values with alternate supplied values
dblink_current_query() RETURNS text
- returns the current query string
dblink_replace(text,text,text) RETURNS text
- replace all occurences of substring-a in the input-string
with substring-b
Documentation
==================================================================
Name
Not installed by default
deprecated
------------
dblink(text,text) RETURNS setof int
- *DEPRECATED* returns a resource id for results from remote query
(Note: must uncomment in dblink.sql to use)
dblink_tok(int,int) RETURNS text
- *DEPRECATED* extracts and returns individual field results; used
only in conjunction with the *DEPRECATED* form of dblink
(Note: must uncomment in dblink.sql to use)
dblink_last_oid(int) RETURNS oid
- *DEPRECATED* returns the last inserted oid
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');
Documentation:
See the following files:
doc/connection
doc/cursor
doc/query
doc/execute
doc/misc
doc/deprecated
==================================================================
Name
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;
==================================================================
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
dblink_strtok -- Extracts and returns individual token from delimited text
Synopsis
dblink_strtok(text inputstring, text delimiter, int posn) RETURNS text
Inputs
inputstring
any string you want to parse a token out of;
e.g. 'f=1&g=3&h=4'
delimiter
a single character to use as the delimiter;
e.g. '&' or '='
posn
the position of the token of interest, 0 based;
e.g. 1
Outputs
Returns text
Example usage
test=# select dblink_strtok(dblink_strtok('f=1&g=3&h=4','&',1),'=',1);
dblink_strtok
---------------
3
(1 row)
==================================================================
Name
dblink_get_pkey -- returns the field names of a relation's primary
key fields
Synopsis
dblink_get_pkey(text relname) RETURNS setof text
Inputs
relname
any relation name;
e.g. 'foobar'
Outputs
Returns setof text -- one row for each primary key field, in order of
precedence
Example usage
test=# select dblink_get_pkey('foobar');
dblink_get_pkey
-----------------
f1
f2
f3
f4
f5
(5 rows)
==================================================================
Name
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)
==================================================================
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)
==================================================================
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_replace -- replace all occurences of substring-a in the
input-string with substring-b
Synopsis
dblink_replace(text input-string, text substring-a, text substring-b) RETURNS text
Inputs
input-string
the starting string, before replacement of substring-a
substring-a
the substring to find and replace
substring-b
the substring to be substituted in place of substring-a
Outputs
Returns text -- a copy of the starting string, but with all occurences of
substring-a replaced with substring-b
Example usage
test=# select dblink_replace('12345678901234567890','56','hello');
dblink_replace
----------------------------
1234hello78901234hello7890
(1 row)
==================================================================
-- Joe Conway

File diff suppressed because it is too large Load Diff

View File

@ -3,7 +3,9 @@
*
* Functions returning results from a remote database
*
* Copyright (c) Joseph Conway <mail@joeconway.com>, 2001, 2002,
* Joe Conway <mail@joeconway.com>
*
* Copyright (c) 2001, 2002 by PostgreSQL Global Development Group
* ALL RIGHTS RESERVED;
*
* Permission to use, copy, modify, and distribute this software and its
@ -28,38 +30,6 @@
#ifndef DBLINK_H
#define DBLINK_H
#include <string.h>
#include "postgres.h"
#include "libpq-fe.h"
#include "libpq-int.h"
#include "fmgr.h"
#include "access/tupdesc.h"
#include "access/heapam.h"
#include "catalog/catname.h"
#include "catalog/pg_index.h"
#include "catalog/pg_type.h"
#include "executor/executor.h"
#include "executor/spi.h"
#include "lib/stringinfo.h"
#include "nodes/nodes.h"
#include "nodes/execnodes.h"
#include "nodes/pg_list.h"
#include "parser/parse_type.h"
#include "tcop/tcopprot.h"
#include "utils/builtins.h"
#include "utils/fmgroids.h"
#include "utils/array.h"
#include "utils/syscache.h"
#ifdef NamespaceRelationName
#include "catalog/namespace.h"
#endif /* NamespaceRelationName */
/*
* Max SQL statement size
*/
#define DBLINK_MAX_SQLSTATE_SIZE 16384
/*
* This struct holds the results of the remote query.
* Use fn_extra to hold a pointer to it across calls
@ -82,43 +52,27 @@ typedef struct
PGresult *res;
} dblink_results;
/*
* This struct holds results in the form of an array.
* Use fn_extra to hold a pointer to it across calls
*/
typedef struct
{
/*
* elem being accessed
*/
int elem_num;
/*
* number of elems
*/
int num_elems;
/*
* the actual array
*/
void *res;
} dblink_array_results;
/*
* External declarations
*/
/* deprecated */
extern Datum dblink(PG_FUNCTION_ARGS);
extern Datum dblink_tok(PG_FUNCTION_ARGS);
extern Datum dblink_strtok(PG_FUNCTION_ARGS);
/* supported */
extern Datum dblink_connect(PG_FUNCTION_ARGS);
extern Datum dblink_disconnect(PG_FUNCTION_ARGS);
extern Datum dblink_open(PG_FUNCTION_ARGS);
extern Datum dblink_close(PG_FUNCTION_ARGS);
extern Datum dblink_fetch(PG_FUNCTION_ARGS);
extern Datum dblink_record(PG_FUNCTION_ARGS);
extern Datum dblink_exec(PG_FUNCTION_ARGS);
extern Datum dblink_get_pkey(PG_FUNCTION_ARGS);
extern Datum dblink_last_oid(PG_FUNCTION_ARGS);
extern Datum dblink_build_sql_insert(PG_FUNCTION_ARGS);
extern Datum dblink_build_sql_delete(PG_FUNCTION_ARGS);
extern Datum dblink_build_sql_update(PG_FUNCTION_ARGS);
extern Datum dblink_current_query(PG_FUNCTION_ARGS);
extern Datum dblink_replace_text(PG_FUNCTION_ARGS);
extern char *debug_query_string;

View File

@ -1,23 +1,60 @@
CREATE OR REPLACE FUNCTION dblink (text,text) RETURNS setof int
AS 'MODULE_PATHNAME','dblink' LANGUAGE 'c'
-- Uncomment the following 9 lines to use original DEPRECATED functions
--CREATE OR REPLACE FUNCTION dblink (text,text) RETURNS setof int
-- AS 'MODULE_PATHNAME','dblink' LANGUAGE 'c'
-- WITH (isstrict);
--CREATE OR REPLACE FUNCTION dblink_tok (int,int) RETURNS text
-- AS 'MODULE_PATHNAME','dblink_tok' LANGUAGE 'c'
-- WITH (isstrict);
--CREATE OR REPLACE FUNCTION dblink_last_oid (int) RETURNS oid
-- AS 'MODULE_PATHNAME','dblink_last_oid' LANGUAGE 'c'
-- WITH (isstrict);
CREATE OR REPLACE FUNCTION dblink_connect (text) RETURNS text
AS 'MODULE_PATHNAME','dblink_connect' LANGUAGE 'c'
WITH (isstrict);
CREATE OR REPLACE FUNCTION dblink_tok (int,int) RETURNS text
AS 'MODULE_PATHNAME','dblink_tok' LANGUAGE 'c'
CREATE OR REPLACE FUNCTION dblink_disconnect () RETURNS text
AS 'MODULE_PATHNAME','dblink_disconnect' LANGUAGE 'c'
WITH (isstrict);
CREATE OR REPLACE FUNCTION dblink_strtok (text,text,int) RETURNS text
AS 'MODULE_PATHNAME','dblink_strtok' LANGUAGE 'c'
WITH (iscachable, isstrict);
CREATE OR REPLACE FUNCTION dblink_open (text,text) RETURNS text
AS 'MODULE_PATHNAME','dblink_open' LANGUAGE 'c'
WITH (isstrict);
CREATE OR REPLACE FUNCTION dblink_get_pkey (text) RETURNS setof text
CREATE OR REPLACE FUNCTION dblink_fetch (text,int) RETURNS setof record
AS 'MODULE_PATHNAME','dblink_fetch' LANGUAGE 'c'
WITH (isstrict);
CREATE OR REPLACE FUNCTION dblink_close (text) RETURNS text
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);
CREATE OR REPLACE FUNCTION dblink (text) RETURNS setof record
AS 'MODULE_PATHNAME','dblink_record' LANGUAGE 'c'
WITH (isstrict);
CREATE OR REPLACE FUNCTION dblink_exec (text,text) RETURNS text
AS 'MODULE_PATHNAME','dblink_exec' LANGUAGE 'c'
WITH (isstrict);
CREATE OR REPLACE FUNCTION dblink_exec (text) RETURNS text
AS 'MODULE_PATHNAME','dblink_exec' LANGUAGE 'c'
WITH (isstrict);
CREATE TYPE dblink_pkey_results AS (position int4, colname text);
CREATE OR REPLACE FUNCTION dblink_get_pkey (text) RETURNS setof dblink_pkey_results
AS 'MODULE_PATHNAME','dblink_get_pkey' LANGUAGE 'c'
WITH (isstrict);
CREATE OR REPLACE FUNCTION dblink_last_oid (int) RETURNS oid
AS 'MODULE_PATHNAME','dblink_last_oid' LANGUAGE 'c'
WITH (isstrict);
CREATE OR REPLACE FUNCTION dblink_build_sql_insert (text, int2vector, int2, _text, _text) RETURNS text
AS 'MODULE_PATHNAME','dblink_build_sql_insert' LANGUAGE 'c'
WITH (isstrict);
@ -32,7 +69,3 @@ CREATE OR REPLACE FUNCTION dblink_build_sql_update (text, int2vector, int2, _tex
CREATE OR REPLACE FUNCTION dblink_current_query () RETURNS text
AS 'MODULE_PATHNAME','dblink_current_query' LANGUAGE 'c';
CREATE OR REPLACE FUNCTION dblink_replace (text,text,text) RETURNS text
AS 'MODULE_PATHNAME','dblink_replace_text' LANGUAGE 'c'
WITH (iscachable, isstrict);