3 * This is the Postgres database abstraction layer.
5 * This program is free software; you can redistribute it and/or modify
6 * it under the terms of the GNU General Public License as published by
7 * the Free Software Foundation; either version 2 of the License, or
8 * (at your option) any later version.
10 * This program is distributed in the hope that it will be useful,
11 * but WITHOUT ANY WARRANTY; without even the implied warranty of
12 * MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the
13 * GNU General Public License for more details.
15 * You should have received a copy of the GNU General Public License along
16 * with this program; if not, write to the Free Software Foundation, Inc.,
17 * 51 Franklin Street, Fifth Floor, Boston, MA 02110-1301, USA.
18 * http://www.gnu.org/copyleft/gpl.html
24 class PostgresField
implements Field
{
25 private $name, $tablename, $type, $nullable, $max_length, $deferred, $deferrable, $conname,
26 $has_default, $default;
29 * @param DatabaseBase $db
30 * @param string $table
31 * @param string $field
32 * @return null|PostgresField
34 static function fromText( $db, $table, $field ) {
37 attnotnull, attlen, conname AS conname,
40 COALESCE(condeferred, 'f') AS deferred,
41 COALESCE(condeferrable, 'f') AS deferrable,
42 CASE WHEN typname = 'int2' THEN 'smallint'
43 WHEN typname = 'int4' THEN 'integer'
44 WHEN typname = 'int8' THEN 'bigint'
45 WHEN typname = 'bpchar' THEN 'char'
46 ELSE typname END AS typname
48 JOIN pg_namespace n ON (n.oid = c.relnamespace)
49 JOIN pg_attribute a ON (a.attrelid = c.oid)
50 JOIN pg_type t ON (t.oid = a.atttypid)
51 LEFT JOIN pg_constraint o ON (o.conrelid = c.oid AND a.attnum = ANY(o.conkey) AND o.contype = 'f')
52 LEFT JOIN pg_attrdef d on c.oid=d.adrelid and a.attnum=d.adnum
59 $table = $db->tableName( $table, 'raw' );
62 $db->addQuotes( $db->getCoreSchema() ),
63 $db->addQuotes( $table ),
64 $db->addQuotes( $field )
67 $row = $db->fetchObject( $res );
71 $n = new PostgresField
;
72 $n->type
= $row->typname
;
73 $n->nullable
= ( $row->attnotnull
== 'f' );
75 $n->tablename
= $table;
76 $n->max_length
= $row->attlen
;
77 $n->deferrable
= ( $row->deferrable
== 't' );
78 $n->deferred
= ( $row->deferred
== 't' );
79 $n->conname
= $row->conname
;
80 $n->has_default
= ( $row->atthasdef
=== 't' );
81 $n->default = $row->adsrc
;
90 function tableName() {
91 return $this->tablename
;
98 function isNullable() {
99 return $this->nullable
;
102 function maxLength() {
103 return $this->max_length
;
106 function is_deferrable() {
107 return $this->deferrable
;
110 function is_deferred() {
111 return $this->deferred
;
115 return $this->conname
;
122 function defaultValue() {
123 if ( $this->has_default
) {
124 return $this->default;
132 * Used to debug transaction processing
133 * Only used if $wgDebugDBTransactions is true
138 class PostgresTransactionState
{
139 private static $WATCHED = array(
141 "desc" => "%s: Connection state changed from %s -> %s\n",
143 PGSQL_CONNECTION_OK
=> "OK",
144 PGSQL_CONNECTION_BAD
=> "BAD"
148 "desc" => "%s: Transaction state changed from %s -> %s\n",
150 PGSQL_TRANSACTION_IDLE
=> "IDLE",
151 PGSQL_TRANSACTION_ACTIVE
=> "ACTIVE",
152 PGSQL_TRANSACTION_INTRANS
=> "TRANS",
153 PGSQL_TRANSACTION_INERROR
=> "ERROR",
154 PGSQL_TRANSACTION_UNKNOWN
=> "UNKNOWN"
163 private $mCurrentState;
165 public function __construct( $conn ) {
166 $this->mConn
= $conn;
168 $this->mCurrentState
= $this->mNewState
;
171 public function update() {
172 $this->mNewState
= array(
173 pg_connection_status( $this->mConn
),
174 pg_transaction_status( $this->mConn
)
178 public function check() {
179 global $wgDebugDBTransactions;
181 if ( $wgDebugDBTransactions ) {
182 if ( $this->mCurrentState
!== $this->mNewState
) {
183 $old = reset( $this->mCurrentState
);
184 $new = reset( $this->mNewState
);
185 foreach ( self
::$WATCHED as $watched ) {
186 if ( $old !== $new ) {
187 $this->log_changed( $old, $new, $watched );
189 $old = next( $this->mCurrentState
);
190 $new = next( $this->mNewState
);
194 $this->mCurrentState
= $this->mNewState
;
197 protected function describe_changed( $status, $desc_table ) {
198 if ( isset( $desc_table[$status] ) ) {
199 return $desc_table[$status];
201 return "STATUS " . $status;
205 protected function log_changed( $old, $new, $watched ) {
206 wfDebug( sprintf( $watched["desc"],
208 $this->describe_changed( $old, $watched["states"] ),
209 $this->describe_changed( $new, $watched["states"] )
215 * Manage savepoints within a transaction
219 class SavepointPostgres
{
220 /** @var DatabaseBase Establish a savepoint within a transaction */
226 * @param DatabaseBase $dbw
229 public function __construct( $dbw, $id ) {
232 $this->didbegin
= false;
233 /* If we are not in a transaction, we need to be for savepoint trickery */
234 if ( !$dbw->trxLevel() ) {
235 $dbw->begin( "FOR SAVEPOINT" );
236 $this->didbegin
= true;
240 public function __destruct() {
241 if ( $this->didbegin
) {
242 $this->dbw
->rollback();
243 $this->didbegin
= false;
247 public function commit() {
248 if ( $this->didbegin
) {
249 $this->dbw
->commit();
250 $this->didbegin
= false;
254 protected function query( $keyword, $msg_ok, $msg_failed ) {
255 global $wgDebugDBTransactions;
256 if ( $this->dbw
->doQuery( $keyword . " " . $this->id
) !== false ) {
257 if ( $wgDebugDBTransactions ) {
258 wfDebug( sprintf( $msg_ok, $this->id
) );
261 wfDebug( sprintf( $msg_failed, $this->id
) );
265 public function savepoint() {
266 $this->query( "SAVEPOINT",
267 "Transaction state: savepoint \"%s\" established.\n",
268 "Transaction state: establishment of savepoint \"%s\" FAILED.\n"
272 public function release() {
273 $this->query( "RELEASE",
274 "Transaction state: savepoint \"%s\" released.\n",
275 "Transaction state: release of savepoint \"%s\" FAILED.\n"
279 public function rollback() {
280 $this->query( "ROLLBACK TO",
281 "Transaction state: savepoint \"%s\" rolled back.\n",
282 "Transaction state: rollback of savepoint \"%s\" FAILED.\n"
286 public function __toString() {
287 return (string)$this->id
;
294 class DatabasePostgres
extends DatabaseBase
{
296 protected $mLastResult = null;
298 /** @var int The number of rows affected as an integer */
299 protected $mAffectedRows = null;
302 private $mInsertId = null;
304 /** @var float|string */
305 private $numericVersion = null;
307 /** @var string Connect string to open a PostgreSQL connection */
308 private $connectString;
310 /** @var PostgresTransactionState */
311 private $mTransactionState;
314 private $mCoreSchema;
320 function cascadingDeletes() {
324 function cleanupTriggers() {
328 function strictIPs() {
332 function realTimestamps() {
336 function implicitGroupby() {
340 function implicitOrderby() {
344 function searchableIPs() {
348 function functionalIndexes() {
352 function hasConstraint( $name ) {
353 $sql = "SELECT 1 FROM pg_catalog.pg_constraint c, pg_catalog.pg_namespace n " .
354 "WHERE c.connamespace = n.oid AND conname = '" .
355 pg_escape_string( $this->mConn
, $name ) . "' AND n.nspname = '" .
356 pg_escape_string( $this->mConn
, $this->getCoreSchema() ) . "'";
357 $res = $this->doQuery( $sql );
359 return $this->numRows( $res );
363 * Usually aborts on failure
364 * @param string $server
365 * @param string $user
366 * @param string $password
367 * @param string $dbName
368 * @throws DBConnectionError|Exception
369 * @return DatabaseBase|null
371 function open( $server, $user, $password, $dbName ) {
372 # Test for Postgres support, to avoid suppressed fatal error
373 if ( !function_exists( 'pg_connect' ) ) {
374 throw new DBConnectionError(
376 "Postgres functions missing, have you compiled PHP with the --with-pgsql\n" .
377 "option? (Note: if you recently installed PHP, you may need to restart your\n" .
378 "webserver and database)\n"
384 if ( !strlen( $user ) ) { # e.g. the class is being loaded
388 $this->mServer
= $server;
390 $this->mUser
= $user;
391 $this->mPassword
= $password;
392 $this->mDBname
= $dbName;
394 $connectVars = array(
397 'password' => $password
399 if ( $server != false && $server != '' ) {
400 $connectVars['host'] = $server;
402 if ( $port != false && $port != '' ) {
403 $connectVars['port'] = $port;
405 if ( $this->mFlags
& DBO_SSL
) {
406 $connectVars['sslmode'] = 1;
409 $this->connectString
= $this->makeConnectionString( $connectVars, PGSQL_CONNECT_FORCE_NEW
);
411 $this->installErrorHandler();
414 $this->mConn
= pg_connect( $this->connectString
);
415 } catch ( Exception
$ex ) {
416 $this->restoreErrorHandler();
420 $phpError = $this->restoreErrorHandler();
422 if ( !$this->mConn
) {
423 wfDebug( "DB connection error\n" );
424 wfDebug( "Server: $server, Database: $dbName, User: $user, Password: " .
425 substr( $password, 0, 3 ) . "...\n" );
426 wfDebug( $this->lastError() . "\n" );
427 throw new DBConnectionError( $this, str_replace( "\n", ' ', $phpError ) );
430 $this->mOpened
= true;
431 $this->mTransactionState
= new PostgresTransactionState( $this->mConn
);
433 global $wgCommandLineMode;
434 # If called from the command-line (e.g. importDump), only show errors
435 if ( $wgCommandLineMode ) {
436 $this->doQuery( "SET client_min_messages = 'ERROR'" );
439 $this->query( "SET client_encoding='UTF8'", __METHOD__
);
440 $this->query( "SET datestyle = 'ISO, YMD'", __METHOD__
);
441 $this->query( "SET timezone = 'GMT'", __METHOD__
);
442 $this->query( "SET standard_conforming_strings = on", __METHOD__
);
443 if ( $this->getServerVersion() >= 9.0 ) {
444 $this->query( "SET bytea_output = 'escape'", __METHOD__
); // PHP bug 53127
447 global $wgDBmwschema;
448 $this->determineCoreSchema( $wgDBmwschema );
454 * Postgres doesn't support selectDB in the same way MySQL does. So if the
455 * DB name doesn't match the open connection, open a new one
459 function selectDB( $db ) {
460 if ( $this->mDBname
!== $db ) {
461 return (bool)$this->open( $this->mServer
, $this->mUser
, $this->mPassword
, $db );
467 function makeConnectionString( $vars ) {
469 foreach ( $vars as $name => $value ) {
470 $s .= "$name='" . str_replace( "'", "\\'", $value ) . "' ";
477 * Closes a database connection, if it is open
478 * Returns success, true if already closed
481 protected function closeConnection() {
482 return pg_close( $this->mConn
);
485 public function doQuery( $sql ) {
486 if ( function_exists( 'mb_convert_encoding' ) ) {
487 $sql = mb_convert_encoding( $sql, 'UTF-8' );
489 $this->mTransactionState
->check();
490 if ( pg_send_query( $this->mConn
, $sql ) === false ) {
491 throw new DBUnexpectedError( $this, "Unable to post new query to PostgreSQL\n" );
493 $this->mLastResult
= pg_get_result( $this->mConn
);
494 $this->mTransactionState
->check();
495 $this->mAffectedRows
= null;
496 if ( pg_result_error( $this->mLastResult
) ) {
500 return $this->mLastResult
;
503 protected function dumpError() {
507 PGSQL_DIAG_MESSAGE_PRIMARY
,
508 PGSQL_DIAG_MESSAGE_DETAIL
,
509 PGSQL_DIAG_MESSAGE_HINT
,
510 PGSQL_DIAG_STATEMENT_POSITION
,
511 PGSQL_DIAG_INTERNAL_POSITION
,
512 PGSQL_DIAG_INTERNAL_QUERY
,
514 PGSQL_DIAG_SOURCE_FILE
,
515 PGSQL_DIAG_SOURCE_LINE
,
516 PGSQL_DIAG_SOURCE_FUNCTION
518 foreach ( $diags as $d ) {
519 wfDebug( sprintf( "PgSQL ERROR(%d): %s\n",
520 $d, pg_result_error_field( $this->mLastResult
, $d ) ) );
524 function reportQueryError( $error, $errno, $sql, $fname, $tempIgnore = false ) {
526 /* Check for constraint violation */
527 if ( $errno === '23505' ) {
528 parent
::reportQueryError( $error, $errno, $sql, $fname, $tempIgnore );
533 /* Transaction stays in the ERROR state until rolledback */
534 if ( $this->mTrxLevel
) {
535 $this->rollback( __METHOD__
);
537 parent
::reportQueryError( $error, $errno, $sql, $fname, false );
540 function queryIgnore( $sql, $fname = __METHOD__
) {
541 return $this->query( $sql, $fname, true );
545 * @param stdClass|ResultWrapper $res
546 * @throws DBUnexpectedError
548 function freeResult( $res ) {
549 if ( $res instanceof ResultWrapper
) {
552 wfSuppressWarnings();
553 $ok = pg_free_result( $res );
556 throw new DBUnexpectedError( $this, "Unable to free Postgres result\n" );
561 * @param ResultWrapper|stdClass $res
563 * @throws DBUnexpectedError
565 function fetchObject( $res ) {
566 if ( $res instanceof ResultWrapper
) {
569 wfSuppressWarnings();
570 $row = pg_fetch_object( $res );
572 # @todo FIXME: HACK HACK HACK HACK debug
574 # @todo hashar: not sure if the following test really trigger if the object
576 if ( pg_last_error( $this->mConn
) ) {
577 throw new DBUnexpectedError(
579 'SQL error: ' . htmlspecialchars( pg_last_error( $this->mConn
) )
586 function fetchRow( $res ) {
587 if ( $res instanceof ResultWrapper
) {
590 wfSuppressWarnings();
591 $row = pg_fetch_array( $res );
593 if ( pg_last_error( $this->mConn
) ) {
594 throw new DBUnexpectedError(
596 'SQL error: ' . htmlspecialchars( pg_last_error( $this->mConn
) )
603 function numRows( $res ) {
604 if ( $res instanceof ResultWrapper
) {
607 wfSuppressWarnings();
608 $n = pg_num_rows( $res );
610 if ( pg_last_error( $this->mConn
) ) {
611 throw new DBUnexpectedError(
613 'SQL error: ' . htmlspecialchars( pg_last_error( $this->mConn
) )
620 function numFields( $res ) {
621 if ( $res instanceof ResultWrapper
) {
625 return pg_num_fields( $res );
628 function fieldName( $res, $n ) {
629 if ( $res instanceof ResultWrapper
) {
633 return pg_field_name( $res, $n );
637 * Return the result of the last call to nextSequenceValue();
638 * This must be called after nextSequenceValue().
642 function insertId() {
643 return $this->mInsertId
;
651 function dataSeek( $res, $row ) {
652 if ( $res instanceof ResultWrapper
) {
656 return pg_result_seek( $res, $row );
659 function lastError() {
660 if ( $this->mConn
) {
661 if ( $this->mLastResult
) {
662 return pg_result_error( $this->mLastResult
);
664 return pg_last_error();
667 return 'No database connection';
671 function lastErrno() {
672 if ( $this->mLastResult
) {
673 return pg_result_error_field( $this->mLastResult
, PGSQL_DIAG_SQLSTATE
);
679 function affectedRows() {
680 if ( !is_null( $this->mAffectedRows
) ) {
681 // Forced result for simulated queries
682 return $this->mAffectedRows
;
684 if ( empty( $this->mLastResult
) ) {
688 return pg_affected_rows( $this->mLastResult
);
692 * Estimate rows in dataset
693 * Returns estimated count, based on EXPLAIN output
694 * This is not necessarily an accurate estimate, so use sparingly
695 * Returns -1 if count cannot be found
696 * Takes same arguments as Database::select()
698 * @param string $table
699 * @param string $vars
700 * @param string $conds
701 * @param string $fname
702 * @param array $options
705 function estimateRowCount( $table, $vars = '*', $conds = '',
706 $fname = __METHOD__
, $options = array()
708 $options['EXPLAIN'] = true;
709 $res = $this->select( $table, $vars, $conds, $fname, $options );
712 $row = $this->fetchRow( $res );
714 if ( preg_match( '/rows=(\d+)/', $row[0], $count ) ) {
723 * Returns information about an index
724 * If errors are explicitly ignored, returns NULL on failure
726 * @param string $table
727 * @param string $index
728 * @param string $fname
731 function indexInfo( $table, $index, $fname = __METHOD__
) {
732 $sql = "SELECT indexname FROM pg_indexes WHERE tablename='$table'";
733 $res = $this->query( $sql, $fname );
737 foreach ( $res as $row ) {
738 if ( $row->indexname
== $this->indexName( $index ) ) {
747 * Returns is of attributes used in index
750 * @param string $index
751 * @param bool|string $schema
754 function indexAttributes( $index, $schema = false ) {
755 if ( $schema === false ) {
756 $schema = $this->getCoreSchema();
759 * A subquery would be not needed if we didn't care about the order
760 * of attributes, but we do
762 $sql = <<<__INDEXATTR__
766 i.indoption[s.g] as option,
769 (SELECT generate_series(array_lower(isub.indkey,1), array_upper(isub.indkey,1)) AS g
773 ON cis.oid=isub.indexrelid
775 ON cis.relnamespace = ns.oid
776 WHERE cis.relname='$index' AND ns.nspname='$schema') AS s,
782 ON ci.oid=i.indexrelid
784 ON ct.oid = i.indrelid
786 ON ci.relnamespace = n.oid
788 ci.relname='$index' AND n.nspname='$schema'
789 AND attrelid = ct.oid
790 AND i.indkey[s.g] = attnum
791 AND i.indclass[s.g] = opcls.oid
792 AND pg_am.oid = opcls.opcmethod
794 $res = $this->query( $sql, __METHOD__ );
797 foreach ( $res as $row ) {
811 function indexUnique( $table, $index, $fname = __METHOD__ ) {
812 $sql = "SELECT indexname FROM pg_indexes WHERE tablename='{$table}'" .
813 " AND indexdef LIKE 'CREATE UNIQUE%(" .
814 $this->strencode( $this->indexName( $index ) ) .
816 $res = $this->query( $sql, $fname );
821 return $res->numRows() > 0;
825 * Change the FOR UPDATE option as necessary based on the join conditions. Then pass
826 * to the parent function to get the actual SQL text.
828 * In Postgres when using FOR UPDATE, only the main table and tables that are inner joined
829 * can be locked. That means tables in an outer join cannot be FOR UPDATE locked. Trying to do
830 * so causes a DB error. This wrapper checks which tables can be locked and adjusts it accordingly.
832 * MySQL uses "ORDER BY NULL" as an optimization hint, but that syntax is illegal in PostgreSQL.
833 * @see DatabaseBase::selectSQLText
835 function selectSQLText( $table, $vars, $conds = '', $fname = __METHOD__,
836 $options = array(), $join_conds = array()
838 if ( is_array( $options ) ) {
839 $forUpdateKey = array_search( 'FOR UPDATE', $options, true );
840 if ( $forUpdateKey !== false && $join_conds ) {
841 unset( $options[$forUpdateKey] );
843 foreach ( $join_conds as $table_cond => $join_cond ) {
844 if ( 0 === preg_match( '/^(?:LEFT|RIGHT|FULL)(?: OUTER)? JOIN$/i', $join_cond[0] ) ) {
845 $options['FOR UPDATE'][] = $table_cond;
850 if ( isset( $options['ORDER BY'] ) && $options['ORDER BY'] == 'NULL' ) {
851 unset( $options['ORDER BY'] );
855 return parent::selectSQLText( $table, $vars, $conds, $fname, $options, $join_conds );
859 * INSERT wrapper, inserts an array into a table
861 * $args may be a single associative array, or an array of these with numeric keys,
862 * for multi-row insert (Postgres version 8.2 and above only).
864 * @param string $table Name of the table to insert to.
865 * @param array $args Items to insert into the table.
866 * @param string $fname Name of the function, for profiling
867 * @param array|string $options String or array. Valid options: IGNORE
868 * @return bool Success of insert operation. IGNORE always returns true.
870 function insert( $table, $args, $fname = __METHOD__, $options = array() ) {
871 if ( !count( $args ) ) {
875 $table = $this->tableName( $table );
876 if ( !isset( $this->numericVersion ) ) {
877 $this->getServerVersion();
880 if ( !is_array( $options ) ) {
881 $options = array( $options );
884 if ( isset( $args[0] ) && is_array( $args[0] ) ) {
886 $keys = array_keys( $args[0] );
889 $keys = array_keys( $args );
892 // If IGNORE is set, we use savepoints to emulate mysql's behavior
894 if ( in_array( 'IGNORE', $options ) ) {
895 $savepoint = new SavepointPostgres( $this, 'mw' );
896 $olde = error_reporting( 0 );
897 // For future use, we may want to track the number of actual inserts
898 // Right now, insert (all writes) simply return true/false
899 $numrowsinserted = 0;
902 $sql = "INSERT INTO $table (" . implode( ',', $keys ) . ') VALUES ';
905 if ( $this->numericVersion >= 8.2 && !$savepoint ) {
907 foreach ( $args as $row ) {
913 $sql .= '(' . $this->makeList( $row ) . ')';
915 $res = (bool)$this->query( $sql, $fname, $savepoint );
919 foreach ( $args as $row ) {
921 $tempsql .= '(' . $this->makeList( $row ) . ')';
924 $savepoint->savepoint();
927 $tempres = (bool)$this->query( $tempsql, $fname, $savepoint );
930 $bar = pg_last_error();
931 if ( $bar != false ) {
932 $savepoint->rollback();
934 $savepoint->release();
939 // If any of them fail, we fail overall for this function call
940 // Note that this will be ignored if IGNORE is set
947 // Not multi, just a lone insert
949 $savepoint->savepoint();
952 $sql .= '(' . $this->makeList( $args ) . ')';
953 $res = (bool)$this->query( $sql, $fname, $savepoint );
955 $bar = pg_last_error();
956 if ( $bar != false ) {
957 $savepoint->rollback();
959 $savepoint->release();
965 error_reporting( $olde );
966 $savepoint->commit();
968 // Set the affected row count for the whole operation
969 $this->mAffectedRows = $numrowsinserted;
971 // IGNORE always returns true
979 * INSERT SELECT wrapper
980 * $varMap must be an associative array of the form array( 'dest1' => 'source1', ...)
981 * Source items may be literals rather then field names, but strings should
982 * be quoted with Database::addQuotes()
983 * $conds may be "*" to copy the whole table
984 * srcTable may be an array of tables.
985 * @todo FIXME: Implement this a little better (seperate select/insert)?
987 * @param string $destTable
988 * @param array|string $srcTable
989 * @param array $varMap
990 * @param array $conds
991 * @param string $fname
992 * @param array $insertOptions
993 * @param array $selectOptions
996 function insertSelect( $destTable, $srcTable, $varMap, $conds, $fname = __METHOD__,
997 $insertOptions = array(), $selectOptions = array() ) {
998 $destTable = $this->tableName( $destTable );
1000 if ( !is_array( $insertOptions ) ) {
1001 $insertOptions = array( $insertOptions );
1005 * If IGNORE is set, we use savepoints to emulate mysql's behavior
1006 * Ignore LOW PRIORITY option, since it is MySQL-specific
1009 if ( in_array( 'IGNORE', $insertOptions ) ) {
1010 $savepoint = new SavepointPostgres( $this, 'mw' );
1011 $olde = error_reporting( 0 );
1012 $numrowsinserted = 0;
1013 $savepoint->savepoint();
1016 if ( !is_array( $selectOptions ) ) {
1017 $selectOptions = array( $selectOptions );
1019 list( $startOpts, $useIndex, $tailOpts ) = $this->makeSelectOptions( $selectOptions );
1020 if ( is_array( $srcTable ) ) {
1021 $srcTable = implode( ',', array_map( array( &$this, 'tableName' ), $srcTable ) );
1023 $srcTable = $this->tableName( $srcTable );
1026 $sql = "INSERT INTO $destTable (" . implode( ',', array_keys( $varMap ) ) . ')' .
1027 " SELECT $startOpts " . implode( ',', $varMap ) .
1028 " FROM $srcTable $useIndex";
1030 if ( $conds != '*' ) {
1031 $sql .= ' WHERE ' . $this->makeList( $conds, LIST_AND );
1034 $sql .= " $tailOpts";
1036 $res = (bool)$this->query( $sql, $fname, $savepoint );
1038 $bar = pg_last_error();
1039 if ( $bar != false ) {
1040 $savepoint->rollback();
1042 $savepoint->release();
1045 error_reporting( $olde );
1046 $savepoint->commit();
1048 // Set the affected row count for the whole operation
1049 $this->mAffectedRows = $numrowsinserted;
1051 // IGNORE always returns true
1058 function tableName( $name, $format = 'quoted' ) {
1059 # Replace reserved words with better ones
1062 return $this->realTableName( 'mwuser', $format );
1064 return $this->realTableName( 'pagecontent', $format );
1066 return $this->realTableName( $name, $format );
1070 /* Don't cheat on installer */
1071 function realTableName( $name, $format = 'quoted' ) {
1072 return parent::tableName( $name, $format );
1076 * Return the next in a sequence, save the value for retrieval via insertId()
1078 * @param string $seqName
1081 function nextSequenceValue( $seqName ) {
1082 $safeseq = str_replace( "'", "''", $seqName );
1083 $res = $this->query( "SELECT nextval('$safeseq')" );
1084 $row = $this->fetchRow( $res );
1085 $this->mInsertId = $row[0];
1087 return $this->mInsertId;
1091 * Return the current value of a sequence. Assumes it has been nextval'ed in this session.
1093 * @param string $seqName
1096 function currentSequenceValue( $seqName ) {
1097 $safeseq = str_replace( "'", "''", $seqName );
1098 $res = $this->query( "SELECT currval('$safeseq')" );
1099 $row = $this->fetchRow( $res );
1105 # Returns the size of a text field, or -1 for "unlimited"
1106 function textFieldSize( $table, $field ) {
1107 $table = $this->tableName( $table );
1108 $sql = "SELECT t.typname as ftype,a.atttypmod as size
1109 FROM pg_class c, pg_attribute a, pg_type t
1110 WHERE relname='$table' AND a.attrelid=c.oid AND
1111 a.atttypid=t.oid and a.attname='$field'";
1112 $res = $this->query( $sql );
1113 $row = $this->fetchObject( $res );
1114 if ( $row->ftype == 'varchar' ) {
1115 $size = $row->size - 4;
1123 function limitResult( $sql, $limit, $offset = false ) {
1124 return "$sql LIMIT $limit " . ( is_numeric( $offset ) ? " OFFSET {$offset} " : '' );
1127 function wasDeadlock() {
1128 return $this->lastErrno() == '40P01';
1131 function duplicateTableStructure( $oldName, $newName, $temporary = false, $fname = __METHOD__ ) {
1132 $newName = $this->addIdentifierQuotes( $newName );
1133 $oldName = $this->addIdentifierQuotes( $oldName );
1135 return $this->query( 'CREATE ' . ( $temporary ? 'TEMPORARY ' : '' ) . " TABLE $newName " .
1136 "(LIKE $oldName INCLUDING DEFAULTS)", $fname );
1139 function listTables( $prefix = null, $fname = __METHOD__ ) {
1140 $eschema = $this->addQuotes( $this->getCoreSchema() );
1141 $result = $this->query( "SELECT tablename FROM pg_tables WHERE schemaname = $eschema", $fname );
1142 $endArray = array();
1144 foreach ( $result as $table ) {
1145 $vars = get_object_vars( $table );
1146 $table = array_pop( $vars );
1147 if ( !$prefix || strpos( $table, $prefix ) === 0 ) {
1148 $endArray[] = $table;
1155 function timestamp( $ts = 0 ) {
1156 return wfTimestamp( TS_POSTGRES, $ts );
1160 * Posted by cc[plus]php[at]c2se[dot]com on 25-Mar-2009 09:12
1161 * to http://www.php.net/manual/en/ref.pgsql.php
1163 * Parsing a postgres array can be a tricky problem, he's my
1164 * take on this, it handles multi-dimensional arrays plus
1165 * escaping using a nasty regexp to determine the limits of each
1168 * This should really be handled by PHP PostgreSQL module
1171 * @param string $text Postgreql array returned in a text form like {a,b}
1172 * @param string $output
1174 * @param int $offset
1177 function pg_array_parse( $text, &$output, $limit = false, $offset = 1 ) {
1178 if ( false === $limit ) {
1179 $limit = strlen( $text ) - 1;
1182 if ( '{}' == $text ) {
1186 if ( '{' != $text[$offset] ) {
1187 preg_match( "/(\\{?\"([^\"\\\\]|\\\\.)*\"|[^,{}]+)+([,}]+)/",
1188 $text, $match, 0, $offset );
1189 $offset += strlen( $match[0] );
1190 $output[] = ( '"' != $match[1][0]
1192 : stripcslashes( substr( $match[1], 1, -1 ) ) );
1193 if ( '},' == $match[3] ) {
1197 $offset = $this->pg_array_parse( $text, $output, $limit, $offset + 1 );
1199 } while ( $limit > $offset );
1205 * Return aggregated value function call
1206 * @param array $valuedata
1207 * @param string $valuename
1210 public function aggregateValue( $valuedata, $valuename = 'value' ) {
1215 * @return string Wikitext of a link to the server software's web site
1217 public function getSoftwareLink() {
1218 return '[{{int:version-db-postgres-url}} PostgreSQL]';
1222 * Return current schema (executes SELECT current_schema())
1226 * @return string Default schema for the current session
1228 function getCurrentSchema() {
1229 $res = $this->query( "SELECT current_schema()", __METHOD__ );
1230 $row = $this->fetchRow( $res );
1236 * Return list of schemas which are accessible without schema name
1237 * This is list does not contain magic keywords like "$user"
1240 * @see getSearchPath()
1241 * @see setSearchPath()
1243 * @return array List of actual schemas for the current sesson
1245 function getSchemas() {
1246 $res = $this->query( "SELECT current_schemas(false)", __METHOD__ );
1247 $row = $this->fetchRow( $res );
1250 /* PHP pgsql support does not support array type, "{a,b}" string is returned */
1252 return $this->pg_array_parse( $row[0], $schemas );
1256 * Return search patch for schemas
1257 * This is different from getSchemas() since it contain magic keywords
1262 * @return array How to search for table names schemas for the current user
1264 function getSearchPath() {
1265 $res = $this->query( "SHOW search_path", __METHOD__ );
1266 $row = $this->fetchRow( $res );
1268 /* PostgreSQL returns SHOW values as strings */
1270 return explode( ",", $row[0] );
1274 * Update search_path, values should already be sanitized
1275 * Values may contain magic keywords like "$user"
1278 * @param array $search_path List of schemas to be searched by default
1280 function setSearchPath( $search_path ) {
1281 $this->query( "SET search_path = " . implode( ", ", $search_path ) );
1285 * Determine default schema for MediaWiki core
1286 * Adjust this session schema search path if desired schema exists
1287 * and is not alread there.
1289 * We need to have name of the core schema stored to be able
1290 * to query database metadata.
1292 * This will be also called by the installer after the schema is created
1296 * @param string $desiredSchema
1298 function determineCoreSchema( $desiredSchema ) {
1299 $this->begin( __METHOD__ );
1300 if ( $this->schemaExists( $desiredSchema ) ) {
1301 if ( in_array( $desiredSchema, $this->getSchemas() ) ) {
1302 $this->mCoreSchema = $desiredSchema;
1303 wfDebug( "Schema \"" . $desiredSchema . "\" already in the search path\n" );
1306 * Prepend our schema (e.g. 'mediawiki') in front
1307 * of the search path
1310 $search_path = $this->getSearchPath();
1311 array_unshift( $search_path,
1312 $this->addIdentifierQuotes( $desiredSchema ) );
1313 $this->setSearchPath( $search_path );
1314 $this->mCoreSchema = $desiredSchema;
1315 wfDebug( "Schema \"" . $desiredSchema . "\" added to the search path\n" );
1318 $this->mCoreSchema = $this->getCurrentSchema();
1319 wfDebug( "Schema \"" . $desiredSchema . "\" not found, using current \"" .
1320 $this->mCoreSchema . "\"\n" );
1322 /* Commit SET otherwise it will be rollbacked on error or IGNORE SELECT */
1323 $this->commit( __METHOD__ );
1327 * Return schema name fore core MediaWiki tables
1330 * @return string Core schema name
1332 function getCoreSchema() {
1333 return $this->mCoreSchema;
1337 * @return string Version information from the database
1339 function getServerVersion() {
1340 if ( !isset( $this->numericVersion ) ) {
1341 $versionInfo = pg_version( $this->mConn );
1342 if ( version_compare( $versionInfo['client'], '7.4.0', 'lt' ) ) {
1343 // Old client, abort install
1344 $this->numericVersion = '7.3 or earlier';
1345 } elseif ( isset( $versionInfo['server'] ) ) {
1347 $this->numericVersion = $versionInfo['server'];
1349 // Bug 16937: broken pgsql extension from PHP<5.3
1350 $this->numericVersion = pg_parameter_status( $this->mConn, 'server_version' );
1354 return $this->numericVersion;
1358 * Query whether a given relation exists (in the given schema, or the
1359 * default mw one if not given)
1360 * @param string $table
1361 * @param array|string $types
1362 * @param bool|string $schema
1365 function relationExists( $table, $types, $schema = false ) {
1366 if ( !is_array( $types ) ) {
1367 $types = array( $types );
1370 $schema = $this->getCoreSchema();
1372 $table = $this->realTableName( $table, 'raw' );
1373 $etable = $this->addQuotes( $table );
1374 $eschema = $this->addQuotes( $schema );
1375 $sql = "SELECT 1 FROM pg_catalog.pg_class c, pg_catalog.pg_namespace n "
1376 . "WHERE c.relnamespace = n.oid AND c.relname = $etable AND n.nspname = $eschema "
1377 . "AND c.relkind IN ('" . implode( "','", $types ) . "')";
1378 $res = $this->query( $sql );
1379 $count = $res ? $res->numRows() : 0;
1381 return (bool)$count;
1385 * For backward compatibility, this function checks both tables and
1387 * @param string $table
1388 * @param string $fname
1389 * @param bool|string $schema
1392 function tableExists( $table, $fname = __METHOD__, $schema = false ) {
1393 return $this->relationExists( $table, array( 'r', 'v' ), $schema );
1396 function sequenceExists( $sequence, $schema = false ) {
1397 return $this->relationExists( $sequence, 'S', $schema );
1400 function triggerExists( $table, $trigger ) {
1402 SELECT 1 FROM pg_class, pg_namespace, pg_trigger
1403 WHERE relnamespace=pg_namespace.oid AND relkind='r'
1404 AND tgrelid=pg_class.oid
1405 AND nspname=%s AND relname=%s AND tgname=%s
1407 $res = $this->query(
1410 $this->addQuotes( $this->getCoreSchema() ),
1411 $this->addQuotes( $table ),
1412 $this->addQuotes( $trigger )
1418 $rows = $res->numRows();
1423 function ruleExists( $table, $rule ) {
1424 $exists = $this->selectField( 'pg_rules', 'rulename',
1426 'rulename' => $rule,
1427 'tablename' => $table,
1428 'schemaname' => $this->getCoreSchema()
1432 return $exists === $rule;
1435 function constraintExists( $table, $constraint ) {
1436 $sql = sprintf( "SELECT 1 FROM information_schema.table_constraints " .
1437 "WHERE constraint_schema = %s AND table_name = %s AND constraint_name = %s",
1438 $this->addQuotes( $this->getCoreSchema() ),
1439 $this->addQuotes( $table ),
1440 $this->addQuotes( $constraint )
1442 $res = $this->query( $sql );
1446 $rows = $res->numRows();
1452 * Query whether a given schema exists. Returns true if it does, false if it doesn't.
1453 * @param string $schema
1456 function schemaExists( $schema ) {
1457 $exists = $this->selectField( '"pg_catalog"."pg_namespace"', 1,
1458 array( 'nspname' => $schema ), __METHOD__ );
1460 return (bool)$exists;
1464 * Returns true if a given role (i.e. user) exists, false otherwise.
1465 * @param string $roleName
1468 function roleExists( $roleName ) {
1469 $exists = $this->selectField( '"pg_catalog"."pg_roles"', 1,
1470 array( 'rolname' => $roleName ), __METHOD__ );
1472 return (bool)$exists;
1475 function fieldInfo( $table, $field ) {
1476 return PostgresField::fromText( $this, $table, $field );
1480 * pg_field_type() wrapper
1481 * @param ResultWrapper|resource $res ResultWrapper or PostgreSQL query result resource
1482 * @param int $index Field number, starting from 0
1485 function fieldType( $res, $index ) {
1486 if ( $res instanceof ResultWrapper ) {
1487 $res = $res->result;
1490 return pg_field_type( $res, $index );
1497 function encodeBlob( $b ) {
1498 return new Blob( pg_escape_bytea( $this->mConn, $b ) );
1501 function decodeBlob( $b ) {
1502 if ( $b instanceof Blob ) {
1506 return pg_unescape_bytea( $b );
1509 function strencode( $s ) { # Should not be called by us
1510 return pg_escape_string( $this->mConn, $s );
1514 * @param null|bool|Blob $s
1515 * @return int|string
1517 function addQuotes( $s ) {
1518 if ( is_null( $s ) ) {
1520 } elseif ( is_bool( $s ) ) {
1521 return intval( $s );
1522 } elseif ( $s instanceof Blob ) {
1523 return "'" . $s->fetch( $s ) . "'";
1526 return "'" . pg_escape_string( $this->mConn, $s ) . "'";
1530 * Postgres specific version of replaceVars.
1531 * Calls the parent version in Database.php
1533 * @param string $ins SQL string, read from a stream (usually tables.sql)
1534 * @return string SQL string
1536 protected function replaceVars( $ins ) {
1537 $ins = parent::replaceVars( $ins );
1539 if ( $this->numericVersion >= 8.3 ) {
1540 // Thanks for not providing backwards-compatibility, 8.3
1541 $ins = preg_replace( "/to_tsvector\s*\(\s*'default'\s*,/", 'to_tsvector(', $ins );
1544 if ( $this->numericVersion <= 8.1 ) { // Our minimum version
1545 $ins = str_replace( 'USING gin', 'USING gist', $ins );
1552 * Various select options
1554 * @param array $options An associative array of options to be turned into
1555 * an SQL query, valid keys are listed in the function.
1558 function makeSelectOptions( $options ) {
1559 $preLimitTail = $postLimitTail = '';
1560 $startOpts = $useIndex = '';
1562 $noKeyOptions = array();
1563 foreach ( $options as $key => $option ) {
1564 if ( is_numeric( $key ) ) {
1565 $noKeyOptions[$option] = true;
1569 $preLimitTail .= $this->makeGroupByWithHaving( $options );
1571 $preLimitTail .= $this->makeOrderBy( $options );
1573 //if ( isset( $options['LIMIT'] ) ) {
1574 // $tailOpts .= $this->limitResult( '', $options['LIMIT'],
1575 // isset( $options['OFFSET'] ) ? $options['OFFSET']
1579 if ( isset( $options['FOR UPDATE'] ) ) {
1580 $postLimitTail .= ' FOR UPDATE OF ' .
1581 implode( ', ', array_map( array( &$this, 'tableName' ), $options['FOR UPDATE'] ) );
1582 } elseif ( isset( $noKeyOptions['FOR UPDATE'] ) ) {
1583 $postLimitTail .= ' FOR UPDATE';
1586 if ( isset( $noKeyOptions['DISTINCT'] ) || isset( $noKeyOptions['DISTINCTROW'] ) ) {
1587 $startOpts .= 'DISTINCT';
1590 return array( $startOpts, $useIndex, $preLimitTail, $postLimitTail );
1593 function getDBname() {
1594 return $this->mDBname;
1597 function getServer() {
1598 return $this->mServer;
1601 function buildConcat( $stringList ) {
1602 return implode( ' || ', $stringList );
1605 public function buildGroupConcatField(
1606 $delimiter, $table, $field, $conds = '', $options = array(), $join_conds = array()
1608 $fld = "array_to_string(array_agg($field)," . $this->addQuotes( $delimiter ) . ')';
1610 return '(' . $this->selectSQLText( $table, $fld, $conds, null, array(), $join_conds ) . ')';
1613 public function getSearchEngine() {
1614 return 'SearchPostgres';
1617 public function streamStatementEnd( &$sql, &$newLine ) {
1618 # Allow dollar quoting for function declarations
1619 if ( substr( $newLine, 0, 4 ) == '$mw$' ) {
1620 if ( $this->delimiter ) {
1621 $this->delimiter = false;
1623 $this->delimiter = ';';
1627 return parent::streamStatementEnd( $sql, $newLine );
1631 * Check to see if a named lock is available. This is non-blocking.
1632 * See http://www.postgresql.org/docs/8.2/static/functions-admin.html#FUNCTIONS-ADVISORY-LOCKS
1634 * @param string $lockName Name of lock to poll
1635 * @param string $method Name of method calling us
1639 public function lockIsFree( $lockName, $method ) {
1640 $key = $this->addQuotes( $this->bigintFromLockName( $lockName ) );
1641 $result = $this->query( "SELECT (CASE(pg_try_advisory_lock($key))
1642 WHEN 'f' THEN 'f' ELSE pg_advisory_unlock($key) END) AS lockstatus", $method );
1643 $row = $this->fetchObject( $result );
1645 return ( $row->lockstatus === 't' );
1649 * See http://www.postgresql.org/docs/8.2/static/functions-admin.html#FUNCTIONS-ADVISORY-LOCKS
1650 * @param string $lockName
1651 * @param string $method
1652 * @param int $timeout
1655 public function lock( $lockName, $method, $timeout = 5 ) {
1656 $key = $this->addQuotes( $this->bigintFromLockName( $lockName ) );
1657 for ( $attempts = 1; $attempts <= $timeout; ++$attempts ) {
1658 $result = $this->query(
1659 "SELECT pg_try_advisory_lock($key) AS lockstatus", $method );
1660 $row = $this->fetchObject( $result );
1661 if ( $row->lockstatus === 't' ) {
1667 wfDebug( __METHOD__ . " failed to acquire lock\n" );
1673 * See http://www.postgresql.org/docs/8.2/static/functions-admin.html#FUNCTIONS-ADVISORY-LOCKSFROM
1674 * PG DOCS: http://www.postgresql.org/docs/8.2/static/functions-admin.html#FUNCTIONS-ADVISORY-LOCKS
1675 * @param string $lockName
1676 * @param string $method
1679 public function unlock( $lockName, $method ) {
1680 $key = $this->addQuotes( $this->bigintFromLockName( $lockName ) );
1681 $result = $this->query( "SELECT pg_advisory_unlock($key) as lockstatus", $method );
1682 $row = $this->fetchObject( $result );
1684 return ( $row->lockstatus === 't' );
1688 * @param string $lockName
1689 * @return string Integer
1691 private function bigintFromLockName( $lockName ) {
1692 return wfBaseConvert( substr( sha1( $lockName ), 0, 15 ), 16, 10 );
1694 } // end DatabasePostgres class