NAME

DBD::Pg - PostgreSQL database driver for the DBI module

SYNOPSIS

use DBI;

$dbh = DBI->connect("dbi:Pg:dbname=$dbname", '', '', {AutoCommit => 0});
# The AutoCommit attribute should always be explicitly set

# For some advanced uses you may need PostgreSQL type values:
use DBD::Pg qw(:pg_types);

# For asynchronous calls, import the async constants:
use DBD::Pg qw(:async);

$dbh->do('INSERT INTO mytable(a) VALUES (1)');

$sth = $dbh->prepare('INSERT INTO mytable(a) VALUES (?)');
$sth->execute();

VERSION

This documents version 2.8.7 of the DBD::Pg module

DESCRIPTION

DBD::Pg is a Perl module that works with the DBI module to provide access to PostgreSQL databases.

MODULE DOCUMENTATION

This documentation describes driver specific behavior and restrictions. It is not supposed to be used as the only reference for the user. In any case consult the DBI documentation first!

Latest DBI docmentation.

THE DBI CLASS

DBI Class Methods

connect

This method creates a database handle by connecting to a database, and is the DBI equivalent of the "new" method. To connect to a Postgres database with a minimum of parameters, use the following syntax:

$dbh = DBI->connect("dbi:Pg:dbname=$dbname", '', '', {AutoCommit => 0});

This connects to the database named in the $dbname variable on the default port (usually 5432) without any user authentication.

The following connect statement shows almost all possible parameters:

$dbh = DBI->connect("dbi:Pg:dbname=$dbname;host=$host;port=$port;options=$options",
                    $username,
                    $password,
                    {AutoCommit => 0, RaiseError => 1, PrintError => 0}
                   );

If a parameter is not given, the connect() method will first look for specific environment variables, and then fall back to hard-coded defaults:

parameter    environment variable    hard coded default
------------------------------------------------------
host         PGHOST                  local domain socket
hostaddr     PGHOSTADDR              local domain socket
port         PGPORT                  5432
dbname*      PGDATABASE              current userid
username     PGUSER                  current userid
password     PGPASSWORD              (none)
options      PGOPTIONS               (none)
service      PGSERVICE               (none)
sslmode      PGSSLMODE               (none)

* May also use the aliases db or database

If the username and password values passed via connect() are undefined (as opposed to merely being empty strings), DBI will use the environment variables DBI_USER and DBI_PASS if they exist.

You can also connect by using a service connection file, which is named pg_service.conf. The location of this file can be controlled by setting the PGSYSCONFDIR environment variable. To use one of the named services within the file, set the name by using either the service parameter or the environment variable PGSERVICE. Note that when connecting this way, only the minimum parameters should be used. For example, to connect to a service named "zephyr", you could use:

$dbh = DBI->connect("dbi:Pg:service=zephyr", '', '');

You could also set $ENV{PGSERVICE} to "zephyr" and connect like this:

$dbh = DBI->connect("dbi:Pg:", '', '');

The format of the pg_service.conf file is simply a bracketed service name, followed by one parameter per line in the format name=value. For example:

[zephyr]
dbname=winds
user=wisp
password=W$2Hc00YSgP
port=6543

There are four valid arguments to the sslmode parameter, which controls whether to use SSL to connect to the database:

  • disable: SSL connections are never used

  • allow: try non-SSL, then SSL

  • prefer: try SSL, then non-SSL

  • require: connect only with SSL

You can also connect using sockets in a specific directory. This may be needed if the server you are connecting to has a different default socket directory from the one used to compile DBD::Pg. Use the complete path to the socket directory as the name of the host, like this:

$dbh = DBI->connect('dbi:Pg:dbname=foo;host=/var/tmp/socket',
  $username,
  $password,
  {AutoCommit => 0, RaiseError => 1});

connect_cached

$dbh = DBI->connect_cached("dbi:Pg:dbname=$dbname", $username, $password, \%options);

Implemented by DBI, no driver-specific impact.

data_sources

@data_sources = DBI->data_sources('Pg');
@data_sources = $dbh->data_sources();

Returns a list of available databases. Unless the environment variable DBI_DSN is set, a connection will be attempted to the database template1. The normal connection environment variables also apply, such as PGHOST, PGPORT, DBI_USER, DBI_PASS, and PGSERVICE.

You can also pass in options to add to the connection string For example, to specify an alternate port and host:

@data_sources = DBI->data_sources('Pg', 'port=5824;host=example.com');

or:

@data_sources = $dbh->data_sources('port=5824;host=example.com');

METHODS COMMON TO ALL HANDLES

For all of the methods below, $h can be either a database handle ($dbh) or a statement handle ($sth). Note that $dbh and $sth can be replaced with any variable name you choose: these are just the names most often used. Another common variable used in this documentation is $rv, which stands for "return value".

err

$rv = $h->err;

Returns the error code from the last method called. For the connect method it returns PQstatus, which is a number used by libpq (the Postgres connection library). A value of 0 indicates no error (CONNECTION_OK), while any other number indicates a failed connection. The only other number commonly seen is 1 (CONNECTION_BAD). See the libpq documentation for the complete list of return codes.

In all other non-connect methods $h-err> returns the PQresultStatus of the current handle. This is a number used by libpq and is one of:

0  Empty query string
1  A command that returns no data successfully completed.
2  A command that returns data sucessfully completed.
3  A COPY OUT command is still in progress.
4  A COPY IN command is still in progress.
5  A bad response was received from the backend.
6  A nonfatal error occurred (a notice or warning message)
7  A fatal error was returned: the last query failed.

errstr

$str = $h->errstr;

Returns the last error that was reported by Postgres. This message is affected by the "pg_errorlevel" setting.

state

$str = $h->state;

Returns a five-character "SQLSTATE" code. Success is indicated by a 00000 code, which gets mapped to an empty string by DBI. A code of S8006 indicates a connection failure, usually because the connection to the Postgres server has been lost.

While this method can be called as either $sth-state> or $dbh-state>, it is usually clearer to always use $dbh-state>.

The list of codes used by PostgreSQL can be found at: http://www.postgresql.org/docs/current/static/errcodes-appendix.html

Note that these codes are part of the SQL standard and only a small number of them will be used by PostgreSQL.

Common codes:

00000 Successful completion
25P01 No active SQL transaction
25P02 In failed SQL transaction
S8006 Connection failure

trace

$h->trace($trace_settings);
$h->trace($trace_settings, $trace_filename);
$trace_settings = $h->trace;

Changes the trace settings on a database or statement handle. The optional second argument specifies a file to write the trace information to. If no filename is given, the information is written to STDERR. Note that tracing can be set globally as well by setting DBI->trace, or by using the environment variable DBI_TRACE.

The value is either a numeric level or a named flag. For the flags that DBD::Pg uses, see parse_trace_flag.

trace_msg

$h->trace_msg($message_text);
$h->trace_msg($message_text, $min_level);

Writes a message to the current trace output (as set by the "trace" method). If a second argument is given, the message is only written if the current tracing level is equal to or greater than the $min_level.

parse_trace_flag and parse_trace_flags

$h->trace($h->parse_trace_flags('SQL|pglibpq'));
$h->trace($h->parse_trace_flags('1|pgstart'));

my $value = DBD::Pg->parse_trace_flag('pglibpq');
DBI->trace($value);

The parse_trace_flags method is used to convert one or more named flags to a number which can passed to the "trace" method. DBD::Pg currently supports the DBI-specific flag, SQL, as well as the ones listed below.

Flags can be combined by using the parse_trace_flags method, which simply calls parse_trace_flag on each item and combines them.

Sometimes you may wish to turn the tracing on before you connect to the database. The second example above shows a way of doing this: the call to DBD::Pg->parse_trace_flags provides a number than can be fed to DBI->trace before you create a database handle.

DBD::Pg supports the following trace flags:

SQL

Outputs all SQL statements. Note that the output provided will not necessarily be in a form suitable to passing directly to Postgres, as server-side prepared statements are used extensively by DBD::Pg. For maximum portability of output (but with a potential performance hit), use with $dbh-{pg_server_prepare} = 0>

pglibpq

Outputs the name of each libpq function (without arguments) immediately before running it. This is a good way to trace the flow of your program at a low level. This information is also output if the trace level is set to 4 or greater.

pgstart

Outputs the name of each internal DBD::Pg function, and other information such as the function arguments or important global variables, as each function starts. This information is also output if the trace level is set to 4 or greater.

pgend

Outputs a simple message at the very end of each internal DBD::Pg function. This is also output if the trace level is set to 4 or greater.

pgprefix

Forces each line of trace output to begin with the string dbdpg: . This helps to differentiate it from the normal DBI trace output.

pglogin

Outputs a message showing the connection string right before a new database connection is attempted, a message when the connection was successful, and a message right after the database has been disconnected. Also output if trace level is 5 or greater.

See the DBI section on TRACING for more information.

func

DBD::Pg uses the func method to support a variety of functions. Note that the name of the function comes last, after the arguments.

table_attributes
$attrs = $dbh->func($table, 'table_attributes');

Use of the tables_attributes function is no longer recommended. Instead, you can use the more portable column_info and primary_key methods to access the same information.

The table_attributes method returns, for the given table argument, a reference to an array of hashes, each of which contains the following keys:

NAME        attribute name
TYPE        attribute type
SIZE        attribute size (-1 for variable size)
NULLABLE    flag nullable
DEFAULT     default value
CONSTRAINT  constraint
PRIMARY_KEY flag is_primary_key
REMARKS     attribute description
lo_creat
$lobjId = $dbh->func($mode, 'lo_creat');

Creates a new large object and returns the object-id. $mode is a bitmask describing different attributes of the new object. Use the following constants:

$dbh->{pg_INV_WRITE}
$dbh->{pg_INV_READ}

Upon failure it returns undef.

lo_open
$lobj_fd = $dbh->func($lobjId, $mode, 'lo_open');

Opens an existing large object and returns an object-descriptor for use in subsequent lo_* calls. For the mode bits see "lo_creat". Returns undef upon failure. Note that 0 is a perfectly correct (and common) object descriptor!

lo_write
$nbytes = $dbh->func($lobj_fd, $buffer, $len, 'lo_write');

