*
*/
-Version 0.6 (14 June, 2003):
- Completely removed previously deprecated functions. Added ability
- to create "named" persistent connections in addition to the single global
- "unnamed" persistent connection.
- Tested under Linux (Red Hat 9) and PostgreSQL 7.4devel.
-
Release Notes:
+ Version 0.7 (as of 25 Feb, 2004)
+ - Added new version of dblink, dblink_exec, dblink_open, dblink_close,
+ and, dblink_fetch -- allows ERROR on remote side of connection to
+ throw NOTICE locally instead of ERROR
Version 0.6
- functions deprecated in 0.5 have been removed
- added ability to create "named" persistent connections
You can use dblink.sql to create the functions in your database of choice, e.g.
- psql -U postgres template1 < dblink.sql
+ psql template1 < dblink.sql
installs following functions into database template1:
cursor
------------
- dblink_open(text,text) RETURNS text
+ dblink_open(text,text [, bool fail_on_error]) RETURNS text
- opens a cursor using unnamed connection already opened with
dblink_connect() that will persist for duration of current backend
or until it is closed
- dblink_open(text,text,text) RETURNS text
+ dblink_open(text,text,text [, bool fail_on_error]) RETURNS text
- opens a cursor using a named 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
+ dblink_fetch(text, int [, bool fail_on_error]) RETURNS setof record
- fetches data from an already opened cursor on the unnamed connection
- dblink_fetch(text, text, int) RETURNS setof record
+ dblink_fetch(text, text, int [, bool fail_on_error]) RETURNS setof record
- fetches data from an already opened cursor on a named connection
- dblink_close(text) RETURNS text
+ dblink_close(text [, bool fail_on_error]) RETURNS text
- closes a cursor on the unnamed connection
- dblink_close(text,text) RETURNS text
+ dblink_close(text,text [, bool fail_on_error]) RETURNS text
- closes a cursor on a named connection
query
------------
- dblink(text,text) RETURNS setof record
+ dblink(text,text [, bool fail_on_error]) RETURNS setof record
- returns a set of results from remote SELECT query; the first argument
is either a connection string, or the name of an already opened
persistant connection
- dblink(text) RETURNS setof record
+ dblink(text [, bool fail_on_error]) RETURNS setof record
- returns a set of results from remote SELECT query, using the unnamed
connection already opened with dblink_connect()
execute
------------
- dblink_exec(text, text) RETURNS text
+ dblink_exec(text, text [, bool fail_on_error]) RETURNS text
- executes an INSERT/UPDATE/DELETE query remotely; the first argument
is either a connection string, or the name of an already opened
persistant connection
- dblink_exec(text) RETURNS text
+ dblink_exec(text [, bool fail_on_error]) RETURNS text
- executes an INSERT/UPDATE/DELETE query remotely, using connection
already opened with dblink_connect()
doc/query
doc/execute
doc/misc
- doc/deprecated
==================================================================
-- Joe Conway
errmsg("%s", p2), \
errdetail("%s", msg))); \
} while (0)
+#define DBLINK_RES_ERROR_AS_NOTICE(p2) \
+ do { \
+ msg = pstrdup(PQerrorMessage(conn)); \
+ if (res) \
+ PQclear(res); \
+ ereport(NOTICE, \
+ (errcode(ERRCODE_SYNTAX_ERROR), \
+ errmsg("%s", p2), \
+ errdetail("%s", msg))); \
+ } while (0)
#define DBLINK_CONN_NOT_AVAIL \
do { \
if(conname) \
if(rcon) \
{ \
conn = rcon->con; \
- freeconn = false; \
} \
else \
{ \
errmsg("could not establish connection"), \
errdetail("%s", msg))); \
} \
+ freeconn = true; \
} \
} while (0)
char *conname = NULL;
StringInfo str = makeStringInfo();
remoteConn *rcon = NULL;
+ bool fail = true; /* default to backward compatible behavior */
if (PG_NARGS() == 2)
{
+ /* text,text */
curname = GET_STR(PG_GETARG_TEXT_P(0));
sql = GET_STR(PG_GETARG_TEXT_P(1));
conn = persistent_conn;
}
else if (PG_NARGS() == 3)
{
+ /* might be text,text,text or text,text,bool */
+ if (get_fn_expr_argtype(fcinfo->flinfo, 2) == BOOLOID)
+ {
+ curname = GET_STR(PG_GETARG_TEXT_P(0));
+ sql = GET_STR(PG_GETARG_TEXT_P(1));
+ fail = PG_GETARG_BOOL(2);
+ conn = persistent_conn;
+ }
+ else
+ {
+ conname = GET_STR(PG_GETARG_TEXT_P(0));
+ curname = GET_STR(PG_GETARG_TEXT_P(1));
+ sql = GET_STR(PG_GETARG_TEXT_P(2));
+ }
+ rcon = getConnectionByName(conname);
+ if (rcon)
+ conn = rcon->con;
+ }
+ else if (PG_NARGS() == 4)
+ {
+ /* text,text,text,bool */
conname = GET_STR(PG_GETARG_TEXT_P(0));
curname = GET_STR(PG_GETARG_TEXT_P(1));
sql = GET_STR(PG_GETARG_TEXT_P(2));
+ fail = PG_GETARG_BOOL(3);
rcon = getConnectionByName(conname);
if (rcon)
conn = rcon->con;
appendStringInfo(str, "DECLARE %s CURSOR FOR %s", curname, sql);
res = PQexec(conn, str->data);
- if (!res ||
- (PQresultStatus(res) != PGRES_COMMAND_OK &&
- PQresultStatus(res) != PGRES_TUPLES_OK))
- DBLINK_RES_ERROR("sql error");
+ if (!res || PQresultStatus(res) != PGRES_COMMAND_OK)
+ {
+ if (fail)
+ DBLINK_RES_ERROR("sql error");
+ else
+ {
+ DBLINK_RES_ERROR_AS_NOTICE("sql error");
+ PQclear(res);
+ PG_RETURN_TEXT_P(GET_TEXT("ERROR"));
+ }
+ }
PQclear(res);
-
PG_RETURN_TEXT_P(GET_TEXT("OK"));
}
StringInfo str = makeStringInfo();
char *msg;
remoteConn *rcon = NULL;
+ bool fail = true; /* default to backward compatible behavior */
if (PG_NARGS() == 1)
{
+ /* text */
curname = GET_STR(PG_GETARG_TEXT_P(0));
conn = persistent_conn;
}
else if (PG_NARGS() == 2)
{
+ /* might be text,text or text,bool */
+ if (get_fn_expr_argtype(fcinfo->flinfo, 1) == BOOLOID)
+ {
+ curname = GET_STR(PG_GETARG_TEXT_P(0));
+ fail = PG_GETARG_BOOL(1);
+ conn = persistent_conn;
+ }
+ else
+ {
+ conname = GET_STR(PG_GETARG_TEXT_P(0));
+ curname = GET_STR(PG_GETARG_TEXT_P(1));
+ rcon = getConnectionByName(conname);
+ if (rcon)
+ conn = rcon->con;
+ }
+ }
+ if (PG_NARGS() == 3)
+ {
+ /* text,text,bool */
conname = GET_STR(PG_GETARG_TEXT_P(0));
curname = GET_STR(PG_GETARG_TEXT_P(1));
+ fail = PG_GETARG_BOOL(2);
rcon = getConnectionByName(conname);
if (rcon)
conn = rcon->con;
/* close the cursor */
res = PQexec(conn, str->data);
if (!res || PQresultStatus(res) != PGRES_COMMAND_OK)
- DBLINK_RES_ERROR("sql error");
+ {
+ if (fail)
+ DBLINK_RES_ERROR("sql error");
+ else
+ {
+ DBLINK_RES_ERROR_AS_NOTICE("sql error");
+ PQclear(res);
+ PG_RETURN_TEXT_P(GET_TEXT("ERROR"));
+ }
+ }
PQclear(res);
char *curname = NULL;
int howmany = 0;
ReturnSetInfo *rsinfo = (ReturnSetInfo *) fcinfo->resultinfo;
+ bool fail = true; /* default to backward compatible */
- if (PG_NARGS() == 3)
+ if (PG_NARGS() == 4)
{
+ /* text,text,int,bool */
conname = GET_STR(PG_GETARG_TEXT_P(0));
curname = GET_STR(PG_GETARG_TEXT_P(1));
howmany = PG_GETARG_INT32(2);
+ fail = PG_GETARG_BOOL(3);
rcon = getConnectionByName(conname);
if (rcon)
conn = rcon->con;
}
+ else if (PG_NARGS() == 3)
+ {
+ /* text,text,int or text,int,bool */
+ if (get_fn_expr_argtype(fcinfo->flinfo, 2) == BOOLOID)
+ {
+ curname = GET_STR(PG_GETARG_TEXT_P(0));
+ howmany = PG_GETARG_INT32(1);
+ fail = PG_GETARG_BOOL(2);
+ conn = persistent_conn;
+ }
+ else
+ {
+ conname = GET_STR(PG_GETARG_TEXT_P(0));
+ curname = GET_STR(PG_GETARG_TEXT_P(1));
+ howmany = PG_GETARG_INT32(2);
+
+ rcon = getConnectionByName(conname);
+ if (rcon)
+ conn = rcon->con;
+ }
+ }
else if (PG_NARGS() == 2)
{
+ /* text,int */
curname = GET_STR(PG_GETARG_TEXT_P(0));
howmany = PG_GETARG_INT32(1);
conn = persistent_conn;
if (!res ||
(PQresultStatus(res) != PGRES_COMMAND_OK &&
PQresultStatus(res) != PGRES_TUPLES_OK))
- DBLINK_RES_ERROR("sql error");
+ {
+ if (fail)
+ DBLINK_RES_ERROR("sql error");
+ else
+ {
+ if (res)
+ PQclear(res);
+ DBLINK_RES_ERROR_AS_NOTICE("sql error");
+ SRF_RETURN_DONE(funcctx);
+ }
+ }
else if (PQresultStatus(res) == PGRES_COMMAND_OK)
{
/* cursor does not exist - closed already or bad name */
/* fast track when no results */
if (funcctx->max_calls < 1)
+ {
+ if (res)
+ PQclear(res);
SRF_RETURN_DONE(funcctx);
+ }
/* check typtype to see if we have a predetermined return type */
functypeid = get_func_rettype(funcid);
bool is_sql_cmd = false;
char *sql_cmd_status = NULL;
MemoryContext oldcontext;
- bool freeconn = true;
+ bool freeconn = false;
/* stuff done only on the first call of the function */
if (SRF_IS_FIRSTCALL())
char *conname = NULL;
remoteConn *rcon = NULL;
ReturnSetInfo *rsinfo = (ReturnSetInfo *) fcinfo->resultinfo;
+ bool fail = true; /* default to backward compatible */
/* create a function context for cross-call persistence */
funcctx = SRF_FIRSTCALL_INIT();
*/
oldcontext = MemoryContextSwitchTo(funcctx->multi_call_memory_ctx);
- if (PG_NARGS() == 2)
+ if (PG_NARGS() == 3)
{
+ /* text,text,bool */
DBLINK_GET_CONN;
sql = GET_STR(PG_GETARG_TEXT_P(1));
+ fail = PG_GETARG_BOOL(2);
+ }
+ else if (PG_NARGS() == 2)
+ {
+ /* text,text or text,bool */
+ if (get_fn_expr_argtype(fcinfo->flinfo, 1) == BOOLOID)
+ {
+ conn = persistent_conn;
+ sql = GET_STR(PG_GETARG_TEXT_P(0));
+ fail = PG_GETARG_BOOL(1);
+ }
+ else
+ {
+ DBLINK_GET_CONN;
+ sql = GET_STR(PG_GETARG_TEXT_P(1));
+ }
}
else if (PG_NARGS() == 1)
{
+ /* text */
conn = persistent_conn;
sql = GET_STR(PG_GETARG_TEXT_P(0));
}
DBLINK_CONN_NOT_AVAIL;
res = PQexec(conn, sql);
- if (!res || (PQresultStatus(res) != PGRES_COMMAND_OK && PQresultStatus(res) != PGRES_TUPLES_OK))
- DBLINK_RES_ERROR("sql error");
+ if (!res ||
+ (PQresultStatus(res) != PGRES_COMMAND_OK &&
+ PQresultStatus(res) != PGRES_TUPLES_OK))
+ {
+ if (fail)
+ DBLINK_RES_ERROR("sql error");
+ else
+ {
+ if (res)
+ PQclear(res);
+ if (freeconn)
+ PQfinish(conn);
+ DBLINK_RES_ERROR_AS_NOTICE("sql error");
+ SRF_RETURN_DONE(funcctx);
+ }
+ }
if (PQresultStatus(res) == PGRES_COMMAND_OK)
{
funcctx->user_fctx = res;
/* if needed, close the connection to the database and cleanup */
- if (freeconn && PG_NARGS() == 2)
+ if (freeconn)
PQfinish(conn);
/* fast track when no results */
if (funcctx->max_calls < 1)
+ {
+ if (res)
+ PQclear(res);
SRF_RETURN_DONE(funcctx);
+ }
/* check typtype to see if we have a predetermined return type */
functypeid = get_func_rettype(funcid);
char *sql = NULL;
char *conname = NULL;
remoteConn *rcon = NULL;
- bool freeconn = true;
+ bool freeconn = false;
+ bool fail = true; /* default to backward compatible behavior */
- if (PG_NARGS() == 2)
+ if (PG_NARGS() == 3)
{
+ /* must be text,text,bool */
DBLINK_GET_CONN;
sql = GET_STR(PG_GETARG_TEXT_P(1));
+ fail = PG_GETARG_BOOL(2);
+ }
+ else if (PG_NARGS() == 2)
+ {
+ /* might be text,text or text,bool */
+ if (get_fn_expr_argtype(fcinfo->flinfo, 1) == BOOLOID)
+ {
+ conn = persistent_conn;
+ sql = GET_STR(PG_GETARG_TEXT_P(0));
+ fail = PG_GETARG_BOOL(1);
+ }
+ else
+ {
+ DBLINK_GET_CONN;
+ sql = GET_STR(PG_GETARG_TEXT_P(1));
+ }
}
else if (PG_NARGS() == 1)
{
+ /* must be single text argument */
conn = persistent_conn;
sql = GET_STR(PG_GETARG_TEXT_P(0));
}
if (!res ||
(PQresultStatus(res) != PGRES_COMMAND_OK &&
PQresultStatus(res) != PGRES_TUPLES_OK))
- DBLINK_RES_ERROR("sql error");
+ {
+ if (fail)
+ DBLINK_RES_ERROR("sql error");
+ else
+ DBLINK_RES_ERROR_AS_NOTICE("sql error");
- if (PQresultStatus(res) == PGRES_COMMAND_OK)
+ /* need a tuple descriptor representing one TEXT column */
+ tupdesc = CreateTemplateTupleDesc(1, false);
+ TupleDescInitEntry(tupdesc, (AttrNumber) 1, "status",
+ TEXTOID, -1, 0, false);
+
+ /*
+ * and save a copy of the command status string to return as our
+ * result tuple
+ */
+ sql_cmd_status = GET_TEXT("ERROR");
+
+ }
+ else if (PQresultStatus(res) == PGRES_COMMAND_OK)
{
/* need a tuple descriptor representing one TEXT column */
tupdesc = CreateTemplateTupleDesc(1, false);
PQclear(res);
/* if needed, close the connection to the database and cleanup */
- if (freeconn && fcinfo->nargs == 2)
+ if (freeconn)
PQfinish(conn);
PG_RETURN_TEXT_P(sql_cmd_status);
CREATE OR REPLACE FUNCTION dblink_connect (text)
RETURNS text
AS 'MODULE_PATHNAME','dblink_connect'
-LANGUAGE 'C' WITH (isstrict);
+LANGUAGE 'C' STRICT;
CREATE OR REPLACE FUNCTION dblink_connect (text, text)
RETURNS text
AS 'MODULE_PATHNAME','dblink_connect'
-LANGUAGE 'C' WITH (isstrict);
+LANGUAGE 'C' STRICT;
CREATE OR REPLACE FUNCTION dblink_disconnect ()
RETURNS text
AS 'MODULE_PATHNAME','dblink_disconnect'
-LANGUAGE 'C' WITH (isstrict);
+LANGUAGE 'C' STRICT;
CREATE OR REPLACE FUNCTION dblink_disconnect (text)
RETURNS text
AS 'MODULE_PATHNAME','dblink_disconnect'
-LANGUAGE 'C' WITH (isstrict);
+LANGUAGE 'C' STRICT;
CREATE OR REPLACE FUNCTION dblink_open (text,text)
RETURNS text
AS 'MODULE_PATHNAME','dblink_open'
-LANGUAGE 'C' WITH (isstrict);
+LANGUAGE 'C' STRICT;
+
+CREATE OR REPLACE FUNCTION dblink_open (text,text,bool)
+RETURNS text
+AS 'MODULE_PATHNAME','dblink_open'
+LANGUAGE 'C' STRICT;
CREATE OR REPLACE FUNCTION dblink_open (text,text,text)
RETURNS text
AS 'MODULE_PATHNAME','dblink_open'
-LANGUAGE 'C' WITH (isstrict);
+LANGUAGE 'C' STRICT;
+
+CREATE OR REPLACE FUNCTION dblink_open (text,text,text,bool)
+RETURNS text
+AS 'MODULE_PATHNAME','dblink_open'
+LANGUAGE 'C' STRICT;
CREATE OR REPLACE FUNCTION dblink_fetch (text,int)
RETURNS setof record
AS 'MODULE_PATHNAME','dblink_fetch'
-LANGUAGE 'C' WITH (isstrict);
+LANGUAGE 'C' STRICT;
+
+CREATE OR REPLACE FUNCTION dblink_fetch (text,int,bool)
+RETURNS setof record
+AS 'MODULE_PATHNAME','dblink_fetch'
+LANGUAGE 'C' STRICT;
CREATE OR REPLACE FUNCTION dblink_fetch (text,text,int)
RETURNS setof record
AS 'MODULE_PATHNAME','dblink_fetch'
-LANGUAGE 'C' WITH (isstrict);
+LANGUAGE 'C' STRICT;
+
+CREATE OR REPLACE FUNCTION dblink_fetch (text,text,int,bool)
+RETURNS setof record
+AS 'MODULE_PATHNAME','dblink_fetch'
+LANGUAGE 'C' STRICT;
CREATE OR REPLACE FUNCTION dblink_close (text)
RETURNS text
AS 'MODULE_PATHNAME','dblink_close'
-LANGUAGE 'C' WITH (isstrict);
+LANGUAGE 'C' STRICT;
+
+CREATE OR REPLACE FUNCTION dblink_close (text,bool)
+RETURNS text
+AS 'MODULE_PATHNAME','dblink_close'
+LANGUAGE 'C' STRICT;
CREATE OR REPLACE FUNCTION dblink_close (text,text)
RETURNS text
AS 'MODULE_PATHNAME','dblink_close'
-LANGUAGE 'C' WITH (isstrict);
+LANGUAGE 'C' STRICT;
+
+CREATE OR REPLACE FUNCTION dblink_close (text,text,bool)
+RETURNS text
+AS 'MODULE_PATHNAME','dblink_close'
+LANGUAGE 'C' STRICT;
CREATE OR REPLACE FUNCTION dblink (text,text)
RETURNS setof record
AS 'MODULE_PATHNAME','dblink_record'
-LANGUAGE 'C' WITH (isstrict);
+LANGUAGE 'C' STRICT;
+
+CREATE OR REPLACE FUNCTION dblink (text,text,bool)
+RETURNS setof record
+AS 'MODULE_PATHNAME','dblink_record'
+LANGUAGE 'C' STRICT;
CREATE OR REPLACE FUNCTION dblink (text)
RETURNS setof record
AS 'MODULE_PATHNAME','dblink_record'
-LANGUAGE 'C' WITH (isstrict);
+LANGUAGE 'C' STRICT;
+
+CREATE OR REPLACE FUNCTION dblink (text,bool)
+RETURNS setof record
+AS 'MODULE_PATHNAME','dblink_record'
+LANGUAGE 'C' STRICT;
CREATE OR REPLACE FUNCTION dblink_exec (text,text)
RETURNS text
AS 'MODULE_PATHNAME','dblink_exec'
-LANGUAGE 'C' WITH (isstrict);
+LANGUAGE 'C' STRICT;
+
+CREATE OR REPLACE FUNCTION dblink_exec (text,text,bool)
+RETURNS text
+AS 'MODULE_PATHNAME','dblink_exec'
+LANGUAGE 'C' STRICT;
CREATE OR REPLACE FUNCTION dblink_exec (text)
RETURNS text
AS 'MODULE_PATHNAME','dblink_exec'
-LANGUAGE 'c' WITH (isstrict);
+LANGUAGE 'c' STRICT;
+
+CREATE OR REPLACE FUNCTION dblink_exec (text,bool)
+RETURNS text
+AS 'MODULE_PATHNAME','dblink_exec'
+LANGUAGE 'c' STRICT;
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);
+LANGUAGE 'c' STRICT;
CREATE OR REPLACE FUNCTION dblink_build_sql_insert (text, int2vector, int4, _text, _text)
RETURNS text
AS 'MODULE_PATHNAME','dblink_build_sql_insert'
-LANGUAGE 'C' WITH (isstrict);
+LANGUAGE 'C' STRICT;
CREATE OR REPLACE FUNCTION dblink_build_sql_delete (text, int2vector, int4, _text)
RETURNS text
AS 'MODULE_PATHNAME','dblink_build_sql_delete'
-LANGUAGE 'C' WITH (isstrict);
+LANGUAGE 'C' STRICT;
CREATE OR REPLACE FUNCTION dblink_build_sql_update (text, int2vector, int4, _text, _text)
RETURNS text
AS 'MODULE_PATHNAME','dblink_build_sql_update'
-LANGUAGE 'C' WITH (isstrict);
+LANGUAGE 'C' STRICT;
CREATE OR REPLACE FUNCTION dblink_current_query ()
RETURNS text
Synopsis
-dblink_open(text cursorname, text sql)
-dblink_open(text connname, text cursorname, text sql)
+dblink_open(text cursorname, text sql [, bool fail_on_error])
+dblink_open(text connname, text cursorname, text sql [, bool fail_on_error])
Inputs
sql statement that you wish to execute on the remote host
e.g. "select * from pg_class"
+ fail_on_error
+
+ If true (default when not present) then an ERROR thrown on the remote side
+ of the connection causes an ERROR to also be thrown locally. If false, the
+ remote ERROR is locally treated as a NOTICE, and the return value is set
+ to 'ERROR'.
+
Outputs
Returns status = "OK"
Synopsis
-dblink_fetch(text cursorname, int32 howmany)
-dblink_fetch(text connname, text cursorname, int32 howmany)
+dblink_fetch(text cursorname, int32 howmany [, bool fail_on_error])
+dblink_fetch(text connname, text cursorname, int32 howmany [, bool fail_on_error])
Inputs
starting at the current cursor position, moving forward. Once the cursor
has positioned to the end, no more rows are produced.
+ fail_on_error
+
+ If true (default when not present) then an ERROR thrown on the remote side
+ of the connection causes an ERROR to also be thrown locally. If false, the
+ remote ERROR is locally treated as a NOTICE, and no rows are returned.
+
Outputs
Returns setof record
Synopsis
-dblink_close(text cursorname)
-dblink_close(text connname, text cursorname)
+dblink_close(text cursorname [, bool fail_on_error])
+dblink_close(text connname, text cursorname [, bool fail_on_error])
Inputs
a reference name for the cursor
+ fail_on_error
+
+ If true (default when not present) then an ERROR thrown on the remote side
+ of the connection causes an ERROR to also be thrown locally. If false, the
+ remote ERROR is locally treated as a NOTICE, and the return value is set
+ to 'ERROR'.
+
Outputs
Returns status = "OK"
+++ /dev/null
-==================================================================
-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)
-
Synopsis
-dblink_exec(text connstr, text sql)
-dblink_exec(text connname, text sql)
-dblink_exec(text sql)
+dblink_exec(text connstr, text sql [, bool fail_on_error])
+dblink_exec(text connname, text sql [, bool fail_on_error])
+dblink_exec(text sql [, bool fail_on_error])
Inputs
connname
connstr
+
If two arguments are present, the first is first assumed to be a specific
connection name to use. If the name is not found, the argument is then
assumed to be a valid connection string, of standard libpq format,
sql statement that you wish to execute on the remote host, e.g.:
insert into foo values(0,'a','{"a0","b0","c0"}');
+ fail_on_error
+
+ If true (default when not present) then an ERROR thrown on the remote side
+ of the connection causes an ERROR to also be thrown locally. If false, the
+ remote ERROR is locally treated as a NOTICE, and the return value is set
+ to 'ERROR'.
+
Outputs
- Returns status of the command
+ Returns status of the command, or 'ERROR' if the command failed.
Notes
1) dblink_open starts an explicit transaction. If, after using dblink_open,
------------------
INSERT 6432584 1
(1 row)
+
+select dblink_exec('myconn','insert into pg_class values (''foo'')',false);
+NOTICE: sql error
+DETAIL: ERROR: null value in column "relnamespace" violates not-null constraint
+
+ dblink_exec
+-------------
+ ERROR
+(1 row)
Synopsis
-dblink(text connstr, text sql)
-dblink(text connname, text sql)
-dblink(text sql)
+dblink(text connstr, text sql [, bool fail_on_error])
+dblink(text connname, text sql [, bool fail_on_error])
+dblink(text sql [, bool fail_on_error])
Inputs
sql statement that you wish to execute on the remote host
e.g. "select * from pg_class"
+ fail_on_error
+
+ If true (default when not present) then an ERROR thrown on the remote side
+ of the connection causes an ERROR to also be thrown locally. If false, the
+ remote ERROR is locally treated as a NOTICE, and no rows are returned.
+
Outputs
Returns setof record
9 | j | {a9,b9,c9}
(2 rows)
+-- open a cursor with bad SQL and fail_on_error set to false
+SELECT dblink_open('rmt_foo_cursor','SELECT * FROM foobar',false);
+NOTICE: sql error
+DETAIL: ERROR: relation "foobar" does not exist
+
+ dblink_open
+-------------
+ ERROR
+(1 row)
+
+-- reset remote transaction state
+SELECT dblink_exec('ABORT');
+ dblink_exec
+-------------
+ ROLLBACK
+(1 row)
+
-- open a cursor
SELECT dblink_open('rmt_foo_cursor','SELECT * FROM foo');
dblink_open
OK
(1 row)
+-- close the cursor
+SELECT dblink_close('rmt_foo_cursor',false);
+ dblink_close
+--------------
+ OK
+(1 row)
+
+-- open the cursor again
+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[]);
9 | j | {a9,b9,c9}
(2 rows)
--- close the cursor
-SELECT dblink_close('rmt_foo_cursor');
+-- intentionally botch a fetch
+SELECT *
+FROM dblink_fetch('rmt_foobar_cursor',4,false) AS t(a int, b text, c text[]);
+NOTICE: sql error
+DETAIL: ERROR: cursor "rmt_foobar_cursor" does not exist
+
+ a | b | c
+---+---+---
+(0 rows)
+
+-- reset remote transaction state
+SELECT dblink_exec('ABORT');
+ dblink_exec
+-------------
+ ROLLBACK
+(1 row)
+
+-- close the wrong cursor
+SELECT dblink_close('rmt_foobar_cursor',false);
+NOTICE: sql error
+DETAIL: ERROR: cursor "rmt_foobar_cursor" does not exist
+
dblink_close
--------------
- OK
+ ERROR
+(1 row)
+
+-- reset remote transaction state
+SELECT dblink_exec('ABORT');
+ dblink_exec
+-------------
+ ROLLBACK
(1 row)
-- should generate 'cursor "rmt_foo_cursor" not found' error
ERROR: sql error
DETAIL: ERROR: cursor "rmt_foo_cursor" does not exist
+-- this time, 'cursor "rmt_foo_cursor" not found' as a notice
+SELECT *
+FROM dblink_fetch('rmt_foo_cursor',4,false) AS t(a int, b text, c text[]);
+NOTICE: sql error
+DETAIL: ERROR: cursor "rmt_foo_cursor" does not exist
+
+ a | b | c
+---+---+---
+(0 rows)
+
-- close the persistent connection
SELECT dblink_disconnect();
dblink_disconnect
11 | l | {a11,b11,c11}
(12 rows)
+-- bad remote select
+SELECT *
+FROM dblink('SELECT * FROM foobar',false) AS t(a int, b text, c text[]);
+NOTICE: sql error
+DETAIL: ERROR: relation "foobar" does not exist
+
+ a | b | c
+---+---+---
+(0 rows)
+
+-- reset remote transaction state
+SELECT dblink_exec('ABORT');
+ dblink_exec
+-------------
+ ROLLBACK
+(1 row)
+
-- change some data
SELECT dblink_exec('UPDATE foo SET f3[2] = ''b99'' WHERE f1 = 11');
dblink_exec
11 | l | {a11,b99,c11}
(1 row)
+-- botch a change to some other data
+SELECT dblink_exec('UPDATE foobar SET f3[2] = ''b99'' WHERE f1 = 11',false);
+NOTICE: sql error
+DETAIL: ERROR: relation "foobar" does not exist
+
+ dblink_exec
+-------------
+ ERROR
+(1 row)
+
+-- reset remote transaction state
+SELECT dblink_exec('ABORT');
+ dblink_exec
+-------------
+ ROLLBACK
+(1 row)
+
-- delete some data
SELECT dblink_exec('DELETE FROM foo WHERE f1 = 11');
dblink_exec
10 | k | {a10,b10,c10}
(3 rows)
+-- use the named persistent connection, but get it wrong
+SELECT *
+FROM dblink('myconn','SELECT * FROM foobar',false) AS t(a int, b text, c text[])
+WHERE t.a > 7;
+NOTICE: sql error
+DETAIL: ERROR: relation "foobar" does not exist
+
+ a | b | c
+---+---+---
+(0 rows)
+
+-- reset remote transaction state
+SELECT dblink_exec('myconn','ABORT');
+ dblink_exec
+-------------
+ ROLLBACK
+(1 row)
+
-- create a second named persistent connection
-- should error with "duplicate connection name"
SELECT dblink_connect('myconn','dbname=regression');
OK
(1 row)
+-- open a cursor incorrectly
+SELECT dblink_open('myconn','rmt_foo_cursor','SELECT * FROM foobar',false);
+NOTICE: sql error
+DETAIL: ERROR: relation "foobar" does not exist
+
+ dblink_open
+-------------
+ ERROR
+(1 row)
+
+-- reset remote transaction state
+SELECT dblink_exec('myconn','ABORT');
+ dblink_exec
+-------------
+ ROLLBACK
+(1 row)
+
-- open a cursor
SELECT dblink_open('myconn','rmt_foo_cursor','SELECT * FROM foo');
dblink_open
10 | k | {a10,b10,c10}
(3 rows)
--- close the cursor
-SELECT dblink_close('myconn','rmt_foo_cursor');
- dblink_close
---------------
- OK
+-- fetch some data incorrectly
+SELECT *
+FROM dblink_fetch('myconn','rmt_foobar_cursor',4,false) AS t(a int, b text, c text[]);
+NOTICE: sql error
+DETAIL: ERROR: cursor "rmt_foobar_cursor" does not exist
+
+ a | b | c
+---+---+---
+(0 rows)
+
+-- reset remote transaction state
+SELECT dblink_exec('myconn','ABORT');
+ dblink_exec
+-------------
+ ROLLBACK
(1 row)
-- should generate 'cursor "rmt_foo_cursor" not found' error
FROM dblink('SELECT * FROM foo') AS t(a int, b text, c text[])
WHERE t.a > 7;
+-- open a cursor with bad SQL and fail_on_error set to false
+SELECT dblink_open('rmt_foo_cursor','SELECT * FROM foobar',false);
+
+-- reset remote transaction state
+SELECT dblink_exec('ABORT');
+
-- open a cursor
SELECT dblink_open('rmt_foo_cursor','SELECT * FROM foo');
+-- close the cursor
+SELECT dblink_close('rmt_foo_cursor',false);
+
+-- open the cursor again
+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[]);
--- close the cursor
-SELECT dblink_close('rmt_foo_cursor');
+-- intentionally botch a fetch
+SELECT *
+FROM dblink_fetch('rmt_foobar_cursor',4,false) AS t(a int, b text, c text[]);
+
+-- reset remote transaction state
+SELECT dblink_exec('ABORT');
+
+-- close the wrong cursor
+SELECT dblink_close('rmt_foobar_cursor',false);
+
+-- reset remote transaction state
+SELECT dblink_exec('ABORT');
-- should generate 'cursor "rmt_foo_cursor" not found' error
SELECT *
FROM dblink_fetch('rmt_foo_cursor',4) AS t(a int, b text, c text[]);
+-- this time, 'cursor "rmt_foo_cursor" not found' as a notice
+SELECT *
+FROM dblink_fetch('rmt_foo_cursor',4,false) AS t(a int, b text, c text[]);
+
-- close the persistent connection
SELECT dblink_disconnect();
SELECT *
FROM dblink('SELECT * FROM foo') AS t(a int, b text, c text[]);
+-- bad remote select
+SELECT *
+FROM dblink('SELECT * FROM foobar',false) AS t(a int, b text, c text[]);
+
+-- reset remote transaction state
+SELECT dblink_exec('ABORT');
+
-- change some data
SELECT dblink_exec('UPDATE foo SET f3[2] = ''b99'' WHERE f1 = 11');
FROM dblink('SELECT * FROM foo') AS t(a int, b text, c text[])
WHERE a = 11;
+-- botch a change to some other data
+SELECT dblink_exec('UPDATE foobar SET f3[2] = ''b99'' WHERE f1 = 11',false);
+
+-- reset remote transaction state
+SELECT dblink_exec('ABORT');
+
-- delete some data
SELECT dblink_exec('DELETE FROM foo WHERE f1 = 11');
FROM dblink('myconn','SELECT * FROM foo') AS t(a int, b text, c text[])
WHERE t.a > 7;
+-- use the named persistent connection, but get it wrong
+SELECT *
+FROM dblink('myconn','SELECT * FROM foobar',false) AS t(a int, b text, c text[])
+WHERE t.a > 7;
+
+-- reset remote transaction state
+SELECT dblink_exec('myconn','ABORT');
+
-- create a second named persistent connection
-- should error with "duplicate connection name"
SELECT dblink_connect('myconn','dbname=regression');
-- close the second named persistent connection
SELECT dblink_disconnect('myconn2');
+-- open a cursor incorrectly
+SELECT dblink_open('myconn','rmt_foo_cursor','SELECT * FROM foobar',false);
+
+-- reset remote transaction state
+SELECT dblink_exec('myconn','ABORT');
+
-- open a cursor
SELECT dblink_open('myconn','rmt_foo_cursor','SELECT * FROM foo');
SELECT *
FROM dblink_fetch('myconn','rmt_foo_cursor',4) AS t(a int, b text, c text[]);
--- close the cursor
-SELECT dblink_close('myconn','rmt_foo_cursor');
+-- fetch some data incorrectly
+SELECT *
+FROM dblink_fetch('myconn','rmt_foobar_cursor',4,false) AS t(a int, b text, c text[]);
+
+-- reset remote transaction state
+SELECT dblink_exec('myconn','ABORT');
-- should generate 'cursor "rmt_foo_cursor" not found' error
SELECT *