-
Notifications
You must be signed in to change notification settings - Fork 3
/
Copy pathdblink.sgml
2029 lines (1727 loc) · 53.2 KB
/
dblink.sgml
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
316
317
318
319
320
321
322
323
324
325
326
327
328
329
330
331
332
333
334
335
336
337
338
339
340
341
342
343
344
345
346
347
348
349
350
351
352
353
354
355
356
357
358
359
360
361
362
363
364
365
366
367
368
369
370
371
372
373
374
375
376
377
378
379
380
381
382
383
384
385
386
387
388
389
390
391
392
393
394
395
396
397
398
399
400
401
402
403
404
405
406
407
408
409
410
411
412
413
414
415
416
417
418
419
420
421
422
423
424
425
426
427
428
429
430
431
432
433
434
435
436
437
438
439
440
441
442
443
444
445
446
447
448
449
450
451
452
453
454
455
456
457
458
459
460
461
462
463
464
465
466
467
468
469
470
471
472
473
474
475
476
477
478
479
480
481
482
483
484
485
486
487
488
489
490
491
492
493
494
495
496
497
498
499
500
501
502
503
504
505
506
507
508
509
510
511
512
513
514
515
516
517
518
519
520
521
522
523
524
525
526
527
528
529
530
531
532
533
534
535
536
537
538
539
540
541
542
543
544
545
546
547
548
549
550
551
552
553
554
555
556
557
558
559
560
561
562
563
564
565
566
567
568
569
570
571
572
573
574
575
576
577
578
579
580
581
582
583
584
585
586
587
588
589
590
591
592
593
594
595
596
597
598
599
600
601
602
603
604
605
606
607
608
609
610
611
612
613
614
615
616
617
618
619
620
621
622
623
624
625
626
627
628
629
630
631
632
633
634
635
636
637
638
639
640
641
642
643
644
645
646
647
648
649
650
651
652
653
654
655
656
657
658
659
660
661
662
663
664
665
666
667
668
669
670
671
672
673
674
675
676
677
678
679
680
681
682
683
684
685
686
687
688
689
690
691
692
693
694
695
696
697
698
699
700
701
702
703
704
705
706
707
708
709
710
711
712
713
714
715
716
717
718
719
720
721
722
723
724
725
726
727
728
729
730
731
732
733
734
735
736
737
738
739
740
741
742
743
744
745
746
747
748
749
750
751
752
753
754
755
756
757
758
759
760
761
762
763
764
765
766
767
768
769
770
771
772
773
774
775
776
777
778
779
780
781
782
783
784
785
786
787
788
789
790
791
792
793
794
795
796
797
798
799
800
801
802
803
804
805
806
807
808
809
810
811
812
813
814
815
816
817
818
819
820
821
822
823
824
825
826
827
828
829
830
831
832
833
834
835
836
837
838
839
840
841
842
843
844
845
846
847
848
849
850
851
852
853
854
855
856
857
858
859
860
861
862
863
864
865
866
867
868
869
870
871
872
873
874
875
876
877
878
879
880
881
882
883
884
885
886
887
888
889
890
891
892
893
894
895
896
897
898
899
900
901
902
903
904
905
906
907
908
909
910
911
912
913
914
915
916
917
918
919
920
921
922
923
924
925
926
927
928
929
930
931
932
933
934
935
936
937
938
939
940
941
942
943
944
945
946
947
948
949
950
951
952
953
954
955
956
957
958
959
960
961
962
963
964
965
966
967
968
969
970
971
972
973
974
975
976
977
978
979
980
981
982
983
984
985
986
987
988
989
990
991
992
993
994
995
996
997
998
999
1000
<!-- doc/src/sgml/dblink.sgml -->
<sect1 id="dblink" xreflabel="dblink">
<title>dblink</title>
<indexterm zone="dblink">
<primary>dblink</primary>
</indexterm>
<para>
<filename>dblink</> is a module which supports connections to
other <productname>PostgreSQL</> databases from within a database
session.
</para>
<refentry id="CONTRIB-DBLINK-CONNECT">
<refmeta>
<refentrytitle>dblink_connect</refentrytitle>
<manvolnum>3</manvolnum>
</refmeta>
<refnamediv>
<refname>dblink_connect</refname>
<refpurpose>opens a persistent connection to a remote database</refpurpose>
</refnamediv>
<refsynopsisdiv>
<synopsis>
dblink_connect(text connstr) returns text
dblink_connect(text connname, text connstr) returns text
</synopsis>
</refsynopsisdiv>
<refsect1>
<title>Description</title>
<para>
<function>dblink_connect()</> establishes a connection to a remote
<productname>PostgreSQL</> database. The server and database to
be contacted are identified through a standard <application>libpq</>
connection string. Optionally, a name can be assigned to the
connection. Multiple named connections can be open at once, but
only one unnamed connection is permitted at a time. The connection
will persist until closed or until the database session is ended.
</para>
<para>
The connection string may also be the name of an existing foreign
server. It is recommended to use
the <function>postgresql_fdw_validator</function> when defining
the corresponding foreign-data wrapper. See the example below, as
well as the following:
<simplelist type="inline">
<member><xref linkend="sql-createforeigndatawrapper"></member>
<member><xref linkend="sql-createserver"></member>
<member><xref linkend="sql-createusermapping"></member>
</simplelist>
</para>
</refsect1>
<refsect1>
<title>Arguments</title>
<variablelist>
<varlistentry>
<term><parameter>conname</parameter></term>
<listitem>
<para>
The name to use for this connection; if omitted, an unnamed
connection is opened, replacing any existing unnamed connection.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><parameter>connstr</parameter></term>
<listitem>
<para><application>libpq</>-style connection info string, for example
<literal>hostaddr=127.0.0.1 port=5432 dbname=mydb user=postgres
password=mypasswd</>.
For details see <function>PQconnectdb</> in
<xref linkend="libpq-connect">.
</para>
</listitem>
</varlistentry>
</variablelist>
</refsect1>
<refsect1>
<title>Return Value</title>
<para>
Returns status, which is always <literal>OK</> (since any error
causes the function to throw an error instead of returning).
</para>
</refsect1>
<refsect1>
<title>Notes</title>
<para>
Only superusers may use <function>dblink_connect</> to create
non-password-authenticated connections. If non-superusers need this
capability, use <function>dblink_connect_u</> instead.
</para>
<para>
It is unwise to choose connection names that contain equal signs,
as this opens a risk of confusion with connection info strings
in other <filename>dblink</> functions.
</para>
</refsect1>
<refsect1>
<title>Examples</title>
<screen>
SELECT dblink_connect('dbname=postgres');
dblink_connect
----------------
OK
(1 row)
SELECT dblink_connect('myconn', 'dbname=postgres');
dblink_connect
----------------
OK
(1 row)
-- FOREIGN DATA WRAPPER functionality
-- Note: local connection must require password authentication for this to work properly
-- Otherwise, you will receive the following error from dblink_connect():
-- ----------------------------------------------------------------------
-- ERROR: password is required
-- DETAIL: Non-superuser cannot connect if the server does not request a password.
-- HINT: Target server's authentication method must be changed.
CREATE USER dblink_regression_test WITH PASSWORD 'secret';
CREATE FOREIGN DATA WRAPPER postgresql VALIDATOR postgresql_fdw_validator;
CREATE SERVER fdtest FOREIGN DATA WRAPPER postgresql OPTIONS (hostaddr '127.0.0.1', dbname 'contrib_regression');
CREATE USER MAPPING FOR dblink_regression_test SERVER fdtest OPTIONS (user 'dblink_regression_test', password 'secret');
GRANT USAGE ON FOREIGN SERVER fdtest TO dblink_regression_test;
GRANT SELECT ON TABLE foo TO dblink_regression_test;
\set ORIGINAL_USER :USER
\c - dblink_regression_test
SELECT dblink_connect('myconn', 'fdtest');
dblink_connect
----------------
OK
(1 row)
SELECT * FROM dblink('myconn','SELECT * FROM foo') AS t(a int, b text, c text[]);
a | b | c
----+---+---------------
0 | a | {a0,b0,c0}
1 | b | {a1,b1,c1}
2 | c | {a2,b2,c2}
3 | d | {a3,b3,c3}
4 | e | {a4,b4,c4}
5 | f | {a5,b5,c5}
6 | g | {a6,b6,c6}
7 | h | {a7,b7,c7}
8 | i | {a8,b8,c8}
9 | j | {a9,b9,c9}
10 | k | {a10,b10,c10}
(11 rows)
\c - :ORIGINAL_USER
REVOKE USAGE ON FOREIGN SERVER fdtest FROM dblink_regression_test;
REVOKE SELECT ON TABLE foo FROM dblink_regression_test;
DROP USER MAPPING FOR dblink_regression_test SERVER fdtest;
DROP USER dblink_regression_test;
DROP SERVER fdtest;
DROP FOREIGN DATA WRAPPER postgresql;
</screen>
</refsect1>
</refentry>
<refentry id="CONTRIB-DBLINK-CONNECT-U">
<refmeta>
<refentrytitle>dblink_connect_u</refentrytitle>
<manvolnum>3</manvolnum>
</refmeta>
<refnamediv>
<refname>dblink_connect_u</refname>
<refpurpose>opens a persistent connection to a remote database, insecurely</refpurpose>
</refnamediv>
<refsynopsisdiv>
<synopsis>
dblink_connect_u(text connstr) returns text
dblink_connect_u(text connname, text connstr) returns text
</synopsis>
</refsynopsisdiv>
<refsect1>
<title>Description</title>
<para>
<function>dblink_connect_u()</> is identical to
<function>dblink_connect()</>, except that it will allow non-superusers
to connect using any authentication method.
</para>
<para>
If the remote server selects an authentication method that does not
involve a password, then impersonation and subsequent escalation of
privileges can occur, because the session will appear to have
originated from the user as which the local <productname>PostgreSQL</>
server runs. Also, even if the remote server does demand a password,
it is possible for the password to be supplied from the server
environment, such as a <filename>~/.pgpass</> file belonging to the
server's user. This opens not only a risk of impersonation, but the
possibility of exposing a password to an untrustworthy remote server.
Therefore, <function>dblink_connect_u()</> is initially
installed with all privileges revoked from <literal>PUBLIC</>,
making it un-callable except by superusers. In some situations
it may be appropriate to grant <literal>EXECUTE</> permission for
<function>dblink_connect_u()</> to specific users who are considered
trustworthy, but this should be done with care. It is also recommended
that any <filename>~/.pgpass</> file belonging to the server's user
<emphasis>not</> contain any records specifying a wildcard host name.
</para>
<para>
For further details see <function>dblink_connect()</>.
</para>
</refsect1>
</refentry>
<refentry id="CONTRIB-DBLINK-DISCONNECT">
<refmeta>
<refentrytitle>dblink_disconnect</refentrytitle>
<manvolnum>3</manvolnum>
</refmeta>
<refnamediv>
<refname>dblink_disconnect</refname>
<refpurpose>closes a persistent connection to a remote database</refpurpose>
</refnamediv>
<refsynopsisdiv>
<synopsis>
dblink_disconnect() returns text
dblink_disconnect(text connname) returns text
</synopsis>
</refsynopsisdiv>
<refsect1>
<title>Description</title>
<para>
<function>dblink_disconnect()</> closes a connection previously opened
by <function>dblink_connect()</>. The form with no arguments closes
an unnamed connection.
</para>
</refsect1>
<refsect1>
<title>Arguments</title>
<variablelist>
<varlistentry>
<term><parameter>conname</parameter></term>
<listitem>
<para>
The name of a named connection to be closed.
</para>
</listitem>
</varlistentry>
</variablelist>
</refsect1>
<refsect1>
<title>Return Value</title>
<para>
Returns status, which is always <literal>OK</> (since any error
causes the function to throw an error instead of returning).
</para>
</refsect1>
<refsect1>
<title>Examples</title>
<screen>
SELECT dblink_disconnect();
dblink_disconnect
-------------------
OK
(1 row)
SELECT dblink_disconnect('myconn');
dblink_disconnect
-------------------
OK
(1 row)
</screen>
</refsect1>
</refentry>
<refentry id="CONTRIB-DBLINK-FUNCTION">
<refmeta>
<refentrytitle>dblink</refentrytitle>
<manvolnum>3</manvolnum>
</refmeta>
<refnamediv>
<refname>dblink</refname>
<refpurpose>executes a query in a remote database</refpurpose>
</refnamediv>
<refsynopsisdiv>
<synopsis>
dblink(text connname, text sql [, bool fail_on_error]) returns setof record
dblink(text connstr, text sql [, bool fail_on_error]) returns setof record
dblink(text sql [, bool fail_on_error]) returns setof record
</synopsis>
</refsynopsisdiv>
<refsect1>
<title>Description</title>
<para>
<function>dblink</> executes a query (usually a <command>SELECT</>,
but it can be any SQL statement that returns rows) in a remote database.
</para>
<para>
When two <type>text</> arguments are given, the first one is first
looked up as a persistent connection's name; if found, the command
is executed on that connection. If not found, the first argument
is treated as a connection info string as for <function>dblink_connect</>,
and the indicated connection is made just for the duration of this command.
</para>
</refsect1>
<refsect1>
<title>Arguments</title>
<variablelist>
<varlistentry>
<term><parameter>conname</parameter></term>
<listitem>
<para>
Name of the connection to use; omit this parameter to use the
unnamed connection.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><parameter>connstr</parameter></term>
<listitem>
<para>
A connection info string, as previously described for
<function>dblink_connect</>.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><parameter>sql</parameter></term>
<listitem>
<para>
The SQL query that you wish to execute in the remote database,
for example <literal>select * from foo</>.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><parameter>fail_on_error</parameter></term>
<listitem>
<para>
If true (the default when omitted) 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 reported as a NOTICE,
and the function returns no rows.
</para>
</listitem>
</varlistentry>
</variablelist>
</refsect1>
<refsect1>
<title>Return Value</title>
<para>
The function returns the row(s) produced by the query. Since
<function>dblink</> can be used with any query, it is declared
to return <type>record</>, rather than specifying any particular
set of columns. This means that you must specify the expected
set of columns in the calling query — otherwise
<productname>PostgreSQL</> would not know what to expect.
Here is an example:
<programlisting>
SELECT *
FROM dblink('dbname=mydb', 'select proname, prosrc from pg_proc')
AS t1(proname name, prosrc text)
WHERE proname LIKE 'bytea%';
</programlisting>
The <quote>alias</> part of the <literal>FROM</> clause must
specify the column names and types that the function will return.
(Specifying column names in an alias is actually standard SQL
syntax, but specifying column types is a <productname>PostgreSQL</>
extension.) This allows the system to understand what
<literal>*</> should expand to, and what <structname>proname</>
in the <literal>WHERE</> clause refers to, in advance of trying
to execute the function. At run time, an error will be thrown
if the actual query result from the remote database does not
have the same number of columns shown in the <literal>FROM</> clause.
The column names need not match, however, and <function>dblink</>
does not insist on exact type matches either. It will succeed
so long as the returned data strings are valid input for the
column type declared in the <literal>FROM</> clause.
</para>
</refsect1>
<refsect1>
<title>Notes</title>
<para>
<function>dblink</> fetches the entire remote query result before
returning any of it to the local system. If the query is expected
to return a large number of rows, it's better to open it as a cursor
with <function>dblink_open</> and then fetch a manageable number
of rows at a time.
</para>
<para>
A convenient way to use <function>dblink</> with predetermined
queries is to create a view.
This allows the column type information to be buried in the view,
instead of having to spell it out in every query. For example,
<programlisting>
CREATE VIEW myremote_pg_proc AS
SELECT *
FROM dblink('dbname=postgres', 'select proname, prosrc from pg_proc')
AS t1(proname name, prosrc text);
SELECT * FROM myremote_pg_proc WHERE proname LIKE 'bytea%';
</programlisting></para>
</refsect1>
<refsect1>
<title>Examples</title>
<screen>
SELECT * FROM dblink('dbname=postgres', 'select proname, prosrc from pg_proc')
AS t1(proname name, prosrc text) WHERE proname LIKE 'bytea%';
proname | prosrc
------------+------------
byteacat | byteacat
byteaeq | byteaeq
bytealt | bytealt
byteale | byteale
byteagt | byteagt
byteage | byteage
byteane | byteane
byteacmp | byteacmp
bytealike | bytealike
byteanlike | byteanlike
byteain | byteain
byteaout | byteaout
(12 rows)
SELECT dblink_connect('dbname=postgres');
dblink_connect
----------------
OK
(1 row)
SELECT * FROM dblink('select proname, prosrc from pg_proc')
AS t1(proname name, prosrc text) WHERE proname LIKE 'bytea%';
proname | prosrc
------------+------------
byteacat | byteacat
byteaeq | byteaeq
bytealt | bytealt
byteale | byteale
byteagt | byteagt
byteage | byteage
byteane | byteane
byteacmp | byteacmp
bytealike | bytealike
byteanlike | byteanlike
byteain | byteain
byteaout | byteaout
(12 rows)
SELECT dblink_connect('myconn', 'dbname=regression');
dblink_connect
----------------
OK
(1 row)
SELECT * FROM dblink('myconn', 'select proname, prosrc from pg_proc')
AS t1(proname name, prosrc text) WHERE proname LIKE 'bytea%';
proname | prosrc
------------+------------
bytearecv | bytearecv
byteasend | byteasend
byteale | byteale
byteagt | byteagt
byteage | byteage
byteane | byteane
byteacmp | byteacmp
bytealike | bytealike
byteanlike | byteanlike
byteacat | byteacat
byteaeq | byteaeq
bytealt | bytealt
byteain | byteain
byteaout | byteaout
(14 rows)
</screen>
</refsect1>
</refentry>
<refentry id="CONTRIB-DBLINK-EXEC">
<refmeta>
<refentrytitle>dblink_exec</refentrytitle>
<manvolnum>3</manvolnum>
</refmeta>
<refnamediv>
<refname>dblink_exec</refname>
<refpurpose>executes a command in a remote database</refpurpose>
</refnamediv>
<refsynopsisdiv>
<synopsis>
dblink_exec(text connname, text sql [, bool fail_on_error]) returns text
dblink_exec(text connstr, text sql [, bool fail_on_error]) returns text
dblink_exec(text sql [, bool fail_on_error]) returns text
</synopsis>
</refsynopsisdiv>
<refsect1>
<title>Description</title>
<para>
<function>dblink_exec</> executes a command (that is, any SQL statement
that doesn't return rows) in a remote database.
</para>
<para>
When two <type>text</> arguments are given, the first one is first
looked up as a persistent connection's name; if found, the command
is executed on that connection. If not found, the first argument
is treated as a connection info string as for <function>dblink_connect</>,
and the indicated connection is made just for the duration of this command.
</para>
</refsect1>
<refsect1>
<title>Arguments</title>
<variablelist>
<varlistentry>
<term><parameter>conname</parameter></term>
<listitem>
<para>
Name of the connection to use; omit this parameter to use the
unnamed connection.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><parameter>connstr</parameter></term>
<listitem>
<para>
A connection info string, as previously described for
<function>dblink_connect</>.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><parameter>sql</parameter></term>
<listitem>
<para>
The SQL command that you wish to execute in the remote database,
for example
<literal>insert into foo values(0,'a','{"a0","b0","c0"}')</>.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><parameter>fail_on_error</parameter></term>
<listitem>
<para>
If true (the default when omitted) 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 reported as a NOTICE,
and the function's return value is set to <literal>ERROR</>.
</para>
</listitem>
</varlistentry>
</variablelist>
</refsect1>
<refsect1>
<title>Return Value</title>
<para>
Returns status, either the command's status string or <literal>ERROR</>.
</para>
</refsect1>
<refsect1>
<title>Examples</title>
<screen>
SELECT dblink_connect('dbname=dblink_test_standby');
dblink_connect
----------------
OK
(1 row)
SELECT dblink_exec('insert into foo values(21,''z'',''{"a0","b0","c0"}'');');
dblink_exec
-----------------
INSERT 943366 1
(1 row)
SELECT dblink_connect('myconn', 'dbname=regression');
dblink_connect
----------------
OK
(1 row)
SELECT dblink_exec('myconn', 'insert into foo values(21,''z'',''{"a0","b0","c0"}'');');
dblink_exec
------------------
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)
</screen>
</refsect1>
</refentry>
<refentry id="CONTRIB-DBLINK-OPEN">
<refmeta>
<refentrytitle>dblink_open</refentrytitle>
<manvolnum>3</manvolnum>
</refmeta>
<refnamediv>
<refname>dblink_open</refname>
<refpurpose>opens a cursor in a remote database</refpurpose>
</refnamediv>
<refsynopsisdiv>
<synopsis>
dblink_open(text cursorname, text sql [, bool fail_on_error]) returns text
dblink_open(text connname, text cursorname, text sql [, bool fail_on_error]) returns text
</synopsis>
</refsynopsisdiv>
<refsect1>
<title>Description</title>
<para>
<function>dblink_open()</> opens a cursor in a remote database.
The cursor can subsequently be manipulated with
<function>dblink_fetch()</> and <function>dblink_close()</>.
</para>
</refsect1>
<refsect1>
<title>Arguments</title>
<variablelist>
<varlistentry>
<term><parameter>conname</parameter></term>
<listitem>
<para>
Name of the connection to use; omit this parameter to use the
unnamed connection.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><parameter>cursorname</parameter></term>
<listitem>
<para>
The name to assign to this cursor.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><parameter>sql</parameter></term>
<listitem>
<para>
The <command>SELECT</> statement that you wish to execute in the remote
database, for example <literal>select * from pg_class</>.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><parameter>fail_on_error</parameter></term>
<listitem>
<para>
If true (the default when omitted) 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 reported as a NOTICE,
and the function's return value is set to <literal>ERROR</>.
</para>
</listitem>
</varlistentry>
</variablelist>
</refsect1>
<refsect1>
<title>Return Value</title>
<para>
Returns status, either <literal>OK</> or <literal>ERROR</>.
</para>
</refsect1>
<refsect1>
<title>Notes</title>
<para>
Since a cursor can only persist within a transaction,
<function>dblink_open</> starts an explicit transaction block
(<command>BEGIN</>) on the remote side, if the remote side was
not already within a transaction. This transaction will be
closed again when the matching <function>dblink_close</> is
executed. Note that if
you use <function>dblink_exec</> to change data between
<function>dblink_open</> and <function>dblink_close</>,
and then an error occurs or you use <function>dblink_disconnect</> before
<function>dblink_close</>, your change <emphasis>will be
lost</> because the transaction will be aborted.
</para>
</refsect1>
<refsect1>
<title>Examples</title>
<screen>
SELECT dblink_connect('dbname=postgres');
dblink_connect
----------------
OK
(1 row)
SELECT dblink_open('foo', 'select proname, prosrc from pg_proc');
dblink_open
-------------
OK
(1 row)
</screen>
</refsect1>
</refentry>
<refentry id="CONTRIB-DBLINK-FETCH">
<refmeta>
<refentrytitle>dblink_fetch</refentrytitle>
<manvolnum>3</manvolnum>
</refmeta>
<refnamediv>
<refname>dblink_fetch</refname>
<refpurpose>returns rows from an open cursor in a remote database</refpurpose>
</refnamediv>
<refsynopsisdiv>
<synopsis>
dblink_fetch(text cursorname, int howmany [, bool fail_on_error]) returns setof record
dblink_fetch(text connname, text cursorname, int howmany [, bool fail_on_error]) returns setof record
</synopsis>
</refsynopsisdiv>
<refsect1>
<title>Description</title>
<para>
<function>dblink_fetch</> fetches rows from a cursor previously
established by <function>dblink_open</>.
</para>
</refsect1>
<refsect1>
<title>Arguments</title>
<variablelist>
<varlistentry>
<term><parameter>conname</parameter></term>
<listitem>
<para>
Name of the connection to use; omit this parameter to use the
unnamed connection.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><parameter>cursorname</parameter></term>
<listitem>
<para>
The name of the cursor to fetch from.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><parameter>howmany</parameter></term>
<listitem>
<para>
The maximum number of rows to retrieve. The next <parameter>howmany</>
rows are fetched, starting at the current cursor position, moving
forward. Once the cursor has reached its end, no more rows are produced.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><parameter>fail_on_error</parameter></term>
<listitem>
<para>
If true (the default when omitted) 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 reported as a NOTICE,
and the function returns no rows.
</para>
</listitem>
</varlistentry>
</variablelist>
</refsect1>
<refsect1>
<title>Return Value</title>
<para>
The function returns the row(s) fetched from the cursor. To use this
function, you will need to specify the expected set of columns,
as previously discussed for <function>dblink</>.
</para>
</refsect1>
<refsect1>
<title>Notes</title>
<para>
On a mismatch between the number of return columns specified in the
<literal>FROM</> clause, and the actual number of columns returned by the
remote cursor, an error will be thrown. In this event, the remote cursor
is still advanced by as many rows as it would have been if the error had
not occurred. The same is true for any other error occurring in the local
query after the remote <command>FETCH</> has been done.
</para>
</refsect1>
<refsect1>
<title>Examples</title>
<screen>
SELECT dblink_connect('dbname=postgres');
dblink_connect
----------------
OK
(1 row)
SELECT dblink_open('foo', 'select proname, prosrc from pg_proc where proname like ''bytea%''');
dblink_open
-------------
OK
(1 row)
SELECT * FROM dblink_fetch('foo', 5) AS (funcname name, source text);
funcname | source
----------+----------
byteacat | byteacat
byteacmp | byteacmp
byteaeq | byteaeq
byteage | byteage
byteagt | byteagt
(5 rows)
SELECT * FROM dblink_fetch('foo', 5) AS (funcname name, source text);
funcname | source
-----------+-----------
byteain | byteain
byteale | byteale
bytealike | bytealike
bytealt | bytealt
byteane | byteane
(5 rows)
SELECT * FROM dblink_fetch('foo', 5) AS (funcname name, source text);
funcname | source
------------+------------
byteanlike | byteanlike
byteaout | byteaout
(2 rows)
SELECT * FROM dblink_fetch('foo', 5) AS (funcname name, source text);
funcname | source
----------+--------
(0 rows)
</screen>
</refsect1>
</refentry>
<refentry id="CONTRIB-DBLINK-CLOSE">
<refmeta>
<refentrytitle>dblink_close</refentrytitle>
<manvolnum>3</manvolnum>
</refmeta>
<refnamediv>
<refname>dblink_close</refname>
<refpurpose>closes a cursor in a remote database</refpurpose>
</refnamediv>
<refsynopsisdiv>
<synopsis>
dblink_close(text cursorname [, bool fail_on_error]) returns text
dblink_close(text connname, text cursorname [, bool fail_on_error]) returns text
</synopsis>
</refsynopsisdiv>
<refsect1>
<title>Description</title>
<para>
<function>dblink_close</> closes a cursor previously opened with
<function>dblink_open</>.
</para>
</refsect1>
<refsect1>
<title>Arguments</title>
<variablelist>
<varlistentry>
<term><parameter>conname</parameter></term>
<listitem>
<para>
Name of the connection to use; omit this parameter to use the
unnamed connection.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><parameter>cursorname</parameter></term>
<listitem>
<para>
The name of the cursor to close.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><parameter>fail_on_error</parameter></term>
<listitem>
<para>
If true (the default when omitted) 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 reported as a NOTICE,
and the function's return value is set to <literal>ERROR</>.
</para>
</listitem>
</varlistentry>
</variablelist>
</refsect1>
<refsect1>
<title>Return Value</title>
<para>
Returns status, either <literal>OK</> or <literal>ERROR</>.
</para>
</refsect1>