Writes $len bytes of c<$buffer> into the large object $lobj_fd. Returns the number of bytes written and undef upon failure.

lo_read
$nbytes = $dbh->func($lobj_fd, $buffer, $len, 'lo_read');

Reads $len bytes into c<$buffer> from large object $lobj_fd. Returns the number of bytes read and undef upon failure.

lo_lseek
$loc = $dbh->func($lobj_fd, $offset, $whence, 'lo_lseek');

Changes the current read or write location on the large object $obj_id. Currently $whence can only be 0 (which is L_SET). Returns the current location and undef upon failure.

lo_tell
$loc = $dbh->func($lobj_fd, 'lo_tell');

Returns the current read or write location on the large object $lobj_fd and undef upon failure.

lo_close
$lobj_fd = $dbh->func($lobj_fd, 'lo_close');

Closes an existing large object. Returns true upon success and false upon failure.

$ret = $dbh->func($lobjId, 'lo_unlink');

Deletes an existing large object. Returns true upon success and false upon failure.

lo_import
$lobjId = $dbh->func($filename, 'lo_import');

Imports a Unix file as a large object and returns the object id of the new object or undef upon failure.

lo_export
$ret = $dbh->func($lobjId, $filename, 'lo_export');

Exports a large object into a Unix file. Returns false upon failure, true otherwise.

getfd
$fd = $dbh->func('getfd');

Deprecated, use $dbh->{pg_socket} instead.

private_attribute_info

$hashref = $dbh->private_attribute_info();
$hashref = $sth->private_attribute_info();

Returns a hash of all private attributes used by DBD::Pg, for either a database or a statement handle. Currently, all the hash values are undef.

ATTRIBUTES COMMON TO ALL HANDLES

InactiveDestroy (boolean)

If set to true, then the "disconnect" method will not be automatically called when the database handle goes out of scope. This is required if you are forking, and even then you must tread carefully and ensure that either the parent or the child handles all database calls from that point forwards, so that messages from the Postgres backend are only handled by one of the processes. If you don't set things up properly, you will see messages such as "server closed the connection unexpectedly". A better solution is usually to rewrite your application not to use forking. See the section on "Asynchronous Queries" for a way to have your script continue to work while the database is processing a request.

RaiseError (boolean, inherited)

Forces errors to always raise an exception. Although it defaults to off, it is recommended that this be turned on, as the alternative is to check the return value of every method (prepare, execute, fetch, etc.) to check for any problems. See the DBI docs for more information.

PrintError (boolean, inherited)

Forces database errors to also generate warnings, which can then be filtered with methods such as locally redefining $SIG{__WARN__} or using modules such as CGI::Carp. This attribute is on by default.

Warn (boolean, inherited)

Enables warnings. This is on by default, and should only be turned off in a local block for a short a time only when absolutely needed.

Executed (boolean, read-only)

Indicates if a handle has been executed. For database handles, this value is true after the "do" method has been called, or when one of the child statement handles has issued an "execute". Issuing a "commit" or "rollback" always resets the attribute to false for database handles. For statement handles, any call to "execute" or its variants will flip the value to true for the lifetime of the statement handle.

Type (scalar)

Returns dr for a driver handle, db for a database handle, and st for a statement handle. Should be rarely needed.

TraceLevel (integer, inherited)

Sets the trace level, similar to the "trace" method. See the sections on "trace" and "parse_trace_flag" for more details.

Active (boolean, read-only)

Indicates if a handle is active or not. For database handles, this indicates if the database has been disconnected or not. For statement handles, it indicates if all the data has been fetched yet or not. Use of this attribute is not encouraged.

Kids (integer, read-only)

Returns the number of child processes created for each handle type. For a driver handle, indicates the number of database handles created. For a database handle, indicates the number of statement handles created. For statement handles, it always returns zero, because statement handles do not create kids.

ActiveKids (integer, read-only)

Same as Kids, but only returns those that are active.

CachedKids (hash ref)

Returns a hashref of handles. If called on a database handle, returns all statement handles created by use of the prepare_cached method. If called on a driver handle, returns all database handles created by the "connect_cached" method.

ChildHandles (array ref)

Implemented by DBI, no driver-specific impact.

PrintWarn (boolean, inherited)

Implemented by DBI, no driver-specific impact.

HandleError (boolean, inherited)

Implemented by DBI, no driver-specific impact.

HandleSetErr (code ref, inherited)

Implemented by DBI, no driver-specific impact.

ErrCount (unsigned integer)

Implemented by DBI, no driver-specific impact.

ShowErrorStatement (boolean, inherited)

Implemented by DBI, no driver-specific impact.

FetchHashKeyName (string, inherited)

Implemented by DBI, no driver-specific impact.

ChopBlanks (boolean, inherited)

Supported by this driver as proposed by DBI. This method is similar to the SQL function RTRIM.

Taint (boolean, inherited)

Implemented by DBI, no driver-specific impact.

TaintIn (boolean, inherited)

Implemented by DBI, no driver-specific impact.

TaintOut (boolean, inherited)

Implemented by DBI, no driver-specific impact.

Profile (inherited)

Implemented by DBI, no driver-specific impact.

LongReadLen (integer, inherited)

Not used by this driver.

LongTruncOk (boolean, inherited)

Not used by this driver.

CompatMode (boolean, inherited)

Not used by this driver.

DBI DATABASE HANDLE OBJECTS

Database Handle Methods

selectall_arrayref

$ary_ref = $dbh->selectall_arrayref($sql);
$ary_ref = $dbh->selectall_arrayref($sql, \%attr);
$ary_ref = $dbh->selectall_arrayref($sql, \%attr, @bind_values);

Returns a reference to an array containing the rows returned by preparing and executing the SQL string. See the DBI documentation for full details.

selectall_hashref

$hash_ref = $dbh->selectall_hashref($sql, $key_field);

Returns a reference to a hash containing the rows returned by preparing and executing the SQL string. See the DBI documentation for full details.

selectcol_arrayref

$ary_ref = $dbh->selectcol_arrayref($sql, \%attr, @bind_values);

Returns a reference to an array containing the first column from each rows returned by preparing and executing the SQL string. It is possible to specify exactly which columns to return. See the DBI documentation for full details.

prepare

$sth = $dbh->prepare($statement, \%attr);

WARNING: DBD::Pg now (as of version 1.40) uses true prepared statements by sending them to the backend to be prepared by the Postgres server. Statements that were legal before may no longer work. See below for details.

The prepare method prepares a statement for later execution. PostgreSQL supports prepared statements, which enables DBD::Pg to only send the query once, and simply send the arguments for every subsequent call to "execute". DBD::Pg can use these server-side prepared statements, or it can just send the entire query to the server each time. The best way is automatically chosen for each query. This will be sufficient for most users: keep reading for a more detailed explanation and some optional flags.

Queries that do not begin with the word "SELECT", "INSERT", "UPDATE", or "DELETE" are never sent as server-side prepared statements.

Deciding whether or not to use prepared statements depends on many factors, but you can force them to be used or not used by using the "pg_server_prepare" attribute when calling "prepare". Setting this to "0" means to never use prepared statements. Setting "pg_server_prepare" to "1" means that prepared statements should be used whenever possible. This is the default when connected to Postgres servers version 8.0 or higher. Servers that are version 7.4 get a special default value of "2", because server-side statements were only partially supported in that version. In this case, it only uses server-side prepares if all parameters are specifically bound.

The "pg_server_prepare" attribute can also be set at connection time like so:

$dbh = DBI->connect($DBNAME, $DBUSER, $DBPASS,
                    { AutoCommit => 0,
                      RaiseError => 1,
                      pg_server_prepare => 0,
                    });

or you may set it after your database handle is created:

$dbh->{pg_server_prepare} = 1;

To enable it for just one particular statement:

$sth = $dbh->prepare("SELECT id FROM mytable WHERE val = ?",
                     { pg_server_prepare => 1 });

You can even toggle between the two as you go:

$sth->{pg_server_prepare} = 1;
$sth->execute(22);
$sth->{pg_server_prepare} = 0;
$sth->execute(44);
$sth->{pg_server_prepare} = 1;
$sth->execute(66);

In the above example, the first execute will use the previously prepared statement. The second execute will not, but will build the query into a single string and send it to the server. The third one will act like the first and only send the arguments. Even if you toggle back and forth, a statement is only prepared once.

Using prepared statements is in theory quite a bit faster: not only does the PostgreSQL backend only have to prepare the query only once, but DBD::Pg no longer has to worry about quoting each value before sending it to the server.

However, there are some drawbacks. The server cannot always choose the ideal parse plan because it will not know the arguments before hand. But for most situations in which you will be executing similar data many times, the default plan will probably work out well. Programs such as PgBouncer which cache connections at a low level should not use prepared statements via DBD::Pg, or must take extra care in the application to account for the fact that prepared statements are not shared across database connections. Further discussion on this subject is beyond the scope of this documentation: please consult the pgsql-performance mailing list, http://archives.postgresql.org/pgsql-performance/

Only certain commands will be sent to a server-side prepare: currently these include SELECT, INSERT, UPDATE, and DELETE. DBD::Pg uses a simple naming scheme for the prepared statements themselves: dbdpg_XY_Z, where Y is the current PID, X is either 'p' or 'n' (depending on if the PID is a positive or negative number), and Z is a number that starts at 1 and increases each time a new statement is prepared. This number is tracked at the database handle level, so multiple statement handles will not collide.

You cannot send more than one command at a time in the same prepare command (by separating them with semi-colons) when using server-side prepares.

The actual PREPARE is usually not performed until the first execute is called, due to the fact that information on the data types (provided by "bind_param") may be provided after the prepare but before the execute.

A server-side prepare may happen before the first "execute", but only if the server can handle the server-side prepare, and the statement contains no placeholders. It will also be prepared if the "pg_prepare_now" attribute is passed in and set to a true value. Similarly, the "pg_prepare_now" attribute can be set to 0 to ensure that the statement is not prepared immediately, although the cases in which you would want this are very rare. Finally, you can set the default behavior of all prepare statements by setting the "pg_prepare_now" attribute on the database handle:

