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