NAME
DBD::Pg - PostgreSQL database driver for the DBI module
VERSION
This documents version 1.46 of the DBD::Pg module
SYNOPSIS
use DBI;
$dbh = DBI->connect("dbi:Pg:dbname=$dbname", "", "", {AutoCommit => 0});
# For some advanced uses you may need PostgreSQL type values:
use DBD::Pg qw(:pg_types);
# See the DBI module documentation for full details
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!
THE DBI CLASS
DBI Class Methods
- connect
-
To connect to a database with a minimum of parameters, use the following syntax:
$dbh = DBI->connect("dbi:Pg:dbname=$dbname", "", "");
This connects to the database $dbname at localhost without any user authentication. This is sufficient for the defaults of PostgreSQL (excluding some package-installed versions).
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});
If a parameter is undefined PostgreSQL first looks for specific environment variables and then it uses 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 "" options PGOPTIONS "" service* PGSERVICE "" sslmode* PGSSLMODE ""
* Only for servers running version 7.4 or greater
** Can also use "db" or "database"
The options parameter specifies runtime options for the Postgres backend. Common usage is to increase the number of buffers with the
-B
option. Also important is the-F
option, which disables automatic fsync() call after each transaction. For further details please refer to the PostgreSQL documentation at http://www.postgresql.org/docs/.For authentication with username and password, appropriate entries have to be made in pg_hba.conf. Please refer to the comments in the pg_hba.conf and the pg_passwd files for the different types of authentication. Note that for these two parameters DBI distinguishes between empty and undefined. If these parameters are undefined DBI substitutes the values of the environment variables
DBI_USER
andDBI_PASS
if present. - available_drivers
-
@driver_names = DBI->available_drivers;
Implemented by DBI, no driver-specific impact.
- data_sources
-
@data_sources = DBI->data_sources('Pg');
This driver supports this method. Note that the necessary database connection to the database "template1" will be made on the localhost without any user authentication. Other preferences can only be set with the environment variables
PGHOST
,PGPORT
,DBI_USER
, andDBI_PASS
.
METHODS COMMON TO ALL HANDLES
- err
-
$rv = $h->err;
Supported by this driver as proposed by DBI. For the connect method it returns
PQstatus
. In all other cases it returnsPQresultStatus
of the current handle. - errstr
-
$str = $h->errstr;
Supported by this driver as proposed by DBI. It returns the
PQerrorMessage
related to the current handle. - state
-
$str = $h->state;
Supported by this driver. 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 PostgreSQL server has been lost. Note that this can be called as both $sth->state and $dbh->state.
PostgreSQL servers version less than 7.4 will return a small subset of the available codes, and should not be relied upon.
The list of codes used by PostgreSQL can be found at: http://www.postgresql.org/docs/current/static/errcodes-appendix.html
- trace
-
$h->trace($trace_level, $trace_filename);
Implemented by DBI, no driver-specific impact.
- trace_msg
-
$h->trace_msg($message_text);
Implemented by DBI, no driver-specific impact.
- func
-
This driver supports a variety of driver specific functions accessible via the
func
method. Note that the name of the function comes last, after the arguments.- table_attributes
-
$attrs = $dbh->func($table, 'table_attributes');
The
table_attributes
function is no longer recommended. Instead, you can use the more portablecolumn_info
andprimary_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
The REMARKS field will be returned as
NULL
for Postgres versions 7.1.x and older. - 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 seelo_creat
. Returnsundef
upon failure. Note that 0 is a perfectly correct object descriptor! - lo_write
-
$nbytes = $dbh->func($lobj_fd, $buf, $len, 'lo_write');
Writes $len bytes of $buf into the large object $lobj_fd. Returns the number of bytes written and
undef
upon failure. - lo_read
-
$nbytes = $dbh->func($lobj_fd, $buf, $len, 'lo_read');
Reads $len bytes into $buf 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 (
L_SET
). Returns the current location andundef
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.
- lo_unlink
-
$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 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.
- pg_notifies
-
$ret = $dbh->func('pg_notifies');
Returns either
undef
or a reference to two-element array [ $table, $backend_pid ] of asynchronous notifications received. - getfd
-
$fd = $dbh->func('getfd');
Returns fd of the actual connection to server. Can be used with select() and func('pg_notifies'). Deprecated in favor of
$dbh->{pg_socket}
.
ATTRIBUTES COMMON TO ALL HANDLES
- Warn (boolean, inherited)
-
Implemented by DBI, no driver-specific impact.
- Active (boolean, read-only)
-
Supported by this driver as proposed by DBI. A database handle is active while it is connected and statement handle is active until it is finished.
- Kids (integer, read-only)
-
Implemented by DBI, no driver-specific impact.
- ActiveKids (integer, read-only)
-
Implemented by DBI, no driver-specific impact.
- CachedKids (hash ref)
-
Implemented by DBI, no driver-specific impact.
- CompatMode (boolean, inherited)
-
Not used by this driver.
- InactiveDestroy (boolean)
-
Implemented by DBI, no driver-specific impact.
- PrintError (boolean, inherited)
-
Implemented by DBI, no driver-specific impact.
- RaiseError (boolean, inherited)
-
Implemented by DBI, no driver-specific impact.
- HandleError (boolean, 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
. - LongReadLen (integer, inherited)
-
Implemented by DBI, not used by this driver.
- LongTruncOk (boolean, inherited)
-
Implemented by DBI, not used by this driver.
- Taint (boolean, inherited)
-
Implemented by DBI, no driver-specific impact.
DBI DATABASE HANDLE OBJECTS
Database Handle Methods
- selectrow_array
-
@row_ary = $dbh->selectrow_array($statement, \%attr, @bind_values);
Implemented by DBI, no driver-specific impact.
- selectrow_arrayref
-
$ary_ref = $dbh->selectrow_arrayref($statement, \%attr, @bind_values);
Implemented by DBI, no driver-specific impact.
- selectrow_hashref
-
$hash_ref = $dbh->selectrow_hashref($statement, \%attr, @bind_values);
Implemented by DBI, no driver-specific impact.
- selectall_arrayref
-
$ary_ref = $dbh->selectall_arrayref($statement, \%attr, @bind_values);
Implemented by DBI, no driver-specific impact.
- selectall_hashref
-
$hash_ref = $dbh->selectall_hashref($statement, $key_field);
Implemented by DBI, no driver-specific impact.
- selectcol_arrayref
-
$ary_ref = $dbh->selectcol_arrayref($statement, \%attr, @bind_values);
Implemented by DBI, no driver-specific impact.
- prepare
-
$sth = $dbh->prepare($statement, \%attr);
WARNING: DBD::Pg now uses true prepared statements by sending them to the backend to be prepared by the PostgreSQL server. Statements that were legal before may no longer work. See below for details.
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.
Statements that do not begin with the word "SELECT", "INSERT", "UPDATE", or "DELETE" will not be sent to be server-side prepared.
Deciding whether or not to use prepared statements depends on many factors, but you can force them to be used or not used by passing the
pg_server_prepare
attribute to prepare(). A "0" means to never use prepared statements. This is the default when connected to servers earlier than version 7.4, which is when prepared statements were introduced. Settingpg_server_prepare
to "1" means that prepared statements should be used whenever possible. This is the default for 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. 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
, andDELETE
. DBD::Pg uses a simple naming scheme for the prepared statements:dbdpg_#
, where "#" starts at 1 and increases. This number is tracked at the database handle level, so multiple statement handles will not collide. If you use your own prepare statements, do not name them "dbdpg_"!The actual
PREPARE
is not performed until the first execute is called, due to the fact that information on the data types (provided bybind_param
) may be given after the prepare but before the execute.A server-side prepare can also happen before the first execute. If the server can handle the server-side prepare and the statement has no placeholders, it will be prepared right away. It will also be prepared if the
pg_prepare_now
attribute is passed. Similarly, the <pg_prepare_now> attribute can be set to 0 to ensure that the statement is not prepared immediately, although cases in which you would want this may be rare. Finally, you can set the default behavior of all prepare statements by setting thepg_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 "do"). Create a statement handle and set the prepared name viapg_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 this query:
SELECT COUNT(*) FROM pg_class WHERE reltuples < 123;
Note: DBD::Pg will not escape your custom prepared statement name, so don't use a name that needs escaping! DBD::Pg uses the prepare names
dbdpg_#
internally, so please do not use those either.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 method, in which each placeholder is represented by a single question mark. This is the method recommended by the DBI specs and is the most portable. Each question mark is replaced by a "dollar sign number" in the order in which they appear in the query (important when using
bind_param
).The second method is to use "dollar sign numbers" directly. This is the method that PostgreSQL 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. 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"; $SQL = "SELECT count(*) FROM pg_class WHERE relpages BETWEEN $1 AND $3";
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 $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 execute requires only a single argument as well:
$sth->execute(2045);
The final placeholder method is the named parameters in the format ":foo". While this syntax is supported by DBD::Pg, its use is highly discouraged.
The different types of placeholders cannot be mixed within a statement, but you may use different ones for each statement handle you have. Again, this is not encouraged.
- 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, \%attr, @bind_values);
Prepare and execute a single statement. Note that an empty statement (string with no length) will not be passed to the server; if you want a simple test, use "SELECT 123" or the ping() function. If neither attr nor bind_values is given, the query will be sent directly to the server without the overhead of creating a statement handle and running prepare and execute.
- last_insert_id
-
$rv = $dbh->last_insert_id($catalog, $schema, $table, $field); $rv = $dbh->last_insert_id($catalog, $schema, $table, $field, \%attr);
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. The $catalog and $field arguments are always ignored. 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 susequent calls. If you need to disable this caching for some reason, you can control it via thepg_cache
attribute.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.
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
-
$rc = $dbh->commit;
Supported by this driver as proposed by DBI. See also the notes about Transactions elsewhere in this document.
- rollback
-
$rc = $dbh->rollback;
Supported by this driver as proposed by DBI. See also the notes about Transactions elsewhere in this document.
- disconnect
-
$rc = $dbh->disconnect;
Supported by this driver as proposed by DBI.
- ping
-
$rc = $dbh->ping;
This driver supports the
ping
method, which can be 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
-
$rc = $dbh->pg_ping;
This is a Postgres-specific extension to the
ping
command. This will check the validity of a database handle in exactly the same way asping
, but instead of returning a 0 for an invalid connection, it will return a negative number. The positive numbers are documented atping
, the negative ones indicate: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.
- column_info
-
$sth = $dbh->column_info( $catalog, $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, two additional non-standard fields are returned:
pg_type - data type with additional info i.e. "character varying(20)" pg_constraint - holds column constraint definition
The REMARKS field will be returned as NULL (
undef
for PostgreSQL versions older than 7.2. The TABLE_SCHEM field will be returned as NULL (undef
) for versions older than 7.4. - table_info
-
$sth = $dbh->table_info( $catalog, $schema, $table, $type );
Supported by this driver as proposed by DBI. This method returns all tables and views visible to the current user. The $catalog argument is currently unused. 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).The TABLE_CAT field will always return NULL (
undef
). The TABLE_SCHEM field returns NULL (undef
) if the server is older than version 7.4.If your database supports tablespaces (version 8.0 or greater), two additional columns are returned, "pg_tablespace_name" and "pg_tablespace_location", that contain the name and location of the tablespace associated with this table. Tables that have not been assigned to a particular tablespace will return NULL (
undef
) for both of these columns. - primary_key_info
-
$sth = $dbh->primary_key_info( $catalog, $schema, $table, \%attr );
Supported by this driver as proposed by DBI. The $catalog argument is currently unused, and the $schema argument has no effect against servers running version 7.2 or older. 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.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 thepg_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
-
Supported by this driver as proposed by DBI.
- 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. This function returns
undef
for PostgreSQL servers earlier than version 7.3. 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 returnundef
for the "UK_NAME" field. - tables
-
@names = $dbh->tables( $catalog, $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. If the database is version 7.3 or later, the name of the schema appears before the table or view name. This can be turned off by adding in thepg_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 | +---------------+------------------------------------+
For further details concerning the PostgreSQL specific datatypes please read pgbuiltin.
- type_info
-
@type_info = $dbh->type_info($data_type);
Implemented by DBI, no driver-specific impact.
- quote
-
$sql = $dbh->quote($value, $data_type);
This module implements its own
quote
method. In addition to the DBI method it also doubles the backslash, because PostgreSQL treats a backslash as an escape character.NOTE: The undocumented (and invalid) support for the
SQL_BINARY
data type is officially deprecated. UsePG_BYTEA
withbind_param()
instead:$rv = $sth->bind_param($param_num, $bind_value, { pg_type => DBD::Pg::PG_BYTEA });
- pg_server_trace
-
$dbh->pg_server_trace($filehandle);
Writes debugging information from the PostgreSQL backend to a file. This is not the same as the 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
function. 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.
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)
-
PostgreSQL specific attribute. If true, boolean values will be returned as the characters 't' and 'f' instead of '1' and '0'.
- Driver (handle)
-
Implemented by DBI, no driver-specific impact.
- Name (string, read-only)
-
The default DBI method is overridden by a driver specific method that returns only the database name. Anything else from the connection string is stripped off. Note that, in contrast to the DBI specs, the DBD::Pg implementation fo this method is read-only.
- RowCacheSize (integer)
-
Implemented by DBI, not used by this driver.
- pg_auto_escape (boolean)
-
PostgreSQL specific attribute. If true, then quotes and backslashes in all parameters will be escaped in the following way:
escape quote with a quote (SQL) escape backslash with a backslash
The default is on. Note that PostgreSQL also accepts quotes that are escaped by a backslash. Any other ASCII character can be used directly in a string constant.
- pg_enable_utf8 (boolean)
-
PostgreSQL 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 theutf8
flag, see Encode. This attribute only relevant under perl 5.8 and later.NB: This attribute is experimental and may be subject to change.
- pg_INV_READ (integer, read-only)
-
Constant to be used for the mode in
lo_creat
andlo_open
. - pg_INV_WRITE (integer, read-only)
-
Constant to be used for the mode in
lo_creat
andlo_open
. - pg_errorlevel (integer)
-
PostgreSQL specific attribute, only works for servers version 7.4 and above. 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)
-
PostgreSQL specific attribute. Returns the version of the PostgreSQL server. If DBD::Pg is unable to figure out the version (e.g. it was compiled against pre 7.4 libraries), it will return a "0". Otherwise, servers below version 7.4 return a "2", and (currently) 7.4 and above return a "3".
- pg_lib_version (integer, read-only)
-
PostgreSQL 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 7.4.2 would be returned as 70402.
- pg_server_version (integer, read-only)
-
PostgreSQL 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)
-
PostgreSQL specific attribute. Returns the name of the current database.
- pg_user (string, read-only)
-
PostgreSQL specific attribute. Returns the name of the user that connected to the server.
- pg_pass (string, read-only)
-
PostgreSQL specific attribute. Returns the password used to connect to the server.
- pg_host (string, read-only)
-
PostgreSQL specific attribute. Returns the host of the current server connection. Locally connected hosts will return an empty string.
- pg_port (integer, read-only)
-
PostgreSQL specific attribute. Returns the port of the connection to the server.
- pg_default_port (integer, read-only)
-
PostgreSQL specific attribute. Returns the default port used if none is specifically givem.
- pg_options (string, read-only)
-
PostgreSQL specific attribute. Returns the command-line options passed to the server. May be an empty string.
- pg_socket (number, read-only)
-
PostgreSQL specific attribute. Returns the file description number of the connection socket to the server.
- pg_pid (number, read-only)
-
PostgreSQL specific attribute. Returns the process id (PID) of the backend server process handling the connection.
DBI STATEMENT HANDLE OBJECTS
Statement Handle Methods
- bind_param
-
$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 the new server-side prepare system with PostgreSQL 7.4. 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 aNULL
to the placeholder. Usingundef
is useful when you want to change just the type and will be overwriting the value later. (Any value is actually usable, butundef
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 tobind_param
.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 => PG_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
-
Currently not supported by this driver.
- 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, theexecute
method can also be used forSELECT ... INTO table
statements.The "prepare/bind/execute" process has changed significantly for PostgreSQL servers 7.4 and later: please see the
prepare()
andbind_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.
- fetchrow_arrayref
-
$ary_ref = $sth->fetchrow_arrayref;
Supported by this driver as proposed by DBI.
- fetchrow_array
-
@ary = $sth->fetchrow_array;
Supported by this driver as proposed by DBI.
- fetchrow_hashref
-
$hash_ref = $sth->fetchrow_hashref;
Supported by this driver as proposed by DBI.
- fetchall_arrayref
-
$tbl_ary_ref = $sth->fetchall_arrayref;
Implemented by DBI, no driver-specific impact.
- finish
-
$rc = $sth->finish;
Supported by this driver as proposed by DBI.
- rows
-
$rv = $sth->rows;
Supported by this driver as proposed by DBI. In contrast to many other drivers the number of rows is available immediately after executing the statement.
- bind_col
-
$rc = $sth->bind_col($column_number, \$var_to_bind, \%attr);
Supported by this driver as proposed by DBI.
- bind_columns
-
$rc = $sth->bind_columns(\%attr, @list_of_refs_to_vars_to_bind);
Supported by this driver as proposed by DBI.
- dump_results
-
$rows = $sth->dump_results($maxlen, $lsep, $fsep, $fh);
Implemented by DBI, no driver-specific impact.
- 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.Starting with PostgreSQL 6.5, every access to a blob has to be put into a transaction. This holds even for a read-only access.
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 (array-ref, read-only)
-
Supported by this driver as proposed by DBI.
- NAME_lc (array-ref, read-only)
-
Implemented by DBI, no driver-specific impact.
- NAME_uc (array-ref, read-only)
-
Implemented by DBI, no driver-specific impact.
- NAME_hash (hash-ref, read-only)
-
Implemented by DBI, no driver-specific impact.
- NAME_lc_hash (hash-ref, read-only)
-
Implemented by DBI, no driver-specific impact.
- NAME_uc_hash (hash-ref, read-only)
-
Implemented by DBI, no driver-specific impact.
- TYPE (array-ref, read-only)
-
Supported by this driver as proposed by DBI
- PRECISION (array-ref, read-only)
-
Supported by this driver.
NUMERIC
types will return the precision. Types ofCHAR
andVARCHAR
will return their size (number of characters). Other types will return the number of bytes. - SCALE (array-ref, read-only)
-
Supported by this driver as proposed by DBI. The only type that will return a value currently is
NUMERIC
. - NULLABLE (array-ref, read-only)
-
Supported by this driver as proposed by DBI. This is only available for servers version 7.3 and later. Others will return "2" for all columns.
- CursorName (string, read-only)
-
Not supported by this driver. See the note about Cursors elsewhere in this document.
Database
(dbh, read-only)-
Implemented by DBI, no driver-specific impact.
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 afterexecute
, then the quoted versions of the values are shown. - Statement (string, read-only)
-
Supported by this driver as proposed by DBI.
- RowCache (integer, read-only)
-
Not supported by this driver.
- pg_size (array-ref, read-only)
-
PostgreSQL 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 (array-ref, read-only)
-
PostgreSQL specific attribute. It returns a reference to an array of strings for each column. The string shows the name of the data_type.
- pg_oid_status (integer, read-only)
-
PostgreSQL specific attribute. It returns the OID of the last INSERT command.
- pg_cmd_status (integer, read-only)
-
PostgreSQL specific attribute. It returns the type of the last command. Possible types are: "INSERT", "DELETE", "UPDATE", "SELECT".
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.
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");
COPY support
DBD::Pg supports the COPY command through three functions: pg_putline, pg_getline, and pg_endcopy. The COPY command allows data to be quickly loaded or read from a table. The basic process is to issue a COPY command via $dbh->do(), do either $dbh->pg_putline or $dbh->pg_getline, and then issue a $dbh->pg_endcopy (for pg_putline only).
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 IN state. It is now ready to receive information via the pg_putline method. The complete syntax of the COPY command is more complex and not documented here: the canonical PostgreSQL documentation for COPY be found at:
http://www.postgresql.org/docs/current/static/sql-copy.html
Note that 7.2 servers can only accept a small subset of later features in the COPY command: most notably they do not accept column specifications.
Once the COPY command has been issued, no other SQL commands are allowed until after pg_endcopy has been successfully called. If in a COPY IN state, you cannot use pg_getline, and if in COPY OUT state, you cannot use pg_putline.
- pg_putline
-
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. The default delimiter is a tab character, but this can be changed in the COPY statement. Returns a 1 on sucessful input. Examples:
$dbh->do("COPY mytable FROM STDIN"); $dbh->pg_putline("123\tPepperoni\t3\n"); $dbh->pg_putline("314\tMushroom\t8\n"); $dbh->pg_putline("6\tAnchovies\t100\n"); $dbh->pg_endcopy; ## This example uses explicit columns and a custom delimiter $dbh->do("COPY mytable(flavor, slices) FROM STDIN WITH DELIMITER '~'"); $dbh->pg_putline("Pepperoni~123\n"); $dbh->pg_putline("Mushroom~314\n"); $dbh->pg_putline("Anchovies~6\n"); $dbh->pg_endcopy;
- pg_getline
-
Used to retrieve data from a table after the server has been put into COPY OUT mode by calling "COPY tablename TO STDOUT". The first argument to pg_getline is the variable into which the data will be stored. The second argument is the size of the variable: this should be greater than the expected size of the row. Returns a 1 on success, and an empty string when the last row has been fetched. Example:
$dbh->do("COPY mytable TO STDOUT"); my @data; my $x=0; 1 while($dbh->pg_getline($data[$x++], 100)); pop @data; ## Remove final "\\.\n" line
If DBD::Pg is compiled with pre-7.4 libraries, this function will not work: you will have to use the old $dbh->func($data, 100, 'getline') command, and call pg_getline manually. Users are highly encouraged to upgrade to a newer version of PostgreSQL if this is the case.
- pg_endcopy
-
When done with pg_putline, call pg_endcopy to put the server back in a normal state. Returns a 1 on success. This method will fail if called when not in a COPY IN or COPY OUT state. Note that you no longer need to send "\\.\n" when in COPY IN mode: pg_endcopy will do this for you automatically as needed. pg_endcopy is only needed after getline if you are using the old-style method, $dbh->func($data, 100, 'getline').
Large Objects
This driver supports all largeobject functions provided by libpq via the func
method. Please note that, starting with PostgreSQL 6.5, any access to a large object -- even read-only large objects -- must be put into a transaction!
Cursors
Although PostgreSQL has a cursor concept, it has not been used in the current implementation. Cursors in PostgreSQL can 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. Hence the execute
method fetches all data at once into data structures located in the front-end application. This approach must to be considered when selecting large amounts of data!
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' -> '0' and 't' -> '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
PostgreSQL version 7.3 introduced schema support. Note that 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.
Currently, 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
AUTHORS
DBI and DBD-Oracle by Tim Bunce (Tim.Bunce@ig.co.uk)
DBD-Pg by Edmund Mergl (E.Mergl@bawue.de) and Jeffrey W. Baker (jwbaker@acm.org). By David Wheeler <david@justatheory.com>, Jason Stewart <jason@openinformatics.com>, Bruce Momjian <pgman@candle.pha.pa.us>, Greg Sabino Mullane <greg@turnstep.com>, and others after v1.13.
Parts of this package have been copied from DBI and DBD-Oracle.
Mailing List
The current maintainers may be reached through the 'dbdpg-general' mailing list: http://gborg.postgresql.org/mailman/listinfo/dbdpg-general/.
This list is available through Gmane (http://www.gmane.org/) as a newsgroup with the name: gmane.comp.db.postgresql.dbdpg
Bug Reports
If you feel certain you have found a bug, you can report it by sending an email to <bug-dbd-pg@rt.cpan.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.
ACKNOWLEDGMENTS
See also DBI/ACKNOWLEDGMENTS.