Repair memory leaks in plpython.
[pgsql.git] / doc / src / sgml / dblink.sgml
blob81f35986c8820b76654268662082c79eb7421bf8
1 <!-- doc/src/sgml/dblink.sgml -->
3 <sect1 id="dblink" xreflabel="dblink">
4 <title>dblink &mdash; connect to other PostgreSQL databases</title>
6 <indexterm zone="dblink">
7 <primary>dblink</primary>
8 </indexterm>
10 <para>
11 <filename>dblink</filename> is a module that supports connections to
12 other <productname>PostgreSQL</productname> databases from within a database
13 session.
14 </para>
16 <para>
17 <filename>dblink</filename> can report the following wait events under the wait
18 event type <literal>Extension</literal>.
19 </para>
21 <variablelist>
22 <varlistentry>
23 <term><literal>DblinkConnect</literal></term>
24 <listitem>
25 <para>
26 Waiting to establish a connection to a remote server.
27 </para>
28 </listitem>
29 </varlistentry>
31 <varlistentry>
32 <term><literal>DblinkGetConnect</literal></term>
33 <listitem>
34 <para>
35 Waiting to establish a connection to a remote server when it could not
36 be found in the list of already-opened connections.
37 </para>
38 </listitem>
39 </varlistentry>
41 <varlistentry>
42 <term><literal>DblinkGetResult</literal></term>
43 <listitem>
44 <para>
45 Waiting to receive the results of a query from a remote server.
46 </para>
47 </listitem>
48 </varlistentry>
49 </variablelist>
51 <para>
52 See also <xref linkend="postgres-fdw"/>, which provides roughly the same
53 functionality using a more modern and standards-compliant infrastructure.
54 </para>
56 <refentry id="contrib-dblink-connect">
57 <indexterm>
58 <primary>dblink_connect</primary>
59 </indexterm>
61 <refmeta>
62 <refentrytitle>dblink_connect</refentrytitle>
63 <manvolnum>3</manvolnum>
64 </refmeta>
66 <refnamediv>
67 <refname>dblink_connect</refname>
68 <refpurpose>opens a persistent connection to a remote database</refpurpose>
69 </refnamediv>
71 <refsynopsisdiv>
72 <synopsis>
73 dblink_connect(text connstr) returns text
74 dblink_connect(text connname, text connstr) returns text
75 </synopsis>
76 </refsynopsisdiv>
78 <refsect1>
79 <title>Description</title>
81 <para>
82 <function>dblink_connect()</function> establishes a connection to a remote
83 <productname>PostgreSQL</productname> database. The server and database to
84 be contacted are identified through a standard <application>libpq</application>
85 connection string. Optionally, a name can be assigned to the
86 connection. Multiple named connections can be open at once, but
87 only one unnamed connection is permitted at a time. The connection
88 will persist until closed or until the database session is ended.
89 </para>
91 <para>
92 The connection string may also be the name of an existing foreign
93 server. It is recommended to use the foreign-data wrapper
94 <literal>dblink_fdw</literal> when defining the foreign
95 server. See the example below, as well as
96 <xref linkend="sql-createserver"/> and
97 <xref linkend="sql-createusermapping"/>.
98 </para>
100 </refsect1>
102 <refsect1>
103 <title>Arguments</title>
105 <variablelist>
106 <varlistentry>
107 <term><parameter>connname</parameter></term>
108 <listitem>
109 <para>
110 The name to use for this connection; if omitted, an unnamed
111 connection is opened, replacing any existing unnamed connection.
112 </para>
113 </listitem>
114 </varlistentry>
116 <varlistentry>
117 <term><parameter>connstr</parameter></term>
118 <listitem>
119 <para><application>libpq</application>-style connection info string, for example
120 <literal>hostaddr=127.0.0.1 port=5432 dbname=mydb user=postgres
121 password=mypasswd options=-csearch_path=</literal>.
122 For details see <xref linkend="libpq-connstring"/>.
123 Alternatively, the name of a foreign server.
124 </para>
125 </listitem>
126 </varlistentry>
127 </variablelist>
128 </refsect1>
130 <refsect1>
131 <title>Return Value</title>
133 <para>
134 Returns status, which is always <literal>OK</literal> (since any error
135 causes the function to throw an error instead of returning).
136 </para>
137 </refsect1>
139 <refsect1>
140 <title>Notes</title>
142 <para>
143 If untrusted users have access to a database that has not adopted a
144 <link linkend="ddl-schemas-patterns">secure schema usage pattern</link>,
145 begin each session by removing publicly-writable schemas from
146 <varname>search_path</varname>. One could, for example,
147 add <literal>options=-csearch_path=</literal> to
148 <parameter>connstr</parameter>. This consideration is not specific
149 to <filename>dblink</filename>; it applies to every interface for
150 executing arbitrary SQL commands.
151 </para>
153 <para>
154 Only superusers may use <function>dblink_connect</function> to create
155 non-password-authenticated and non-GSSAPI-authenticated connections.
156 If non-superusers need this capability, use
157 <function>dblink_connect_u</function> instead.
158 </para>
160 <para>
161 It is unwise to choose connection names that contain equal signs,
162 as this opens a risk of confusion with connection info strings
163 in other <filename>dblink</filename> functions.
164 </para>
165 </refsect1>
167 <refsect1>
168 <title>Examples</title>
170 <screen>
171 SELECT dblink_connect('dbname=postgres options=-csearch_path=');
172 dblink_connect
173 ----------------
175 (1 row)
177 SELECT dblink_connect('myconn', 'dbname=postgres options=-csearch_path=');
178 dblink_connect
179 ----------------
181 (1 row)
183 -- FOREIGN DATA WRAPPER functionality
184 -- Note: local connection must require password authentication for this to work properly
185 -- Otherwise, you will receive the following error from dblink_connect():
186 -- ERROR: password is required
187 -- DETAIL: Non-superuser cannot connect if the server does not request a password.
188 -- HINT: Target server's authentication method must be changed.
190 CREATE SERVER fdtest FOREIGN DATA WRAPPER dblink_fdw OPTIONS (hostaddr '127.0.0.1', dbname 'contrib_regression');
192 CREATE USER regress_dblink_user WITH PASSWORD 'secret';
193 CREATE USER MAPPING FOR regress_dblink_user SERVER fdtest OPTIONS (user 'regress_dblink_user', password 'secret');
194 GRANT USAGE ON FOREIGN SERVER fdtest TO regress_dblink_user;
195 GRANT SELECT ON TABLE foo TO regress_dblink_user;
197 \set ORIGINAL_USER :USER
198 \c - regress_dblink_user
199 SELECT dblink_connect('myconn', 'fdtest');
200 dblink_connect
201 ----------------
203 (1 row)
205 SELECT * FROM dblink('myconn', 'SELECT * FROM foo') AS t(a int, b text, c text[]);
206 a | b | c
207 ----+---+---------------
208 0 | a | {a0,b0,c0}
209 1 | b | {a1,b1,c1}
210 2 | c | {a2,b2,c2}
211 3 | d | {a3,b3,c3}
212 4 | e | {a4,b4,c4}
213 5 | f | {a5,b5,c5}
214 6 | g | {a6,b6,c6}
215 7 | h | {a7,b7,c7}
216 8 | i | {a8,b8,c8}
217 9 | j | {a9,b9,c9}
218 10 | k | {a10,b10,c10}
219 (11 rows)
221 \c - :ORIGINAL_USER
222 REVOKE USAGE ON FOREIGN SERVER fdtest FROM regress_dblink_user;
223 REVOKE SELECT ON TABLE foo FROM regress_dblink_user;
224 DROP USER MAPPING FOR regress_dblink_user SERVER fdtest;
225 DROP USER regress_dblink_user;
226 DROP SERVER fdtest;
227 </screen>
228 </refsect1>
229 </refentry>
231 <refentry id="contrib-dblink-connect-u">
232 <indexterm>
233 <primary>dblink_connect_u</primary>
234 </indexterm>
236 <refmeta>
237 <refentrytitle>dblink_connect_u</refentrytitle>
238 <manvolnum>3</manvolnum>
239 </refmeta>
241 <refnamediv>
242 <refname>dblink_connect_u</refname>
243 <refpurpose>opens a persistent connection to a remote database, insecurely</refpurpose>
244 </refnamediv>
246 <refsynopsisdiv>
247 <synopsis>
248 dblink_connect_u(text connstr) returns text
249 dblink_connect_u(text connname, text connstr) returns text
250 </synopsis>
251 </refsynopsisdiv>
253 <refsect1>
254 <title>Description</title>
256 <para>
257 <function>dblink_connect_u()</function> is identical to
258 <function>dblink_connect()</function>, except that it will allow non-superusers
259 to connect using any authentication method.
260 </para>
262 <para>
263 If the remote server selects an authentication method that does not
264 involve a password, then impersonation and subsequent escalation of
265 privileges can occur, because the session will appear to have
266 originated from the user as which the local <productname>PostgreSQL</productname>
267 server runs. Also, even if the remote server does demand a password,
268 it is possible for the password to be supplied from the server
269 environment, such as a <filename>~/.pgpass</filename> file belonging to the
270 server's user. This opens not only a risk of impersonation, but the
271 possibility of exposing a password to an untrustworthy remote server.
272 Therefore, <function>dblink_connect_u()</function> is initially
273 installed with all privileges revoked from <literal>PUBLIC</literal>,
274 making it un-callable except by superusers. In some situations
275 it may be appropriate to grant <literal>EXECUTE</literal> permission for
276 <function>dblink_connect_u()</function> to specific users who are considered
277 trustworthy, but this should be done with care. It is also recommended
278 that any <filename>~/.pgpass</filename> file belonging to the server's user
279 <emphasis>not</emphasis> contain any records specifying a wildcard host name.
280 </para>
282 <para>
283 For further details see <function>dblink_connect()</function>.
284 </para>
285 </refsect1>
286 </refentry>
288 <refentry id="contrib-dblink-disconnect">
289 <indexterm>
290 <primary>dblink_disconnect</primary>
291 </indexterm>
293 <refmeta>
294 <refentrytitle>dblink_disconnect</refentrytitle>
295 <manvolnum>3</manvolnum>
296 </refmeta>
298 <refnamediv>
299 <refname>dblink_disconnect</refname>
300 <refpurpose>closes a persistent connection to a remote database</refpurpose>
301 </refnamediv>
303 <refsynopsisdiv>
304 <synopsis>
305 dblink_disconnect() returns text
306 dblink_disconnect(text connname) returns text
307 </synopsis>
308 </refsynopsisdiv>
310 <refsect1>
311 <title>Description</title>
313 <para>
314 <function>dblink_disconnect()</function> closes a connection previously opened
315 by <function>dblink_connect()</function>. The form with no arguments closes
316 an unnamed connection.
317 </para>
318 </refsect1>
320 <refsect1>
321 <title>Arguments</title>
323 <variablelist>
324 <varlistentry>
325 <term><parameter>connname</parameter></term>
326 <listitem>
327 <para>
328 The name of a named connection to be closed.
329 </para>
330 </listitem>
331 </varlistentry>
332 </variablelist>
333 </refsect1>
335 <refsect1>
336 <title>Return Value</title>
338 <para>
339 Returns status, which is always <literal>OK</literal> (since any error
340 causes the function to throw an error instead of returning).
341 </para>
342 </refsect1>
344 <refsect1>
345 <title>Examples</title>
347 <screen>
348 SELECT dblink_disconnect();
349 dblink_disconnect
350 -------------------
352 (1 row)
354 SELECT dblink_disconnect('myconn');
355 dblink_disconnect
356 -------------------
358 (1 row)
359 </screen>
360 </refsect1>
361 </refentry>
363 <refentry id="contrib-dblink-function">
364 <indexterm>
365 <primary>dblink</primary>
366 </indexterm>
368 <refmeta>
369 <refentrytitle>dblink</refentrytitle>
370 <manvolnum>3</manvolnum>
371 </refmeta>
373 <refnamediv>
374 <refname>dblink</refname>
375 <refpurpose>executes a query in a remote database</refpurpose>
376 </refnamediv>
378 <refsynopsisdiv>
379 <synopsis>
380 dblink(text connname, text sql [, bool fail_on_error]) returns setof record
381 dblink(text connstr, text sql [, bool fail_on_error]) returns setof record
382 dblink(text sql [, bool fail_on_error]) returns setof record
383 </synopsis>
384 </refsynopsisdiv>
386 <refsect1>
387 <title>Description</title>
389 <para>
390 <function>dblink</function> executes a query (usually a <command>SELECT</command>,
391 but it can be any SQL statement that returns rows) in a remote database.
392 </para>
394 <para>
395 When two <type>text</type> arguments are given, the first one is first
396 looked up as a persistent connection's name; if found, the command
397 is executed on that connection. If not found, the first argument
398 is treated as a connection info string as for <function>dblink_connect</function>,
399 and the indicated connection is made just for the duration of this command.
400 </para>
401 </refsect1>
403 <refsect1>
404 <title>Arguments</title>
406 <variablelist>
407 <varlistentry>
408 <term><parameter>connname</parameter></term>
409 <listitem>
410 <para>
411 Name of the connection to use; omit this parameter to use the
412 unnamed connection.
413 </para>
414 </listitem>
415 </varlistentry>
417 <varlistentry>
418 <term><parameter>connstr</parameter></term>
419 <listitem>
420 <para>
421 A connection info string, as previously described for
422 <function>dblink_connect</function>.
423 </para>
424 </listitem>
425 </varlistentry>
427 <varlistentry>
428 <term><parameter>sql</parameter></term>
429 <listitem>
430 <para>
431 The SQL query that you wish to execute in the remote database,
432 for example <literal>select * from foo</literal>.
433 </para>
434 </listitem>
435 </varlistentry>
437 <varlistentry>
438 <term><parameter>fail_on_error</parameter></term>
439 <listitem>
440 <para>
441 If true (the default when omitted) then an error thrown on the
442 remote side of the connection causes an error to also be thrown
443 locally. If false, the remote error is locally reported as a NOTICE,
444 and the function returns no rows.
445 </para>
446 </listitem>
447 </varlistentry>
448 </variablelist>
449 </refsect1>
451 <refsect1>
452 <title>Return Value</title>
454 <para>
455 The function returns the row(s) produced by the query. Since
456 <function>dblink</function> can be used with any query, it is declared
457 to return <type>record</type>, rather than specifying any particular
458 set of columns. This means that you must specify the expected
459 set of columns in the calling query &mdash; otherwise
460 <productname>PostgreSQL</productname> would not know what to expect.
461 Here is an example:
463 <programlisting>
464 SELECT *
465 FROM dblink('dbname=mydb options=-csearch_path=',
466 'select proname, prosrc from pg_proc')
467 AS t1(proname name, prosrc text)
468 WHERE proname LIKE 'bytea%';
469 </programlisting>
471 The <quote>alias</quote> part of the <literal>FROM</literal> clause must
472 specify the column names and types that the function will return.
473 (Specifying column names in an alias is actually standard SQL
474 syntax, but specifying column types is a <productname>PostgreSQL</productname>
475 extension.) This allows the system to understand what
476 <literal>*</literal> should expand to, and what <structname>proname</structname>
477 in the <literal>WHERE</literal> clause refers to, in advance of trying
478 to execute the function. At run time, an error will be thrown
479 if the actual query result from the remote database does not
480 have the same number of columns shown in the <literal>FROM</literal> clause.
481 The column names need not match, however, and <function>dblink</function>
482 does not insist on exact type matches either. It will succeed
483 so long as the returned data strings are valid input for the
484 column type declared in the <literal>FROM</literal> clause.
485 </para>
486 </refsect1>
488 <refsect1>
489 <title>Notes</title>
491 <para>
492 A convenient way to use <function>dblink</function> with predetermined
493 queries is to create a view.
494 This allows the column type information to be buried in the view,
495 instead of having to spell it out in every query. For example,
497 <programlisting>
498 CREATE VIEW myremote_pg_proc AS
499 SELECT *
500 FROM dblink('dbname=postgres options=-csearch_path=',
501 'select proname, prosrc from pg_proc')
502 AS t1(proname name, prosrc text);
504 SELECT * FROM myremote_pg_proc WHERE proname LIKE 'bytea%';
505 </programlisting></para>
506 </refsect1>
508 <refsect1>
509 <title>Examples</title>
511 <screen>
512 SELECT * FROM dblink('dbname=postgres options=-csearch_path=',
513 'select proname, prosrc from pg_proc')
514 AS t1(proname name, prosrc text) WHERE proname LIKE 'bytea%';
515 proname | prosrc
516 ------------+------------
517 byteacat | byteacat
518 byteaeq | byteaeq
519 bytealt | bytealt
520 byteale | byteale
521 byteagt | byteagt
522 byteage | byteage
523 byteane | byteane
524 byteacmp | byteacmp
525 bytealike | bytealike
526 byteanlike | byteanlike
527 byteain | byteain
528 byteaout | byteaout
529 (12 rows)
531 SELECT dblink_connect('dbname=postgres options=-csearch_path=');
532 dblink_connect
533 ----------------
535 (1 row)
537 SELECT * FROM dblink('select proname, prosrc from pg_proc')
538 AS t1(proname name, prosrc text) WHERE proname LIKE 'bytea%';
539 proname | prosrc
540 ------------+------------
541 byteacat | byteacat
542 byteaeq | byteaeq
543 bytealt | bytealt
544 byteale | byteale
545 byteagt | byteagt
546 byteage | byteage
547 byteane | byteane
548 byteacmp | byteacmp
549 bytealike | bytealike
550 byteanlike | byteanlike
551 byteain | byteain
552 byteaout | byteaout
553 (12 rows)
555 SELECT dblink_connect('myconn', 'dbname=regression options=-csearch_path=');
556 dblink_connect
557 ----------------
559 (1 row)
561 SELECT * FROM dblink('myconn', 'select proname, prosrc from pg_proc')
562 AS t1(proname name, prosrc text) WHERE proname LIKE 'bytea%';
563 proname | prosrc
564 ------------+------------
565 bytearecv | bytearecv
566 byteasend | byteasend
567 byteale | byteale
568 byteagt | byteagt
569 byteage | byteage
570 byteane | byteane
571 byteacmp | byteacmp
572 bytealike | bytealike
573 byteanlike | byteanlike
574 byteacat | byteacat
575 byteaeq | byteaeq
576 bytealt | bytealt
577 byteain | byteain
578 byteaout | byteaout
579 (14 rows)
580 </screen>
581 </refsect1>
582 </refentry>
584 <refentry id="contrib-dblink-exec">
585 <indexterm>
586 <primary>dblink_exec</primary>
587 </indexterm>
589 <refmeta>
590 <refentrytitle>dblink_exec</refentrytitle>
591 <manvolnum>3</manvolnum>
592 </refmeta>
594 <refnamediv>
595 <refname>dblink_exec</refname>
596 <refpurpose>executes a command in a remote database</refpurpose>
597 </refnamediv>
599 <refsynopsisdiv>
600 <synopsis>
601 dblink_exec(text connname, text sql [, bool fail_on_error]) returns text
602 dblink_exec(text connstr, text sql [, bool fail_on_error]) returns text
603 dblink_exec(text sql [, bool fail_on_error]) returns text
604 </synopsis>
605 </refsynopsisdiv>
607 <refsect1>
608 <title>Description</title>
610 <para>
611 <function>dblink_exec</function> executes a command (that is, any SQL statement
612 that doesn't return rows) in a remote database.
613 </para>
615 <para>
616 When two <type>text</type> arguments are given, the first one is first
617 looked up as a persistent connection's name; if found, the command
618 is executed on that connection. If not found, the first argument
619 is treated as a connection info string as for <function>dblink_connect</function>,
620 and the indicated connection is made just for the duration of this command.
621 </para>
622 </refsect1>
624 <refsect1>
625 <title>Arguments</title>
627 <variablelist>
628 <varlistentry>
629 <term><parameter>connname</parameter></term>
630 <listitem>
631 <para>
632 Name of the connection to use; omit this parameter to use the
633 unnamed connection.
634 </para>
635 </listitem>
636 </varlistentry>
638 <varlistentry>
639 <term><parameter>connstr</parameter></term>
640 <listitem>
641 <para>
642 A connection info string, as previously described for
643 <function>dblink_connect</function>.
644 </para>
645 </listitem>
646 </varlistentry>
648 <varlistentry>
649 <term><parameter>sql</parameter></term>
650 <listitem>
651 <para>
652 The SQL command that you wish to execute in the remote database,
653 for example
654 <literal>insert into foo values(0, 'a', '{"a0","b0","c0"}')</literal>.
655 </para>
656 </listitem>
657 </varlistentry>
659 <varlistentry>
660 <term><parameter>fail_on_error</parameter></term>
661 <listitem>
662 <para>
663 If true (the default when omitted) then an error thrown on the
664 remote side of the connection causes an error to also be thrown
665 locally. If false, the remote error is locally reported as a NOTICE,
666 and the function's return value is set to <literal>ERROR</literal>.
667 </para>
668 </listitem>
669 </varlistentry>
670 </variablelist>
671 </refsect1>
673 <refsect1>
674 <title>Return Value</title>
676 <para>
677 Returns status, either the command's status string or <literal>ERROR</literal>.
678 </para>
679 </refsect1>
681 <refsect1>
682 <title>Examples</title>
684 <screen>
685 SELECT dblink_connect('dbname=dblink_test_standby');
686 dblink_connect
687 ----------------
689 (1 row)
691 SELECT dblink_exec('insert into foo values(21, ''z'', ''{"a0","b0","c0"}'');');
692 dblink_exec
693 -----------------
694 INSERT 943366 1
695 (1 row)
697 SELECT dblink_connect('myconn', 'dbname=regression');
698 dblink_connect
699 ----------------
701 (1 row)
703 SELECT dblink_exec('myconn', 'insert into foo values(21, ''z'', ''{"a0","b0","c0"}'');');
704 dblink_exec
705 ------------------
706 INSERT 6432584 1
707 (1 row)
709 SELECT dblink_exec('myconn', 'insert into pg_class values (''foo'')',false);
710 NOTICE: sql error
711 DETAIL: ERROR: null value in column "relnamespace" violates not-null constraint
713 dblink_exec
714 -------------
715 ERROR
716 (1 row)
717 </screen>
718 </refsect1>
719 </refentry>
721 <refentry id="contrib-dblink-open">
722 <indexterm>
723 <primary>dblink_open</primary>
724 </indexterm>
726 <refmeta>
727 <refentrytitle>dblink_open</refentrytitle>
728 <manvolnum>3</manvolnum>
729 </refmeta>
731 <refnamediv>
732 <refname>dblink_open</refname>
733 <refpurpose>opens a cursor in a remote database</refpurpose>
734 </refnamediv>
736 <refsynopsisdiv>
737 <synopsis>
738 dblink_open(text cursorname, text sql [, bool fail_on_error]) returns text
739 dblink_open(text connname, text cursorname, text sql [, bool fail_on_error]) returns text
740 </synopsis>
741 </refsynopsisdiv>
743 <refsect1>
744 <title>Description</title>
746 <para>
747 <function>dblink_open()</function> opens a cursor in a remote database.
748 The cursor can subsequently be manipulated with
749 <function>dblink_fetch()</function> and <function>dblink_close()</function>.
750 </para>
751 </refsect1>
753 <refsect1>
754 <title>Arguments</title>
756 <variablelist>
757 <varlistentry>
758 <term><parameter>connname</parameter></term>
759 <listitem>
760 <para>
761 Name of the connection to use; omit this parameter to use the
762 unnamed connection.
763 </para>
764 </listitem>
765 </varlistentry>
767 <varlistentry>
768 <term><parameter>cursorname</parameter></term>
769 <listitem>
770 <para>
771 The name to assign to this cursor.
772 </para>
773 </listitem>
774 </varlistentry>
776 <varlistentry>
777 <term><parameter>sql</parameter></term>
778 <listitem>
779 <para>
780 The <command>SELECT</command> statement that you wish to execute in the remote
781 database, for example <literal>select * from pg_class</literal>.
782 </para>
783 </listitem>
784 </varlistentry>
786 <varlistentry>
787 <term><parameter>fail_on_error</parameter></term>
788 <listitem>
789 <para>
790 If true (the default when omitted) then an error thrown on the
791 remote side of the connection causes an error to also be thrown
792 locally. If false, the remote error is locally reported as a NOTICE,
793 and the function's return value is set to <literal>ERROR</literal>.
794 </para>
795 </listitem>
796 </varlistentry>
797 </variablelist>
798 </refsect1>
800 <refsect1>
801 <title>Return Value</title>
803 <para>
804 Returns status, either <literal>OK</literal> or <literal>ERROR</literal>.
805 </para>
806 </refsect1>
808 <refsect1>
809 <title>Notes</title>
811 <para>
812 Since a cursor can only persist within a transaction,
813 <function>dblink_open</function> starts an explicit transaction block
814 (<command>BEGIN</command>) on the remote side, if the remote side was
815 not already within a transaction. This transaction will be
816 closed again when the matching <function>dblink_close</function> is
817 executed. Note that if
818 you use <function>dblink_exec</function> to change data between
819 <function>dblink_open</function> and <function>dblink_close</function>,
820 and then an error occurs or you use <function>dblink_disconnect</function> before
821 <function>dblink_close</function>, your change <emphasis>will be
822 lost</emphasis> because the transaction will be aborted.
823 </para>
824 </refsect1>
826 <refsect1>
827 <title>Examples</title>
829 <screen>
830 SELECT dblink_connect('dbname=postgres options=-csearch_path=');
831 dblink_connect
832 ----------------
834 (1 row)
836 SELECT dblink_open('foo', 'select proname, prosrc from pg_proc');
837 dblink_open
838 -------------
840 (1 row)
841 </screen>
842 </refsect1>
843 </refentry>
845 <refentry id="contrib-dblink-fetch">
846 <indexterm>
847 <primary>dblink_fetch</primary>
848 </indexterm>
850 <refmeta>
851 <refentrytitle>dblink_fetch</refentrytitle>
852 <manvolnum>3</manvolnum>
853 </refmeta>
855 <refnamediv>
856 <refname>dblink_fetch</refname>
857 <refpurpose>returns rows from an open cursor in a remote database</refpurpose>
858 </refnamediv>
860 <refsynopsisdiv>
861 <synopsis>
862 dblink_fetch(text cursorname, int howmany [, bool fail_on_error]) returns setof record
863 dblink_fetch(text connname, text cursorname, int howmany [, bool fail_on_error]) returns setof record
864 </synopsis>
865 </refsynopsisdiv>
867 <refsect1>
868 <title>Description</title>
870 <para>
871 <function>dblink_fetch</function> fetches rows from a cursor previously
872 established by <function>dblink_open</function>.
873 </para>
874 </refsect1>
876 <refsect1>
877 <title>Arguments</title>
879 <variablelist>
880 <varlistentry>
881 <term><parameter>connname</parameter></term>
882 <listitem>
883 <para>
884 Name of the connection to use; omit this parameter to use the
885 unnamed connection.
886 </para>
887 </listitem>
888 </varlistentry>
890 <varlistentry>
891 <term><parameter>cursorname</parameter></term>
892 <listitem>
893 <para>
894 The name of the cursor to fetch from.
895 </para>
896 </listitem>
897 </varlistentry>
899 <varlistentry>
900 <term><parameter>howmany</parameter></term>
901 <listitem>
902 <para>
903 The maximum number of rows to retrieve. The next <parameter>howmany</parameter>
904 rows are fetched, starting at the current cursor position, moving
905 forward. Once the cursor has reached its end, no more rows are produced.
906 </para>
907 </listitem>
908 </varlistentry>
910 <varlistentry>
911 <term><parameter>fail_on_error</parameter></term>
912 <listitem>
913 <para>
914 If true (the default when omitted) then an error thrown on the
915 remote side of the connection causes an error to also be thrown
916 locally. If false, the remote error is locally reported as a NOTICE,
917 and the function returns no rows.
918 </para>
919 </listitem>
920 </varlistentry>
921 </variablelist>
922 </refsect1>
924 <refsect1>
925 <title>Return Value</title>
927 <para>
928 The function returns the row(s) fetched from the cursor. To use this
929 function, you will need to specify the expected set of columns,
930 as previously discussed for <function>dblink</function>.
931 </para>
932 </refsect1>
934 <refsect1>
935 <title>Notes</title>
937 <para>
938 On a mismatch between the number of return columns specified in the
939 <literal>FROM</literal> clause, and the actual number of columns returned by the
940 remote cursor, an error will be thrown. In this event, the remote cursor
941 is still advanced by as many rows as it would have been if the error had
942 not occurred. The same is true for any other error occurring in the local
943 query after the remote <command>FETCH</command> has been done.
944 </para>
945 </refsect1>
947 <refsect1>
948 <title>Examples</title>
950 <screen>
951 SELECT dblink_connect('dbname=postgres options=-csearch_path=');
952 dblink_connect
953 ----------------
955 (1 row)
957 SELECT dblink_open('foo', 'select proname, prosrc from pg_proc where proname like ''bytea%''');
958 dblink_open
959 -------------
961 (1 row)
963 SELECT * FROM dblink_fetch('foo', 5) AS (funcname name, source text);
964 funcname | source
965 ----------+----------
966 byteacat | byteacat
967 byteacmp | byteacmp
968 byteaeq | byteaeq
969 byteage | byteage
970 byteagt | byteagt
971 (5 rows)
973 SELECT * FROM dblink_fetch('foo', 5) AS (funcname name, source text);
974 funcname | source
975 -----------+-----------
976 byteain | byteain
977 byteale | byteale
978 bytealike | bytealike
979 bytealt | bytealt
980 byteane | byteane
981 (5 rows)
983 SELECT * FROM dblink_fetch('foo', 5) AS (funcname name, source text);
984 funcname | source
985 ------------+------------
986 byteanlike | byteanlike
987 byteaout | byteaout
988 (2 rows)
990 SELECT * FROM dblink_fetch('foo', 5) AS (funcname name, source text);
991 funcname | source
992 ----------+--------
993 (0 rows)
994 </screen>
995 </refsect1>
996 </refentry>
998 <refentry id="contrib-dblink-close">
999 <indexterm>
1000 <primary>dblink_close</primary>
1001 </indexterm>
1003 <refmeta>
1004 <refentrytitle>dblink_close</refentrytitle>
1005 <manvolnum>3</manvolnum>
1006 </refmeta>
1008 <refnamediv>
1009 <refname>dblink_close</refname>
1010 <refpurpose>closes a cursor in a remote database</refpurpose>
1011 </refnamediv>
1013 <refsynopsisdiv>
1014 <synopsis>
1015 dblink_close(text cursorname [, bool fail_on_error]) returns text
1016 dblink_close(text connname, text cursorname [, bool fail_on_error]) returns text
1017 </synopsis>
1018 </refsynopsisdiv>
1020 <refsect1>
1021 <title>Description</title>
1023 <para>
1024 <function>dblink_close</function> closes a cursor previously opened with
1025 <function>dblink_open</function>.
1026 </para>
1027 </refsect1>
1029 <refsect1>
1030 <title>Arguments</title>
1032 <variablelist>
1033 <varlistentry>
1034 <term><parameter>connname</parameter></term>
1035 <listitem>
1036 <para>
1037 Name of the connection to use; omit this parameter to use the
1038 unnamed connection.
1039 </para>
1040 </listitem>
1041 </varlistentry>
1043 <varlistentry>
1044 <term><parameter>cursorname</parameter></term>
1045 <listitem>
1046 <para>
1047 The name of the cursor to close.
1048 </para>
1049 </listitem>
1050 </varlistentry>
1052 <varlistentry>
1053 <term><parameter>fail_on_error</parameter></term>
1054 <listitem>
1055 <para>
1056 If true (the default when omitted) then an error thrown on the
1057 remote side of the connection causes an error to also be thrown
1058 locally. If false, the remote error is locally reported as a NOTICE,
1059 and the function's return value is set to <literal>ERROR</literal>.
1060 </para>
1061 </listitem>
1062 </varlistentry>
1063 </variablelist>
1064 </refsect1>
1066 <refsect1>
1067 <title>Return Value</title>
1069 <para>
1070 Returns status, either <literal>OK</literal> or <literal>ERROR</literal>.
1071 </para>
1072 </refsect1>
1074 <refsect1>
1075 <title>Notes</title>
1077 <para>
1078 If <function>dblink_open</function> started an explicit transaction block,
1079 and this is the last remaining open cursor in this connection,
1080 <function>dblink_close</function> will issue the matching <command>COMMIT</command>.
1081 </para>
1082 </refsect1>
1084 <refsect1>
1085 <title>Examples</title>
1087 <screen>
1088 SELECT dblink_connect('dbname=postgres options=-csearch_path=');
1089 dblink_connect
1090 ----------------
1092 (1 row)
1094 SELECT dblink_open('foo', 'select proname, prosrc from pg_proc');
1095 dblink_open
1096 -------------
1098 (1 row)
1100 SELECT dblink_close('foo');
1101 dblink_close
1102 --------------
1104 (1 row)
1105 </screen>
1106 </refsect1>
1107 </refentry>
1109 <refentry id="contrib-dblink-get-connections">
1110 <indexterm>
1111 <primary>dblink_get_connections</primary>
1112 </indexterm>
1114 <refmeta>
1115 <refentrytitle>dblink_get_connections</refentrytitle>
1116 <manvolnum>3</manvolnum>
1117 </refmeta>
1119 <refnamediv>
1120 <refname>dblink_get_connections</refname>
1121 <refpurpose>returns the names of all open named dblink connections</refpurpose>
1122 </refnamediv>
1124 <refsynopsisdiv>
1125 <synopsis>
1126 dblink_get_connections() returns text[]
1127 </synopsis>
1128 </refsynopsisdiv>
1130 <refsect1>
1131 <title>Description</title>
1133 <para>
1134 <function>dblink_get_connections</function> returns an array of the names
1135 of all open named <filename>dblink</filename> connections.
1136 </para>
1137 </refsect1>
1139 <refsect1>
1140 <title>Return Value</title>
1142 <para>Returns a text array of connection names, or NULL if none.</para>
1143 </refsect1>
1145 <refsect1>
1146 <title>Examples</title>
1148 <programlisting>
1149 SELECT dblink_get_connections();
1150 </programlisting>
1151 </refsect1>
1152 </refentry>
1154 <refentry id="contrib-dblink-error-message">
1155 <indexterm>
1156 <primary>dblink_error_message</primary>
1157 </indexterm>
1159 <refmeta>
1160 <refentrytitle>dblink_error_message</refentrytitle>
1161 <manvolnum>3</manvolnum>
1162 </refmeta>
1164 <refnamediv>
1165 <refname>dblink_error_message</refname>
1166 <refpurpose>gets last error message on the named connection</refpurpose>
1167 </refnamediv>
1169 <refsynopsisdiv>
1170 <synopsis>
1171 dblink_error_message(text connname) returns text
1172 </synopsis>
1173 </refsynopsisdiv>
1175 <refsect1>
1176 <title>Description</title>
1178 <para>
1179 <function>dblink_error_message</function> fetches the most recent remote
1180 error message for a given connection.
1181 </para>
1182 </refsect1>
1184 <refsect1>
1185 <title>Arguments</title>
1187 <variablelist>
1188 <varlistentry>
1189 <term><parameter>connname</parameter></term>
1190 <listitem>
1191 <para>
1192 Name of the connection to use.
1193 </para>
1194 </listitem>
1195 </varlistentry>
1196 </variablelist>
1197 </refsect1>
1199 <refsect1>
1200 <title>Return Value</title>
1202 <para>
1203 Returns last error message, or <literal>OK</literal> if there has been
1204 no error in this connection.
1205 </para>
1206 </refsect1>
1208 <refsect1>
1209 <title>Notes</title>
1211 <para>
1212 When asynchronous queries are initiated by
1213 <function>dblink_send_query</function>, the error message associated with
1214 the connection might not get updated until the server's response message
1215 is consumed. This typically means that <function>dblink_is_busy</function>
1216 or <function>dblink_get_result</function> should be called prior to
1217 <function>dblink_error_message</function>, so that any error generated by
1218 the asynchronous query will be visible.
1219 </para>
1220 </refsect1>
1222 <refsect1>
1223 <title>Examples</title>
1225 <programlisting>
1226 SELECT dblink_error_message('dtest1');
1227 </programlisting>
1228 </refsect1>
1229 </refentry>
1231 <refentry id="contrib-dblink-send-query">
1232 <indexterm>
1233 <primary>dblink_send_query</primary>
1234 </indexterm>
1236 <refmeta>
1237 <refentrytitle>dblink_send_query</refentrytitle>
1238 <manvolnum>3</manvolnum>
1239 </refmeta>
1241 <refnamediv>
1242 <refname>dblink_send_query</refname>
1243 <refpurpose>sends an async query to a remote database</refpurpose>
1244 </refnamediv>
1246 <refsynopsisdiv>
1247 <synopsis>
1248 dblink_send_query(text connname, text sql) returns int
1249 </synopsis>
1250 </refsynopsisdiv>
1252 <refsect1>
1253 <title>Description</title>
1255 <para>
1256 <function>dblink_send_query</function> sends a query to be executed
1257 asynchronously, that is, without immediately waiting for the result.
1258 There must not be an async query already in progress on the
1259 connection.
1260 </para>
1262 <para>
1263 After successfully dispatching an async query, completion status
1264 can be checked with <function>dblink_is_busy</function>, and the results
1265 are ultimately collected with <function>dblink_get_result</function>.
1266 It is also possible to attempt to cancel an active async query
1267 using <function>dblink_cancel_query</function>.
1268 </para>
1269 </refsect1>
1271 <refsect1>
1272 <title>Arguments</title>
1274 <variablelist>
1275 <varlistentry>
1276 <term><parameter>connname</parameter></term>
1277 <listitem>
1278 <para>
1279 Name of the connection to use.
1280 </para>
1281 </listitem>
1282 </varlistentry>
1284 <varlistentry>
1285 <term><parameter>sql</parameter></term>
1286 <listitem>
1287 <para>
1288 The SQL statement that you wish to execute in the remote database,
1289 for example <literal>select * from pg_class</literal>.
1290 </para>
1291 </listitem>
1292 </varlistentry>
1293 </variablelist>
1294 </refsect1>
1296 <refsect1>
1297 <title>Return Value</title>
1299 <para>
1300 Returns 1 if the query was successfully dispatched, 0 otherwise.
1301 </para>
1302 </refsect1>
1304 <refsect1>
1305 <title>Examples</title>
1307 <programlisting>
1308 SELECT dblink_send_query('dtest1', 'SELECT * FROM foo WHERE f1 &lt; 3');
1309 </programlisting>
1310 </refsect1>
1311 </refentry>
1313 <refentry id="contrib-dblink-is-busy">
1314 <indexterm>
1315 <primary>dblink_is_busy</primary>
1316 </indexterm>
1318 <refmeta>
1319 <refentrytitle>dblink_is_busy</refentrytitle>
1320 <manvolnum>3</manvolnum>
1321 </refmeta>
1323 <refnamediv>
1324 <refname>dblink_is_busy</refname>
1325 <refpurpose>checks if connection is busy with an async query</refpurpose>
1326 </refnamediv>
1328 <refsynopsisdiv>
1329 <synopsis>
1330 dblink_is_busy(text connname) returns int
1331 </synopsis>
1332 </refsynopsisdiv>
1334 <refsect1>
1335 <title>Description</title>
1337 <para>
1338 <function>dblink_is_busy</function> tests whether an async query is in progress.
1339 </para>
1340 </refsect1>
1342 <refsect1>
1343 <title>Arguments</title>
1345 <variablelist>
1346 <varlistentry>
1347 <term><parameter>connname</parameter></term>
1348 <listitem>
1349 <para>
1350 Name of the connection to check.
1351 </para>
1352 </listitem>
1353 </varlistentry>
1354 </variablelist>
1355 </refsect1>
1357 <refsect1>
1358 <title>Return Value</title>
1360 <para>
1361 Returns 1 if connection is busy, 0 if it is not busy.
1362 If this function returns 0, it is guaranteed that
1363 <function>dblink_get_result</function> will not block.
1364 </para>
1365 </refsect1>
1367 <refsect1>
1368 <title>Examples</title>
1370 <programlisting>
1371 SELECT dblink_is_busy('dtest1');
1372 </programlisting>
1373 </refsect1>
1374 </refentry>
1376 <refentry id="contrib-dblink-get-notify">
1377 <indexterm>
1378 <primary>dblink_get_notify</primary>
1379 </indexterm>
1381 <refmeta>
1382 <refentrytitle>dblink_get_notify</refentrytitle>
1383 <manvolnum>3</manvolnum>
1384 </refmeta>
1386 <refnamediv>
1387 <refname>dblink_get_notify</refname>
1388 <refpurpose>retrieve async notifications on a connection</refpurpose>
1389 </refnamediv>
1391 <refsynopsisdiv>
1392 <synopsis>
1393 dblink_get_notify() returns setof (notify_name text, be_pid int, extra text)
1394 dblink_get_notify(text connname) returns setof (notify_name text, be_pid int, extra text)
1395 </synopsis>
1396 </refsynopsisdiv>
1398 <refsect1>
1399 <title>Description</title>
1401 <para>
1402 <function>dblink_get_notify</function> retrieves notifications on either
1403 the unnamed connection, or on a named connection if specified.
1404 To receive notifications via dblink, <function>LISTEN</function> must
1405 first be issued, using <function>dblink_exec</function>.
1406 For details see <xref linkend="sql-listen"/> and <xref linkend="sql-notify"/>.
1407 </para>
1409 </refsect1>
1411 <refsect1>
1412 <title>Arguments</title>
1414 <variablelist>
1415 <varlistentry>
1416 <term><parameter>connname</parameter></term>
1417 <listitem>
1418 <para>
1419 The name of a named connection to get notifications on.
1420 </para>
1421 </listitem>
1422 </varlistentry>
1423 </variablelist>
1424 </refsect1>
1426 <refsect1>
1427 <title>Return Value</title>
1428 <para>Returns <type>setof (notify_name text, be_pid int, extra text)</type>, or an empty set if none.</para>
1429 </refsect1>
1431 <refsect1>
1432 <title>Examples</title>
1434 <screen>
1435 SELECT dblink_exec('LISTEN virtual');
1436 dblink_exec
1437 -------------
1438 LISTEN
1439 (1 row)
1441 SELECT * FROM dblink_get_notify();
1442 notify_name | be_pid | extra
1443 -------------+--------+-------
1444 (0 rows)
1446 NOTIFY virtual;
1447 NOTIFY
1449 SELECT * FROM dblink_get_notify();
1450 notify_name | be_pid | extra
1451 -------------+--------+-------
1452 virtual | 1229 |
1453 (1 row)
1454 </screen>
1455 </refsect1>
1456 </refentry>
1458 <refentry id="contrib-dblink-get-result">
1459 <indexterm>
1460 <primary>dblink_get_result</primary>
1461 </indexterm>
1463 <refmeta>
1464 <refentrytitle>dblink_get_result</refentrytitle>
1465 <manvolnum>3</manvolnum>
1466 </refmeta>
1468 <refnamediv>
1469 <refname>dblink_get_result</refname>
1470 <refpurpose>gets an async query result</refpurpose>
1471 </refnamediv>
1473 <refsynopsisdiv>
1474 <synopsis>
1475 dblink_get_result(text connname [, bool fail_on_error]) returns setof record
1476 </synopsis>
1477 </refsynopsisdiv>
1479 <refsect1>
1480 <title>Description</title>
1482 <para>
1483 <function>dblink_get_result</function> collects the results of an
1484 asynchronous query previously sent with <function>dblink_send_query</function>.
1485 If the query is not already completed, <function>dblink_get_result</function>
1486 will wait until it is.
1487 </para>
1488 </refsect1>
1490 <refsect1>
1491 <title>Arguments</title>
1493 <variablelist>
1494 <varlistentry>
1495 <term><parameter>connname</parameter></term>
1496 <listitem>
1497 <para>
1498 Name of the connection to use.
1499 </para>
1500 </listitem>
1501 </varlistentry>
1503 <varlistentry>
1504 <term><parameter>fail_on_error</parameter></term>
1505 <listitem>
1506 <para>
1507 If true (the default when omitted) then an error thrown on the
1508 remote side of the connection causes an error to also be thrown
1509 locally. If false, the remote error is locally reported as a NOTICE,
1510 and the function returns no rows.
1511 </para>
1512 </listitem>
1513 </varlistentry>
1514 </variablelist>
1515 </refsect1>
1517 <refsect1>
1518 <title>Return Value</title>
1520 <para>
1521 For an async query (that is, an SQL statement returning rows),
1522 the function returns the row(s) produced by the query. To use this
1523 function, you will need to specify the expected set of columns,
1524 as previously discussed for <function>dblink</function>.
1525 </para>
1527 <para>
1528 For an async command (that is, an SQL statement not returning rows),
1529 the function returns a single row with a single text column containing
1530 the command's status string. It is still necessary to specify that
1531 the result will have a single text column in the calling <literal>FROM</literal>
1532 clause.
1533 </para>
1534 </refsect1>
1536 <refsect1>
1537 <title>Notes</title>
1539 <para>
1540 This function <emphasis>must</emphasis> be called if
1541 <function>dblink_send_query</function> returned 1.
1542 It must be called once for each query
1543 sent, and one additional time to obtain an empty set result,
1544 before the connection can be used again.
1545 </para>
1547 <para>
1548 When using <function>dblink_send_query</function> and
1549 <function>dblink_get_result</function>, <application>dblink</application> fetches the entire
1550 remote query result before returning any of it to the local query
1551 processor. If the query returns a large number of rows, this can result
1552 in transient memory bloat in the local session. It may be better to open
1553 such a query as a cursor with <function>dblink_open</function> and then fetch a
1554 manageable number of rows at a time. Alternatively, use plain
1555 <function>dblink()</function>, which avoids memory bloat by spooling large result
1556 sets to disk.
1557 </para>
1558 </refsect1>
1560 <refsect1>
1561 <title>Examples</title>
1563 <screen>
1564 contrib_regression=# SELECT dblink_connect('dtest1', 'dbname=contrib_regression');
1565 dblink_connect
1566 ----------------
1568 (1 row)
1570 contrib_regression=# SELECT * FROM
1571 contrib_regression-# dblink_send_query('dtest1', 'select * from foo where f1 &lt; 3') AS t1;
1573 ----
1575 (1 row)
1577 contrib_regression=# SELECT * FROM dblink_get_result('dtest1') AS t1(f1 int, f2 text, f3 text[]);
1578 f1 | f2 | f3
1579 ----+----+------------
1580 0 | a | {a0,b0,c0}
1581 1 | b | {a1,b1,c1}
1582 2 | c | {a2,b2,c2}
1583 (3 rows)
1585 contrib_regression=# SELECT * FROM dblink_get_result('dtest1') AS t1(f1 int, f2 text, f3 text[]);
1586 f1 | f2 | f3
1587 ----+----+----
1588 (0 rows)
1590 contrib_regression=# SELECT * FROM
1591 contrib_regression-# dblink_send_query('dtest1', 'select * from foo where f1 &lt; 3; select * from foo where f1 &gt; 6') AS t1;
1593 ----
1595 (1 row)
1597 contrib_regression=# SELECT * FROM dblink_get_result('dtest1') AS t1(f1 int, f2 text, f3 text[]);
1598 f1 | f2 | f3
1599 ----+----+------------
1600 0 | a | {a0,b0,c0}
1601 1 | b | {a1,b1,c1}
1602 2 | c | {a2,b2,c2}
1603 (3 rows)
1605 contrib_regression=# SELECT * FROM dblink_get_result('dtest1') AS t1(f1 int, f2 text, f3 text[]);
1606 f1 | f2 | f3
1607 ----+----+---------------
1608 7 | h | {a7,b7,c7}
1609 8 | i | {a8,b8,c8}
1610 9 | j | {a9,b9,c9}
1611 10 | k | {a10,b10,c10}
1612 (4 rows)
1614 contrib_regression=# SELECT * FROM dblink_get_result('dtest1') AS t1(f1 int, f2 text, f3 text[]);
1615 f1 | f2 | f3
1616 ----+----+----
1617 (0 rows)
1618 </screen>
1619 </refsect1>
1620 </refentry>
1622 <refentry id="contrib-dblink-cancel-query">
1623 <indexterm>
1624 <primary>dblink_cancel_query</primary>
1625 </indexterm>
1627 <refmeta>
1628 <refentrytitle>dblink_cancel_query</refentrytitle>
1629 <manvolnum>3</manvolnum>
1630 </refmeta>
1632 <refnamediv>
1633 <refname>dblink_cancel_query</refname>
1634 <refpurpose>cancels any active query on the named connection</refpurpose>
1635 </refnamediv>
1637 <refsynopsisdiv>
1638 <synopsis>
1639 dblink_cancel_query(text connname) returns text
1640 </synopsis>
1641 </refsynopsisdiv>
1643 <refsect1>
1644 <title>Description</title>
1646 <para>
1647 <function>dblink_cancel_query</function> attempts to cancel any query that
1648 is in progress on the named connection. Note that this is not
1649 certain to succeed (since, for example, the remote query might
1650 already have finished). A cancel request simply improves the
1651 odds that the query will fail soon. You must still complete the
1652 normal query protocol, for example by calling
1653 <function>dblink_get_result</function>.
1654 </para>
1655 </refsect1>
1657 <refsect1>
1658 <title>Arguments</title>
1660 <variablelist>
1661 <varlistentry>
1662 <term><parameter>connname</parameter></term>
1663 <listitem>
1664 <para>
1665 Name of the connection to use.
1666 </para>
1667 </listitem>
1668 </varlistentry>
1669 </variablelist>
1670 </refsect1>
1672 <refsect1>
1673 <title>Return Value</title>
1675 <para>
1676 Returns <literal>OK</literal> if the cancel request has been sent, or
1677 the text of an error message on failure.
1678 </para>
1679 </refsect1>
1681 <refsect1>
1682 <title>Examples</title>
1684 <programlisting>
1685 SELECT dblink_cancel_query('dtest1');
1686 </programlisting>
1687 </refsect1>
1688 </refentry>
1690 <refentry id="contrib-dblink-get-pkey">
1691 <indexterm>
1692 <primary>dblink_get_pkey</primary>
1693 </indexterm>
1695 <refmeta>
1696 <refentrytitle>dblink_get_pkey</refentrytitle>
1697 <manvolnum>3</manvolnum>
1698 </refmeta>
1700 <refnamediv>
1701 <refname>dblink_get_pkey</refname>
1702 <refpurpose>returns the positions and field names of a relation's
1703 primary key fields
1704 </refpurpose>
1705 </refnamediv>
1707 <refsynopsisdiv>
1708 <synopsis>
1709 dblink_get_pkey(text relname) returns setof dblink_pkey_results
1710 </synopsis>
1711 </refsynopsisdiv>
1713 <refsect1>
1714 <title>Description</title>
1716 <para>
1717 <function>dblink_get_pkey</function> provides information about the primary
1718 key of a relation in the local database. This is sometimes useful
1719 in generating queries to be sent to remote databases.
1720 </para>
1721 </refsect1>
1723 <refsect1>
1724 <title>Arguments</title>
1726 <variablelist>
1727 <varlistentry>
1728 <term><parameter>relname</parameter></term>
1729 <listitem>
1730 <para>
1731 Name of a local relation, for example <literal>foo</literal> or
1732 <literal>myschema.mytab</literal>. Include double quotes if the
1733 name is mixed-case or contains special characters, for
1734 example <literal>"FooBar"</literal>; without quotes, the string
1735 will be folded to lower case.
1736 </para>
1737 </listitem>
1738 </varlistentry>
1739 </variablelist>
1740 </refsect1>
1742 <refsect1>
1743 <title>Return Value</title>
1745 <para>
1746 Returns one row for each primary key field, or no rows if the relation
1747 has no primary key. The result row type is defined as
1749 <programlisting>
1750 CREATE TYPE dblink_pkey_results AS (position int, colname text);
1751 </programlisting>
1753 The <literal>position</literal> column simply runs from 1 to <replaceable>N</replaceable>;
1754 it is the number of the field within the primary key, not the number
1755 within the table's columns.
1756 </para>
1757 </refsect1>
1759 <refsect1>
1760 <title>Examples</title>
1762 <screen>
1763 CREATE TABLE foobar (
1764 f1 int,
1765 f2 int,
1766 f3 int,
1767 PRIMARY KEY (f1, f2, f3)
1769 CREATE TABLE
1771 SELECT * FROM dblink_get_pkey('foobar');
1772 position | colname
1773 ----------+---------
1774 1 | f1
1775 2 | f2
1776 3 | f3
1777 (3 rows)
1778 </screen>
1779 </refsect1>
1780 </refentry>
1782 <refentry id="contrib-dblink-build-sql-insert">
1783 <indexterm>
1784 <primary>dblink_build_sql_insert</primary>
1785 </indexterm>
1787 <refmeta>
1788 <refentrytitle>dblink_build_sql_insert</refentrytitle>
1789 <manvolnum>3</manvolnum>
1790 </refmeta>
1792 <refnamediv>
1793 <refname>dblink_build_sql_insert</refname>
1794 <refpurpose>
1795 builds an INSERT statement using a local tuple, replacing the
1796 primary key field values with alternative supplied values
1797 </refpurpose>
1798 </refnamediv>
1800 <refsynopsisdiv>
1801 <synopsis>
1802 dblink_build_sql_insert(text relname,
1803 int2vector primary_key_attnums,
1804 integer num_primary_key_atts,
1805 text[] src_pk_att_vals_array,
1806 text[] tgt_pk_att_vals_array) returns text
1807 </synopsis>
1808 </refsynopsisdiv>
1810 <refsect1>
1811 <title>Description</title>
1813 <para>
1814 <function>dblink_build_sql_insert</function> can be useful in doing selective
1815 replication of a local table to a remote database. It selects a row
1816 from the local table based on primary key, and then builds an SQL
1817 <command>INSERT</command> command that will duplicate that row, but with
1818 the primary key values replaced by the values in the last argument.
1819 (To make an exact copy of the row, just specify the same values for
1820 the last two arguments.)
1821 </para>
1822 </refsect1>
1824 <refsect1>
1825 <title>Arguments</title>
1827 <variablelist>
1828 <varlistentry>
1829 <term><parameter>relname</parameter></term>
1830 <listitem>
1831 <para>
1832 Name of a local relation, for example <literal>foo</literal> or
1833 <literal>myschema.mytab</literal>. Include double quotes if the
1834 name is mixed-case or contains special characters, for
1835 example <literal>"FooBar"</literal>; without quotes, the string
1836 will be folded to lower case.
1837 </para>
1838 </listitem>
1839 </varlistentry>
1841 <varlistentry>
1842 <term><parameter>primary_key_attnums</parameter></term>
1843 <listitem>
1844 <para>
1845 Attribute numbers (1-based) of the primary key fields,
1846 for example <literal>1 2</literal>.
1847 </para>
1848 </listitem>
1849 </varlistentry>
1851 <varlistentry>
1852 <term><parameter>num_primary_key_atts</parameter></term>
1853 <listitem>
1854 <para>
1855 The number of primary key fields.
1856 </para>
1857 </listitem>
1858 </varlistentry>
1860 <varlistentry>
1861 <term><parameter>src_pk_att_vals_array</parameter></term>
1862 <listitem>
1863 <para>
1864 Values of the primary key fields to be used to look up the
1865 local tuple. Each field is represented in text form.
1866 An error is thrown if there is no local row with these
1867 primary key values.
1868 </para>
1869 </listitem>
1870 </varlistentry>
1872 <varlistentry>
1873 <term><parameter>tgt_pk_att_vals_array</parameter></term>
1874 <listitem>
1875 <para>
1876 Values of the primary key fields to be placed in the resulting
1877 <command>INSERT</command> command. Each field is represented in text form.
1878 </para>
1879 </listitem>
1880 </varlistentry>
1881 </variablelist>
1882 </refsect1>
1884 <refsect1>
1885 <title>Return Value</title>
1887 <para>Returns the requested SQL statement as text.</para>
1888 </refsect1>
1890 <refsect1>
1891 <title>Notes</title>
1893 <para>
1894 As of <productname>PostgreSQL</productname> 9.0, the attribute numbers in
1895 <parameter>primary_key_attnums</parameter> are interpreted as logical
1896 column numbers, corresponding to the column's position in
1897 <literal>SELECT * FROM relname</literal>. Previous versions interpreted the
1898 numbers as physical column positions. There is a difference if any
1899 column(s) to the left of the indicated column have been dropped during
1900 the lifetime of the table.
1901 </para>
1902 </refsect1>
1904 <refsect1>
1905 <title>Examples</title>
1907 <screen>
1908 SELECT dblink_build_sql_insert('foo', '1 2', 2, '{"1", "a"}', '{"1", "b''a"}');
1909 dblink_build_sql_insert
1910 --------------------------------------------------
1911 INSERT INTO foo(f1,f2,f3) VALUES('1','b''a','1')
1912 (1 row)
1913 </screen>
1914 </refsect1>
1915 </refentry>
1917 <refentry id="contrib-dblink-build-sql-delete">
1918 <indexterm>
1919 <primary>dblink_build_sql_delete</primary>
1920 </indexterm>
1922 <refmeta>
1923 <refentrytitle>dblink_build_sql_delete</refentrytitle>
1924 <manvolnum>3</manvolnum>
1925 </refmeta>
1927 <refnamediv>
1928 <refname>dblink_build_sql_delete</refname>
1929 <refpurpose>builds a DELETE statement using supplied values for primary
1930 key field values
1931 </refpurpose>
1932 </refnamediv>
1934 <refsynopsisdiv>
1935 <synopsis>
1936 dblink_build_sql_delete(text relname,
1937 int2vector primary_key_attnums,
1938 integer num_primary_key_atts,
1939 text[] tgt_pk_att_vals_array) returns text
1940 </synopsis>
1941 </refsynopsisdiv>
1943 <refsect1>
1944 <title>Description</title>
1946 <para>
1947 <function>dblink_build_sql_delete</function> can be useful in doing selective
1948 replication of a local table to a remote database. It builds an SQL
1949 <command>DELETE</command> command that will delete the row with the given
1950 primary key values.
1951 </para>
1952 </refsect1>
1954 <refsect1>
1955 <title>Arguments</title>
1957 <variablelist>
1958 <varlistentry>
1959 <term><parameter>relname</parameter></term>
1960 <listitem>
1961 <para>
1962 Name of a local relation, for example <literal>foo</literal> or
1963 <literal>myschema.mytab</literal>. Include double quotes if the
1964 name is mixed-case or contains special characters, for
1965 example <literal>"FooBar"</literal>; without quotes, the string
1966 will be folded to lower case.
1967 </para>
1968 </listitem>
1969 </varlistentry>
1971 <varlistentry>
1972 <term><parameter>primary_key_attnums</parameter></term>
1973 <listitem>
1974 <para>
1975 Attribute numbers (1-based) of the primary key fields,
1976 for example <literal>1 2</literal>.
1977 </para>
1978 </listitem>
1979 </varlistentry>
1981 <varlistentry>
1982 <term><parameter>num_primary_key_atts</parameter></term>
1983 <listitem>
1984 <para>
1985 The number of primary key fields.
1986 </para>
1987 </listitem>
1988 </varlistentry>
1990 <varlistentry>
1991 <term><parameter>tgt_pk_att_vals_array</parameter></term>
1992 <listitem>
1993 <para>
1994 Values of the primary key fields to be used in the resulting
1995 <command>DELETE</command> command. Each field is represented in text form.
1996 </para>
1997 </listitem>
1998 </varlistentry>
1999 </variablelist>
2000 </refsect1>
2002 <refsect1>
2003 <title>Return Value</title>
2005 <para>Returns the requested SQL statement as text.</para>
2006 </refsect1>
2008 <refsect1>
2009 <title>Notes</title>
2011 <para>
2012 As of <productname>PostgreSQL</productname> 9.0, the attribute numbers in
2013 <parameter>primary_key_attnums</parameter> are interpreted as logical
2014 column numbers, corresponding to the column's position in
2015 <literal>SELECT * FROM relname</literal>. Previous versions interpreted the
2016 numbers as physical column positions. There is a difference if any
2017 column(s) to the left of the indicated column have been dropped during
2018 the lifetime of the table.
2019 </para>
2020 </refsect1>
2022 <refsect1>
2023 <title>Examples</title>
2025 <screen>
2026 SELECT dblink_build_sql_delete('"MyFoo"', '1 2', 2, '{"1", "b"}');
2027 dblink_build_sql_delete
2028 ---------------------------------------------
2029 DELETE FROM "MyFoo" WHERE f1='1' AND f2='b'
2030 (1 row)
2031 </screen>
2032 </refsect1>
2033 </refentry>
2035 <refentry id="contrib-dblink-build-sql-update">
2036 <indexterm>
2037 <primary>dblink_build_sql_update</primary>
2038 </indexterm>
2040 <refmeta>
2041 <refentrytitle>dblink_build_sql_update</refentrytitle>
2042 <manvolnum>3</manvolnum>
2043 </refmeta>
2045 <refnamediv>
2046 <refname>dblink_build_sql_update</refname>
2047 <refpurpose>builds an UPDATE statement using a local tuple, replacing
2048 the primary key field values with alternative supplied values
2049 </refpurpose>
2050 </refnamediv>
2052 <refsynopsisdiv>
2053 <synopsis>
2054 dblink_build_sql_update(text relname,
2055 int2vector primary_key_attnums,
2056 integer num_primary_key_atts,
2057 text[] src_pk_att_vals_array,
2058 text[] tgt_pk_att_vals_array) returns text
2059 </synopsis>
2060 </refsynopsisdiv>
2062 <refsect1>
2063 <title>Description</title>
2065 <para>
2066 <function>dblink_build_sql_update</function> can be useful in doing selective
2067 replication of a local table to a remote database. It selects a row
2068 from the local table based on primary key, and then builds an SQL
2069 <command>UPDATE</command> command that will duplicate that row, but with
2070 the primary key values replaced by the values in the last argument.
2071 (To make an exact copy of the row, just specify the same values for
2072 the last two arguments.) The <command>UPDATE</command> command always assigns
2073 all fields of the row &mdash; the main difference between this and
2074 <function>dblink_build_sql_insert</function> is that it's assumed that
2075 the target row already exists in the remote table.
2076 </para>
2077 </refsect1>
2079 <refsect1>
2080 <title>Arguments</title>
2082 <variablelist>
2083 <varlistentry>
2084 <term><parameter>relname</parameter></term>
2085 <listitem>
2086 <para>
2087 Name of a local relation, for example <literal>foo</literal> or
2088 <literal>myschema.mytab</literal>. Include double quotes if the
2089 name is mixed-case or contains special characters, for
2090 example <literal>"FooBar"</literal>; without quotes, the string
2091 will be folded to lower case.
2092 </para>
2093 </listitem>
2094 </varlistentry>
2096 <varlistentry>
2097 <term><parameter>primary_key_attnums</parameter></term>
2098 <listitem>
2099 <para>
2100 Attribute numbers (1-based) of the primary key fields,
2101 for example <literal>1 2</literal>.
2102 </para>
2103 </listitem>
2104 </varlistentry>
2106 <varlistentry>
2107 <term><parameter>num_primary_key_atts</parameter></term>
2108 <listitem>
2109 <para>
2110 The number of primary key fields.
2111 </para>
2112 </listitem>
2113 </varlistentry>
2115 <varlistentry>
2116 <term><parameter>src_pk_att_vals_array</parameter></term>
2117 <listitem>
2118 <para>
2119 Values of the primary key fields to be used to look up the
2120 local tuple. Each field is represented in text form.
2121 An error is thrown if there is no local row with these
2122 primary key values.
2123 </para>
2124 </listitem>
2125 </varlistentry>
2127 <varlistentry>
2128 <term><parameter>tgt_pk_att_vals_array</parameter></term>
2129 <listitem>
2130 <para>
2131 Values of the primary key fields to be placed in the resulting
2132 <command>UPDATE</command> command. Each field is represented in text form.
2133 </para>
2134 </listitem>
2135 </varlistentry>
2136 </variablelist>
2137 </refsect1>
2139 <refsect1>
2140 <title>Return Value</title>
2142 <para>Returns the requested SQL statement as text.</para>
2143 </refsect1>
2145 <refsect1>
2146 <title>Notes</title>
2148 <para>
2149 As of <productname>PostgreSQL</productname> 9.0, the attribute numbers in
2150 <parameter>primary_key_attnums</parameter> are interpreted as logical
2151 column numbers, corresponding to the column's position in
2152 <literal>SELECT * FROM relname</literal>. Previous versions interpreted the
2153 numbers as physical column positions. There is a difference if any
2154 column(s) to the left of the indicated column have been dropped during
2155 the lifetime of the table.
2156 </para>
2157 </refsect1>
2159 <refsect1>
2160 <title>Examples</title>
2162 <screen>
2163 SELECT dblink_build_sql_update('foo', '1 2', 2, '{"1", "a"}', '{"1", "b"}');
2164 dblink_build_sql_update
2165 -------------------------------------------------------------
2166 UPDATE foo SET f1='1',f2='b',f3='1' WHERE f1='1' AND f2='b'
2167 (1 row)
2168 </screen>
2169 </refsect1>
2170 </refentry>
2172 </sect1>