1Pg(3) User Contributed Perl Documentation Pg(3)
2
3
4
6 DBD::Pg - PostgreSQL database driver for the DBI module
7
9 use DBI;
10
11 $dbh = DBI->connect("dbi:Pg:dbname=$dbname", '', '', {AutoCommit => 0});
12 # The AutoCommit attribute should always be explicitly set
13
14 # For some advanced uses you may need PostgreSQL type values:
15 use DBD::Pg qw(:pg_types);
16
17 $dbh->do('INSERT INTO mytable(a) VALUES (1)');
18
19 $sth = $dbh->prepare('INSERT INTO mytable(a) VALUES (?)');
20 $sth->execute();
21
23 This documents version 3.10.5 of the DBD::Pg module
24
26 DBD::Pg is a Perl module that works with the DBI module to provide
27 access to PostgreSQL databases.
28
30 This documentation describes driver specific behavior and restrictions.
31 It is not supposed to be used as the only reference for the user. In
32 any case consult the DBI documentation first!
33
34 Latest DBI documentation.
35
37 DBI Class Methods
38 connect
39
40 This method creates a database handle by connecting to a database, and
41 is the DBI equivalent of the "new" method. To connect to a Postgres
42 database with a minimum of parameters, use the following syntax:
43
44 $dbh = DBI->connect("dbi:Pg:dbname=$dbname", '', '', {AutoCommit => 0});
45
46 This connects to the database named in the $dbname variable on the
47 default port (usually 5432) without any user authentication.
48
49 The following connect statement shows almost all possible parameters:
50
51 $dbh = DBI->connect("dbi:Pg:dbname=$dbname;host=$host;port=$port;options=$options",
52 $username,
53 $password,
54 {AutoCommit => 0, RaiseError => 1, PrintError => 0}
55 );
56
57 Parameters containing unusual characters such as spaces can be wrapped
58 in single quotes around the value e.g. "dbi:Pg:dbname='spacey
59 name';host=$host"
60
61 If a parameter is not given, the connect() method will first look for
62 specific environment variables, and then fall back to hard-coded
63 defaults:
64
65 parameter environment variable hard coded default
66 ------------------------------------------------------
67 host PGHOST local domain socket
68 hostaddr PGHOSTADDR local domain socket
69 port PGPORT 5432
70 dbname* PGDATABASE current userid
71 username PGUSER current userid
72 password PGPASSWORD (none)
73 options PGOPTIONS (none)
74 service PGSERVICE (none)
75 sslmode PGSSLMODE (none)
76
77 * May also use the aliases "db" or "database"
78
79 If the username and password values passed via "connect()" are
80 undefined (as opposed to merely being empty strings), DBI will use the
81 environment variables DBI_USER and DBI_PASS if they exist.
82
83 You can also connect by using a service connection file, which is named
84 pg_service.conf. The location of this file can be controlled by setting
85 the PGSYSCONFDIR environment variable. To use one of the named services
86 within the file, set the name by using either the service parameter or
87 the environment variable PGSERVICE. Note that when connecting this way,
88 only the minimum parameters should be used. For example, to connect to
89 a service named "zephyr", you could use:
90
91 $dbh = DBI->connect("dbi:Pg:service=zephyr", '', '');
92
93 You could also set $ENV{PGSERVICE} to "zephyr" and connect like this:
94
95 $dbh = DBI->connect("dbi:Pg:", '', '');
96
97 The format of the pg_service.conf file is simply a bracketed service
98 name, followed by one parameter per line in the format name=value. For
99 example:
100
101 [zephyr]
102 dbname=winds
103 user=wisp
104 password=W$2Hc00YSgP
105 port=6543
106
107 There are four valid arguments to the sslmode parameter, which controls
108 whether to use SSL to connect to the database:
109
110 · disable: SSL connections are never used
111
112 · allow: try non-SSL, then SSL
113
114 · prefer: try SSL, then non-SSL
115
116 · require: connect only with SSL
117
118 You can also connect using sockets in a specific directory. This may be
119 needed if the server you are connecting to has a different default
120 socket directory from the one used to compile DBD::Pg. Use the
121 complete path to the socket directory as the name of the host, like
122 this:
123
124 $dbh = DBI->connect('dbi:Pg:dbname=foo;host=/var/tmp/socket',
125 $username,
126 $password,
127 {AutoCommit => 0, RaiseError => 1});
128
129 The attribute hash can also contain a key named "dbd_verbose", which
130 simply calls "$dbh->trace('DBD')" after the handle is created. This
131 attribute is not recommended, as it is clearer to simply explicitly
132 call "trace" explicitly in your script.
133
134 connect_cached
135
136 $dbh = DBI->connect_cached("dbi:Pg:dbname=$dbname", $username, $password, \%options);
137
138 Implemented by DBI, no driver-specific impact.
139
140 data_sources
141
142 @data_sources = DBI->data_sources('Pg');
143 @data_sources = $dbh->data_sources();
144
145 Returns a list of available databases. Unless the environment variable
146 "DBI_DSN" is set, a connection will be attempted to the database
147 "template1". The normal connection environment variables also apply,
148 such as "PGHOST", "PGPORT", "DBI_USER", "DBI_PASS", and "PGSERVICE".
149
150 You can also pass in options to add to the connection string For
151 example, to specify an alternate port and host:
152
153 @data_sources = DBI->data_sources('Pg', 'port=5824;host=example.com');
154
155 or:
156
157 @data_sources = $dbh->data_sources('port=5824;host=example.com');
158
159 Methods Common To All Handles
160 For all of the methods below, $h can be either a database handle ($dbh)
161 or a statement handle ($sth). Note that $dbh and $sth can be replaced
162 with any variable name you choose: these are just the names most often
163 used. Another common variable used in this documentation is $rv, which
164 stands for "return value".
165
166 err
167
168 $rv = $h->err;
169
170 Returns the error code from the last method called. For the connect
171 method it returns "PQstatus", which is a number used by libpq (the
172 Postgres connection library). A value of 0 indicates no error
173 (CONNECTION_OK), while any other number indicates a failed connection.
174 The only other number commonly seen is 1 (CONNECTION_BAD). See the
175 libpq documentation for the complete list of return codes.
176
177 In all other non-connect methods "$h->err" returns the "PQresultStatus"
178 of the current handle. This is a number used by libpq and is one of:
179
180 0 Empty query string
181 1 A command that returns no data successfully completed.
182 2 A command that returns data successfully completed.
183 3 A COPY OUT command is still in progress.
184 4 A COPY IN command is still in progress.
185 5 A bad response was received from the backend.
186 6 A nonfatal error occurred (a notice or warning message)
187 7 A fatal error was returned: the last query failed.
188
189 errstr
190
191 $str = $h->errstr;
192
193 Returns the last error that was reported by Postgres. This message is
194 affected by the pg_errorlevel setting.
195
196 state
197
198 $str = $h->state;
199
200 Returns a five-character "SQLSTATE" code. Success is indicated by a
201 00000 code, which gets mapped to an empty string by DBI. A code of
202 "S8006" indicates a connection failure, usually because the connection
203 to the Postgres server has been lost.
204
205 While this method can be called as either "$sth->state" or
206 "$dbh->state", it is usually clearer to always use "$dbh->state".
207
208 The list of codes used by PostgreSQL can be found at:
209 <http://www.postgresql.org/docs/current/static/errcodes-appendix.html>
210
211 Note that these codes are part of the SQL standard and only a small
212 number of them will be used by PostgreSQL.
213
214 Common codes:
215
216 00000 Successful completion
217 25P01 No active SQL transaction
218 25P02 In failed SQL transaction
219 S8006 Connection failure
220
221 trace
222
223 $h->trace($trace_settings);
224 $h->trace($trace_settings, $trace_filename);
225 $trace_settings = $h->trace;
226
227 Changes the trace settings on a database or statement handle. The
228 optional second argument specifies a file to write the trace
229 information to. If no filename is given, the information is written to
230 STDERR. Note that tracing can be set globally as well by setting
231 "DBI->trace", or by using the environment variable DBI_TRACE.
232
233 The value is either a numeric level or a named flag. For the flags that
234 DBD::Pg uses, see parse_trace_flag.
235
236 trace_msg
237
238 $h->trace_msg($message_text);
239 $h->trace_msg($message_text, $min_level);
240
241 Writes a message to the current trace output (as set by the "trace"
242 method). If a second argument is given, the message is only written if
243 the current tracing level is equal to or greater than the $min_level.
244
245 parse_trace_flag and parse_trace_flags
246
247 $h->trace($h->parse_trace_flags('SQL|pglibpq'));
248 $h->trace($h->parse_trace_flags('1|pgstart'));
249
250 ## Simpler:
251 $h->trace('SQL|pglibpq');
252 $h->trace('1|pgstart');
253
254 my $value = DBD::Pg->parse_trace_flag('pglibpq');
255 DBI->trace($value);
256
257 The parse_trace_flags method is used to convert one or more named flags
258 to a number which can passed to the "trace" method. DBD::Pg currently
259 supports the DBI-specific flag, "SQL", as well as the ones listed
260 below.
261
262 Flags can be combined by using the parse_trace_flags method, which
263 simply calls "parse_trace_flag" on each item and combines them.
264
265 Sometimes you may wish to turn the tracing on before you connect to the
266 database. The second example above shows a way of doing this: the call
267 to "DBD::Pg->parse_trace_flags" provides a number than can be fed to
268 "DBI->trace" before you create a database handle.
269
270 DBD::Pg supports the following trace flags:
271
272 SQL Outputs all SQL statements. Note that the output provided will not
273 necessarily be in a form suitable to passing directly to Postgres,
274 as server-side prepared statements are used extensively by DBD::Pg.
275 For maximum portability of output (but with a potential performance
276 hit), use with "$dbh->{pg_server_prepare} = 0".
277
278 DBD Turns on all non-DBI flags, in other words, only the ones that are
279 specific to DBD::Pg (all those below which start with the letters
280 'pg').
281
282 pglibpq
283 Outputs the name of each libpq function (without arguments)
284 immediately before running it. This is a good way to trace the flow
285 of your program at a low level. This information is also output if
286 the trace level is set to 4 or greater.
287
288 pgstart
289 Outputs the name of each internal DBD::Pg function, and other
290 information such as the function arguments or important global
291 variables, as each function starts. This information is also output
292 if the trace level is set to 4 or greater.
293
294 pgend
295 Outputs a simple message at the very end of each internal DBD::Pg
296 function. This is also output if the trace level is set to 4 or
297 greater.
298
299 pgprefix
300 Forces each line of trace output to begin with the string "dbdpg:
301 ". This helps to differentiate it from the normal DBI trace output.
302
303 pglogin
304 Outputs a message showing the connection string right before a new
305 database connection is attempted, a message when the connection was
306 successful, and a message right after the database has been
307 disconnected. Also output if trace level is 5 or greater.
308
309 See the DBI section on TRACING for more information.
310
311 func
312
313 DBD::Pg uses the "func" method to support a variety of functions. Note
314 that the name of the function comes last, after the arguments.
315
316 table_attributes
317 $attrs = $dbh->func($table, 'table_attributes');
318
319 Use of the tables_attributes function is no longer recommended.
320 Instead, you can use the more portable "column_info" and
321 "primary_key" methods to access the same information.
322
323 The table_attributes method returns, for the given table argument,
324 a reference to an array of hashes, each of which contains the
325 following keys:
326
327 NAME attribute name
328 TYPE attribute type
329 SIZE attribute size (-1 for variable size)
330 NULLABLE flag nullable
331 DEFAULT default value
332 CONSTRAINT constraint
333 PRIMARY_KEY flag is_primary_key
334 REMARKS attribute description
335
336 pg_lo_creat
337 $lobjId = $dbh->pg_lo_creat($mode);
338
339 Creates a new large object and returns the object-id. $mode is a
340 bitmask describing read and write access to the new object. This
341 setting is ignored since Postgres version 8.1. For backwards
342 compatibility, however, you should set a valid mode anyway (see
343 "pg_lo_open" for a list of valid modes).
344
345 Upon failure it returns "undef". This function cannot be used if
346 AutoCommit is enabled.
347
348 The old way of calling large objects functions is deprecated:
349 $dbh->func(.., 'lo_);
350
351 pg_lo_open
352 $lobj_fd = $dbh->pg_lo_open($lobjId, $mode);
353
354 Opens an existing large object and returns an object-descriptor for
355 use in subsequent "pg_lo_*" calls. $mode is a bitmask describing
356 read and write access to the opened object. It may be one of:
357
358 $dbh->{pg_INV_READ}
359 $dbh->{pg_INV_WRITE}
360 $dbh->{pg_INV_READ} | $dbh->{pg_INV_WRITE}
361
362 "pg_INV_WRITE" and "pg_INV_WRITE | pg_INV_READ" modes are
363 identical; in both modes, the large object can be read from or
364 written to. Reading from the object will provide the object as
365 written in other committed transactions, along with any writes
366 performed by the current transaction. Objects opened with
367 "pg_INV_READ" cannot be written to. Reading from this object will
368 provide the stored data at the time of the transaction snapshot
369 which was active when "pg_lo_write" was called.
370
371 Returns "undef" upon failure. Note that 0 is a perfectly correct
372 (and common) object descriptor! This function cannot be used if
373 AutoCommit is enabled.
374
375 pg_lo_write
376 $nbytes = $dbh->pg_lo_write($lobj_fd, $buffer, $len);
377
378 Writes $len bytes of c<$buffer> into the large object $lobj_fd.
379 Returns the number of bytes written and "undef" upon failure. This
380 function cannot be used if AutoCommit is enabled.
381
382 pg_lo_read
383 $nbytes = $dbh->pg_lo_read($lobj_fd, $buffer, $len);
384
385 Reads $len bytes into c<$buffer> from large object $lobj_fd.
386 Returns the number of bytes read and "undef" upon failure. This
387 function cannot be used if AutoCommit is enabled.
388
389 pg_lo_lseek
390 $loc = $dbh->pg_lo_lseek($lobj_fd, $offset, $whence);
391
392 Changes the current read or write location on the large object
393 $obj_id. Currently $whence can only be 0 (which is L_SET). Returns
394 the current location and "undef" upon failure. This function cannot
395 be used if AutoCommit is enabled.
396
397 pg_lo_tell
398 $loc = $dbh->pg_lo_tell($lobj_fd);
399
400 Returns the current read or write location on the large object
401 $lobj_fd and "undef" upon failure. This function cannot be used if
402 AutoCommit is enabled.
403
404 pg_lo_truncate
405 $loc = $dbh->pg_lo_truncate($lobj_fd, $len);
406
407 Truncates the given large object to the new size. Returns "undef"
408 on failure, and 0 on success. This function cannot be used if
409 AutoCommit is enabled.
410
411 pg_lo_close
412 $lobj_fd = $dbh->pg_lo_close($lobj_fd);
413
414 Closes an existing large object. Returns true upon success and
415 false upon failure. This function cannot be used if AutoCommit is
416 enabled.
417
418 pg_lo_unlink
419 $ret = $dbh->pg_lo_unlink($lobjId);
420
421 Deletes an existing large object. Returns true upon success and
422 false upon failure. This function cannot be used if AutoCommit is
423 enabled.
424
425 pg_lo_import
426 $lobjId = $dbh->pg_lo_import($filename);
427
428 Imports a Unix file as a large object and returns the object id of
429 the new object or "undef" upon failure.
430
431 pg_lo_import_with_oid
432 $lobjId = $dbh->pg_lo_import($filename, $OID);
433
434 Same as pg_lo_import, but attempts to use the supplied OID as the
435 large object number. If this number is 0, it falls back to the
436 behavior of pg_lo_import (which assigns the next available OID).
437
438 This is only available when DBD::Pg is compiled against a Postgres
439 server version 8.4 or later.
440
441 pg_lo_export
442 $ret = $dbh->pg_lo_export($lobjId, $filename);
443
444 Exports a large object into a Unix file. Returns false upon
445 failure, true otherwise.
446
447 getfd
448 $fd = $dbh->func('getfd');
449
450 Deprecated, use $dbh->{pg_socket} instead.
451
452 private_attribute_info
453
454 $hashref = $dbh->private_attribute_info();
455 $hashref = $sth->private_attribute_info();
456
457 Returns a hash of all private attributes used by DBD::Pg, for either a
458 database or a statement handle. Currently, all the hash values are
459 undef.
460
462 InactiveDestroy (boolean)
463
464 If set to true, then the "disconnect" method will not be automatically
465 called when the database handle goes out of scope. This is required if
466 you are forking, and even then you must tread carefully and ensure that
467 either the parent or the child (but not both!) handles all database
468 calls from that point forwards, so that messages from the Postgres
469 backend are only handled by one of the processes. If you don't set
470 things up properly, you will see messages such as "server closed the
471 connection unexpectedly", and "message type 0x32 arrived from server
472 while idle". The best solution is to either have the child process
473 reconnect to the database with a fresh database handle, or to rewrite
474 your application not to use forking. See the section on "Asynchronous
475 Queries" for a way to have your script continue to work while the
476 database is processing a request.
477
478 AutoInactiveDestroy (boolean)
479
480 The InactiveDestroy attribute, described above, needs to be explicitly
481 set in the child process after a fork. If the code that performs the
482 fork is in a third party module such as Sys::Syslog, this can present a
483 problem. Use AutoInactiveDestroy to get around this problem.
484
485 RaiseError (boolean, inherited)
486
487 Forces errors to always raise an exception. Although it defaults to
488 off, it is recommended that this be turned on, as the alternative is to
489 check the return value of every method (prepare, execute, fetch, etc.)
490 manually, which is easy to forget to do.
491
492 PrintError (boolean, inherited)
493
494 Forces database errors to also generate warnings, which can then be
495 filtered with methods such as locally redefining $SIG{__WARN__} or
496 using modules such as "CGI::Carp". This attribute is on by default.
497
498 ShowErrorStatement (boolean, inherited)
499
500 Appends information about the current statement to error messages. If
501 placeholder information is available, adds that as well. Defaults to
502 false.
503
504 Note that this will not work when using "do" without any arguments.
505
506 Warn (boolean, inherited)
507
508 Enables warnings. This is on by default, and should only be turned off
509 in a local block for a short a time only when absolutely needed.
510
511 Executed (boolean, read-only)
512
513 Indicates if a handle has been executed. For database handles, this
514 value is true after the "do" method has been called, or when one of the
515 child statement handles has issued an "execute". Issuing a "commit" or
516 "rollback" always resets the attribute to false for database handles.
517 For statement handles, any call to "execute" or its variants will flip
518 the value to true for the lifetime of the statement handle.
519
520 TraceLevel (integer, inherited)
521
522 Sets the trace level, similar to the "trace" method. See the sections
523 on "trace" and parse_trace_flag for more details.
524
525 Active (boolean, read-only)
526
527 Indicates if a handle is active or not. For database handles, this
528 indicates if the database has been disconnected or not. For statement
529 handles, it indicates if all the data has been fetched yet or not. Use
530 of this attribute is not encouraged.
531
532 Kids (integer, read-only)
533
534 Returns the number of child processes created for each handle type. For
535 a driver handle, indicates the number of database handles created. For
536 a database handle, indicates the number of statement handles created.
537 For statement handles, it always returns zero, because statement
538 handles do not create kids.
539
540 ActiveKids (integer, read-only)
541
542 Same as "Kids", but only returns those that are active.
543
544 CachedKids (hash ref)
545
546 Returns a hashref of handles. If called on a database handle, returns
547 all statement handles created by use of the "prepare_cached" method. If
548 called on a driver handle, returns all database handles created by the
549 "connect_cached" method.
550
551 ChildHandles (array ref)
552
553 Implemented by DBI, no driver-specific impact.
554
555 PrintWarn (boolean, inherited)
556
557 Implemented by DBI, no driver-specific impact.
558
559 HandleError (boolean, inherited)
560
561 Implemented by DBI, no driver-specific impact.
562
563 HandleSetErr (code ref, inherited)
564
565 Implemented by DBI, no driver-specific impact.
566
567 ErrCount (unsigned integer)
568
569 Implemented by DBI, no driver-specific impact.
570
571 FetchHashKeyName (string, inherited)
572
573 Implemented by DBI, no driver-specific impact.
574
575 ChopBlanks (boolean, inherited)
576
577 Supported by DBD::Pg as proposed by DBI. This method is similar to the
578 SQL function "RTRIM".
579
580 Taint (boolean, inherited)
581
582 Implemented by DBI, no driver-specific impact.
583
584 TaintIn (boolean, inherited)
585
586 Implemented by DBI, no driver-specific impact.
587
588 TaintOut (boolean, inherited)
589
590 Implemented by DBI, no driver-specific impact.
591
592 Profile (inherited)
593
594 Implemented by DBI, no driver-specific impact.
595
596 Type (scalar)
597
598 Returns "dr" for a driver handle, "db" for a database handle, and "st"
599 for a statement handle. Should be rarely needed.
600
601 LongReadLen
602
603 Not used by DBD::Pg
604
605 LongTruncOk
606
607 Not used by DBD::Pg
608
609 CompatMode
610
611 Not used by DBD::Pg
612
614 Database Handle Methods
615 selectall_arrayref
616
617 $ary_ref = $dbh->selectall_arrayref($sql);
618 $ary_ref = $dbh->selectall_arrayref($sql, \%attr);
619 $ary_ref = $dbh->selectall_arrayref($sql, \%attr, @bind_values);
620
621 Returns a reference to an array containing the rows returned by
622 preparing and executing the SQL string. See the DBI documentation for
623 full details.
624
625 selectall_hashref
626
627 $hash_ref = $dbh->selectall_hashref($sql, $key_field);
628
629 Returns a reference to a hash containing the rows returned by preparing
630 and executing the SQL string. See the DBI documentation for full
631 details.
632
633 selectcol_arrayref
634
635 $ary_ref = $dbh->selectcol_arrayref($sql, \%attr, @bind_values);
636
637 Returns a reference to an array containing the first column from each
638 rows returned by preparing and executing the SQL string. It is possible
639 to specify exactly which columns to return. See the DBI documentation
640 for full details.
641
642 prepare
643
644 $sth = $dbh->prepare($statement, \%attr);
645
646 WARNING: DBD::Pg now (as of version 1.40) uses true prepared statements
647 by sending them to the backend to be prepared by the Postgres server.
648 Statements that were legal before may no longer work. See below for
649 details.
650
651 The prepare method prepares a statement for later execution. PostgreSQL
652 supports prepared statements, which enables DBD::Pg to only send the
653 query once, and simply send the arguments for every subsequent call to
654 "execute". DBD::Pg can use these server-side prepared statements, or
655 it can just send the entire query to the server each time. The best way
656 is automatically chosen for each query. This will be sufficient for
657 most users: keep reading for a more detailed explanation and some
658 optional flags.
659
660 Queries that do not begin with the word "SELECT", "INSERT", "UPDATE",
661 or "DELETE" are never sent as server-side prepared statements.
662
663 Deciding whether or not to use prepared statements depends on many
664 factors, but you can force them to be used or not used by using the
665 pg_server_prepare attribute when calling "prepare". Setting this to
666 false means to never use prepared statements. Setting pg_server_prepare
667 to true means that prepared statements should be used whenever
668 possible. This is the default.
669
670 The pg_server_prepare attribute can also be set at connection time like
671 so:
672
673 $dbh = DBI->connect($DBNAME, $DBUSER, $DBPASS,
674 { AutoCommit => 0,
675 RaiseError => 1,
676 pg_server_prepare => 0,
677 });
678
679 or you may set it after your database handle is created:
680
681 $dbh->{pg_server_prepare} = 1;
682
683 To enable it for just one particular statement:
684
685 $sth = $dbh->prepare("SELECT id FROM mytable WHERE val = ?",
686 { pg_server_prepare => 1 });
687
688 You can even toggle between the two as you go:
689
690 $sth->{pg_server_prepare} = 1;
691 $sth->execute(22);
692 $sth->{pg_server_prepare} = 0;
693 $sth->execute(44);
694 $sth->{pg_server_prepare} = 1;
695 $sth->execute(66);
696
697 In the above example, the first execute will use the previously
698 prepared statement. The second execute will not, but will build the
699 query into a single string and send it to the server. The third one
700 will act like the first and only send the arguments. Even if you
701 toggle back and forth, a statement is only prepared once.
702
703 Using prepared statements is in theory quite a bit faster: not only
704 does the PostgreSQL backend only have to prepare the query only once,
705 but DBD::Pg no longer has to worry about quoting each value before
706 sending it to the server.
707
708 However, there are some drawbacks. The server cannot always choose the
709 ideal parse plan because it will not know the arguments before hand.
710 But for most situations in which you will be executing similar data
711 many times, the default plan will probably work out well. Programs such
712 as PgBouncer which cache connections at a low level should not use
713 prepared statements via DBD::Pg, or must take extra care in the
714 application to account for the fact that prepared statements are not
715 shared across database connections. Further discussion on this subject
716 is beyond the scope of this documentation: please consult the pgsql-
717 performance mailing list,
718 <http://archives.postgresql.org/pgsql-performance/>
719
720 Only certain commands will be sent to a server-side prepare: currently
721 these include "SELECT", "INSERT", "UPDATE", and "DELETE". DBD::Pg uses
722 a simple naming scheme for the prepared statements themselves:
723 dbdpg_XY_Z, where Y is the current PID, X is either 'p' or 'n'
724 (depending on if the PID is a positive or negative number), and Z is a
725 number that starts at 1 and increases each time a new statement is
726 prepared. This number is tracked at the database handle level, so
727 multiple statement handles will not collide.
728
729 You cannot send more than one command at a time in the same prepare
730 command (by separating them with semi-colons) when using server-side
731 prepares.
732
733 The actual "PREPARE" is usually not performed until the first execute
734 is called, due to the fact that information on the data types (provided
735 by "bind_param") may be provided after the prepare but before the
736 execute.
737
738 A server-side prepare may happen before the first "execute", but only
739 if the server can handle the server-side prepare, and the statement
740 contains no placeholders. It will also be prepared if the
741 pg_prepare_now attribute is passed in and set to a true value.
742 Similarly, the pg_prepare_now attribute can be set to 0 to ensure that
743 the statement is not prepared immediately, although the cases in which
744 you would want this are very rare. Finally, you can set the default
745 behavior of all prepare statements by setting the pg_prepare_now
746 attribute on the database handle:
747
748 $dbh->{pg_prepare_now} = 1;
749
750 The following two examples will be prepared right away:
751
752 $sth->prepare("SELECT 123"); ## no placeholders
753
754 $sth->prepare("SELECT 123, ?", {pg_prepare_now => 1});
755
756 The following two examples will NOT be prepared right away:
757
758 $sth->prepare("SELECT 123, ?"); ## has a placeholder
759
760 $sth->prepare("SELECT 123", {pg_prepare_now => 0});
761
762 There are times when you may want to prepare a statement yourself. To
763 do this, simply send the "PREPARE" statement directly to the server
764 (e.g. with the "do" method). Create a statement handle and set the
765 prepared name via the pg_prepare_name attribute. The statement handle
766 can be created with a dummy statement, as it will not be executed.
767 However, it should have the same number of placeholders as your
768 prepared statement. Example:
769
770 $dbh->do('PREPARE mystat AS SELECT COUNT(*) FROM pg_class WHERE reltuples < ?');
771 $sth = $dbh->prepare('SELECT ?');
772 $sth->bind_param(1, 1, SQL_INTEGER);
773 $sth->{pg_prepare_name} = 'mystat';
774 $sth->execute(123);
775
776 The above will run the equivalent of this query on the backend:
777
778 EXECUTE mystat(123);
779
780 which is the equivalent of:
781
782 SELECT COUNT(*) FROM pg_class WHERE reltuples < 123;
783
784 You can force DBD::Pg to send your query directly to the server by
785 adding the pg_direct attribute to your prepare call. This is not
786 recommended, but is added just in case you need it.
787
788 Placeholders
789
790 There are three types of placeholders that can be used in DBD::Pg. The
791 first is the "question mark" type, in which each placeholder is
792 represented by a single question mark character. This is the method
793 recommended by the DBI specs and is the most portable. Each question
794 mark is internally replaced by a "dollar sign number" in the order in
795 which they appear in the query (important when using "bind_param").
796
797 The second type of placeholder is "dollar sign numbers". This is the
798 method that Postgres uses internally and is overall probably the best
799 method to use if you do not need compatibility with other database
800 systems. DBD::Pg, like PostgreSQL, allows the same number to be used
801 more than once in the query. Numbers must start with "1" and increment
802 by one value (but can appear in any order within the query). If the
803 same number appears more than once in a query, it is treated as a
804 single parameter and all instances are replaced at once. Examples:
805
806 Not legal:
807
808 $SQL = 'SELECT count(*) FROM pg_class WHERE relpages > $2'; # Does not start with 1
809
810 $SQL = 'SELECT count(*) FROM pg_class WHERE relpages BETWEEN $1 AND $3'; # Missing 2
811
812 Legal:
813
814 $SQL = 'SELECT count(*) FROM pg_class WHERE relpages > $1';
815
816 $SQL = 'SELECT count(*) FROM pg_class WHERE relpages BETWEEN $1 AND $2';
817
818 $SQL = 'SELECT count(*) FROM pg_class WHERE relpages BETWEEN $2 AND $1'; # legal but confusing
819
820 $SQL = 'SELECT count(*) FROM pg_class WHERE relpages BETWEEN $1 AND $2 AND reltuples > $1';
821
822 $SQL = 'SELECT count(*) FROM pg_class WHERE relpages > $1 AND reltuples > $1';
823
824 In the final statement above, DBI thinks there is only one placeholder,
825 so this statement will replace both placeholders:
826
827 $sth->bind_param(1, 2045);
828
829 While a simple execute with no bind_param calls requires only a single
830 argument as well:
831
832 $sth->execute(2045);
833
834 The final placeholder type is "named parameters" in the format ":foo".
835 While this syntax is supported by DBD::Pg, its use is discouraged in
836 favor of dollar-sign numbers.
837
838 The different types of placeholders cannot be mixed within a statement,
839 but you may use different ones for each statement handle you have. This
840 is confusing at best, so stick to one style within your program.
841
842 If your queries use operators that contain question marks (e.g. some of
843 the native Postgres geometric operators and JSON operators) or array
844 slices (e.g. "data[100:300]"), there are methods to instruct DBD::Pg to
845 not treat some symbols as placeholders. First, you may simply add a
846 backslash before the start of a placeholder, and DBD::Pg will strip the
847 backslash and not treat the character as a placeholder.
848
849 You can also tell DBD::Pg to ignore any non-dollar sign placeholders by
850 setting the pg_placeholder_dollaronly attribute at either the database
851 handle or the statement handle level. Examples:
852
853 $dbh->{pg_placeholder_dollaronly} = 1;
854 $sth = $dbh->prepare(q{SELECT * FROM mytable WHERE lseg1 ?# lseg2 AND name = $1});
855 $sth->execute('segname');
856
857 Alternatively, you can set it at prepare time:
858
859 $sth = $dbh->prepare(q{SELECT * FROM mytable WHERE lseg1 ?-| lseg2 AND name = $1},
860 {pg_placeholder_dollaronly => 1});
861 $sth->execute('segname');
862
863 If your queries use array slices but you still want to use question
864 marks as placeholders, you can tell DBD::Pg to ignore just colon
865 placeholders by setting the "pg_placeholder_nocolons" attribute in the
866 same way. Examples:
867
868 $dbh->{pg_placeholder_nocolons} = 1;
869 $sth = $dbh->prepare(q{SELECT array[1:2] FROM mytable WHERE id = ?});
870 $sth->execute(1);
871
872 Again, you may set it param time as well:
873
874 $sth = $dbh->prepare(q{SELECT array[1:2] FROM mytable WHERE id = ?},
875 {pg_placeholder_nocolons => 1});
876 $sth->execute(1);
877
878 It should be noted that placeholders only work when used outside of a
879 literal string context; i.e., the following examples will not
880 define/use any placeholders due to appearing inside strings within the
881 SQL:
882
883 $sth = $dbh->prepare(q{SELECT id FROM mytable WHERE text LIKE '%?'});
884 $dbh->do(q{DO LANGUAGE plpgsql $$ BEGIN RAISE NOTICE ?; END $$}, undef, $message);
885
886 See the DBI placeholder documentation for more details.
887
888 prepare_cached
889
890 $sth = $dbh->prepare_cached($statement, \%attr);
891
892 Implemented by DBI, no driver-specific impact. This method is most
893 useful when using a server that supports server-side prepares, and you
894 have asked the prepare to happen immediately via the pg_prepare_now
895 attribute.
896
897 do
898
899 $rv = $dbh->do($statement);
900 $rv = $dbh->do($statement, \%attr);
901 $rv = $dbh->do($statement, \%attr, @bind_values);
902
903 Prepare and execute a single statement. Returns the number of rows
904 affected if the query was successful, returns undef if an error
905 occurred, and returns -1 if the number of rows is unknown or not
906 available. Note that this method will return 0E0 instead of 0 for 'no
907 rows were affected', in order to always return a true value if no error
908 occurred.
909
910 If neither "\%attr" nor @bind_values is given, the query will be sent
911 directly to the server without the overhead of internally creating a
912 statement handle and running prepare and execute, for a measurable
913 speed increase.
914
915 Note that an empty statement (a string with no length) will not be
916 passed to the server; if you want a simple test, use "SELECT 123" or
917 the "ping" method.
918
919 last_insert_id
920
921 $rv = $dbh->last_insert_id(undef, $schema, $table, undef);
922 $rv = $dbh->last_insert_id(undef, $schema, $table, undef, {sequence => $seqname});
923
924 Attempts to return the id of the last value to be inserted into a
925 table. You can either provide a sequence name (preferred) or provide a
926 table name with optional schema, and DBD::Pg will attempt to find the
927 sequence itself. The current value of the sequence is returned by a
928 call to the "CURRVAL()" PostgreSQL function. This will fail if the
929 sequence has not yet been used in the current database connection.
930
931 If you do not know the name of the sequence, you can provide a table
932 name and DBD::Pg will attempt to return the correct value. To do this,
933 there must be at least one column in the table with a "NOT NULL"
934 constraint, that has a unique constraint, and which uses a sequence as
935 a default value (either manually, or via the "SERIAL" pseudotype or
936 "GENERATED ... AS IDENTITY"). If more than one column meets these
937 conditions, the primary key will be used. This involves some looking up
938 of things in the system table, so DBD::Pg will cache the sequence name
939 for subsequent calls. If you need to disable this caching for some
940 reason, (such as the sequence name changing), you can control it by
941 adding "pg_cache => 0" to the final (hashref) argument for
942 last_insert_id.
943
944 Please keep in mind that this method is far from foolproof, so make
945 your script use it properly. Specifically, make sure that it is called
946 immediately after the insert, and that the insert does not add a value
947 to the column that is using the sequence as a default value. However,
948 because we are using sequences, you can be sure that the value you got
949 back has not been used by any other process.
950
951 Some examples:
952
953 $dbh->do('CREATE SEQUENCE lii_seq START 1');
954 $dbh->do(q{CREATE TABLE lii (
955 foobar INTEGER NOT NULL UNIQUE DEFAULT nextval('lii_seq'),
956 baz VARCHAR)});
957 $SQL = 'INSERT INTO lii(baz) VALUES (?)';
958 $sth = $dbh->prepare($SQL);
959 for (qw(uno dos tres cuatro)) {
960 $sth->execute($_);
961 my $newid = $dbh->last_insert_id(undef,undef,undef,undef,{sequence=>'lii_seq'});
962 print "Last insert id was $newid\n";
963 }
964
965 If you did not want to worry about the sequence name:
966
967 $dbh->do('CREATE TABLE lii2 (
968 foobar SERIAL UNIQUE,
969 baz VARCHAR)');
970 $SQL = 'INSERT INTO lii2(baz) VALUES (?)';
971 $sth = $dbh->prepare($SQL);
972 for (qw(uno dos tres cuatro)) {
973 $sth->execute($_);
974 my $newid = $dbh->last_insert_id(undef,undef,"lii2",undef);
975 print "Last insert id was $newid\n";
976 }
977
978 commit
979
980 $rv = $dbh->commit;
981
982 Issues a COMMIT to the server, indicating that the current transaction
983 is finished and that all changes made will be visible to other
984 processes. If AutoCommit is enabled, then a warning is given and no
985 COMMIT is issued. Returns true on success, false on error. See also
986 the section on "Transactions".
987
988 rollback
989
990 $rv = $dbh->rollback;
991
992 Issues a ROLLBACK to the server, which discards any changes made in the
993 current transaction. If AutoCommit is enabled, then a warning is given
994 and no ROLLBACK is issued. Returns true on success, and false on error.
995 See also the the section on "Transactions".
996
997 begin_work
998
999 This method turns on transactions until the next call to "commit" or
1000 "rollback", if AutoCommit is currently enabled. If it is not enabled,
1001 calling begin_work will issue an error. Note that the transaction will
1002 not actually begin until the first statement after begin_work is
1003 called. Example:
1004
1005 $dbh->{AutoCommit} = 1;
1006 $dbh->do('INSERT INTO foo VALUES (123)'); ## Changes committed immediately
1007 $dbh->begin_work();
1008 ## Not in a transaction yet, but AutoCommit is set to 0
1009
1010 $dbh->do("INSERT INTO foo VALUES (345)");
1011 ## DBD::PG actually issues two statements here:
1012 ## BEGIN;
1013 ## INSERT INTO foo VALUES (345)
1014 ## We are now in a transaction
1015
1016 $dbh->commit();
1017 ## AutoCommit is now set to 1 again
1018
1019 disconnect
1020
1021 $rv = $dbh->disconnect;
1022
1023 Disconnects from the Postgres database. Any uncommitted changes will be
1024 rolled back upon disconnection. It's good policy to always explicitly
1025 call commit or rollback at some point before disconnecting, rather than
1026 relying on the default rollback behavior.
1027
1028 This method may give warnings about "disconnect invalidates X active
1029 statement handle(s)". This means that you called "$sth->execute()" but
1030 did not finish fetching all the rows from them. To avoid seeing this
1031 warning, either fetch all the rows or call "$sth->finish()" for each
1032 executed statement handle.
1033
1034 If the script exits before disconnect is called (or, more precisely, if
1035 the database handle is no longer referenced by anything), then the
1036 database handle's DESTROY method will call the rollback() and
1037 disconnect() methods automatically. It is best to explicitly disconnect
1038 rather than rely on this behavior.
1039
1040 quote
1041
1042 $rv = $dbh->quote($value, $data_type);
1043
1044 This module implements its own "quote" method. For simple string types,
1045 both backslashes and single quotes are doubled. You may also quote
1046 arrayrefs and receive a string suitable for passing into Postgres array
1047 columns.
1048
1049 If the value contains backslashes, and the server is version 8.1 or
1050 higher, then the escaped string syntax will be used (which places a
1051 capital E before the first single quote). This syntax is always used
1052 when quoting bytea values on servers 8.1 and higher.
1053
1054 The "data_type" argument is optional and should be one of the type
1055 constants exported by DBD::Pg (such as PG_BYTEA). In addition to
1056 string, bytea, char, bool, and other standard types, the following
1057 geometric types are supported: point, line, lseg, box, path, polygon,
1058 and circle (PG_POINT, PG_LINE, PG_LSEG, PG_BOX, PG_PATH, PG_POLYGON,
1059 and PG_CIRCLE respectively). To quote a Postgres-specific data type,
1060 you must use a 'hashref' argument like so:
1061
1062 my $quotedval = $dbh->quote($value, { pg_type => PG_VARCHAR });
1063
1064 NOTE: The undocumented (and invalid) support for the "SQL_BINARY" data
1065 type is officially deprecated. Use "PG_BYTEA" with "bind_param()"
1066 instead:
1067
1068 $rv = $sth->bind_param($param_num, $bind_value,
1069 { pg_type => PG_BYTEA });
1070
1071 quote_identifier
1072
1073 $string = $dbh->quote_identifier( $name );
1074 $string = $dbh->quote_identifier( undef, $schema, $table);
1075
1076 Returns a quoted version of the supplied string, which is commonly a
1077 schema, table, or column name. The three argument form will return the
1078 schema and the table together, separated by a dot. Examples:
1079
1080 print $dbh->quote_identifier('grapefruit'); ## Prints: "grapefruit"
1081
1082 print $dbh->quote_identifier('juicy fruit'); ## Prints: "juicy fruit"
1083
1084 print $dbh->quote_identifier(undef, 'public', 'pg_proc');
1085 ## Prints: "public"."pg_proc"
1086
1087 pg_notifies
1088
1089 $ret = $dbh->pg_notifies;
1090
1091 Looks for any asynchronous notifications received and returns either
1092 "undef" or a reference to a three-element array consisting of an event
1093 name, the PID of the backend that sent the NOTIFY command, and the
1094 optional payload string. Note that this does not check if the
1095 connection to the database is still valid first - for that, use the
1096 c<ping> method. You may need to commit if not in autocommit mode - new
1097 notices will not be picked up while in the middle of a transaction. An
1098 example:
1099
1100 $dbh->do("LISTEN abc");
1101 $dbh->do("LISTEN def");
1102
1103 ## Hang around until we get the message we want
1104 LISTENLOOP: {
1105 while (my $notify = $dbh->pg_notifies) {
1106 my ($name, $pid, $payload) = @$notify;
1107 print qq{I received notice "$name" from PID $pid, payload was "$payload"\n};
1108 ## Do something based on the notice received
1109 }
1110 $dbh->ping() or die qq{Ping failed!};
1111 $dbh->commit();
1112 sleep(5);
1113 redo;
1114 }
1115
1116 Payloads will always be an empty string unless you are connecting to a
1117 Postgres server version 9.0 or higher.
1118
1119 ping
1120
1121 $rv = $dbh->ping;
1122
1123 The "ping" method determines if there is a working connection to an
1124 active database server. It does this by sending a small query to the
1125 server, currently 'DBD::Pg ping test v3.10.5'. It returns 0 (false) if
1126 the connection is not valid, otherwise it returns a positive number
1127 (true). The value returned indicates the current state:
1128
1129 Value Meaning
1130 --------------------------------------------------
1131 1 Database is idle (not in a transaction)
1132 2 Database is active, there is a command in progress (usually seen after a COPY command)
1133 3 Database is idle within a transaction
1134 4 Database is idle, within a failed transaction
1135
1136 Additional information on why a handle is not valid can be obtained by
1137 using the "pg_ping" method.
1138
1139 pg_ping
1140
1141 $rv = $dbh->pg_ping;
1142
1143 This is a DBD::Pg-specific extension to the "ping" method. This will
1144 check the validity of a database handle in exactly the same way as
1145 "ping", but instead of returning a 0 for an invalid connection, it will
1146 return a negative number. So in addition to returning the positive
1147 numbers documented for "ping", it may also return the following:
1148
1149 Value Meaning
1150 --------------------------------------------------
1151 -1 There is no connection to the database at all (e.g. after disconnect)
1152 -2 An unknown transaction status was returned (e.g. after forking)
1153 -3 The test query failed (PQexec returned null)
1154 -4 PQstatus returned a CONNECTION_BAD
1155
1156 pg_error_field
1157
1158 $value = $dbh->pg_error_field('context');
1159
1160 The pg_error_field returns specific information about the last error
1161 that occurred. It needs to be called as soon as possible after an
1162 error occurs, as any other query sent to Postgres (via $dbh or $sth)
1163 will reset all the error information. Note that this is called at the
1164 database handle ($dbh) level, but can return errors that occurred via
1165 both database handles (e.g. $dbh->do) and statement handles (e.g.
1166 $sth->execute). It takes a single argument, indicating which field to
1167 return. The value returned will be undef if the previous command was
1168 not an error, or if the field is not applicable to the current error.
1169
1170 The canonical list of field types can be found at:
1171
1172 <https://www.postgresql.org/docs/current/libpq-exec.html#LIBPQ-PQRESULTERRORFIELD>
1173
1174 The literal names on that page can be used (e.g.
1175 PG_DIAG_STATEMENT_HINT), but lowercase is accepted too, as well as the
1176 following abbreviated forms:
1177
1178 severity
1179 severity_nonlocal (only for Postgres 10 and above)
1180 state
1181 primary
1182 detail (does not work well for Postgres < 9.2)
1183 hint
1184 statement_position
1185 internal_position
1186 internal_query
1187 context
1188 schema (only for Postgres 9.3 and above)
1189 table (only for Postgres 9.3 and above)
1190 column (only for Postgres 9.3 and above)
1191 type (only for Postgres 9.3 and above)
1192 constraint (only for Postgres 9.3 and above)
1193 source_file
1194 source_line
1195 source_function
1196
1197 get_info
1198
1199 $value = $dbh->get_info($info_type);
1200
1201 Supports a very large set (> 250) of the information types, including
1202 the minimum recommended by DBI.
1203
1204 Items of note:
1205
1206 SQL_KEYWORDS
1207 This returns all items reserved by Postgres but NOT reserved by
1208 SQL:2011 standard. See:
1209
1210 http://www.postgresql.org/docs/current/static/sql-keywords-appendix.htm
1211
1212 table_info
1213
1214 $sth = $dbh->table_info(undef, $schema, $table, $type);
1215
1216 Returns all tables and views visible to the current user. The schema
1217 and table arguments will do a "LIKE" search if a percent sign ("%") or
1218 an underscore ("_") is detected in the argument. The $type argument
1219 accepts any comma-separated combination of "TABLE", "VIEW", "SYSTEM
1220 TABLE", "SYSTEM VIEW", "MATERIALIZED VIEW", "SYSTEM MATERIALIZED VIEW",
1221 "FOREIGN TABLE", "SYSTEM FOREIGN TABLE", or "LOCAL TEMPORARY". (Using
1222 all is the default action.)
1223
1224 Note that a statement handle is returned, and not a direct list of
1225 tables. See the examples below for ways to handle this.
1226
1227 The following fields are returned:
1228
1229 TABLE_CAT: The name of the database that the table or view is in
1230 (always the current database).
1231
1232 TABLE_SCHEM: The name of the schema that the table or view is in.
1233
1234 TABLE_NAME: The name of the table or view.
1235
1236 TABLE_TYPE: The type of object returned. Will be one of "TABLE",
1237 "VIEW", "MATERIALIZED VIEW", "SYSTEM VIEW", "SYSTEM MATERIALIZED VIEW",
1238 "SYSTEM TABLE", "FOREIGN TABLE", "SYSTEM FOREIGN TABLE", or "LOCAL
1239 TEMPORARY".
1240
1241 The TABLE_SCHEM and TABLE_NAME will be quoted via "quote_ident()".
1242
1243 Four additional fields specific to DBD::Pg are returned:
1244
1245 pg_schema: the unquoted name of the schema
1246
1247 pg_table: the unquoted name of the table
1248
1249 pg_tablespace_name: the name of the tablespace the table is in
1250
1251 pg_tablespace_location: the location of the tablespace the table is in
1252
1253 Tables that have not been assigned to a particular tablespace (or
1254 views) will return NULL ("undef") for both of the above field.
1255
1256 Rows are returned alphabetically, with all tables first, and then all
1257 views.
1258
1259 Examples of use:
1260
1261 ## Display all tables and views in the public schema:
1262 $sth = $dbh->table_info('', 'public', undef, undef);
1263 for my $rel (@{$sth->fetchall_arrayref({})}) {
1264 print "$rel->{TABLE_TYPE} name is $rel->{TABLE_NAME}\n";
1265 }
1266
1267
1268 # Display the schema of all tables named 'foo':
1269 $sth = $dbh->table_info('', undef, 'foo', 'TABLE');
1270 for my $rel (@{$sth->fetchall_arrayref({})}) {
1271 print "Table name is $rel->{TABLE_SCHEM}.$rel->{TABLE_NAME}\n";
1272 }
1273
1274 column_info
1275
1276 $sth = $dbh->column_info( undef, $schema, $table, $column );
1277
1278 Supported by this driver as proposed by DBI with the follow exceptions.
1279 These fields are currently always returned with NULL ("undef") values:
1280
1281 BUFFER_LENGTH
1282 DECIMAL_DIGITS
1283 NUM_PREC_RADIX
1284 SQL_DATA_TYPE
1285 SQL_DATETIME_SUB
1286 CHAR_OCTET_LENGTH
1287
1288 Also, six additional non-standard fields are returned:
1289
1290 pg_type: data type with additional info i.e. "character varying(20)"
1291
1292 pg_constraint: holds column constraint definition
1293
1294 pg_schema: the unquoted name of the schema
1295
1296 pg_table: the unquoted name of the table
1297
1298 pg_column: the unquoted name of the column
1299
1300 pg_enum_values: an array reference of allowed values for an enum column
1301
1302 Note that the TABLE_SCHEM, TABLE_NAME, and COLUMN_NAME fields all
1303 return output wrapped in quote_ident(). If you need the unquoted
1304 version, use the pg_ fields above.
1305
1306 primary_key_info
1307
1308 $sth = $dbh->primary_key_info( undef, $schema, $table, \%attr );
1309
1310 Supported by this driver as proposed by DBI. There are no search
1311 patterns allowed, but leaving the $schema argument blank will cause the
1312 first table found in the schema search path to be used. An additional
1313 field, "DATA_TYPE", is returned and shows the data type for each of the
1314 arguments in the "COLUMN_NAME" field.
1315
1316 This method will also return tablespace information for servers that
1317 support tablespaces. See the "table_info" entry for more information.
1318
1319 The five additional custom fields returned are:
1320
1321 pg_tablespace_name: name of the tablespace, if any
1322
1323 pg_tablespace_location: location of the tablespace
1324
1325 pg_schema: the unquoted name of the schema
1326
1327 pg_table: the unquoted name of the table
1328
1329 pg_column: the unquoted name of the column
1330
1331 In addition to the standard format of returning one row for each column
1332 found for the primary key, you can pass the "pg_onerow" attribute to
1333 force a single row to be used. If the primary key has multiple columns,
1334 the "KEY_SEQ", "COLUMN_NAME", and "DATA_TYPE" fields will return a
1335 comma-delimited string. If the "pg_onerow" attribute is set to "2", the
1336 fields will be returned as an arrayref, which can be useful when
1337 multiple columns are involved:
1338
1339 $sth = $dbh->primary_key_info('', '', 'dbd_pg_test', {pg_onerow => 2});
1340 if (defined $sth) {
1341 my $pk = $sth->fetchall_arrayref()->[0];
1342 print "Table $pk->[2] has a primary key on these columns:\n";
1343 for (my $x=0; defined $pk->[3][$x]; $x++) {
1344 print "Column: $pk->[3][$x] (data type: $pk->[6][$x])\n";
1345 }
1346 }
1347
1348 primary_key
1349
1350 @key_column_names = $dbh->primary_key(undef, $schema, $table);
1351
1352 Simple interface to the "primary_key_info" method. Returns a list of
1353 the column names that comprise the primary key of the specified table.
1354 The list is in primary key column sequence order. If there is no
1355 primary key then an empty list is returned.
1356
1357 foreign_key_info
1358
1359 $sth = $dbh->foreign_key_info( $pk_catalog, $pk_schema, $pk_table,
1360 $fk_catalog, $fk_schema, $fk_table );
1361
1362 Supported by this driver as proposed by DBI, using the SQL/CLI variant.
1363 There are no search patterns allowed, but leaving the $schema argument
1364 blank will cause the first table found in the schema search path to be
1365 used. Two additional fields, "UK_DATA_TYPE" and "FK_DATA_TYPE", are
1366 returned to show the data type for the unique and foreign key columns.
1367 Foreign keys that have no named constraint (where the referenced column
1368 only has an unique index) will return "undef" for the "UK_NAME" field.
1369
1370 statistics_info
1371
1372 $sth = $dbh->statistics_info( undef, $schema, $table, $unique_only, $quick );
1373
1374 Returns a statement handle that can be fetched from to give statistics
1375 information on a specific table and its indexes. The $table argument is
1376 mandatory. The $schema argument is optional but recommended. The
1377 $unique_only argument, if true, causes only information about unique
1378 indexes to be returned. The $quick argument is not used by DBD::Pg. For
1379 information on the format of the standard rows returned, please see the
1380 DBI documentation.
1381
1382 DBI section on statistics_info
1383
1384 In addition, the following Postgres specific columns are returned:
1385
1386 pg_expression
1387 Postgres allows indexes on functions and scalar expressions based
1388 on one or more columns. This field will always be populated if an
1389 index, but the lack of an entry in the COLUMN_NAME should indicate
1390 that this is an index expression.
1391
1392 tables
1393
1394 @names = $dbh->tables( undef, $schema, $table, $type, \%attr );
1395
1396 Supported by this driver as proposed by DBI. This method returns all
1397 tables and/or views (including foreign tables and materialized views)
1398 which are visible to the current user: see "table_info" for more
1399 information about the arguments. The name of the schema appears before
1400 the table or view name. This can be turned off by adding in the
1401 "pg_noprefix" attribute:
1402
1403 my @tables = $dbh->tables( '', '', 'dbd_pg_test', '', {pg_noprefix => 1} );
1404
1405 type_info_all
1406
1407 $type_info_all = $dbh->type_info_all;
1408
1409 Supported by this driver as proposed by DBI. Information is only
1410 provided for SQL datatypes and for frequently used datatypes. The
1411 mapping between the PostgreSQL typename and the SQL92 datatype (if
1412 possible) has been done according to the following table:
1413
1414 +---------------+------------------------------------+
1415 | typname | SQL92 |
1416 |---------------+------------------------------------|
1417 | bool | BOOL |
1418 | text | / |
1419 | bpchar | CHAR(n) |
1420 | varchar | VARCHAR(n) |
1421 | int2 | SMALLINT |
1422 | int4 | INT |
1423 | int8 | BIGINT |
1424 | money | / |
1425 | float4 | FLOAT(p) p<7=float4, p<16=float8 |
1426 | float8 | REAL |
1427 | abstime | / |
1428 | reltime | / |
1429 | tinterval | / |
1430 | date | / |
1431 | time | / |
1432 | datetime | / |
1433 | timespan | TINTERVAL |
1434 | timestamp | TIMESTAMP |
1435 +---------------+------------------------------------+
1436
1437 type_info
1438
1439 @type_info = $dbh->type_info($data_type);
1440
1441 Returns a list of hash references holding information about one or more
1442 variants of $data_type. See the DBI documentation for more details.
1443
1444 pg_server_trace
1445
1446 $dbh->pg_server_trace($filehandle);
1447
1448 Writes debugging information from the PostgreSQL backend to a file.
1449 This is not related to the DBI "trace" method and you should not use
1450 this method unless you know what you are doing. If you do enable this,
1451 be aware that the file will grow very large, very quick. To stop
1452 logging to the file, use the "pg_server_untrace" method. The first
1453 argument must be a file handle, not a filename. Example:
1454
1455 my $pid = $dbh->{pg_pid};
1456 my $file = "pgbackend.$pid.debug.log";
1457 open(my $fh, ">$file") or die qq{Could not open "$file": $!\n};
1458 $dbh->pg_server_trace($fh);
1459 ## Run code you want to trace here
1460 $dbh->pg_server_untrace;
1461 close($fh);
1462
1463 pg_server_untrace
1464
1465 $dbh->pg_server_untrace;
1466
1467 Stop server logging to a previously opened file.
1468
1469 selectrow_array
1470
1471 @row_ary = $dbh->selectrow_array($sql);
1472 @row_ary = $dbh->selectrow_array($sql, \%attr);
1473 @row_ary = $dbh->selectrow_array($sql, \%attr, @bind_values);
1474
1475 Returns an array of row information after preparing and executing the
1476 provided SQL string. The rows are returned by calling "fetchrow_array".
1477 The string can also be a statement handle generated by a previous
1478 prepare. Note that only the first row of data is returned. If called in
1479 a scalar context, only the first column of the first row is returned.
1480 Because this is not portable, it is not recommended that you use this
1481 method in that way.
1482
1483 selectrow_arrayref
1484
1485 $ary_ref = $dbh->selectrow_arrayref($statement);
1486 $ary_ref = $dbh->selectrow_arrayref($statement, \%attr);
1487 $ary_ref = $dbh->selectrow_arrayref($statement, \%attr, @bind_values);
1488
1489 Exactly the same as "selectrow_array", except that it returns a
1490 reference to an array, by internal use of the "fetchrow_arrayref"
1491 method.
1492
1493 selectrow_hashref
1494
1495 $hash_ref = $dbh->selectrow_hashref($sql);
1496 $hash_ref = $dbh->selectrow_hashref($sql, \%attr);
1497 $hash_ref = $dbh->selectrow_hashref($sql, \%attr, @bind_values);
1498
1499 Exactly the same as "selectrow_array", except that it returns a
1500 reference to an hash, by internal use of the "fetchrow_hashref" method.
1501
1502 clone
1503
1504 $other_dbh = $dbh->clone();
1505
1506 Creates a copy of the database handle by connecting with the same
1507 parameters as the original handle, then trying to merge the attributes.
1508 See the DBI documentation for complete usage.
1509
1510 Database Handle Attributes
1511 AutoCommit (boolean)
1512
1513 Supported by DBD::Pg as proposed by DBI. According to the
1514 classification of DBI, PostgreSQL is a database in which a transaction
1515 must be explicitly started. Without starting a transaction, every
1516 change to the database becomes immediately permanent. The default of
1517 AutoCommit is on, but this may change in the future, so it is highly
1518 recommended that you explicitly set it when calling "connect". For
1519 details see the notes about "Transactions" elsewhere in this document.
1520
1521 ParamValues (hash ref, read-only)
1522
1523 Ignored unless inside a "do" method call. There it is temporarily
1524 aliased to the "ParamValues" hash from the temporary statement handle
1525 inside an internal "prepare / execute / fetch" routine, invisible from
1526 outside, and is treated correspondingly (see "ParamValues" in
1527 "Statement Handle Attributes"). This allows for correct reporting of
1528 values bound to placeholders to the caller, should the query fail (see
1529 "ShowErrorStatement").
1530
1531 pg_bool_tf (boolean)
1532
1533 DBD::Pg specific attribute. If true, boolean values will be returned as
1534 the characters 't' and 'f' instead of '1' and '0'.
1535
1536 ReadOnly (boolean)
1537
1538 $dbh->{ReadOnly} = 1;
1539
1540 Specifies if the current database connection should be in read-only
1541 mode or not. In this mode, changes that change the database are not
1542 allowed and will throw an error. Note: this method will not work if
1543 "AutoCommit" is true. The read-only effect is accomplished by sending a
1544 SET TRANSACTION READ ONLY after every begin. For more details, please
1545 see:
1546
1547 http://www.postgresql.org/docs/current/interactive/sql-set-transaction.html
1548
1549 Please not that this method is not foolproof: there are still ways to
1550 update the database. Consider this a safety net to catch applications
1551 that should not be issuing commands such as INSERT, UPDATE, or DELETE.
1552
1553 This method requires DBI version 1.55 or better.
1554
1555 pg_server_prepare (boolean)
1556
1557 DBD::Pg specific attribute. Indicates if DBD::Pg should attempt to use
1558 server-side prepared statements. The default value, true, indicates
1559 that prepared statements should be used whenever possible. See the
1560 section on the "prepare" method for more information.
1561
1562 pg_switch_prepared (integer)
1563
1564 DBD::Pg specific attribute. Indicates when DBD::Pg will internally
1565 switch from using PQexecParams to PQexecPrepared. In other words, when
1566 it will start using server-side prepared statements (assuming all other
1567 requirements for them are met). The default value, 2, means that a
1568 prepared statement will be prepared and used the second and subsequent
1569 time execute is called. To always use PQexecPrepared instead of
1570 PQexecParams, set pg_switch_prepared to 1 (this was the default
1571 behavior in earlier versions). Setting pg_switch_prepared to 0 will
1572 force DBD::Pg to always use PQexecParams.
1573
1574 pg_placeholder_dollaronly (boolean)
1575
1576 DBD::Pg specific attribute. Defaults to false. When true, question
1577 marks inside of statements are not treated as placeholders. Useful for
1578 statements that contain unquoted question marks, such as geometric
1579 operators. Note that you may also simply escape question marks with a
1580 backslash to prevent them from being treated as placeholders.
1581
1582 pg_placeholder_nocolons (boolean)
1583
1584 DBD::Pg specific attribute. Defaults to false. When true, colons inside
1585 of statements are not treated as placeholders. Useful for statements
1586 that contain an array slice. You may also place a backslash directly
1587 before the colon to prevent it from being treated as a placeholder.
1588
1589 pg_enable_utf8 (integer)
1590
1591 DBD::Pg specific attribute. The behavior of DBD::Pg with regards to
1592 this flag has changed as of version 3.0.0. The default value for this
1593 attribute, -1, indicates that the internal Perl "utf8" flag will be
1594 turned on for all strings coming back from the database if the
1595 client_encoding is set to 'UTF8'. Use of this default is highly
1596 encouraged. If your code was previously using pg_enable_utf8, you can
1597 probably remove mention of it entirely.
1598
1599 If this attribute is set to 0, then the internal "utf8" flag will
1600 *never* be turned on for returned data, regardless of the current
1601 client_encoding.
1602
1603 If this attribute is set to 1, then the internal "utf8" flag will
1604 *always* be turned on for returned data, regardless of the current
1605 client_encoding (with the exception of bytea data).
1606
1607 Note that the value of client_encoding is only checked on connection
1608 time. If you change the client_encoding to/from 'UTF8' after
1609 connecting, you can set pg_enable_utf8 to -1 to force DBD::Pg to read
1610 in the new client_encoding and act accordingly.
1611
1612 pg_errorlevel (integer)
1613
1614 DBD::Pg specific attribute. Sets the amount of information returned by
1615 the server's error messages. Valid entries are 0, 1, and 2. Any other
1616 number will be forced to the default value of 1.
1617
1618 A value of 0 ("TERSE") will show severity, primary text, and position
1619 only and will usually fit on a single line. A value of 1 ("DEFAULT")
1620 will also show any detail, hint, or context fields. A value of 2
1621 ("VERBOSE") will show all available information.
1622
1623 pg_lib_version (integer, read-only)
1624
1625 DBD::Pg specific attribute. Indicates which version of PostgreSQL that
1626 DBD::Pg was compiled against. In other words, which libraries were
1627 used. Returns a number with major, minor, and revision together;
1628 version 8.1.4 would be returned as 80104.
1629
1630 pg_server_version (integer, read-only)
1631
1632 DBD::Pg specific attribute. Indicates which version of PostgreSQL that
1633 the current database handle is connected to. Returns a number with
1634 major, minor, and revision together; version 8.0.1 would be 80001.
1635
1636 Name (string, read-only)
1637
1638 Returns the name of the current database. This is the same as the DSN,
1639 without the "dbi:Pg:" part. Before version 2.0.0, this only returned
1640 the bare database name (e.g. 'foo'). From version 2.0.0 onwards, it
1641 returns the more correct output (e.g. 'dbname=foo')
1642
1643 Username (string, read-only)
1644
1645 Returns the name of the user connected to the database.
1646
1647 pg_db (string, read-only)
1648
1649 DBD::Pg specific attribute. Returns the name of the current database.
1650
1651 pg_user (string, read-only)
1652
1653 DBD::Pg specific attribute. Returns the name of the user that connected
1654 to the server.
1655
1656 pg_host (string, read-only)
1657
1658 DBD::Pg specific attribute. Returns the host of the current server
1659 connection. Locally connected hosts will return an empty string.
1660
1661 pg_port (integer, read-only)
1662
1663 DBD::Pg specific attribute. Returns the port of the connection to the
1664 server.
1665
1666 pg_socket (integer, read-only)
1667
1668 DBD::Pg specific attribute. Returns the file description number of the
1669 connection socket to the server.
1670
1671 pg_pass (string, read-only)
1672
1673 DBD::Pg specific attribute. Returns the password used to connect to the
1674 server.
1675
1676 pg_options (string, read-only)
1677
1678 DBD::Pg specific attribute. Returns the command-line options passed to
1679 the server. May be an empty string.
1680
1681 pg_default_port (integer, read-only)
1682
1683 DBD::Pg specific attribute. Returns the default port used if none is
1684 specifically given.
1685
1686 pg_pid (integer, read-only)
1687
1688 DBD::Pg specific attribute. Returns the process id (PID) of the backend
1689 server process handling the connection.
1690
1691 pg_prepare_now (boolean)
1692
1693 DBD::Pg specific attribute. Default is off. If true, then the "prepare"
1694 method will immediately prepare commands, rather than waiting until the
1695 first execute.
1696
1697 pg_expand_array (boolean)
1698
1699 DBD::Pg specific attribute. Defaults to true. If false, arrays returned
1700 from the server will not be changed into a Perl arrayref, but remain as
1701 a string.
1702
1703 pg_async_status (integer, read-only)
1704
1705 DBD::Pg specific attribute. Returns the current status of an
1706 asynchronous command. 0 indicates no asynchronous command is in
1707 progress, 1 indicates that an asynchronous command has started and -1
1708 indicated that an asynchronous command has been cancelled.
1709
1710 pg_standard_conforming_strings (boolean, read-only)
1711
1712 DBD::Pg specific attribute. Returns true if the server is currently
1713 using standard conforming strings. Only available if the target server
1714 is version 8.2 or better.
1715
1716 pg_INV_READ (integer, read-only)
1717
1718 Constant to be used for the mode in "pg_lo_creat" and "pg_lo_open".
1719
1720 pg_INV_WRITE (integer, read-only)
1721
1722 Constant to be used for the mode in "pg_lo_creat" and "pg_lo_open".
1723
1724 Driver (handle, read-only)
1725
1726 Holds the handle of the parent driver. The only recommended use for
1727 this is to find the name of the driver using:
1728
1729 $dbh->{Driver}->{Name}
1730
1731 pg_protocol (integer, read-only)
1732
1733 DBD::Pg specific attribute. Returns the version of the PostgreSQL
1734 server. If DBD::Pg is unable to figure out the version, it will return
1735 a "0". Otherwise, a "3" is returned.
1736
1737 RowCacheSize
1738
1739 Not used by DBD::Pg
1740
1742 Statement Handle Methods
1743 bind_param
1744
1745 $rv = $sth->bind_param($param_num, $bind_value);
1746 $rv = $sth->bind_param($param_num, $bind_value, $bind_type);
1747 $rv = $sth->bind_param($param_num, $bind_value, \%attr);
1748
1749 Allows the user to bind a value and/or a data type to a placeholder.
1750 This is especially important when using server-side prepares. See the
1751 "prepare" method for more information.
1752
1753 The value of $param_num is a number if using the '?' or '$1' style
1754 placeholders. If using ":foo" style placeholders, the complete name
1755 (e.g. ":foo") must be given. For numeric values, you can either use a
1756 number or use a literal '$1'. See the examples below.
1757
1758 The $bind_value argument is fairly self-explanatory. A value of "undef"
1759 will bind a "NULL" to the placeholder. Using "undef" is useful when you
1760 want to change just the type and will be overwriting the value later.
1761 (Any value is actually usable, but "undef" is easy and efficient).
1762
1763 The "\%attr" hash is used to indicate the data type of the placeholder.
1764 The default value is "varchar". If you need something else, you must
1765 use one of the values provided by DBI or by DBD::Pg. To use a SQL
1766 value, modify your "use DBI" statement at the top of your script as
1767 follows:
1768
1769 use DBI qw(:sql_types);
1770
1771 This will import some constants into your script. You can plug those
1772 directly into the "bind_param" call. Some common ones that you will
1773 encounter are:
1774
1775 SQL_INTEGER
1776
1777 To use PostgreSQL data types, import the list of values like this:
1778
1779 use DBD::Pg qw(:pg_types);
1780
1781 You can then set the data types by setting the value of the "pg_type"
1782 key in the hash passed to "bind_param". The current list of Postgres
1783 data types exported is:
1784
1785 PG_ACLITEM PG_ACLITEMARRAY PG_ANY PG_ANYARRAY PG_ANYELEMENT PG_ANYENUM
1786 PG_ANYNONARRAY PG_ANYRANGE PG_BIT PG_BITARRAY PG_BOOL PG_BOOLARRAY
1787 PG_BOX PG_BOXARRAY PG_BPCHAR PG_BPCHARARRAY PG_BYTEA PG_BYTEAARRAY
1788 PG_CHAR PG_CHARARRAY PG_CID PG_CIDARRAY PG_CIDR PG_CIDRARRAY
1789 PG_CIRCLE PG_CIRCLEARRAY PG_CSTRING PG_CSTRINGARRAY PG_DATE PG_DATEARRAY
1790 PG_DATERANGE PG_DATERANGEARRAY PG_EVENT_TRIGGER PG_FDW_HANDLER PG_FLOAT4 PG_FLOAT4ARRAY
1791 PG_FLOAT8 PG_FLOAT8ARRAY PG_GTSVECTOR PG_GTSVECTORARRAY PG_INDEX_AM_HANDLER PG_INET
1792 PG_INETARRAY PG_INT2 PG_INT2ARRAY PG_INT2VECTOR PG_INT2VECTORARRAY PG_INT4
1793 PG_INT4ARRAY PG_INT4RANGE PG_INT4RANGEARRAY PG_INT8 PG_INT8ARRAY PG_INT8RANGE
1794 PG_INT8RANGEARRAY PG_INTERNAL PG_INTERVAL PG_INTERVALARRAY PG_JSON PG_JSONARRAY
1795 PG_JSONB PG_JSONBARRAY PG_JSONPATH PG_JSONPATHARRAY PG_LANGUAGE_HANDLER PG_LINE
1796 PG_LINEARRAY PG_LSEG PG_LSEGARRAY PG_MACADDR PG_MACADDR8 PG_MACADDR8ARRAY
1797 PG_MACADDRARRAY PG_MONEY PG_MONEYARRAY PG_NAME PG_NAMEARRAY PG_NUMERIC
1798 PG_NUMERICARRAY PG_NUMRANGE PG_NUMRANGEARRAY PG_OID PG_OIDARRAY PG_OIDVECTOR
1799 PG_OIDVECTORARRAY PG_OPAQUE PG_PATH PG_PATHARRAY PG_PG_ATTRIBUTE PG_PG_CLASS
1800 PG_PG_DDL_COMMAND PG_PG_DEPENDENCIES PG_PG_LSN PG_PG_LSNARRAY PG_PG_MCV_LIST PG_PG_NDISTINCT
1801 PG_PG_NODE_TREE PG_PG_PROC PG_PG_TYPE PG_POINT PG_POINTARRAY PG_POLYGON
1802 PG_POLYGONARRAY PG_RECORD PG_RECORDARRAY PG_REFCURSOR PG_REFCURSORARRAY PG_REGCLASS
1803 PG_REGCLASSARRAY PG_REGCONFIG PG_REGCONFIGARRAY PG_REGDICTIONARY PG_REGDICTIONARYARRAY PG_REGNAMESPACE
1804 PG_REGNAMESPACEARRAY PG_REGOPER PG_REGOPERARRAY PG_REGOPERATOR PG_REGOPERATORARRAY PG_REGPROC
1805 PG_REGPROCARRAY PG_REGPROCEDURE PG_REGPROCEDUREARRAY PG_REGROLE PG_REGROLEARRAY PG_REGTYPE
1806 PG_REGTYPEARRAY PG_TABLE_AM_HANDLER PG_TEXT PG_TEXTARRAY PG_TID PG_TIDARRAY
1807 PG_TIME PG_TIMEARRAY PG_TIMESTAMP PG_TIMESTAMPARRAY PG_TIMESTAMPTZ PG_TIMESTAMPTZARRAY
1808 PG_TIMETZ PG_TIMETZARRAY PG_TRIGGER PG_TSM_HANDLER PG_TSQUERY PG_TSQUERYARRAY
1809 PG_TSRANGE PG_TSRANGEARRAY PG_TSTZRANGE PG_TSTZRANGEARRAY PG_TSVECTOR PG_TSVECTORARRAY
1810 PG_TXID_SNAPSHOT PG_TXID_SNAPSHOTARRAY PG_UNKNOWN PG_UUID PG_UUIDARRAY PG_VARBIT
1811 PG_VARBITARRAY PG_VARCHAR PG_VARCHARARRAY PG_VOID PG_XID PG_XIDARRAY
1812 PG_XML PG_XMLARRAY
1813
1814 Data types are "sticky," in that once a data type is set to a certain
1815 placeholder, it will remain for that placeholder, unless it is
1816 explicitly set to something else afterwards. If the statement has
1817 already been prepared, and you switch the data type to something else,
1818 DBD::Pg will re-prepare the statement for you before doing the next
1819 execute.
1820
1821 Examples:
1822
1823 use DBI qw(:sql_types);
1824 use DBD::Pg qw(:pg_types);
1825
1826 $SQL = "SELECT id FROM ptable WHERE size > ? AND title = ?";
1827 $sth = $dbh->prepare($SQL);
1828
1829 ## Both arguments below are bound to placeholders as "varchar"
1830 $sth->execute(123, "Merk");
1831
1832 ## Reset the datatype for the first placeholder to an integer
1833 $sth->bind_param(1, undef, SQL_INTEGER);
1834
1835 ## The "undef" bound above is not used, since we supply params to execute
1836 $sth->execute(123, "Merk");
1837
1838 ## Set the first placeholder's value and data type
1839 $sth->bind_param(1, 234, { pg_type => PG_TIMESTAMP });
1840
1841 ## Set the second placeholder's value and data type.
1842 ## We don't send a third argument, so the default "varchar" is used
1843 $sth->bind_param('$2', "Zool");
1844
1845 ## We realize that the wrong data type was set above, so we change it:
1846 $sth->bind_param('$1', 234, { pg_type => SQL_INTEGER });
1847
1848 ## We also got the wrong value, so we change that as well.
1849 ## Because the data type is sticky, we don't need to change it
1850 $sth->bind_param(1, 567);
1851
1852 ## This executes the statement with 567 (integer) and "Zool" (varchar)
1853 $sth->execute();
1854
1855 bind_param_inout
1856
1857 $rv = $sth->bind_param_inout($param_num, \$scalar, 0);
1858
1859 Experimental support for this feature is provided. The first argument
1860 to bind_param_inout should be a placeholder number. The second argument
1861 should be a reference to a scalar variable in your script. The third
1862 argument is not used and should simply be set to 0. Note that what this
1863 really does is assign a returned column to the variable, in the order
1864 in which the column appears. For example:
1865
1866 my $foo = 123;
1867 $sth = $dbh->prepare("SELECT 1+?::int");
1868 $sth->bind_param_inout(1, \$foo, 0);
1869 $foo = 222;
1870 $sth->execute(444);
1871 $sth->fetch;
1872
1873 The above will cause $foo to have a new value of "223" after the final
1874 fetch. Note that the variables bound in this manner are very sticky,
1875 and will trump any values passed in to execute. This is because the
1876 binding is done as late as possible, at the execute() stage, allowing
1877 the value to be changed between the time it was bound and the time the
1878 query is executed. Thus, the above execute is the same as:
1879
1880 $sth->execute();
1881
1882 bind_param_array
1883
1884 $rv = $sth->bind_param_array($param_num, $array_ref_or_value)
1885 $rv = $sth->bind_param_array($param_num, $array_ref_or_value, $bind_type)
1886 $rv = $sth->bind_param_array($param_num, $array_ref_or_value, \%attr)
1887
1888 Binds an array of values to a placeholder, so that each is used in turn
1889 by a call to the "execute_array" method.
1890
1891 execute
1892
1893 $rv = $sth->execute(@bind_values);
1894
1895 Executes a previously prepared statement. In addition to "UPDATE",
1896 "DELETE", "INSERT" statements, for which it returns always the number
1897 of affected rows, the "execute" method can also be used for "SELECT ...
1898 INTO table" statements.
1899
1900 The "prepare/bind/execute" process has changed significantly for
1901 PostgreSQL servers 7.4 and later: please see the "prepare()" and
1902 "bind_param()" entries for much more information.
1903
1904 Setting one of the bind_values to "undef" is the equivalent of setting
1905 the value to NULL in the database. Setting the bind_value to
1906 $DBDPG_DEFAULT is equivalent to sending the literal string 'DEFAULT' to
1907 the backend. Note that using this option will force server-side
1908 prepares off until such time as PostgreSQL supports using DEFAULT in
1909 prepared statements.
1910
1911 DBD::Pg also supports passing in arrays to execute: simply pass in an
1912 arrayref, and DBD::Pg will flatten it into a string suitable for input
1913 on the backend.
1914
1915 If you are using Postgres version 8.2 or greater, you can also use any
1916 of the fetch methods to retrieve the values of a "RETURNING" clause
1917 after you execute an "UPDATE", "DELETE", or "INSERT". For example:
1918
1919 $dbh->do(q{CREATE TABLE abc (id SERIAL, country TEXT)});
1920 $SQL = q{INSERT INTO abc (country) VALUES (?) RETURNING id};
1921 $sth = $dbh->prepare($SQL);
1922 $sth->execute('France');
1923 $countryid = $sth->fetch()->[0];
1924 $sth->execute('New Zealand');
1925 $countryid = $sth->fetch()->[0];
1926
1927 execute_array
1928
1929 $tuples = $sth->execute_array() or die $sth->errstr;
1930 $tuples = $sth->execute_array(\%attr) or die $sth->errstr;
1931 $tuples = $sth->execute_array(\%attr, @bind_values) or die $sth->errstr;
1932
1933 ($tuples, $rows) = $sth->execute_array(\%attr) or die $sth->errstr;
1934 ($tuples, $rows) = $sth->execute_array(\%attr, @bind_values) or die $sth->errstr;
1935
1936 Execute a prepared statement once for each item in a passed-in hashref,
1937 or items that were previously bound via the "bind_param_array" method.
1938 See the DBI documentation for more details.
1939
1940 execute_for_fetch
1941
1942 $tuples = $sth->execute_for_fetch($fetch_tuple_sub);
1943 $tuples = $sth->execute_for_fetch($fetch_tuple_sub, \@tuple_status);
1944
1945 ($tuples, $rows) = $sth->execute_for_fetch($fetch_tuple_sub);
1946 ($tuples, $rows) = $sth->execute_for_fetch($fetch_tuple_sub, \@tuple_status);
1947
1948 Used internally by the "execute_array" method, and rarely used
1949 directly. See the DBI documentation for more details.
1950
1951 fetchrow_arrayref
1952
1953 $ary_ref = $sth->fetchrow_arrayref;
1954
1955 Fetches the next row of data from the statement handle, and returns a
1956 reference to an array holding the column values. Any columns that are
1957 NULL are returned as undef within the array.
1958
1959 If there are no more rows or if an error occurs, then this method
1960 return undef. You should check "$sth->err" afterwards (or use the
1961 RaiseError attribute) to discover if the undef returned was due to an
1962 error.
1963
1964 Note that the same array reference is returned for each fetch, so don't
1965 store the reference and then use it after a later fetch. Also, the
1966 elements of the array are also reused for each row, so take care if you
1967 want to take a reference to an element. See also "bind_columns".
1968
1969 fetchrow_array
1970
1971 @ary = $sth->fetchrow_array;
1972
1973 Similar to the "fetchrow_arrayref" method, but returns a list of column
1974 information rather than a reference to a list. Do not use this in a
1975 scalar context.
1976
1977 fetchrow_hashref
1978
1979 $hash_ref = $sth->fetchrow_hashref;
1980 $hash_ref = $sth->fetchrow_hashref($name);
1981
1982 Fetches the next row of data and returns a hashref containing the name
1983 of the columns as the keys and the data itself as the values. Any NULL
1984 value is returned as an undef value.
1985
1986 If there are no more rows or if an error occurs, then this method
1987 return undef. You should check "$sth->err" afterwards (or use the
1988 RaiseError attribute) to discover if the undef returned was due to an
1989 error.
1990
1991 The optional $name argument should be either "NAME", "NAME_lc" or
1992 "NAME_uc", and indicates what sort of transformation to make to the
1993 keys in the hash.
1994
1995 fetchall_arrayref
1996
1997 $tbl_ary_ref = $sth->fetchall_arrayref();
1998 $tbl_ary_ref = $sth->fetchall_arrayref( $slice );
1999 $tbl_ary_ref = $sth->fetchall_arrayref( $slice, $max_rows );
2000
2001 Returns a reference to an array of arrays that contains all the
2002 remaining rows to be fetched from the statement handle. If there are no
2003 more rows, an empty arrayref will be returned. If an error occurs, the
2004 data read in so far will be returned. Because of this, you should
2005 always check "$sth->err" after calling this method, unless RaiseError
2006 has been enabled.
2007
2008 If $slice is an array reference, fetchall_arrayref uses the
2009 "fetchrow_arrayref" method to fetch each row as an array ref. If the
2010 $slice array is not empty then it is used as a slice to select
2011 individual columns by perl array index number (starting at 0, unlike
2012 column and parameter numbers which start at 1).
2013
2014 With no parameters, or if $slice is undefined, fetchall_arrayref acts
2015 as if passed an empty array ref.
2016
2017 If $slice is a hash reference, fetchall_arrayref uses
2018 "fetchrow_hashref" to fetch each row as a hash reference.
2019
2020 See the DBI documentation for a complete discussion.
2021
2022 fetchall_hashref
2023
2024 $hash_ref = $sth->fetchall_hashref( $key_field );
2025
2026 Returns a hashref containing all rows to be fetched from the statement
2027 handle. See the DBI documentation for a full discussion.
2028
2029 finish
2030
2031 $rv = $sth->finish;
2032
2033 Indicates to DBI that you are finished with the statement handle and
2034 are not going to use it again. Only needed when you have not fetched
2035 all the possible rows.
2036
2037 rows
2038
2039 $rv = $sth->rows;
2040
2041 Returns the number of rows returned by the last query. In contrast to
2042 many other DBD modules, the number of rows is available immediately
2043 after calling "$sth->execute". Note that the "execute" method itself
2044 returns the number of rows itself, which means that this method is
2045 rarely needed.
2046
2047 bind_col
2048
2049 $rv = $sth->bind_col($column_number, \$var_to_bind);
2050 $rv = $sth->bind_col($column_number, \$var_to_bind, \%attr );
2051 $rv = $sth->bind_col($column_number, \$var_to_bind, $bind_type );
2052
2053 Binds a Perl variable and/or some attributes to an output column of a
2054 SELECT statement. Column numbers count up from 1. You do not need to
2055 bind output columns in order to fetch data.
2056
2057 See the DBI documentation for a discussion of the optional parameters
2058 "\%attr" and $bind_type
2059
2060 bind_columns
2061
2062 $rv = $sth->bind_columns(@list_of_refs_to_vars_to_bind);
2063
2064 Calls the "bind_col" method for each column in the SELECT statement,
2065 using the supplied list.
2066
2067 dump_results
2068
2069 $rows = $sth->dump_results($maxlen, $lsep, $fsep, $fh);
2070
2071 Fetches all the rows from the statement handle, calls "DBI::neat_list"
2072 for each row, and prints the results to $fh (which defaults to STDOUT).
2073 Rows are separated by $lsep (which defaults to a newline). Columns are
2074 separated by $fsep (which defaults to a comma). The $maxlen controls
2075 how wide the output can be, and defaults to 35.
2076
2077 This method is designed as a handy utility for prototyping and testing
2078 queries. Since it uses "neat_list" to format and edit the string for
2079 reading by humans, it is not recommended for data transfer
2080 applications.
2081
2082 blob_read
2083
2084 $blob = $sth->blob_read($id, $offset, $len);
2085
2086 Supported by DBD::Pg. This method is implemented by DBI but not
2087 currently documented by DBI, so this method might change.
2088
2089 This method seems to be heavily influenced by the current
2090 implementation of blobs in Oracle. Nevertheless we try to be as
2091 compatible as possible. Whereas Oracle suffers from the limitation that
2092 blobs are related to tables and every table can have only one blob
2093 (datatype LONG), PostgreSQL handles its blobs independent of any table
2094 by using so-called object identifiers. This explains why the
2095 "blob_read" method is blessed into the STATEMENT package and not part
2096 of the DATABASE package. Here the field parameter has been used to
2097 handle this object identifier. The offset and len parameters may be set
2098 to zero, in which case the whole blob is fetched at once.
2099
2100 See also the PostgreSQL-specific functions concerning blobs, which are
2101 available via the "func" interface.
2102
2103 For further information and examples about blobs, please read the
2104 chapter about Large Objects in the PostgreSQL Programmer's Guide at
2105 <http://www.postgresql.org/docs/current/static/largeobjects.html>.
2106
2107 pg_canonical_ids
2108
2109 $data = $sth->pg_canonical_ids;
2110
2111 DBD::Pg specific method. It returns Oid of table and position in table
2112 for every column in result set.
2113
2114 Returns array of arrays with Table Oid and Column Position for every
2115 column in result set or undef if current column is not a simple
2116 reference.
2117
2118 pg_canonical_names
2119
2120 $data = $sth->pg_canonical_names;
2121
2122 DBD::Pg specific method. It returns array of original (or canonical)
2123 names (from where this data is actually came from) of columns in
2124 Schema.Table.Column format or undef if current column is not a simple
2125 reference.
2126
2127 Note that this method is quite slow because it need additional
2128 information from server for every column that is simple reference.
2129 Consider to use "pg_canonical_ids" instead.
2130
2131 Statement Handle Attributes
2132 NUM_OF_FIELDS (integer, read-only)
2133
2134 Returns the number of columns returned by the current statement. A
2135 number will only be returned for SELECT statements, for SHOW statements
2136 (which always return 1), and for INSERT, UPDATE, and DELETE statements
2137 which contain a RETURNING clause. This method returns undef if called
2138 before "execute()".
2139
2140 NUM_OF_PARAMS (integer, read-only)
2141
2142 Returns the number of placeholders in the current statement.
2143
2144 NAME (arrayref, read-only)
2145
2146 Returns an arrayref of column names for the current statement. This
2147 method will only work for SELECT statements, for SHOW statements, and
2148 for INSERT, UPDATE, and DELETE statements which contain a RETURNING
2149 clause. This method returns undef if called before "execute()".
2150
2151 NAME_lc (arrayref, read-only)
2152
2153 The same as the "NAME" attribute, except that all column names are
2154 forced to lower case.
2155
2156 NAME_uc (arrayref, read-only)
2157
2158 The same as the "NAME" attribute, except that all column names are
2159 forced to upper case.
2160
2161 NAME_hash (hashref, read-only)
2162
2163 Similar to the "NAME" attribute, but returns a hashref of column names
2164 instead of an arrayref. The names of the columns are the keys of the
2165 hash, and the values represent the order in which the columns are
2166 returned, starting at 0. This method returns undef if called before
2167 "execute()".
2168
2169 NAME_lc_hash (hashref, read-only)
2170
2171 The same as the "NAME_hash" attribute, except that all column names are
2172 forced to lower case.
2173
2174 NAME_uc_hash (hashref, read-only)
2175
2176 The same as the "NAME_hash" attribute, except that all column names are
2177 forced to lower case.
2178
2179 TYPE (arrayref, read-only)
2180
2181 Returns an arrayref indicating the data type for each column in the
2182 statement. This method returns undef if called before "execute()".
2183
2184 PRECISION (arrayref, read-only)
2185
2186 Returns an arrayref of integer values for each column returned by the
2187 statement. The number indicates the precision for "NUMERIC" columns,
2188 the size in number of characters for "CHAR" and "VARCHAR" columns, and
2189 for all other types of columns it returns the number of bytes. This
2190 method returns undef if called before "execute()".
2191
2192 SCALE (arrayref, read-only)
2193
2194 Returns an arrayref of integer values for each column returned by the
2195 statement. The number indicates the scale of the that column. The only
2196 type that will return a value is "NUMERIC". This method returns undef
2197 if called before "execute()".
2198
2199 NULLABLE (arrayref, read-only)
2200
2201 Returns an arrayref of integer values for each column returned by the
2202 statement. The number indicates if the column is nullable or not. 0 =
2203 not nullable, 1 = nullable, 2 = unknown. This method returns undef if
2204 called before "execute()".
2205
2206 Database (dbh, read-only)
2207
2208 Returns the database handle this statement handle was created from.
2209
2210 ParamValues (hash ref, read-only)
2211
2212 Returns a reference to a hash containing the values currently bound to
2213 placeholders. If the "named parameters" type of placeholders are being
2214 used (such as ":foo"), then the keys of the hash will be the names of
2215 the placeholders (without the colon). If the "dollar sign numbers" type
2216 of placeholders are being used, the keys of the hash will be the
2217 numbers, without the dollar signs. If the "question mark" type is used,
2218 integer numbers will be returned, starting at one and increasing for
2219 every placeholder.
2220
2221 If this method is called before "execute", the literal values passed in
2222 are returned. If called after "execute", then the quoted versions of
2223 the values are returned.
2224
2225 ParamTypes (hash ref, read-only)
2226
2227 Returns a reference to a hash containing the type names currently bound
2228 to placeholders. The keys are the same as returned by the ParamValues
2229 method. The values are hashrefs containing a single key value pair, in
2230 which the key is either 'TYPE' if the type has a generic SQL
2231 equivalent, and 'pg_type' if the type can only be expressed by a
2232 Postgres type. The value is the internal number corresponding to the
2233 type originally passed in. (Placeholders that have not yet been bound
2234 will return undef as the value). This allows the output of ParamTypes
2235 to be passed back to the "bind_param" method.
2236
2237 Statement (string, read-only)
2238
2239 Returns the statement string passed to the most recent "prepare" method
2240 called in this database handle, even if that method failed. This is
2241 especially useful where "RaiseError" is enabled and the exception
2242 handler checks $@ and sees that a "prepare" method call failed.
2243
2244 pg_current_row (integer, read-only)
2245
2246 DBD::Pg specific attribute. Returns the number of the tuple (row) that
2247 was most recently fetched. Returns zero before and after fetching is
2248 performed.
2249
2250 pg_numbound (integer, read-only)
2251
2252 DBD::Pg specific attribute. Returns the number of placeholders that are
2253 currently bound (via bind_param).
2254
2255 pg_bound (hashref, read-only)
2256
2257 DBD::Pg specific attribute. Returns a hash of all named placeholders.
2258 The key is the name of the placeholder, and the value is a 0 or a 1,
2259 indicating if the placeholder has been bound yet (e.g. via bind_param)
2260
2261 pg_size (arrayref, read-only)
2262
2263 DBD::Pg specific attribute. It returns a reference to an array of
2264 integer values for each column. The integer shows the size of the
2265 column in bytes. Variable length columns are indicated by -1.
2266
2267 pg_type (arrayref, read-only)
2268
2269 DBD::Pg specific attribute. It returns a reference to an array of
2270 strings for each column. The string shows the name of the data_type.
2271
2272 pg_segments (arrayref, read-only)
2273
2274 DBD::Pg specific attribute. Returns an arrayref of the query split on
2275 the placeholders.
2276
2277 pg_oid_status (integer, read-only)
2278
2279 DBD::Pg specific attribute. It returns the OID of the last INSERT
2280 command.
2281
2282 pg_cmd_status (integer, read-only)
2283
2284 DBD::Pg specific attribute. It returns the type of the last command.
2285 Possible types are: "INSERT", "DELETE", "UPDATE", "SELECT".
2286
2287 pg_direct (boolean)
2288
2289 DBD::Pg specific attribute. Default is false. If true, the query is
2290 passed directly to the backend without parsing for placeholders.
2291
2292 pg_prepare_now (boolean)
2293
2294 DBD::Pg specific attribute. Default is off. If true, the query will be
2295 immediately prepared, rather than waiting for the "execute" call.
2296
2297 pg_prepare_name (string)
2298
2299 DBD::Pg specific attribute. Specifies the name of the prepared
2300 statement to use for this statement handle. Not normally needed, see
2301 the section on the "prepare" method for more information.
2302
2303 pg_server_prepare (boolean)
2304
2305 DBD::Pg specific attribute. Indicates if DBD::Pg should attempt to use
2306 server-side prepared statements for this statement handle. The default
2307 value, true, indicates that prepared statements should be used whenever
2308 possible. See the section on the "prepare" method for more information.
2309
2310 pg_switch_prepared (integer)
2311
2312 DBD::Pg specific attribute. Indicates when DBD::Pg will internally
2313 switch from using PQexecParams to PQexecPrepared. In other words, when
2314 it will start using server-side prepared statements (assuming all other
2315 requirements for them are met). The default value, 2, means that a
2316 prepared statement will be prepared and used the second and subsequent
2317 time execute is called. To always use PQexecPrepared instead of
2318 PQexecParams, set pg_switch_prepared to 1 (this was the default
2319 behavior in earlier versions). Setting pg_switch_prepared to 0 will
2320 force DBD::Pg to always use PQexecParams.
2321
2322 pg_placeholder_dollaronly (boolean)
2323
2324 DBD::Pg specific attribute. Defaults to false. When true, question
2325 marks inside of the query being prepared are not treated as
2326 placeholders. Useful for statements that contain unquoted question
2327 marks, such as geometric operators. Note that you may also simply
2328 escape question marks with a backslash to prevent them from being
2329 treated as placeholders.
2330
2331 pg_placeholder_nocolons (boolean)
2332
2333 DBD::Pg specific attribute. Defaults to false. When true, colons inside
2334 of statements are not treated as placeholders. Useful for statements
2335 that contain an array slice. You may also place a backslash directly
2336 before the colon to prevent it from being treated as a placeholder.
2337
2338 pg_async (integer)
2339
2340 DBD::Pg specific attribute. Indicates the current behavior for
2341 asynchronous queries. See the section on "Asynchronous Constants" for
2342 more information.
2343
2344 pg_async_status (integer, read-only)
2345
2346 DBD::Pg specific attribute. Returns the current status of an
2347 asynchronous command. 0 indicates no asynchronous command is in
2348 progress, 1 indicates that an asynchronous command has started and -1
2349 indicated that an asynchronous command has been cancelled.
2350
2351 RowsInCache
2352
2353 Not used by DBD::Pg
2354
2355 RowCache
2356
2357 Not used by DBD::Pg
2358
2359 CursorName
2360
2361 Not used by DBD::Pg. See the note about "Cursors" elsewhere in this
2362 document.
2363
2365 Encoding
2366 DBD::Pg has extensive support for a client_encoding of UTF-8, and most
2367 things like encoding and decoding should happen automatically. If you
2368 are using a different encoding, you will need do the encoding and
2369 decoding yourself. For this reason, it is highly recommended to always
2370 use a client_encoding of UTF-8. The server_encoding can be anything,
2371 and no recommendations are made there, other than avoid SQL_ASCII
2372 whenever possible.
2373
2374 Transactions
2375 Transaction behavior is controlled via the "AutoCommit" attribute. For
2376 a complete definition of "AutoCommit" please refer to the DBI
2377 documentation.
2378
2379 According to the DBI specification the default for "AutoCommit" is a
2380 true value. In this mode, any change to the database becomes valid
2381 immediately. Any "BEGIN", "COMMIT" or "ROLLBACK" statements will be
2382 rejected. Note that preparing a statement does not always contact the
2383 server, as the actual "PREPARE" is usually postponed until the first
2384 call to "execute".
2385
2386 Savepoints
2387 PostgreSQL version 8.0 introduced the concept of savepoints, which
2388 allows transactions to be rolled back to a certain point without
2389 affecting the rest of the transaction. DBD::Pg encourages using the
2390 following methods to control savepoints:
2391
2392 "pg_savepoint"
2393
2394 Creates a savepoint. This will fail unless you are inside of a
2395 transaction. The only argument is the name of the savepoint. Note that
2396 PostgreSQL DOES allow multiple savepoints with the same name to exist.
2397
2398 $dbh->pg_savepoint("mysavepoint");
2399
2400 "pg_rollback_to"
2401
2402 Rolls the database back to a named savepoint, discarding any work
2403 performed after that point. If more than one savepoint with that name
2404 exists, rolls back to the most recently created one.
2405
2406 $dbh->pg_rollback_to("mysavepoint");
2407
2408 "pg_release"
2409
2410 Releases (or removes) a named savepoint. If more than one savepoint
2411 with that name exists, it will only destroy the most recently created
2412 one. Note that all savepoints created after the one being released are
2413 also destroyed.
2414
2415 $dbh->pg_release("mysavepoint");
2416
2417 Asynchronous Queries
2418 It is possible to send a query to the backend and have your script do
2419 other work while the query is running on the backend. Both queries sent
2420 by the "do" method, and by the "execute" method can be sent
2421 asynchronously. The basic usage is as follows:
2422
2423 print "Async do() example:\n";
2424 $dbh->do("SELECT long_running_query()", {pg_async => PG_ASYNC});
2425 do_something_else();
2426 {
2427 if ($dbh->pg_ready()) {
2428 $res = $dbh->pg_result();
2429 print "Result of do(): $res\n";
2430 }
2431 print "Query is still running...\n";
2432 if (cancel_request_received) {
2433 $dbh->pg_cancel();
2434 }
2435 sleep 1;
2436 redo;
2437 }
2438
2439 print "Async prepare/execute example:\n";
2440 $sth = $dbh->prepare("SELECT long_running_query(1)", {pg_async => PG_ASYNC});
2441 $sth->execute();
2442
2443 ## Changed our mind, cancel and run again:
2444 $sth = $dbh->prepare("SELECT 678", {pg_async => PG_ASYNC + PG_OLDQUERY_CANCEL});
2445 $sth->execute();
2446
2447 do_something_else();
2448
2449 if (!$sth->pg_ready) {
2450 do_another_thing();
2451 }
2452
2453 ## We wait until it is done, and get the result:
2454 $res = $dbh->pg_result();
2455
2456 Asynchronous Constants
2457
2458 There are currently three asynchronous constants automatically exported
2459 by DBD::Pg.
2460
2461 PG_ASYNC
2462 This is a constant for the number 1. It is passed to either the
2463 "do" or the "prepare" method as a value to the pg_async key and
2464 indicates that the query should be sent asynchronously.
2465
2466 PG_OLDQUERY_CANCEL
2467 This is a constant for the number 2. When passed to either the "do"
2468 or the "prepare" method, it causes any currently running
2469 asynchronous query to be cancelled and rolled back. It has no
2470 effect if no asynchronous query is currently running.
2471
2472 PG_OLDQUERY_WAIT
2473 This is a constant for the number 4. When passed to either the "do"
2474 or the "prepare" method, it waits for any currently running
2475 asynchronous query to complete. It has no effect if there is no
2476 asynchronous query currently running.
2477
2478 Asynchronous Methods
2479
2480 pg_cancel
2481 This database-level method attempts to cancel any currently running
2482 asynchronous query. It returns true if the cancel succeeded, and
2483 false otherwise. Note that a query that has finished before this
2484 method is executed will also return false. WARNING: a successful
2485 cancellation may leave the database in an unusable state, so you
2486 may need to ROLLBACK or ROLLBACK TO a savepoint. As of version
2487 2.17.0 of DBD::Pg, rollbacks are not done automatically.
2488
2489 $result = $dbh->pg_cancel();
2490
2491 pg_ready
2492 This method can be called as a database handle method or (for
2493 convenience) as a statement handle method. Both simply see if a
2494 previously issued asynchronous query has completed yet. It returns
2495 true if the statement has finished, in which case you should then
2496 call the "pg_result" method. Calls to "pg_ready()" should only be
2497 used when you have other things to do while the query is running.
2498 If you simply want to wait until the query is done, do not call
2499 pg_ready() over and over, but simply call the pg_result() method.
2500
2501 my $time = 0;
2502 while (!$dbh->pg_ready) {
2503 print "Query is still running. Seconds: $time\n";
2504 $time++;
2505 sleep 1;
2506 }
2507 $result = $dbh->pg_result;
2508
2509 pg_result
2510 This database handle method returns the results of a previously
2511 issued asynchronous query. If the query is still running, this
2512 method will wait until it has finished. The result returned is the
2513 number of rows: the same thing that would have been returned by the
2514 asynchronous "do" or "execute" if it had been called without an
2515 asynchronous flag.
2516
2517 $result = $dbh->pg_result;
2518
2519 Asynchronous Examples
2520
2521 Here are some working examples of asynchronous queries. Note that we'll
2522 use the pg_sleep function to emulate a long-running query.
2523
2524 use strict;
2525 use warnings;
2526 use Time::HiRes 'sleep';
2527 use DBD::Pg ':async';
2528
2529 my $dbh = DBI->connect('dbi:Pg:dbname=postgres', 'postgres', '', {AutoCommit=>0,RaiseError=>1});
2530
2531 ## Kick off a long running query on the first database:
2532 my $sth = $dbh->prepare("SELECT pg_sleep(?)", {pg_async => PG_ASYNC});
2533 $sth->execute(5);
2534
2535 ## While that is running, do some other things
2536 print "Your query is processing. Thanks for waiting\n";
2537 check_on_the_kids(); ## Expensive sub, takes at least three seconds.
2538
2539 while (!$dbh->pg_ready) {
2540 check_on_the_kids();
2541 ## If the above function returns quickly for some reason, we add a small sleep
2542 sleep 0.1;
2543 }
2544
2545 print "The query has finished. Gathering results\n";
2546 my $result = $sth->pg_result;
2547 print "Result: $result\n";
2548 my $info = $sth->fetchall_arrayref();
2549
2550 Without asynchronous queries, the above script would take about 8
2551 seconds to run: five seconds waiting for the execute to finish, then
2552 three for the check_on_the_kids() function to return. With asynchronous
2553 queries, the script takes about 6 seconds to run, and gets in two
2554 iterations of check_on_the_kids in the process.
2555
2556 Here's an example showing the ability to cancel a long-running query.
2557 Imagine two slave databases in different geographic locations over a
2558 slow network. You need information as quickly as possible, so you query
2559 both at once. When you get an answer, you tell the other one to stop
2560 working on your query, as you don't need it anymore.
2561
2562 use strict;
2563 use warnings;
2564 use Time::HiRes 'sleep';
2565 use DBD::Pg ':async';
2566
2567 my $dbhslave1 = DBI->connect('dbi:Pg:dbname=postgres;host=slave1', 'postgres', '', {AutoCommit=>0,RaiseError=>1});
2568 my $dbhslave2 = DBI->connect('dbi:Pg:dbname=postgres;host=slave2', 'postgres', '', {AutoCommit=>0,RaiseError=>1});
2569
2570 $SQL = "SELECT count(*) FROM largetable WHERE flavor='blueberry'";
2571
2572 my $sth1 = $dbhslave1->prepare($SQL, {pg_async => PG_ASYNC});
2573 my $sth2 = $dbhslave2->prepare($SQL, {pg_async => PG_ASYNC});
2574
2575 $sth1->execute();
2576 $sth2->execute();
2577
2578 my $winner;
2579 while (!defined $winner) {
2580 if ($sth1->pg_ready) {
2581 $winner = 1;
2582 }
2583 elsif ($sth2->pg_ready) {
2584 $winner = 2;
2585 }
2586 Time::HiRes::sleep 0.05;
2587 }
2588
2589 my $count;
2590 if ($winner == 1) {
2591 $sth2->pg_cancel();
2592 $sth1->pg_result();
2593 $count = $sth1->fetchall_arrayref()->[0][0];
2594 }
2595 else {
2596 $sth1->pg_cancel();
2597 $sth2->pg_result();
2598 $count = $sth2->fetchall_arrayref()->[0][0];
2599 }
2600
2601 Array support
2602 DBD::Pg allows arrays (as arrayrefs) to be passed in to both the
2603 "quote" and the "execute" methods. In both cases, the array is
2604 flattened into a string representing a Postgres array.
2605
2606 When fetching rows from a table that contains a column with an array
2607 type, the result will be passed back to your script as an arrayref.
2608
2609 To turn off the automatic parsing of returned arrays into arrayrefs,
2610 you can set the attribute pg_expand_array, which is true by default.
2611
2612 $dbh->{pg_expand_array} = 0;
2613
2614 COPY support
2615 DBD::Pg allows for quick (bulk) reading and storing of data by using
2616 the COPY command. The basic process is to use "$dbh->do" to issue a
2617 COPY command, and then to either add rows using "pg_putcopydata", or to
2618 read them by using "pg_getcopydata".
2619
2620 The first step is to put the server into "COPY" mode. This is done by
2621 sending a complete COPY command to the server, by using the "do"
2622 method. For example:
2623
2624 $dbh->do("COPY foobar FROM STDIN");
2625
2626 This would tell the server to enter a COPY IN mode (yes, that's
2627 confusing, but the mode is COPY IN because of the command COPY FROM).
2628 It is now ready to receive information via the "pg_putcopydata" method.
2629 The complete syntax of the COPY command is more complex and not
2630 documented here: the canonical PostgreSQL documentation for COPY can be
2631 found at:
2632
2633 http://www.postgresql.org/docs/current/static/sql-copy.html
2634
2635 Once a COPY command has been issued, no other SQL commands are allowed
2636 until "pg_putcopyend" has been issued (for COPY FROM), or the final
2637 "pg_getcopydata" has been called (for COPY TO).
2638
2639 Note: All other COPY methods (pg_putline, pg_getline, etc.) are now
2640 heavily deprecated in favor of the pg_getcopydata, pg_putcopydata, and
2641 pg_putcopyend methods.
2642
2643 pg_getcopydata
2644
2645 Used to retrieve data from a table after the server has been put into a
2646 COPY OUT mode by calling "COPY tablename TO STDOUT". Data is always
2647 returned one data row at a time. The first argument to pg_getcopydata
2648 is the variable into which the data will be stored (this variable
2649 should not be undefined, or it may throw a warning, although it may be
2650 a reference). The pg_getcopydata method returns a number greater than 1
2651 indicating the new size of the variable, or a -1 when the COPY has
2652 finished. Once a -1 has been returned, no other action is necessary, as
2653 COPY mode will have already terminated. Example:
2654
2655 $dbh->do("COPY mytable TO STDOUT");
2656 my @data;
2657 my $x=0;
2658 1 while $dbh->pg_getcopydata($data[$x++]) >= 0;
2659
2660 There is also a variation of this method called pg_getcopydata_async,
2661 which, as the name suggests, returns immediately. The only difference
2662 from the original method is that this version may return a 0,
2663 indicating that the row is not ready to be delivered yet. When this
2664 happens, the variable has not been changed, and you will need to call
2665 the method again until you get a non-zero result. (Data is still
2666 always returned one data row at a time.)
2667
2668 pg_putcopydata
2669
2670 Used to put data into a table after the server has been put into COPY
2671 IN mode by calling "COPY tablename FROM STDIN". The only argument is
2672 the data you want inserted. Issue a pg_putcopyend() when you have added
2673 all your rows.
2674
2675 The default delimiter is a tab character, but this can be changed in
2676 the COPY statement. Returns a 1 on successful input. Examples:
2677
2678 ## Simple example:
2679 $dbh->do("COPY mytable FROM STDIN");
2680 $dbh->pg_putcopydata("123\tPepperoni\t3\n");
2681 $dbh->pg_putcopydata("314\tMushroom\t8\n");
2682 $dbh->pg_putcopydata("6\tAnchovies\t100\n");
2683 $dbh->pg_putcopyend();
2684
2685 ## This example uses explicit columns and a custom delimiter
2686 $dbh->do("COPY mytable(flavor, slices) FROM STDIN WITH DELIMITER '~'");
2687 $dbh->pg_putcopydata("Pepperoni~123\n");
2688 $dbh->pg_putcopydata("Mushroom~314\n");
2689 $dbh->pg_putcopydata("Anchovies~6\n");
2690 $dbh->pg_putcopyend();
2691
2692 pg_putcopyend
2693
2694 When you are finished with pg_putcopydata, call pg_putcopyend to let
2695 the server know that you are done, and it will return to a normal, non-
2696 COPY state. Returns a 1 on success. This method will fail if called
2697 when not in COPY IN mode.
2698
2699 Postgres limits
2700 For convenience, DBD::Pg can export certain constants representing the
2701 limits of Postgres data types. To use them, just add ":pg_limits" when
2702 DBD::Pg is used:
2703
2704 use DBD::Pg qw/:pg_limits/;
2705
2706 The constants and their values are:
2707
2708 PG_MIN_SMALLINT -32768
2709 PG_MAX_SMALLINT 32767
2710 PG_MIN_INTEGER -2147483648
2711 PG_MAX_INTEGER 2147483647
2712 PG_MIN_BIGINT -9223372036854775808
2713 PG_MAX_BIGINT 9223372036854775807
2714 PG_MIN_SMALLSERIAL 1
2715 PG_MAX_SMALLSERIAL 32767
2716 PG_MIN_SERIAL 1
2717 PG_MAX_SERIAL 2147483647
2718 PG_MIN_BIGSERIAL 1
2719 PG_MAX_BIGSERIAL 9223372036854775807
2720
2721 Large Objects
2722 DBD::Pg supports all largeobject functions provided by libpq via the
2723 "$dbh->pg_lo*" methods. Please note that access to a large object, even
2724 read-only large objects, must be put into a transaction.
2725
2726 Cursors
2727 Although PostgreSQL supports cursors, they have not been used in the
2728 current implementation. When DBD::Pg was created, cursors in PostgreSQL
2729 could only be used inside a transaction block. Because only one
2730 transaction block at a time is allowed, this would have implied the
2731 restriction not to use any nested "SELECT" statements. Therefore the
2732 "execute" method fetches all data at once into data structures located
2733 in the front-end application. This fact must to be considered when
2734 selecting large amounts of data!
2735
2736 You can use cursors in your application, but you'll need to do a little
2737 work. First you must declare your cursor. Now you can issue queries
2738 against the cursor, then select against your queries. This typically
2739 results in a double loop, like this:
2740
2741 # WITH HOLD is not needed if AutoCommit is off
2742 $dbh->do("DECLARE csr CURSOR WITH HOLD FOR $sql");
2743 while (1) {
2744 my $sth = $dbh->prepare("fetch 1000 from csr");
2745 $sth->execute;
2746 last if 0 == $sth->rows;
2747
2748 while (my $row = $sth->fetchrow_hashref) {
2749 # Do something with the data.
2750 }
2751 }
2752 $dbh->do("CLOSE csr");
2753
2754 Datatype bool
2755 The current implementation of PostgreSQL returns 't' for true and 'f'
2756 for false. From the Perl point of view, this is a rather unfortunate
2757 choice. DBD::Pg therefore translates the result for the "BOOL" data
2758 type in a Perlish manner: 'f' becomes the number 0 and 't' becomes the
2759 number 1. This way the application does not have to check the database-
2760 specific returned values for the data-type "BOOL" because Perl treats 0
2761 as false and 1 as true. You may set the pg_bool_tf attribute to a true
2762 value to change the values back to 't' and 'f' if you wish.
2763
2764 Boolean values can be passed to PostgreSQL as TRUE, 't', 'true', 'y',
2765 'yes' or '1' for true and FALSE, 'f', 'false', 'n', 'no' or '0' for
2766 false.
2767
2768 Schema support
2769 The PostgreSQL schema concept may differ from those of other databases.
2770 In a nutshell, a schema is a named collection of objects within a
2771 single database. Please refer to the PostgreSQL documentation for more
2772 details:
2773
2774 <http://www.postgresql.org/docs/current/static/ddl-schemas.html>
2775
2776 DBD::Pg does not provide explicit support for PostgreSQL schemas.
2777 However, schema functionality may be used without any restrictions by
2778 explicitly addressing schema objects, e.g.
2779
2780 my $res = $dbh->selectall_arrayref("SELECT * FROM my_schema.my_table");
2781
2782 or by manipulating the schema search path with "SET search_path", e.g.
2783
2784 $dbh->do("SET search_path TO my_schema, public");
2785
2787 The DBI module
2788
2790 To report a bug, or view the current list of bugs, please visit
2791 http://rt.cpan.org/Public/Dist/Display.html?Name=DBD-Pg
2792
2794 Patches can be submitted to rt.cpan.org. Detailed information on how to
2795 help out with this module can be found in the README.dev file. The
2796 latest development version can be obtained via: git clone
2797 git://github.com/bucardo/dbdpg.git
2798
2800 DBI by Tim Bunce <http://www.tim.bunce.name>
2801
2802 The original DBD-Pg was by Edmund Mergl (E.Mergl@bawue.de) and Jeffrey
2803 W. Baker (jwbaker@acm.org). Major developers include David Wheeler
2804 <david@justatheory.com>, Jason Stewart <jason@openinformatics.com>,
2805 Bruce Momjian <pgman@candle.pha.pa.us>, and Greg Sabino Mullane
2806 <greg@turnstep.com>, with help from many others: see the Changes file
2807 (<http://search.cpan.org/dist/DBD-Pg/Changes>) for a complete list.
2808
2809 Parts of this package were originally copied from DBI and DBD-Oracle.
2810
2811 Mailing List
2812
2813 The current maintainers may be reached through the 'dbd-pg' mailing
2814 list: <dbd-pg@perl.org>. Subscribe by sending an email to
2815 dbd-pg-subscribe@perl.org. Visit the archives at
2816 http://grokbase.com/g/perl/dbd-pg
2817
2819 Copyright (C) 1994-2020, Greg Sabino Mullane
2820
2821 This module (DBD::Pg) is free software; you can redistribute it and/or
2822 modify it under the same terms as Perl 5.10.0. For more details, see
2823 the full text of the licenses in the directory LICENSES.
2824
2825
2826
2827perl v5.30.2 2020-03-24 Pg(3)