DBD::Pg - PostgreSQL database driver for the DBI module
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
$dbh = DBI->connect("dbi:Pg:dbname=$dbname", "", "");
This connects to the database $dbname 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});
If a parameter is not given, the PostgreSQL server will first look for specific environment variables, and then use 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)
* 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" and "DBI_PASS" if present.
You can also conenct 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:
@driver_names = DBI->available_drivers;
Implemented by DBI, no driver-specific impact.
@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", "DBI_PASS", and "PGSERVICE".
$rv = $h->err;
Supported by this driver as proposed by DBI. For the connect method it returns "PQstatus". In all other cases it returns "PQresultStatus" of the current handle.
$str = $h->errstr;
Supported by this driver as proposed by DBI. It returns the "PQerrorMessage" related to the current handle.
$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 state can be called as either $sth->state or $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>
$h->trace($trace_level); $h->trace($trace_level, $trace_filename);
Implemented by DBI, no driver-specific impact.
$h->trace_msg($message_text); $h->trace_msg($message_text, $min_level);
Implemented by DBI, no driver-specific impact.
$attrs = $dbh->func($table, 'table_attributes');
The "table_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
The REMARKS field will be returned as "NULL" for Postgres versions 7.1.x and older.
$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".
$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 object descriptor!
$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.
$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.
$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 and "undef" upon failure.
$loc = $dbh->func($lobj_fd, 'lo_tell');
Returns the current read or write location on the large object $lobj_fd and "undef" upon failure.
$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.
$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.
$ret = $dbh->func($lobjId, $filename, 'lo_export');
Exports a large object into a Unix file. Returns false upon failure, true otherwise.
$ret = $dbh->func('pg_notifies');
Returns either "undef" or a reference to two-element array [ $table, $backend_pid ] of asynchronous notifications received.
$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}".
@row_ary = $dbh->selectrow_array($statement, \%attr, @bind_values);
Implemented by DBI, no driver-specific impact.
$ary_ref = $dbh->selectrow_arrayref($statement, \%attr, @bind_values);
Implemented by DBI, no driver-specific impact.
$hash_ref = $dbh->selectrow_hashref($statement, \%attr, @bind_values);
Implemented by DBI, no driver-specific impact.
$ary_ref = $dbh->selectall_arrayref($statement, \%attr, @bind_values);
Implemented by DBI, no driver-specific impact.
$hash_ref = $dbh->selectall_hashref($statement, $key_field);
Implemented by DBI, no driver-specific impact.
$ary_ref = $dbh->selectcol_arrayref($statement, \%attr, @bind_values);
Implemented by DBI, no driver-specific impact.
$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. Setting "pg_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", and "DELETE". 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_''!
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 not performed until the first execute is called, due to the fact that information on the data types (provided by "bind_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 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 ``do''). Create a statement handle and set the prepared name via "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 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.
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.
$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.
$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.
$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 the "pg_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"; }
$rc = $dbh->commit;
Supported by this driver as proposed by DBI. See also the notes about Transactions elsewhere in this document.
$rc = $dbh->rollback;
Supported by this driver as proposed by DBI. See also the notes about Transactions elsewhere in this document.
$rc = $dbh->disconnect;
Supported by this driver as proposed by DBI.
$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.
$rc = $dbh->pg_ping;
This is a DBD::Pg-specific extension to the "ping" command. 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.
$value = $dbh->get_info($info_type);
Supports a very large set (> 250) of the information types, including the minimum recommended by DBI.
$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.
$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.
$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 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"; } }
$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 return "undef" for the ``UK_NAME'' field.
@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 the "pg_noprefix" attribute:
my @tables = $dbh->tables( '', '', 'dbd_pg_test', '', {pg_noprefix => 1} );
$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 = $dbh->type_info($data_type);
Implemented by DBI, no driver-specific impact.
$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. Use "PG_BYTEA" with "bind_param()" instead:
$rv = $sth->bind_param($param_num, $bind_value, { pg_type => DBD::Pg::PG_BYTEA });
$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);
$dbh->pg_server_untrace
Stop server logging to a previously opened file.
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.
NB: This attribute is experimental and may be subject to change.
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.
$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 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".
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();
$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.
$ary_ref = $sth->fetchrow_arrayref;
Supported by this driver as proposed by DBI.
@ary = $sth->fetchrow_array;
Supported by this driver as proposed by DBI.
$hash_ref = $sth->fetchrow_hashref;
Supported by this driver as proposed by DBI.
$tbl_ary_ref = $sth->fetchall_arrayref;
Implemented by DBI, no driver-specific impact.
$rc = $sth->finish;
Supported by this driver as proposed by DBI.
$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.
$rc = $sth->bind_col($column_number, \$var_to_bind, \%attr);
Supported by this driver as proposed by DBI.
$rc = $sth->bind_columns(\%attr, @list_of_refs_to_vars_to_bind);
Supported by this driver as proposed by DBI.
$rows = $sth->dump_results($maxlen, $lsep, $fsep, $fh);
Implemented by DBI, no driver-specific impact.
$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>.
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.
$dbh->pg_savepoint("mysavepoint");
$dbh->pg_rollback_to("mysavepoint");
$dbh->pg_release("mysavepoint");
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.
$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;
$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.
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.
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");
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>.
Закладки на сайте Проследить за страницей |
Created 1996-2024 by Maxim Chirkov Добавить, Поддержать, Вебмастеру |