$dbh->{pg_prepare_now} = 1;

The following two examples will be prepared right away:

$sth->prepare("SELECT 123"); ## no placeholders

$sth->prepare("SELECT 123, ?", {pg_prepare_now => 1});

The following two examples will NOT be prepared right away:

$sth->prepare("SELECT 123, ?"); ## has a placeholder

$sth->prepare("SELECT 123", {pg_prepare_now => 0});

There are times when you may want to prepare a statement yourself. To do this, simply send the PREPARE statement directly to the server (e.g. with the "do" method). Create a statement handle and set the prepared name via the "pg_prepare_name" attribute. The statement handle can be created with a dummy statement, as it will not be executed. However, it should have the same number of placeholders as your prepared statement. Example:

$dbh->do("PREPARE mystat AS SELECT COUNT(*) FROM pg_class WHERE reltuples < ?");
$sth = $dbh->prepare("SELECT ?");
$sth->bind_param(1, 1, SQL_INTEGER);
$sth->{pg_prepare_name} = "mystat";
$sth->execute(123);

The above will run the equivalent of this query on the backend:

EXECUTE mystat(123);

which is the equivalent of:

SELECT COUNT(*) FROM pg_class WHERE reltuples < 123;

You can force DBD::Pg to send your query directly to the server by adding the "pg_direct" attribute to your prepare call. This is not recommended, but is added just in case you need it.

Placeholders

There are three types of placeholders that can be used in DBD::Pg. The first is the "question mark" type, in which each placeholder is represented by a single question mark character. This is the method recommended by the DBI specs and is the most portable. Each question mark is internally replaced by a "dollar sign number" in the order in which they appear in the query (important when using "bind_param").

The method second type of placeholder is "dollar sign numbers". This is the method that Postgres uses internally and is overall probably the best method to use if you do not need compatibility with other database systems. DBD::Pg, like PostgreSQL, allows the same number to be used more than once in the query. Numbers must start with "1" and increment by one value (but can appear in any order within the query). If the same number appears more than once in a query, it is treated as a single parameter and all instances are replaced at once. Examples:

Not legal:

$SQL = 'SELECT count(*) FROM pg_class WHERE relpages > $2'; # Does not start with 1

$SQL = 'SELECT count(*) FROM pg_class WHERE relpages BETWEEN $1 AND $3'; # Missing 2

Legal:

$SQL = 'SELECT count(*) FROM pg_class WHERE relpages > $1';

$SQL = 'SELECT count(*) FROM pg_class WHERE relpages BETWEEN $1 AND $2';

$SQL = 'SELECT count(*) FROM pg_class WHERE relpages BETWEEN $2 AND $1'; # legal but confusing

$SQL = 'SELECT count(*) FROM pg_class WHERE relpages BETWEEN $1 AND $2 AND reltuples > $1';

$SQL = 'SELECT count(*) FROM pg_class WHERE relpages > $1 AND reltuples > $1';

In the final statement above, DBI thinks there is only one placeholder, so this statement will replace both placeholders:

$sth->bind_param(1, 2045);

While a simple execute with no bind_param calls requires only a single argument as well:

$sth->execute(2045);

The final placeholder type is "named parameters" in the format ":foo". While this syntax is supported by DBD::Pg, its use is discouraged in favor of dollar-sign numbers.

The different types of placeholders cannot be mixed within a statement, but you may use different ones for each statement handle you have. This is confusing at best, so stick to one style within your program.

If your queries use operators that contain question marks (e.g. some of the native Postgres geometric operators) or array slices (e.g. data[100:300]), you can tell DBD::Pg to ignore any non-dollar sign placeholders by setting the "pg_placeholder_dollaronly" attribute at either the database handle or the statement handle level. Examples:

$dbh->{pg_placeholder_dollaronly} = 1;
$sth = $dbh->prepare(q{SELECT * FROM mytable WHERE lseg1 ?# lseg2 AND name = $1});
$sth->execute('segname');

Alternatively, you can set it at prepare time:

$sth = $dbh->prepare(q{SELECT * FROM mytable WHERE lseg1 ?-| lseg2 AND name = $1},
  {pg_placeholder_dollaronly = 1});
$sth->execute('segname');

prepare_cached

$sth = $dbh->prepare_cached($statement, \%attr);

Implemented by DBI, no driver-specific impact. This method is most useful when using a server that supports server-side prepares, and you have asked the prepare to happen immediately via the "pg_prepare_now" attribute.

do

$rv = $dbh->do($statement);
$rv = $dbh->do($statement, \%attr);
$rv = $dbh->do($statement, \%attr, @bind_values);

Prepare and execute a single statement. Returns the number of rows affected if the query was successful, returns undef if an error occurred, and returns -1 if the number of rows is unknown or not available. Note that this method will return 0E0 instead of 0 for 'no rows were affected', in order to always return a true value if no error occurred.

If neither \%attr nor @bind_values is given, the query will be sent directly to the server without the overhead of internally creating a statement handle and running prepare and execute, for a measurable speed increase.

Note that an empty statement (a string with no length) will not be passed to the server; if you want a simple test, use "SELECT 123" or the "ping" method.

last_insert_id

$rv = $dbh->last_insert_id(undef, $schema, $table, undef);
$rv = $dbh->last_insert_id(undef, $schema, $table, undef, {sequence => $seqname});

Attempts to return the id of the last value to be inserted into a table. You can either provide a sequence name (preferred) or provide a table name with optional schema, and DBD::Pg will attempt to find the sequence itself. The current value of the sequence is returned by a call to the CURRVAL() PostgreSQL function. This will fail if the sequence has not yet been used in the current database connection.

If you do not know the name of the sequence, you can provide a table name and DBD::Pg will attempt to return the correct value. To do this, there must be at least one column in the table with a NOT NULL constraint, that has a unique constraint, and which uses a sequence as a default value. If more than one column meets these conditions, the primary key will be used. This involves some looking up of things in the system table, so DBD::Pg will cache the sequence name for subsequent calls. If you need to disable this caching for some reason, (such as the sequence name changing), you can control it by adding pg_cache = 0> to the final (hashref) argument for last_insert_id.

Please keep in mind that this method is far from foolproof, so make your script use it properly. Specifically, make sure that it is called immediately after the insert, and that the insert does not add a value to the column that is using the sequence as a default value. However, because we are using sequences, you can be sure that the value you got back has not been used by any other process.

Some examples:

$dbh->do("CREATE SEQUENCE lii_seq START 1");
$dbh->do("CREATE TABLE lii (
  foobar INTEGER NOT NULL UNIQUE DEFAULT nextval('lii_seq'),
  baz VARCHAR)");
$SQL = "INSERT INTO lii(baz) VALUES (?)";
$sth = $dbh->prepare($SQL);
for (qw(uno dos tres cuatro)) {
  $sth->execute($_);
  my $newid = $dbh->last_insert_id(C<undef>,undef,undef,undef,{sequence=>'lii_seq'});
  print "Last insert id was $newid\n";
}

If you did not want to worry about the sequence name:

$dbh->do("CREATE TABLE lii2 (
  foobar SERIAL UNIQUE,
  baz VARCHAR)");
$SQL = "INSERT INTO lii2(baz) VALUES (?)";
$sth = $dbh->prepare($SQL);
for (qw(uno dos tres cuatro)) {
  $sth->execute($_);
  my $newid = $dbh->last_insert_id(undef,undef,"lii2",undef);
  print "Last insert id was $newid\n";
}

commit

$rv = $dbh->commit;

Issues a COMMIT to the server, indicating that the current transaction is finished and that all changes made will be visible to other processes. If AutoCommit is enabled, then a warning is given and no COMMIT is issued. Returns true on success, false on error. See also the the section on "Transactions".

rollback

$rv = $dbh->rollback;

Issues a ROLLBACK to the server, which discards any changes made in the current transaction. If AutoCommit is enabled, then a warning is given and no ROLLBACK is issued. Returns true on success, and false on error. See also the the section on "Transactions".

begin_work

This method turns on transactions until the next call to "commit" or "rollback", if "AutoCommit" is currently enabled. If it is not enabled, calling begin_work will issue an error. Note that the transaction will not actually begin until the first statement after begin_work is called. Example:

$dbh->{AutoCommit} = 1;
$dbh->do("INSERT INTO foo VALUES (123)"); ## Changes committed immediately
$dbh->begin_work();
## Not in a transaction yet, but AutoCommit is set to 0

$dbh->do("INSERT INTO foo VALUES (345)");
## DBD::PG actually issues two statements here:
## BEGIN;
## INSERT INTO foo VALUES (345)
## We are now in a transaction

$dbh->commit();
## AutoCommit is now set to 1 again

disconnect

$rv = $dbh->disconnect;

Disconnects from the Postgres database. Any uncommitted changes will be rolled back upon disconnection. It's good policy to always explicitly call commit or rollback at some point before disconnecting, rather than relying on the default rollback behavior.

This method may give warnings about "disconnect invalidates X active statement handle(s)". This means that you called $sth->execute() but did not finish fetching all the rows from them. To avoid seeing this warning, either fetch all the rows or call $sth->finish() for each executed statement handle.

If the script exits before disconnect is called (or, more precisely, if the database handle is no longer referenced by anything), then the database handle's DESTROY method will call the rollback() and disconnect() methods automatically. It is best to explicitly disconnect rather than rely on this behavior.

pg_notifies

$ret = $dbh->pg_notifies;

Looks for any asynchronous notifications received and returns either undef or a reference to a three-element array consisting of an event name, the PID of the backend that sent the NOTIFY command, and the optional payload string. Note that this does not check if the connection to the database is still valid first - for that, use the c<ping> method. You may need to commit if not in autocommit mode - new notices will not be picked up while in the middle of a transaction. An example:

$dbh->do("LISTEN abc");
$dbh->do("LISTEN def");

## Hang around until we get the message we want
LISTENLOOP: {
  while (my $notify = $dbh->pg_notifies) {
    my ($name, $pid, $payload) = @$notify;
    print qq{I received notice "$name" from PID $pid, payload was "$payload"\n};
    ## Do something based on the notice received
  }
  $dbh->ping() or die qq{Ping failed!};
  $dbh->commit();
  sleep(5);
  redo;
}

Payloads will always be an empty string unless you are connecting to a Postgres server version 8.4 or higher.

ping

$rv = $dbh->ping;

This ping method is used to check the validity of a database handle. The value returned is either 0, indicating that the connection is no longer valid, or a positive integer, indicating the following:

Value    Meaning
--------------------------------------------------
  1      Database is idle (not in a transaction)
  2      Database is active, there is a command in progress (usually seen after a COPY command)
  3      Database is idle within a transaction
  4      Database is idle, within a failed transaction

Additional information on why a handle is not valid can be obtained by using the "pg_ping" method.

pg_ping

$rv = $dbh->pg_ping;

This is a DBD::Pg-specific extension to the "ping" method. This will check the validity of a database handle in exactly the same way as ping, but instead of returning a 0 for an invalid connection, it will return a negative number. So in addition to returning the positive numbers documented for ping, it may also return the following:

Value    Meaning
--------------------------------------------------
 -1      There is no connection to the database at all (e.g. after C<disconnect>)
 -2      An unknown transaction status was returned (e.g. after forking)
 -3      The handle exists, but no data was returned from a test query.

In practice, you should only ever see -1 and -2.

get_info

$value = $dbh->get_info($info_type);

Supports a very large set (> 250) of the information types, including the minimum recommended by DBI.

table_info

$sth = $dbh->table_info(undef, $schema, $table, $type);

Returns all tables and views visible to the current user. The schema and table arguments will do a LIKE search if a percent sign (%) or an underscore (_) is detected in the argument. The $type argument accepts a value of either "TABLE" or "VIEW" (using both is the default action). Note that a statement handle is returned, and not a direct list of tables. See the examples below for ways to handle this.

The following fields are returned:

TABLE_CAT: Always NULL, as Postgres does not have the concept of catalogs.

TABLE_SCHEM: The name of the schema that the table or view is in.

TABLE_NAME: The name of the table or view.

TABLE_TYPE: The type of object returned. Will be one of "TABLE", "VIEW", or "SYSTEM TABLE".

The TABLE_SCHEM and TABLE_NAME will be quoted via quote_ident().

Two additional fields specific to DBD::Pg are returned:

pg_schema: the unquoted name of the schema

pg_table: the unquoted name of the table

If your database supports tablespaces (version 8.0 or greater), two additional DBD::Pg specific fields are returned:

pg_tablespace_name: the name of the tablespace the table is in

pg_tablespace_location: the location of the tablespace the table is in

Tables that have not been assigned to a particular tablespace (or views) will return NULL (undef) for both of the above field.

Rows are returned alphabetically, with all tables first, and then all views.

Examples of use:

## Display all tables and views in the public schema:
$sth = $dbh->table_info('', 'public', undef, undef);
for my $rel ({@$sth->fetchall_arrayref({})}) {
  print "$rel->{TABLE_TYPE} name is $rel->{TABLE_NAME}\n";
}


# Display the schema of all tables named 'foo':
$sth = $dbh->table_info('', undef, 'foo', 'TABLE');
for my $rel (@{$sth->fetchall_arrayref({})}) {
  print "Table name is $rel->{TABLE_SCHEM}.$rel->{TABLE_NAME}\n";
}

column_info

$sth = $dbh->column_info( undef, $schema, $table, $column );

Supported by this driver as proposed by DBI with the follow exceptions. These fields are currently always returned with NULL (undef) values:

TABLE_CAT
BUFFER_LENGTH
DECIMAL_DIGITS
NUM_PREC_RADIX
SQL_DATA_TYPE
SQL_DATETIME_SUB
CHAR_OCTET_LENGTH

Also, six additional non-standard fields are returned:

pg_type: data type with additional info i.e. "character varying(20)"

pg_constraint: holds column constraint definition

pg_schema: the unquoted name of the schema

pg_table: the unquoted name of the table

pg_column: the unquoted name of the column

pg_enum_values: an array reference of allowed values for an enum column

Note that the TABLE_SCHEM, TABLE_NAME, and COLUMN_NAME fields all return output wrapped in quote_ident(). If you need the unquoted version, use the pg_ fields above.

primary_key_info

$sth = $dbh->primary_key_info( undef, $schema, $table, \%attr );

Supported by this driver as proposed by DBI. There are no search patterns allowed, but leaving the $schema argument blank will cause the first table found in the schema search path to be used. An additional field, "DATA_TYPE", is returned and shows the data type for each of the arguments in the "COLUMN_NAME" field.

This method will also return tablespace information for servers that support tablespaces. See the "table_info" entry for more information.

The five additional custom fields returned are:

pg_tablespace_name: name of the tablespace, if any

pg_tablespace_location: location of the tablespace

pg_schema: the unquoted name of the schema

pg_table: the unquoted name of the table

pg_column: the unquoted name of the column

In addition to the standard format of returning one row for each column found for the primary key, you can pass the pg_onerow attribute to force a single row to be used. If the primary key has multiple columns, the "KEY_SEQ", "COLUMN_NAME", and "DATA_TYPE" fields will return a comma-delimited string. If the pg_onerow attribute is set to "2", the fields will be returned as an arrayref, which can be useful when multiple columns are involved:

$sth = $dbh->primary_key_info('', '', 'dbd_pg_test', {pg_onerow => 2});
if (defined $sth) {
  my $pk = $sth->fetchall_arrayref()->[0];
  print "Table $pk->[2] has a primary key on these columns:\n";
  for (my $x=0; defined $pk->[3][$x]; $x++) {
    print "Column: $pk->[3][$x]  (data type: $pk->[6][$x])\n";
  }
}

primary_key

@key_column_names = $dbh->primary_key(undef, $schema, $table);

Simple interface to the "primary_key_info" method. Returns a list of the column names that comprise the primary key of the specified table. The list is in primary key column sequence order. If there is no primary key then an empty list is returned.

foreign_key_info

$sth = $dbh->foreign_key_info( $pk_catalog, $pk_schema, $pk_table,
                               $fk_catalog, $fk_schema, $fk_table );

Supported by this driver as proposed by DBI, using the SQL/CLI variant. There are no search patterns allowed, but leaving the $schema argument blank will cause the first table found in the schema search path to be used. Two additional fields, "UK_DATA_TYPE" and "FK_DATA_TYPE", are returned to show the data type for the unique and foreign key columns. Foreign keys that have no named constraint (where the referenced column only has an unique index) will return undef for the "UK_NAME" field.

statistics_info

$sth = $dbh->statistics_info( undef, $schema, $table, $unique_only, $quick );

Returns a statement handle that can be fetched from to give statistics information on a specific table and its indexes. The $table argument is mandatory. The $schema argument is optional but recommended. The $unique_only argument, if true, causes only information about unique indexes to be returned. The $quick argument is not used by DBD::Pg. For information on the format of the rows returned, please see the DBI documentation.

DBI section on statistics_info

tables

@names = $dbh->tables( undef, $schema, $table, $type, \%attr );

Supported by this driver as proposed by DBI. This method returns all tables and/or views which are visible to the current user: see "table_info" for more information about the arguments. The name of the schema appears before the table or view name. This can be turned off by adding in the pg_noprefix attribute:

my @tables = $dbh->tables( '', '', 'dbd_pg_test', '', {pg_noprefix => 1} );

type_info_all

$type_info_all = $dbh->type_info_all;

Supported by this driver as proposed by DBI. Information is only provided for SQL datatypes and for frequently used datatypes. The mapping between the PostgreSQL typename and the SQL92 datatype (if possible) has been done according to the following table:

+---------------+------------------------------------+
| typname       | SQL92                              |
|---------------+------------------------------------|
| bool          | BOOL                               |
| text          | /                                  |
| bpchar        | CHAR(n)                            |
| varchar       | VARCHAR(n)                         |
| int2          | SMALLINT                           |
| int4          | INT                                |
| int8          | /                                  |
| money         | /                                  |
| float4        | FLOAT(p)   p<7=float4, p<16=float8 |
| float8        | REAL                               |
| abstime       | /                                  |
| reltime       | /                                  |
| tinterval     | /                                  |
| date          | /                                  |
| time          | /                                  |
| datetime      | /                                  |
| timespan      | TINTERVAL                          |
| timestamp     | TIMESTAMP                          |
+---------------+------------------------------------+

type_info

@type_info = $dbh->type_info($data_type);

Implemented by DBI, no driver-specific impact.

quote

$rv = $dbh->quote($value, $data_type);

This module implements its own quote method. For simple string types, both backslashes and single quotes are doubled. You may also quote arrayrefs and receive a string suitable for passing into Postgres array columns.

If the value contains backslashes, and the server is version 8.1 or higher, then the escaped string syntax will be used (which places a capital E before the first single quote). This syntax is always used when quoting bytea values on servers 8.1 and higher.

The data_type argument is optional and should be one of the type constants exported by DBD::Pg (such as PG_BYTEA). In addition to string, bytea, char, bool, and other standard types, the following geometric types are supported: point, line, lseg, box, path, polygon, and circle (PG_POINT, PG_LINE, PG_LSEG, PG_BOX, PG_POLYGON, and PG_CIRCLE respectively).

NOTE: The undocumented (and invalid) support for the SQL_BINARY data type is officially deprecated. Use PG_BYTEA with bind_param() instead:

$rv = $sth->bind_param($param_num, $bind_value,
                       { pg_type => PG_BYTEA });

quote_identifier

$string = $dbh->quote_identifier( $name );
$string = $dbh->quote_identifier( undef, $schema, $table);

Returns a quoted version of the supplied string, which is commonly a schema, table, or column name. The three argument form will return the schema and the table together, separated by a dot. Examples:

print $dbh->quote_identifier('grapefruit'); ## Prints: "grapefruit"

print $dbh->quote_identifier('juicy fruit'); ## Prints: "juicy fruit"

print $dbh->quote_identifier(undef, 'public', 'pg_proc');
## Prints: "public"."pg_proc"

pg_server_trace

$dbh->pg_server_trace($filehandle);

Writes debugging information from the PostgreSQL backend to a file. This is not related to the DBI "trace" method and you should not use this method unless you know what you are doing. If you do enable this, be aware that the file will grow very large, very quick. To stop logging to the file, use the "pg_server_untrace" method. The first argument must be a file handle, not a filename. Example:

my $pid = $dbh->{pg_pid};
my $file = "pgbackend.$pid.debug.log";
open(my $fh, ">$file") or die qq{Could not open "$file": $!\n};
$dbh->pg_server_trace($fh);
## Run code you want to trace here
$dbh->pg_server_untrace;
close($fh);

pg_server_untrace

$dbh->pg_server_untrace;

Stop server logging to a previously opened file.

selectrow_array

@row_ary = $dbh->selectrow_array($sql);
@row_ary = $dbh->selectrow_array($sql, \%attr);
@row_ary = $dbh->selectrow_array($sql, \%attr, @bind_values);

Returns an array of row information after preparing and executing the provided SQL string. The rows are returned by calling "fetchrow_array". The string can also be a statement handle generated by a previous prepare. Note that only the first row of data is returned. If called in a scalar context, only the first column of the first row is returned. Because this is not portable, it is not recommended that you use this method in that way.

selectrow_arrayref

$ary_ref = $dbh->selectrow_arrayref($statement);
$ary_ref = $dbh->selectrow_arrayref($statement, \%attr);
$ary_ref = $dbh->selectrow_arrayref($statement, \%attr, @bind_values);

Exactly the same as "selectrow_array", except that it returns a reference to an array, by internal use of the "fetchrow_arrayref" method.

selectrow_hashref

$hash_ref = $dbh->selectrow_hashref($sql);
$hash_ref = $dbh->selectrow_hashref($sql, \%attr);
$hash_ref = $dbh->selectrow_hashref($sql, \%attr, @bind_values);

Exactly the same as "selectrow_array", except that it returns a reference to an hash, by internal use of the "fetchrow_hashref" method.

clone

$other_dbh = $dbh->clone();

Creates a copy of the database handle by connecting with the same parameters as the original handle, then trying to merge the attributes. See the DBI documentation for complete usage.

Database Handle Attributes

AutoCommit (boolean)

Supported by this driver as proposed by DBI. According to the classification of DBI, PostgreSQL is a database in which a transaction must be explicitly started. Without starting a transaction, every change to the database becomes immediately permanent. The default of AutoCommit is on, but this may change in the future, so it is highly recommended that you explicitly set it when calling "connect". For details see the notes about "Transactions" elsewhere in this document.

pg_bool_tf (boolean)

DBD::Pg specific attribute. If true, boolean values will be returned as the characters 't' and 'f' instead of '1' and '0'.

Name (string, read-only)

Returns the name of the current database.

Username (string, read-only)

Returns the name of the user connected to the database.

pg_enable_utf8 (boolean)

DBD::Pg specific attribute. If true, then the utf8 flag will be turned for returned character data (if the data is valid UTF-8). For details about the utf8 flag, see the Encode module. This attribute is only relevant under perl 5.8 and later.

pg_errorlevel (integer)

DBD::Pg specific attribute. Sets the amount of information returned by the server's error messages. Valid entries are 0, 1, and 2. Any other number will be forced to the default value of 1.

A value of 0 ("TERSE") will show severity, primary text, and position only and will usually fit on a single line. A value of 1 ("DEFAULT") will also show any detail, hint, or context fields. A value of 2 ("VERBOSE") will show all available information.

pg_protocol (integer, read-only)

DBD::Pg specific attribute. Returns the version of the PostgreSQL server. If DBD::Pg is unable to figure out the version, it will return a "0". Otherwise, a "3" is returned.

pg_lib_version (integer, read-only)

DBD::Pg specific attribute. Indicates which version of PostgreSQL that DBD::Pg was compiled against. In other words, which libraries were used. Returns a number with major, minor, and revision together; version 8.1.4 would be returned as 80104.

pg_server_version (integer, read-only)

DBD::Pg specific attribute. Indicates which version of PostgreSQL that the current database handle is connected to. Returns a number with major, minor, and revision together; version 8.0.1 would be 80001.

pg_db (string, read-only)

DBD::Pg specific attribute. Returns the name of the current database.

pg_user (string, read-only)

DBD::Pg specific attribute. Returns the name of the user that connected to the server.

pg_pass (string, read-only)

DBD::Pg specific attribute. Returns the password used to connect to the server.

pg_host (string, read-only)

DBD::Pg specific attribute. Returns the host of the current server connection. Locally connected hosts will return an empty string.

pg_port (integer, read-only)

DBD::Pg specific attribute. Returns the port of the connection to the server.

pg_default_port (integer, read-only)

DBD::Pg specific attribute. Returns the default port used if none is specifically given.

pg_options (string, read-only)

DBD::Pg specific attribute. Returns the command-line options passed to the server. May be an empty string.

pg_socket (integer, read-only)

DBD::Pg specific attribute. Returns the file description number of the connection socket to the server.

pg_pid (integer, read-only)

DBD::Pg specific attribute. Returns the process id (PID) of the backend server process handling the connection.

pg_prepare_now (boolean)

DBD::Pg specific attribute. Default is off. If true, then the "prepare" method will immediately prepare commands, rather than waiting until the first execute.

pg_server_prepare (integer)

DBD::Pg specific attribute. Indicates if DBD::Pg should attempt to use server-side prepared statements. The default value, 1, indicates that prepared statements should be used whenever possible. See the section on the "prepare" method for more information.

pg_placeholder_dollaronly (boolean)

DBD::Pg specific attribute. Defaults to false. When true, question marks inside of statements are not treated as "placeholders". Useful for statements that contain unquoted question marks, such as geometric operators.

pg_expand_array (boolean, read-only)

DBD::Pg specific attribute. Defaults to false. If false, arrays returned from the server will not be changed into a Perl arrayref, but remain as a string.

pg_async_status (integer, read-only)

DBD::Pg specific attribute. Returns the current status of an asynchronous command. 0 indicates no asynchronous command is in progress, 1 indicates that an asynchronous command has started and -1 indicated that an asynchronous command has been cancelled.

pg_standard_conforming_strings (boolean, read-only)

DBD::Pg specific attribute. Returns true if the server is currently using standard conforming strings. Only available if the target server is version 8.2 or better.

pg_INV_READ (integer, read-only)

Constant to be used for the mode in "lo_creat" and "lo_open".

pg_INV_WRITE (integer, read-only)

Constant to be used for the mode in "lo_creat" and "lo_open".

Driver (handle)

Holds the handle of the parent driver. The only recommended use for this is to find the name of the driver using:

$dbh->{Driver}->{Name}

RowCacheSize (integer)

Not used for DBD::Pg

DBI STATEMENT HANDLE OBJECTS

Statement Handle Methods

bind_param

$rv = $sth->bind_param($param_num, $bind_value);
$rv = $sth->bind_param($param_num, $bind_value, $bind_type);
$rv = $sth->bind_param($param_num, $bind_value, \%attr);

Allows the user to bind a value and/or a data type to a placeholder. This is especially important when using server-side prepares. See the "prepare" method for more information.

The value of $param_num is a number if using the '?' or '$1' style placeholders. If using ":foo" style placeholders, the complete name (e.g. ":foo") must be given. For numeric values, you can either use a number or use a literal '$1'. See the examples below.

The $bind_value argument is fairly self-explanatory. A value of undef will bind a NULL to the placeholder. Using undef is useful when you want to change just the type and will be overwriting the value later. (Any value is actually usable, but undef is easy and efficient).

The \%attr hash is used to indicate the data type of the placeholder. The default value is "varchar". If you need something else, you must use one of the values provided by DBI or by DBD::Pg. To use a SQL value, modify your "use DBI" statement at the top of your script as follows:

use DBI qw(:sql_types);

This will import some constants into your script. You can plug those directly into the bind_param call. Some common ones that you will encounter are:

SQL_INTEGER

To use PostgreSQL data types, import the list of values like this:

use DBD::Pg qw(:pg_types);

You can then set the data types by setting the value of the pg_type key in the hash passed to bind_param. The current list of Postgres data types exported is:

PG_ABSTIME PG_ABSTIMEARRAY PG_ACLITEM PG_ACLITEMARRAY PG_ANY PG_ANYARRAY
PG_ANYELEMENT PG_ANYENUM PG_ANYNONARRAY PG_BIT PG_BITARRAY PG_BOOL
PG_BOOLARRAY PG_BOX PG_BOXARRAY PG_BPCHAR PG_BPCHARARRAY PG_BYTEA
PG_BYTEAARRAY PG_CHAR PG_CHARARRAY PG_CID PG_CIDARRAY PG_CIDR
PG_CIDRARRAY PG_CIRCLE PG_CIRCLEARRAY PG_CSTRING PG_CSTRINGARRAY PG_DATE
PG_DATEARRAY PG_FLOAT4 PG_FLOAT4ARRAY PG_FLOAT8 PG_FLOAT8ARRAY PG_GTSVECTOR
PG_GTSVECTORARRAY PG_INET PG_INETARRAY PG_INT2 PG_INT2ARRAY PG_INT2VECTOR
PG_INT2VECTORARRAY PG_INT4 PG_INT4ARRAY PG_INT8 PG_INT8ARRAY PG_INTERNAL
PG_INTERVAL PG_INTERVALARRAY PG_LANGUAGE_HANDLER PG_LINE PG_LINEARRAY PG_LSEG
PG_LSEGARRAY PG_MACADDR PG_MACADDRARRAY PG_MONEY PG_MONEYARRAY PG_NAME
PG_NAMEARRAY PG_NUMERIC PG_NUMERICARRAY PG_OID PG_OIDARRAY PG_OIDVECTOR
PG_OIDVECTORARRAY PG_OPAQUE PG_PATH PG_PATHARRAY PG_PG_ATTRIBUTE PG_PG_CLASS
PG_PG_PROC PG_PG_TYPE PG_POINT PG_POINTARRAY PG_POLYGON PG_POLYGONARRAY
PG_RECORD PG_REFCURSOR PG_REFCURSORARRAY PG_REGCLASS PG_REGCLASSARRAY PG_REGCONFIG
PG_REGCONFIGARRAY PG_REGDICTIONARY PG_REGDICTIONARYARRAY PG_REGOPER PG_REGOPERARRAY PG_REGOPERATOR
PG_REGOPERATORARRAY PG_REGPROC PG_REGPROCARRAY PG_REGPROCEDURE PG_REGPROCEDUREARRAY PG_REGTYPE
PG_REGTYPEARRAY PG_RELTIME PG_RELTIMEARRAY PG_SMGR PG_TEXT PG_TEXTARRAY
PG_TID PG_TIDARRAY PG_TIME PG_TIMEARRAY PG_TIMESTAMP PG_TIMESTAMPARRAY
PG_TIMESTAMPTZ PG_TIMESTAMPTZARRAY PG_TIMETZ PG_TIMETZARRAY PG_TINTERVAL PG_TINTERVALARRAY
PG_TRIGGER PG_TSQUERY PG_TSQUERYARRAY PG_TSVECTOR PG_TSVECTORARRAY PG_TXID_SNAPSHOT
PG_TXID_SNAPSHOTARRAY PG_UNKNOWN PG_UUID PG_UUIDARRAY PG_VARBIT PG_VARBITARRAY
PG_VARCHAR PG_VARCHARARRAY PG_VOID PG_XID PG_XIDARRAY PG_XML
PG_XMLARRAY

Data types are "sticky," in that once a data type is set to a certain placeholder, it will remain for that placeholder, unless it is explicitly set to something else afterwards. If the statement has already been prepared, and you switch the data type to something else, DBD::Pg will re-prepare the statement for you before doing the next execute.

Examples:

use DBI qw(:sql_types);
use DBD::Pg qw(:pg_types);

$SQL = "SELECT id FROM ptable WHERE size > ? AND title = ?";
$sth = $dbh->prepare($SQL);

## Both arguments below are bound to placeholders as "varchar"
$sth->execute(123, "Merk");

## Reset the datatype for the first placeholder to an integer
$sth->bind_param(1, undef, SQL_INTEGER);

## The "undef" bound above is not used, since we supply params to execute
$sth->execute(123, "Merk");

## Set the first placeholder's value and data type
$sth->bind_param(1, 234, { pg_type => PG_TIMESTAMP });

## Set the second placeholder's value and data type.
## We don't send a third argument, so the default "varchar" is used
$sth->bind_param('$2', "Zool");

## We realize that the wrong data type was set above, so we change it:
$sth->bind_param('$1', 234, { pg_type => SQL_INTEGER });

## We also got the wrong value, so we change that as well.
## Because the data type is sticky, we don't need to change it
$sth->bind_param(1, 567);

## This executes the statement with 567 (integer) and "Zool" (varchar)
$sth->execute();

bind_param_inout

$rv = $sth->bind_param_inout($param_num, \$scalar, 0);

Experimental support for this feature is provided. The first argument to bind_param_inout should be a placeholder number. The second argument should be a reference to a scalar variable in your script. The third argument is not used and should simply be set to 0. Note that what this really does is assign a returned column to the variable, in the order in which the column appears. For example:

my $foo = 123;
$sth = $dbh->prepare("SELECT 1+?::int");
$sth->bind_param_inout(1, \$foo, 0);
$foo = 222;
$sth->execute(444);
$sth->fetch;

The above will cause $foo to have a new value of "223" after the final fetch. Note that the variables bound in this manner are very sticky, and will trump any values passed in to execute. This is because the binding is done as late as possible, at the execute() stage, allowing the value to be changed between the time it was bound and the time the query is executed. Thus, the above execute is the same as:

$sth->execute();

bind_param_array

$rv = $sth->bind_param_array($param_num, $array_ref_or_value)
$rv = $sth->bind_param_array($param_num, $array_ref_or_value, $bind_type)
$rv = $sth->bind_param_array($param_num, $array_ref_or_value, \%attr)

Binds an array of values to a placeholder, so that each is used in turn by a call to the "execute_array" method.

execute

$rv = $sth->execute(@bind_values);

Executes a previously prepared statement. In addition to UPDATE, DELETE, INSERT statements, for which it returns always the number of affected rows, the execute method can also be used for SELECT ... INTO table statements.

The "prepare/bind/execute" process has changed significantly for PostgreSQL servers 7.4 and later: please see the prepare() and bind_param() entries for much more information.

Setting one of the bind_values to "undef" is the equivalent of setting the value to NULL in the database. Setting the bind_value to $DBDPG_DEFAULT is equivalent to sending the literal string 'DEFAULT' to the backend. Note that using this option will force server-side prepares off until such time as PostgreSQL supports using DEFAULT in prepared statements.

DBD::Pg also supports passing in arrays to execute: simply pass in an arrayref, and DBD::Pg will flatten it into a string suitable for input on the backend.

If you are using Postgres version 8.2 or greater, you can also use any of the fetch methods to retrieve the values of a RETURNING clause after you execute an UPDATE, DELETE, or INSERT. For example:

$dbh->do(q{CREATE TABLE abc (id SERIAL, country TEXT)});
$SQL = q{INSERT INTO abc (country) VALUES (?) RETURNING id};
$sth = $dbh->prepare($SQL);
$sth->execute('France');
$countryid = $sth->fetch()->[0];
$sth->execute('New Zealand');
$countryid = $sth->fetch()->[0];

execute_array

$tuples = $sth->execute_array() or die $sth->errstr;
$tuples = $sth->execute_array(\%attr) or die $sth->errstr;
$tuples = $sth->execute_array(\%attr, @bind_values) or die $sth->errstr;

($tuples, $rows) = $sth->execute_array(\%attr) or die $sth->errstr;
($tuples, $rows) = $sth->execute_array(\%attr, @bind_values) or die $sth->errstr;

Execute a prepared statement once for each item in a passed-in hashref, or items that were previously bound via the "bind_param_array" method. See the DBI documentation for more details.

execute_for_fetch

$tuples = $sth->execute_for_fetch($fetch_tuple_sub);
$tuples = $sth->execute_for_fetch($fetch_tuple_sub, \@tuple_status);

($tuples, $rows) = $sth->execute_for_fetch($fetch_tuple_sub);
($tuples, $rows) = $sth->execute_for_fetch($fetch_tuple_sub, \@tuple_status);

Used internally by the "execute_array" method, and rarely used directly. See the DBI documentation for more details.

fetchrow_arrayref

$ary_ref = $sth->fetchrow_arrayref;

Fetches the next row of data from the statement handle, and returns a reference to an array holding the column values. Any columns that are NULL are returned as undef within the array.

If there are no more rows or if an error occurs, the this method return undef. You should check $sth->err afterwards (or use the "RaiseError" attribute) to discover if the undef returned was due to an error.

Note that the same array reference is returned for each fetch, so don't store the reference and then use it after a later fetch. Also, the elements of the array are also reused for each row, so take care if you want to take a reference to an element. See also "bind_columns".

fetchrow_array

@ary = $sth->fetchrow_array;

Similar to the "fetchrow_arrayref" method, but returns a list of column information rather than a reference to a list. Do not use this in a scalar context.

fetchrow_hashref

$hash_ref = $sth->fetchrow_hashref;
$hash_ref = $sth->fetchrow_hashref($name);

Fetches the next row of data and returns a hashref containing the name of the columns as the keys and the data itself as the values. Any NULL value is returned as as undef value.

If there are no more rows or if an error occurs, the this method return undef. You should check $sth->err afterwards (or use the "RaiseError" attribute) to discover if the undef returned was due to an error.

The optional $name argument should be either NAME, NAME_lc or NAME_uc, and indicates what sort of transformation to make to the keys in the hash.

fetchall_arrayref

$tbl_ary_ref = $sth->fetchall_arrayref();
$tbl_ary_ref = $sth->fetchall_arrayref( $slice );
$tbl_ary_ref = $sth->fetchall_arrayref( $slice, $max_rows );

Returns a reference to an array of arrays that contains all the remaining rows to be fetched from the statement handle. If there are no more rows, an empty arrayref will be returned. If an error occurs, the data read in so far will be returned. Because of this, you should always check $sth->err after calling this method, unless "RaiseError" has been enabled.

If $slice is an array reference, fetchall_arrayref uses the "fetchrow_arrayref" method to fetch each row as an array ref. If the $slice array is not empty then it is used as a slice to select individual columns by perl array index number (starting at 0, unlike column and parameter numbers which start at 1).

With no parameters, or if $slice is undefined, fetchall_arrayref acts as if passed an empty array ref.

If $slice is a hash reference, fetchall_arrayref uses "fetchrow_hashref" to fetch each row as a hash reference.

See the DBI documentation for a complete discussion.

fetchall_arrayref

$hash_ref = $sth->fetchall_hashref( $key_field );

Returns a hashref containing all rows to be fetched from the statement handle. See the DBI documentation for a full discussion.

finish

$rv = $sth->finish;

Indicates to DBI that you are finished with the statement handle and are not going to use it again. Only needed when you have not fetched all the possible rows.

rows

$rv = $sth->rows;

Returns the number of rows returned by the last query. In contrast to many other drivers, the number of rows is available immediately after calling $sth->execute. Note that the "execute" method itself returns the number of rows itself, which means that this method is rarely needed.

bind_col

$rv = $sth->bind_col($column_number, \$var_to_bind);
$rv = $sth->bind_col($column_number, \$var_to_bind, \%attr );
$rv = $sth->bind_col($column_number, \$var_to_bind, $bind_type );

Binds a Perl variable and/or some attributes to an output column of a SELECT statement. Column numbers count up from 1. You do not need to bind output columns in order to fetch data.

See the DBI documentation for a discussion of the optional parameters \%attr and $bind_type

bind_columns

$rv = $sth->bind_columns(@list_of_refs_to_vars_to_bind);

Calls the "bind_col" method for each column in the SELECT statement, using the supplied list.

dump_results

$rows = $sth->dump_results($maxlen, $lsep, $fsep, $fh);

Fetches all the rows from the statement handle, calls DBI::neat_list for each row, and prints the results to $fh (which defaults to STDOUT). Rows are separated by $lsep (which defaults to a newline). Columns are separated by $fsep (which defaults to a comma). The $maxlen controls how wide the output can be, and defaults to 35.

This method is designed as a handy utility for prototyping and testing queries. Since it uses "neat_list" to format and edit the string for reading by humans, it is not recommended for data transfer applications.

blob_read

$blob = $sth->blob_read($id, $offset, $len);

Supported by this driver as proposed by DBI. Implemented by DBI but not documented, so this method might change.

This method seems to be heavily influenced by the current implementation of blobs in Oracle. Nevertheless we try to be as compatible as possible. Whereas Oracle suffers from the limitation that blobs are related to tables and every table can have only one blob (datatype LONG), PostgreSQL handles its blobs independent of any table by using so-called object identifiers. This explains why the blob_read method is blessed into the STATEMENT package and not part of the DATABASE package. Here the field parameter has been used to handle this object identifier. The offset and len parameters may be set to zero, in which case the driver fetches the whole blob at once.

See also the PostgreSQL-specific functions concerning blobs, which are available via the func interface.

For further information and examples about blobs, please read the chapter about Large Objects in the PostgreSQL Programmer's Guide at http://www.postgresql.org/docs/current/static/largeobjects.html.

Statement Handle Attributes

NUM_OF_FIELDS (integer, read-only)

Implemented by DBI, no driver-specific impact.

NUM_OF_PARAMS (integer, read-only)

Implemented by DBI, no driver-specific impact.

NAME (arrayref, read-only)

Supported by this driver as proposed by DBI.

NAME_lc (arrayref, read-only)

Implemented by DBI, no driver-specific impact.

NAME_uc (arrayref, read-only)

Implemented by DBI, no driver-specific impact.

NAME_hash (hashref, read-only)

Implemented by DBI, no driver-specific impact.

NAME_lc_hash (hashref, read-only)

Implemented by DBI, no driver-specific impact.

NAME_uc_hash (hashref, read-only)

Implemented by DBI, no driver-specific impact.

TYPE (arrayref, read-only)

Supported by this driver as proposed by DBI

PRECISION (arrayref, read-only)

Returns a reference to an array of integer values of each column. NUMERIC types will return the precision. Types of CHAR and VARCHAR will return their size (number of characters). Other types will return the number of bytes.

SCALE (arrayref, read-only)

Returns a reference to an array of integer values of each column. The only type that will return a value currently is NUMERIC.

NULLABLE (arrayref, read-only)

Supported by this driver as proposed by DBI.

CursorName (string, read-only)

Not supported by this driver. See the note about "Cursors" elsewhere in this document.

Database (dbh, read-only)

Returns the database handle this statement handle was created from.

ParamValues (hash ref, read-only)

Supported by this driver as proposed by DBI. If called before "execute", the literal values passed in are returned. If called after "execute", then the quoted versions of the values are shown.

ParamTypes (hash ref, read-only)

Returns a hash of all current placeholders. The keys are the names of the placeholders, and the values are the types that have been bound to each one. Placeholders that have not yet been bound will return undef as the value.

Statement (string, read-only)

Returns the statement string passed to the most recent "prepare" method called in this database handle, even if that method failed. This is especially useful where "RaiseError" is enabled and the exception handler checks $@ and sees that a ’prepare’ method call failed.

pg_current_row (integer, read-only)

DBD::Pg specific attribute. Returns the number of the tuple (row) that was most recently fetched. Returns zero before and after fetching is performed.

pg_numbound (integer, read-only)

DBD::Pg specific attribute. Returns the number of placeholders that are currently bound (via bind_param).

pg_bound (hashref, read-only)

DBD::Pg specific attribute. Returns a hash of all named placeholders. The key is the name of the placeholder, and the value is a 0 or a 1, indicating if the placeholder has been bound yet (e.g. via bind_param)

pg_size (arrayref, read-only)

DBD::Pg specific attribute. It returns a reference to an array of integer values for each column. The integer shows the size of the column in bytes. Variable length columns are indicated by -1.

pg_type (arrayref, read-only)

DBD::Pg specific attribute. It returns a reference to an array of strings for each column. The string shows the name of the data_type.

pg_segments (arrayref, read-only)

DBD::Pg specific attribute. Returns an arrayref of the query split on the placeholders.

pg_oid_status (integer, read-only)

DBD::Pg specific attribute. It returns the OID of the last INSERT command.

pg_cmd_status (integer, read-only)

DBD::Pg specific attribute. It returns the type of the last command. Possible types are: "INSERT", "DELETE", "UPDATE", "SELECT".

pg_direct (boolean)

DBD::Pg specific attribute. Default is false. If true, the query is passed directly to the backend without parsing for placeholders.

pg_prepare_now (boolean)

DBD::Pg specific attribute. Default is off. If true, the query will be immediately prepared, rather than waiting for the "execute" call.

pg_prepare_name (string)

DBD::Pg specific attribute. Specifies the name of the prepared statement to use for this statement handle. Not normally needed, see the section on the "prepare" method for more information.

pg_server_prepare (integer)

DBD::Pg specific attribute. Indicates if DBD::Pg should attempt to use server-side prepared statements for this statement handle. The default value, 1, indicates that prepared statements should be used whenever possible. See the section on the "prepare" method for more information.

pg_placeholder_dollaronly (boolean)

DBD::Pg specific attribute. Defaults to off. When true, question marks inside of the query being prepared are not treated as placeholders. Useful for statements that contain unquoted question marks, such as geometric operators.

pg_async (integer)

DBD::Pg specific attribute. Indicates the current behavior for asynchronous queries. See the section on "Asynchronous Constants" for more information.

RowsInCache

Not used by DBD::Pg

RowCache (integer, read-only)

Not used by DBD::Pg

FURTHER INFORMATION

Transactions

Transaction behavior is controlled via the "AutoCommit" attribute. For a complete definition of AutoCommit please refer to the DBI documentation.

According to the DBI specification the default for AutoCommit is a true value. In this mode, any change to the database becomes valid immediately. Any BEGIN, COMMIT or ROLLBACK statements will be rejected. DBD::Pg implements AutoCommit by issuing a BEGIN statement immediately before executing a statement, and a COMMIT afterwards. Note that preparing a statement is not always enough to trigger the first BEGIN, as the actual PREPARE is usually postponed until the first call to "execute".

Savepoints

PostgreSQL version 8.0 introduced the concept of savepoints, which allows transactions to be rolled back to a certain point without affecting the rest of the transaction. DBD::Pg encourages using the following methods to control savepoints:

pg_savepoint

Creates a savepoint. This will fail unless you are inside of a transaction. The only argument is the name of the savepoint. Note that PostgreSQL DOES allow multiple savepoints with the same name to exist.

$dbh->pg_savepoint("mysavepoint");

pg_rollback_to

Rolls the database back to a named savepoint, discarding any work performed after that point. If more than one savepoint with that name exists, rolls back to the most recently created one.

$dbh->pg_rollback_to("mysavepoint");

pg_release

Releases (or removes) a named savepoint. If more than one savepoint with that name exists, it will only destroy the most recently created one. Note that all savepoints created after the one being released are also destroyed.

$dbh->pg_release("mysavepoint");

Asynchronous Queries

It is possible to send a query to the backend and have your script do other work while the query is running on the backend. Both queries sent by the "do" method, and by the "execute" method can be sent asynchronously. (NOTE: This will only work if DBD::Pg has been compiled against Postgres libraries of version 8.0 or greater) The basic usage is as follows:

use DBD::Pg ':async';

print "Async do() example:\n";
$dbh->do("SELECT long_running_query()", {pg_async => PG_ASYNC});
do_something_else();
{
  if ($dbh->pg_ready()) {
    $res = $pg_result();
    print "Result of do(): $res\n";
  }
  print "Query is still running...\n";
  if (cancel_request_received) {
    $dbh->pg_cancel();
  }
  sleep 1;
  redo;
}

print "Async prepare/execute example:\n";
$sth = $dbh->prepare("SELECT long_running_query(1)", {pg_async => PG_ASYNC});
$sth->execute();

## Changed our mind, cancel and run again:
$sth = $dbh->prepare("SELECT 678", {pg_async => PG_ASYNC + PG_OLDQUERY_CANCEL});
$sth->execute();

do_something_else();

if (!$sth->pg_ready) {
  do_another_thing();
}

## We wait until it is done, and get the result:
$res = $dbh->pg_result();

Asynchronous Constants

There are currently three asynchronous constants exported by DBD::Pg. You can import all of them by putting either of these at the top of your script:

use DBD::Pg;

use DBD::Pg ':async';

You may also use the numbers instead of the constants, but using the constants is recommended as it makes your script more readable.

PG_ASYNC

This is a constant for the number 1. It is passed to either the "do" or the "prepare" method as a value to the pg_async key and indicates that the query should be sent asynchronously.

PG_OLDQUERY_CANCEL

This is a constant for the number 2. When passed to either the "do" or the "prepare" method, it causes any currently running asynchronous query to be cancelled and rolled back. It has no effect if no asynchronous query is currently running.

PG_OLDQUERY_WAIT

This is a constant for the number 4. When passed to either the "do" or the "prepare" method, it waits for any currently running asynchronous query to complete. It has no effect if there is no asynchronous query currently running.

Asynchronous Methods

pg_cancel

This database-level method attempts to cancel any currently running asynchronous query. It returns true if the cancel succeeded, and false otherwise. Note that a query that has finished before this method is executed will also return false. WARNING: a successful cancellation will leave the database in an unusable state, so DBD::Pg will automatically clear out the error message and issue a ROLLBACK.

$result = $dbh->pg_cancel();
pg_ready

This method can be called as a database handle method or (for convenience) as a statement handle method. Both simply see if a previously issued asynchronous query has completed yet. It returns true if the statement has finished, in which case you should then call the "pg_result" method. Calls to pg_ready() should only be used when you have other things to do while the query is running. If you simply want to wait until the query is done, do not call pg_ready() over and over, but simply call the pg_result() method.

my $time = 0;
while (!$dbh->pg_ready) {
  print "Query is still running. Seconds: $time\n";
  $time++;
  sleep 1;
}
$result = $dbh->pg_result;
pg_result

This database handle method returns the results of a previously issued asynchronous query. If the query is still running, this method will wait until it has finished. The result returned is the number of rows: the same thing that would have been returned by the asynchronous "do" or "execute" if it had been called without an asynchronous flag.

$result = $dbh->pg_result;

Asynchronous Examples

Here are some working examples of asynchronous queries. Note that we'll use the pg_sleep function to emulate a long-running query.

use strict;
use warnings;
use Time::HiRes 'sleep';
use DBD::Pg ':async';

my $dbh = DBI->connect('dbi:Pg:dbname=postgres', 'postgres', '', {AutoCommit=>0,RaiseError=>1});

## Kick off a long running query on the first database:
my $sth = $dbh->prepare("SELECT pg_sleep(?)", {pg_async => PG_ASYNC});
$sth->execute(5);

## While that is running, do some other things
print "Your query is processing. Thanks for waiting\n";
check_on_the_kids(); ## Expensive sub, takes at least three seconds.

while (!$dbh->pg_ready) {
  check_on_the_kids();
  ## If the above function returns quickly for some reason, we add a small sleep
  sleep 0.1;
}

print "The query has finished. Gathering results\n";
my $result = $sth->pg_result;
print "Result: $result\n";
my $info = $sth->fetchall_arrayref();

Without asynchronous queries, the above script would take about 8 seconds to run: five seconds waiting for the execute to finish, then three for the check_on_the_kids() function to return. With asynchronous queries, the script takes about 6 seconds to run, and gets in two iterations of check_on_the_kids in the process.

Here's an example showing the ability to cancel a long-running query. Imagine two slave databases in different geographic locations over a slow network. You need information as quickly as possible, so you query both at once. When you get an answer, you tell the other one to stop working on your query, as you don't need it anymore.

use strict;
use warnings;
use Time::HiRes 'sleep';
use DBD::Pg ':async';

my $dbhslave1 = DBI->connect('dbi:Pg:dbname=postgres;host=slave1', 'postgres', '', {AutoCommit=>0,RaiseError=>1});
my $dbhslave2 = DBI->connect('dbi:Pg:dbname=postgres;host=slave2', 'postgres', '', {AutoCommit=>0,RaiseError=>1});

$SQL = "SELECT count(*) FROM largetable WHERE flavor='blueberry'";

my $sth1 = $dbhslave1->prepare($SQL, {pg_async => PG_ASYNC});
my $sth2 = $dbhslave2->prepare($SQL, {pg_async => PG_ASYNC});

$sth1->execute();
$sth2->execute();

my $winner;
while (!defined $winner) {
  if ($sth1->pg_ready) {
    $winner = 1;
  }
  elsif ($sth2->pg_ready) {
    $winner = 2;
  }
  Time::HiRes::sleep 0.05;
}

my $count;
if ($winner == 1) {
  $sth2->pg_cancel();
  $sth1->pg_result();
  $count = $sth1->fetchall_arrayref()->[0][0];
}
else {
  $sth1->pg_cancel();
  $sth2->pg_result();
  $count = $sth2->fetchall_arrayref()->[0][0];
}

Array support

DBD::Pg allows arrays (as arrayrefs) to be passed in to both the "quote" and the "execute" methods. In both cases, the array is flattened into a string representing a Postgres array.

When fetching rows from a table that contains a column with an array type, the result will be passed back to your script as an arrayref.

To turn off the automatic parsing of returned arrays into arrayrefs, you can set the attribute pg_expand_array, which is true by default.

$dbh->{pg_expand_array} = 0;

COPY support

DBD::Pg allows for the quick (bulk) reading and storing of data by using the COPY command. The basic process is to use $dbh->do to issue a COPY command, and then to either add rows using "pg_putcopydata", or to read them by using "pg_getcopydata".

The first step is to put the server into "COPY" mode. This is done by sending a complete COPY command to the server, by using the "do" method. For example:

$dbh->do("COPY foobar FROM STDIN");

This would tell the server to enter a COPY OUT state. It is now ready to receive information via the "pg_putcopydata" method. The complete syntax of the COPY command is more complex and not documented here: the canonical PostgreSQL documentation for COPY can be found at:

http://www.postgresql.org/docs/current/static/sql-copy.html

Once the COPY command has been issued, no other SQL commands are allowed until "pg_putcopyend" has been issued, or the final "pg_getcopydata" has been called.

Note: All other COPY methods (pg_putline, pg_getline, etc.) are now heavily deprecated in favor of the pg_getcopydata, pg_putcopydata, and pg_putcopyend methods.

pg_getcopydata

Used to retrieve data from a table after the server has been put into COPY OUT mode by calling "COPY tablename TO STDOUT". Data is always returned one data row at a time. The first argument to pg_getcopydata is the variable into which the data will be stored (this variable should not be undefined, or it may throw a warning, although it may be a reference). This argument returns a number greater than 1 indicating the new size of the variable, or a -1 when the COPY has finished. Once a -1 has been returned, no other action is necessary, as COPY mode will have already terminated. Example:

$dbh->do("COPY mytable TO STDOUT");
my @data;
my $x=0;
1 while $dbh->pg_getcopydata($data[$x++]) > 0;

There is also a variation of this method called pg_getcopydata_async, which, as the name suggests, returns immediately. The only difference from the original method is that this version may return a 0, indicating that the row is not ready to be delivered yet. When this happens, the variable has not been changed, and you will need to call the method again until you get a non-zero result. (Data is still always returned one data row at a time.)

pg_putcopydata

Used to put data into a table after the server has been put into COPY IN mode by calling "COPY tablename FROM STDIN". The only argument is the data you want inserted. Issue a pg_putcopyend() when you have added all your rows.

The default delimiter is a tab character, but this can be changed in the COPY statement. Returns a 1 on successful input. Examples:

## Simple example:
$dbh->do("COPY mytable FROM STDIN");
$dbh->pg_putcopydata("123\tPepperoni\t3\n");
$dbh->pg_putcopydata("314\tMushroom\t8\n");
$dbh->pg_putcopydata("6\tAnchovies\t100\n");
$dbh->pg_putcopyend();

## This example uses explicit columns and a custom delimiter
$dbh->do("COPY mytable(flavor, slices) FROM STDIN WITH DELIMITER '~'");
$dbh->pg_putcopydata("Pepperoni~123\n");
$dbh->pg_putcopydata("Mushroom~314\n");
$dbh->pg_putcopydata("Anchovies~6\n");
$dbh->pg_putcopyend();

pg_putcopyend

When you are finished with pg_putcopydata, call pg_putcopyend to let the server know that you are done, and it will return to a normal, non-COPY state. Returns a 1 on success. This method will fail if called when not in a COPY IN or COPY OUT state.

Large Objects

This driver supports all largeobject functions provided by libpq via the func method. Please note that access to a large object, even read-only large objects, must be put into a transaction.

Cursors

Although PostgreSQL supports cursors, they have not been used in the current implementation. When DBD::Pg was created, cursors in PostgreSQL could only be used inside a transaction block. Because only one transaction block at a time is allowed, this would have implied the restriction not to use any nested SELECT statements. Therefore the "execute" method fetches all data at once into data structures located in the front-end application. This fact must to be considered when selecting large amounts of data!

You can use cursors in your application, but you'll need to do a little work. First you must declare your cursor. Now you can issue queries against the cursor, then select against your queries. This typically results in a double loop, like this:

# WITH HOLD is not needed if AutoCommit is off
$dbh->do("DECLARE csr CURSOR WITH HOLD FOR $sql");
while (1) {
  my $sth = $dbh->prepare("fetch 1000 from csr");
  $sth->execute;
  last if 0 == $sth->rows;

  while (my $row = $sth->fetchrow_hashref) {
    # Do something with the data.
  }
}
$dbh->do("CLOSE csr");

Datatype bool

The current implementation of PostgreSQL returns 't' for true and 'f' for false. From the Perl point of view, this is a rather unfortunate choice. DBD::Pg therefore translates the result for the BOOL data type in a Perlish manner: 'f' becomes the number 0 and 't' becomes the number 1. This way the application does not have to check the database-specific returned values for the data-type BOOL because Perl treats 0 as false and 1 as true. You may set the pg_bool_tf attribute to a true value to change the values back to 't' and 'f' if you wish.

Boolean values can be passed to PostgreSQL as TRUE, 't', 'true', 'y', 'yes' or '1' for true and FALSE, 'f', 'false', 'n', 'no' or '0' for false.

Schema support

The PostgreSQL schema concept may differ from those of other databases. In a nutshell, a schema is a named collection of objects within a single database. Please refer to the PostgreSQL documentation for more details:

http://www.postgresql.org/docs/current/static/ddl-schemas.html

DBD::Pg does not provide explicit support for PostgreSQL schemas. However, schema functionality may be used without any restrictions by explicitly addressing schema objects, e.g.

my $res = $dbh->selectall_arrayref("SELECT * FROM my_schema.my_table");

or by manipulating the schema search path with SET search_path, e.g.

$dbh->do("SET search_path TO my_schema, public");

SEE ALSO

The DBI module

BUGS

To report a bug, or view the current list of bugs, please visit http://rt.cpan.org/Public/Dist/Display.html?Name=DBD-Pg

AUTHORS

DBI by Tim Bunce http://www.tim.bunce.name

The original DBD-Pg was by Edmund Mergl (E.Mergl@bawue.de) and Jeffrey W. Baker (jwbaker@acm.org). Major developers include David Wheeler <david@justatheory.com>, Jason Stewart <jason@openinformatics.com>, Bruce Momjian <pgman@candle.pha.pa.us>, and Greg Sabino Mullane <greg@turnstep.com>, with help from many others: see the Changes file for a complete list.

Parts of this package were originally copied from DBI and DBD-Oracle.

Mailing List

The current maintainers may be reached through the 'dbd-pg' mailing list: <dbd-pg@perl.org>

COPYRIGHT

The DBD::Pg module is free software. You may distribute under the terms of either the GNU General Public License or the Artistic License, as specified in the Perl README file.

1 POD Error

The following errors were encountered while parsing the POD:

Around line 3570:

Non-ASCII character seen before =encoding in '’prepare’'. Assuming UTF-8