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
;
121 function defaultValue() {
122 if ( $this->has_default
) {
123 return $this->default;
131 * Used to debug transaction processing
132 * Only used if $wgDebugDBTransactions is true
137 class PostgresTransactionState
{
138 private static $WATCHED = array(
140 "desc" => "%s: Connection state changed from %s -> %s\n",
142 PGSQL_CONNECTION_OK
=> "OK",
143 PGSQL_CONNECTION_BAD
=> "BAD"
147 "desc" => "%s: Transaction state changed from %s -> %s\n",
149 PGSQL_TRANSACTION_IDLE
=> "IDLE",
150 PGSQL_TRANSACTION_ACTIVE
=> "ACTIVE",
151 PGSQL_TRANSACTION_INTRANS
=> "TRANS",
152 PGSQL_TRANSACTION_INERROR
=> "ERROR",
153 PGSQL_TRANSACTION_UNKNOWN
=> "UNKNOWN"
162 private $mCurrentState;
164 public function __construct( $conn ) {
165 $this->mConn
= $conn;
167 $this->mCurrentState
= $this->mNewState
;
170 public function update() {
171 $this->mNewState
= array(
172 pg_connection_status( $this->mConn
),
173 pg_transaction_status( $this->mConn
)
177 public function check() {
178 global $wgDebugDBTransactions;
180 if ( $wgDebugDBTransactions ) {
181 if ( $this->mCurrentState
!== $this->mNewState
) {
182 $old = reset( $this->mCurrentState
);
183 $new = reset( $this->mNewState
);
184 foreach ( self
::$WATCHED as $watched ) {
185 if ( $old !== $new ) {
186 $this->log_changed( $old, $new, $watched );
188 $old = next( $this->mCurrentState
);
189 $new = next( $this->mNewState
);
193 $this->mCurrentState
= $this->mNewState
;
196 protected function describe_changed( $status, $desc_table ) {
197 if ( isset( $desc_table[$status] ) ) {
198 return $desc_table[$status];
200 return "STATUS " . $status;
204 protected function log_changed( $old, $new, $watched ) {
205 wfDebug( sprintf( $watched["desc"],
207 $this->describe_changed( $old, $watched["states"] ),
208 $this->describe_changed( $new, $watched["states"] )
214 * Manage savepoints within a transaction
218 class SavepointPostgres
{
219 /** @var DatabaseBase Establish a savepoint within a transaction */
225 * @param DatabaseBase $dbw
228 public function __construct( $dbw, $id ) {
231 $this->didbegin
= false;
232 /* If we are not in a transaction, we need to be for savepoint trickery */
233 if ( !$dbw->trxLevel() ) {
234 $dbw->begin( "FOR SAVEPOINT" );
235 $this->didbegin
= true;
239 public function __destruct() {
240 if ( $this->didbegin
) {
241 $this->dbw
->rollback();
242 $this->didbegin
= false;
246 public function commit() {
247 if ( $this->didbegin
) {
248 $this->dbw
->commit();
249 $this->didbegin
= false;
253 protected function query( $keyword, $msg_ok, $msg_failed ) {
254 global $wgDebugDBTransactions;
255 if ( $this->dbw
->doQuery( $keyword . " " . $this->id
) !== false ) {
256 if ( $wgDebugDBTransactions ) {
257 wfDebug( sprintf( $msg_ok, $this->id
) );
260 wfDebug( sprintf( $msg_failed, $this->id
) );
264 public function savepoint() {
265 $this->query( "SAVEPOINT",
266 "Transaction state: savepoint \"%s\" established.\n",
267 "Transaction state: establishment of savepoint \"%s\" FAILED.\n"
271 public function release() {
272 $this->query( "RELEASE",
273 "Transaction state: savepoint \"%s\" released.\n",
274 "Transaction state: release of savepoint \"%s\" FAILED.\n"
278 public function rollback() {
279 $this->query( "ROLLBACK TO",
280 "Transaction state: savepoint \"%s\" rolled back.\n",
281 "Transaction state: rollback of savepoint \"%s\" FAILED.\n"
285 public function __toString() {
286 return (string)$this->id
;
293 class DatabasePostgres
extends DatabaseBase
{
295 protected $mLastResult = null;
297 /** @var int The number of rows affected as an integer */
298 protected $mAffectedRows = null;
301 private $mInsertId = null;
303 /** @var float|string */
304 private $numericVersion = null;
306 /** @var string Connect string to open a PostgreSQL connection */
307 private $connectString;
309 /** @var PostgresTransactionState */
310 private $mTransactionState;
313 private $mCoreSchema;
319 function cascadingDeletes() {
323 function cleanupTriggers() {
327 function strictIPs() {
331 function realTimestamps() {
335 function implicitGroupby() {
339 function implicitOrderby() {
343 function searchableIPs() {
347 function functionalIndexes() {
351 function hasConstraint( $name ) {
352 $sql = "SELECT 1 FROM pg_catalog.pg_constraint c, pg_catalog.pg_namespace n " .
353 "WHERE c.connamespace = n.oid AND conname = '" .
354 pg_escape_string( $this->mConn
, $name ) . "' AND n.nspname = '" .
355 pg_escape_string( $this->mConn
, $this->getCoreSchema() ) . "'";
356 $res = $this->doQuery( $sql );
358 return $this->numRows( $res );
362 * Usually aborts on failure
363 * @param string $server
364 * @param string $user
365 * @param string $password
366 * @param string $dbName
367 * @throws DBConnectionError|Exception
368 * @return DatabaseBase|null
370 function open( $server, $user, $password, $dbName ) {
371 # Test for Postgres support, to avoid suppressed fatal error
372 if ( !function_exists( 'pg_connect' ) ) {
373 throw new DBConnectionError(
375 "Postgres functions missing, have you compiled PHP with the --with-pgsql\n" .
376 "option? (Note: if you recently installed PHP, you may need to restart your\n" .
377 "webserver and database)\n"
383 if ( !strlen( $user ) ) { # e.g. the class is being loaded
387 $this->mServer
= $server;
389 $this->mUser
= $user;
390 $this->mPassword
= $password;
391 $this->mDBname
= $dbName;
393 $connectVars = array(
396 'password' => $password
398 if ( $server != false && $server != '' ) {
399 $connectVars['host'] = $server;
401 if ( $port != false && $port != '' ) {
402 $connectVars['port'] = $port;
404 if ( $this->mFlags
& DBO_SSL
) {
405 $connectVars['sslmode'] = 1;
408 $this->connectString
= $this->makeConnectionString( $connectVars, PGSQL_CONNECT_FORCE_NEW
);
410 $this->installErrorHandler();
413 $this->mConn
= pg_connect( $this->connectString
);
414 } catch ( Exception
$ex ) {
415 $this->restoreErrorHandler();
419 $phpError = $this->restoreErrorHandler();
421 if ( !$this->mConn
) {
422 wfDebug( "DB connection error\n" );
423 wfDebug( "Server: $server, Database: $dbName, User: $user, Password: " .
424 substr( $password, 0, 3 ) . "...\n" );
425 wfDebug( $this->lastError() . "\n" );
426 throw new DBConnectionError( $this, str_replace( "\n", ' ', $phpError ) );
429 $this->mOpened
= true;
430 $this->mTransactionState
= new PostgresTransactionState( $this->mConn
);
432 global $wgCommandLineMode;
433 # If called from the command-line (e.g. importDump), only show errors
434 if ( $wgCommandLineMode ) {
435 $this->doQuery( "SET client_min_messages = 'ERROR'" );
438 $this->query( "SET client_encoding='UTF8'", __METHOD__
);
439 $this->query( "SET datestyle = 'ISO, YMD'", __METHOD__
);
440 $this->query( "SET timezone = 'GMT'", __METHOD__
);
441 $this->query( "SET standard_conforming_strings = on", __METHOD__
);
442 if ( $this->getServerVersion() >= 9.0 ) {
443 $this->query( "SET bytea_output = 'escape'", __METHOD__
); // PHP bug 53127
446 global $wgDBmwschema;
447 $this->determineCoreSchema( $wgDBmwschema );
453 * Postgres doesn't support selectDB in the same way MySQL does. So if the
454 * DB name doesn't match the open connection, open a new one
458 function selectDB( $db ) {
459 if ( $this->mDBname
!== $db ) {
460 return (bool)$this->open( $this->mServer
, $this->mUser
, $this->mPassword
, $db );
466 function makeConnectionString( $vars ) {
468 foreach ( $vars as $name => $value ) {
469 $s .= "$name='" . str_replace( "'", "\\'", $value ) . "' ";
476 * Closes a database connection, if it is open
477 * Returns success, true if already closed
480 protected function closeConnection() {
481 return pg_close( $this->mConn
);
484 public function doQuery( $sql ) {
485 if ( function_exists( 'mb_convert_encoding' ) ) {
486 $sql = mb_convert_encoding( $sql, 'UTF-8' );
488 $this->mTransactionState
->check();
489 if ( pg_send_query( $this->mConn
, $sql ) === false ) {
490 throw new DBUnexpectedError( $this, "Unable to post new query to PostgreSQL\n" );
492 $this->mLastResult
= pg_get_result( $this->mConn
);
493 $this->mTransactionState
->check();
494 $this->mAffectedRows
= null;
495 if ( pg_result_error( $this->mLastResult
) ) {
499 return $this->mLastResult
;
502 protected function dumpError() {
506 PGSQL_DIAG_MESSAGE_PRIMARY
,
507 PGSQL_DIAG_MESSAGE_DETAIL
,
508 PGSQL_DIAG_MESSAGE_HINT
,
509 PGSQL_DIAG_STATEMENT_POSITION
,
510 PGSQL_DIAG_INTERNAL_POSITION
,
511 PGSQL_DIAG_INTERNAL_QUERY
,
513 PGSQL_DIAG_SOURCE_FILE
,
514 PGSQL_DIAG_SOURCE_LINE
,
515 PGSQL_DIAG_SOURCE_FUNCTION
517 foreach ( $diags as $d ) {
518 wfDebug( sprintf( "PgSQL ERROR(%d): %s\n",
519 $d, pg_result_error_field( $this->mLastResult
, $d ) ) );
523 function reportQueryError( $error, $errno, $sql, $fname, $tempIgnore = false ) {
524 /* Transaction stays in the ERROR state until rolledback */
526 /* Check for constraint violation */
527 if ( $errno === '23505' ) {
528 parent
::reportQueryError( $error, $errno, $sql, $fname, $tempIgnore );
533 /* Don't ignore serious errors */
534 $this->rollback( __METHOD__
);
535 parent
::reportQueryError( $error, $errno, $sql, $fname, false );
538 function queryIgnore( $sql, $fname = __METHOD__
) {
539 return $this->query( $sql, $fname, true );
543 * @param stdClass|ResultWrapper $res
544 * @throws DBUnexpectedError
546 function freeResult( $res ) {
547 if ( $res instanceof ResultWrapper
) {
550 wfSuppressWarnings();
551 $ok = pg_free_result( $res );
554 throw new DBUnexpectedError( $this, "Unable to free Postgres result\n" );
559 * @param ResultWrapper|stdClass $res
561 * @throws DBUnexpectedError
563 function fetchObject( $res ) {
564 if ( $res instanceof ResultWrapper
) {
567 wfSuppressWarnings();
568 $row = pg_fetch_object( $res );
570 # @todo FIXME: HACK HACK HACK HACK debug
572 # @todo hashar: not sure if the following test really trigger if the object
574 if ( pg_last_error( $this->mConn
) ) {
575 throw new DBUnexpectedError(
577 'SQL error: ' . htmlspecialchars( pg_last_error( $this->mConn
) )
584 function fetchRow( $res ) {
585 if ( $res instanceof ResultWrapper
) {
588 wfSuppressWarnings();
589 $row = pg_fetch_array( $res );
591 if ( pg_last_error( $this->mConn
) ) {
592 throw new DBUnexpectedError(
594 'SQL error: ' . htmlspecialchars( pg_last_error( $this->mConn
) )
601 function numRows( $res ) {
602 if ( $res instanceof ResultWrapper
) {
605 wfSuppressWarnings();
606 $n = pg_num_rows( $res );
608 if ( pg_last_error( $this->mConn
) ) {
609 throw new DBUnexpectedError(
611 'SQL error: ' . htmlspecialchars( pg_last_error( $this->mConn
) )
618 function numFields( $res ) {
619 if ( $res instanceof ResultWrapper
) {
623 return pg_num_fields( $res );
626 function fieldName( $res, $n ) {
627 if ( $res instanceof ResultWrapper
) {
631 return pg_field_name( $res, $n );
635 * Return the result of the last call to nextSequenceValue();
636 * This must be called after nextSequenceValue().
640 function insertId() {
641 return $this->mInsertId
;
649 function dataSeek( $res, $row ) {
650 if ( $res instanceof ResultWrapper
) {
654 return pg_result_seek( $res, $row );
657 function lastError() {
658 if ( $this->mConn
) {
659 if ( $this->mLastResult
) {
660 return pg_result_error( $this->mLastResult
);
662 return pg_last_error();
665 return 'No database connection';
669 function lastErrno() {
670 if ( $this->mLastResult
) {
671 return pg_result_error_field( $this->mLastResult
, PGSQL_DIAG_SQLSTATE
);
677 function affectedRows() {
678 if ( !is_null( $this->mAffectedRows
) ) {
679 // Forced result for simulated queries
680 return $this->mAffectedRows
;
682 if ( empty( $this->mLastResult
) ) {
686 return pg_affected_rows( $this->mLastResult
);
690 * Estimate rows in dataset
691 * Returns estimated count, based on EXPLAIN output
692 * This is not necessarily an accurate estimate, so use sparingly
693 * Returns -1 if count cannot be found
694 * Takes same arguments as Database::select()
696 * @param string $table
697 * @param string $vars
698 * @param string $conds
699 * @param string $fname
700 * @param array $options
703 function estimateRowCount( $table, $vars = '*', $conds = '',
704 $fname = __METHOD__
, $options = array()
706 $options['EXPLAIN'] = true;
707 $res = $this->select( $table, $vars, $conds, $fname, $options );
710 $row = $this->fetchRow( $res );
712 if ( preg_match( '/rows=(\d+)/', $row[0], $count ) ) {
721 * Returns information about an index
722 * If errors are explicitly ignored, returns NULL on failure
724 * @param string $table
725 * @param string $index
726 * @param string $fname
729 function indexInfo( $table, $index, $fname = __METHOD__
) {
730 $sql = "SELECT indexname FROM pg_indexes WHERE tablename='$table'";
731 $res = $this->query( $sql, $fname );
735 foreach ( $res as $row ) {
736 if ( $row->indexname
== $this->indexName( $index ) ) {
745 * Returns is of attributes used in index
748 * @param string $index
749 * @param bool|string $schema
752 function indexAttributes( $index, $schema = false ) {
753 if ( $schema === false ) {
754 $schema = $this->getCoreSchema();
757 * A subquery would be not needed if we didn't care about the order
758 * of attributes, but we do
760 $sql = <<<__INDEXATTR__
764 i.indoption[s.g] as option,
767 (SELECT generate_series(array_lower(isub.indkey,1), array_upper(isub.indkey,1)) AS g
771 ON cis.oid=isub.indexrelid
773 ON cis.relnamespace = ns.oid
774 WHERE cis.relname='$index' AND ns.nspname='$schema') AS s,
780 ON ci.oid=i.indexrelid
782 ON ct.oid = i.indrelid
784 ON ci.relnamespace = n.oid
786 ci.relname='$index' AND n.nspname='$schema'
787 AND attrelid = ct.oid
788 AND i.indkey[s.g] = attnum
789 AND i.indclass[s.g] = opcls.oid
790 AND pg_am.oid = opcls.opcmethod
792 $res = $this->query( $sql, __METHOD__ );
795 foreach ( $res as $row ) {
809 function indexUnique( $table, $index, $fname = __METHOD__ ) {
810 $sql = "SELECT indexname FROM pg_indexes WHERE tablename='{$table}'" .
811 " AND indexdef LIKE 'CREATE UNIQUE%(" .
812 $this->strencode( $this->indexName( $index ) ) .
814 $res = $this->query( $sql, $fname );
819 return $res->numRows() > 0;
823 * Change the FOR UPDATE option as necessary based on the join conditions. Then pass
824 * to the parent function to get the actual SQL text.
826 * In Postgres when using FOR UPDATE, only the main table and tables that are inner joined
827 * can be locked. That means tables in an outer join cannot be FOR UPDATE locked. Trying to do
828 * so causes a DB error. This wrapper checks which tables can be locked and adjusts it accordingly.
830 function selectSQLText( $table, $vars, $conds = '', $fname = __METHOD__,
831 $options = array(), $join_conds = array()
833 if ( is_array( $options ) ) {
834 $forUpdateKey = array_search( 'FOR UPDATE', $options, true );
835 if ( $forUpdateKey !== false && $join_conds ) {
836 unset( $options[$forUpdateKey] );
838 foreach ( $join_conds as $table_cond => $join_cond ) {
839 if ( 0 === preg_match( '/^(?:LEFT|RIGHT|FULL)(?: OUTER)? JOIN$/i', $join_cond[0] ) ) {
840 $options['FOR UPDATE'][] = $table_cond;
846 return parent::selectSQLText( $table, $vars, $conds, $fname, $options, $join_conds );
850 * INSERT wrapper, inserts an array into a table
852 * $args may be a single associative array, or an array of these with numeric keys,
853 * for multi-row insert (Postgres version 8.2 and above only).
855 * @param string $table Name of the table to insert to.
856 * @param array $args Items to insert into the table.
857 * @param string $fname Name of the function, for profiling
858 * @param array|string $options String or array. Valid options: IGNORE
859 * @return bool Success of insert operation. IGNORE always returns true.
861 function insert( $table, $args, $fname = __METHOD__, $options = array() ) {
862 if ( !count( $args ) ) {
866 $table = $this->tableName( $table );
867 if ( !isset( $this->numericVersion ) ) {
868 $this->getServerVersion();
871 if ( !is_array( $options ) ) {
872 $options = array( $options );
875 if ( isset( $args[0] ) && is_array( $args[0] ) ) {
877 $keys = array_keys( $args[0] );
880 $keys = array_keys( $args );
883 // If IGNORE is set, we use savepoints to emulate mysql's behavior
885 if ( in_array( 'IGNORE', $options ) ) {
886 $savepoint = new SavepointPostgres( $this, 'mw' );
887 $olde = error_reporting( 0 );
888 // For future use, we may want to track the number of actual inserts
889 // Right now, insert (all writes) simply return true/false
890 $numrowsinserted = 0;
893 $sql = "INSERT INTO $table (" . implode( ',', $keys ) . ') VALUES ';
896 if ( $this->numericVersion >= 8.2 && !$savepoint ) {
898 foreach ( $args as $row ) {
904 $sql .= '(' . $this->makeList( $row ) . ')';
906 $res = (bool)$this->query( $sql, $fname, $savepoint );
910 foreach ( $args as $row ) {
912 $tempsql .= '(' . $this->makeList( $row ) . ')';
915 $savepoint->savepoint();
918 $tempres = (bool)$this->query( $tempsql, $fname, $savepoint );
921 $bar = pg_last_error();
922 if ( $bar != false ) {
923 $savepoint->rollback();
925 $savepoint->release();
930 // If any of them fail, we fail overall for this function call
931 // Note that this will be ignored if IGNORE is set
938 // Not multi, just a lone insert
940 $savepoint->savepoint();
943 $sql .= '(' . $this->makeList( $args ) . ')';
944 $res = (bool)$this->query( $sql, $fname, $savepoint );
946 $bar = pg_last_error();
947 if ( $bar != false ) {
948 $savepoint->rollback();
950 $savepoint->release();
956 error_reporting( $olde );
957 $savepoint->commit();
959 // Set the affected row count for the whole operation
960 $this->mAffectedRows = $numrowsinserted;
962 // IGNORE always returns true
970 * INSERT SELECT wrapper
971 * $varMap must be an associative array of the form array( 'dest1' => 'source1', ...)
972 * Source items may be literals rather then field names, but strings should
973 * be quoted with Database::addQuotes()
974 * $conds may be "*" to copy the whole table
975 * srcTable may be an array of tables.
976 * @todo FIXME: Implement this a little better (seperate select/insert)?
978 * @param string $destTable
979 * @param array|string $srcTable
980 * @param array $varMap
981 * @param array $conds
982 * @param string $fname
983 * @param array $insertOptions
984 * @param array $selectOptions
987 function insertSelect( $destTable, $srcTable, $varMap, $conds, $fname = __METHOD__,
988 $insertOptions = array(), $selectOptions = array() ) {
989 $destTable = $this->tableName( $destTable );
991 if ( !is_array( $insertOptions ) ) {
992 $insertOptions = array( $insertOptions );
996 * If IGNORE is set, we use savepoints to emulate mysql's behavior
997 * Ignore LOW PRIORITY option, since it is MySQL-specific
1000 if ( in_array( 'IGNORE', $insertOptions ) ) {
1001 $savepoint = new SavepointPostgres( $this, 'mw' );
1002 $olde = error_reporting( 0 );
1003 $numrowsinserted = 0;
1004 $savepoint->savepoint();
1007 if ( !is_array( $selectOptions ) ) {
1008 $selectOptions = array( $selectOptions );
1010 list( $startOpts, $useIndex, $tailOpts ) = $this->makeSelectOptions( $selectOptions );
1011 if ( is_array( $srcTable ) ) {
1012 $srcTable = implode( ',', array_map( array( &$this, 'tableName' ), $srcTable ) );
1014 $srcTable = $this->tableName( $srcTable );
1017 $sql = "INSERT INTO $destTable (" . implode( ',', array_keys( $varMap ) ) . ')' .
1018 " SELECT $startOpts " . implode( ',', $varMap ) .
1019 " FROM $srcTable $useIndex";
1021 if ( $conds != '*' ) {
1022 $sql .= ' WHERE ' . $this->makeList( $conds, LIST_AND );
1025 $sql .= " $tailOpts";
1027 $res = (bool)$this->query( $sql, $fname, $savepoint );
1029 $bar = pg_last_error();
1030 if ( $bar != false ) {
1031 $savepoint->rollback();
1033 $savepoint->release();
1036 error_reporting( $olde );
1037 $savepoint->commit();
1039 // Set the affected row count for the whole operation
1040 $this->mAffectedRows = $numrowsinserted;
1042 // IGNORE always returns true
1049 function tableName( $name, $format = 'quoted' ) {
1050 # Replace reserved words with better ones
1053 return $this->realTableName( 'mwuser', $format );
1055 return $this->realTableName( 'pagecontent', $format );
1057 return $this->realTableName( $name, $format );
1061 /* Don't cheat on installer */
1062 function realTableName( $name, $format = 'quoted' ) {
1063 return parent::tableName( $name, $format );
1067 * Return the next in a sequence, save the value for retrieval via insertId()
1069 * @param string $seqName
1072 function nextSequenceValue( $seqName ) {
1073 $safeseq = str_replace( "'", "''", $seqName );
1074 $res = $this->query( "SELECT nextval('$safeseq')" );
1075 $row = $this->fetchRow( $res );
1076 $this->mInsertId = $row[0];
1078 return $this->mInsertId;
1082 * Return the current value of a sequence. Assumes it has been nextval'ed in this session.
1084 * @param string $seqName
1087 function currentSequenceValue( $seqName ) {
1088 $safeseq = str_replace( "'", "''", $seqName );
1089 $res = $this->query( "SELECT currval('$safeseq')" );
1090 $row = $this->fetchRow( $res );
1096 # Returns the size of a text field, or -1 for "unlimited"
1097 function textFieldSize( $table, $field ) {
1098 $table = $this->tableName( $table );
1099 $sql = "SELECT t.typname as ftype,a.atttypmod as size
1100 FROM pg_class c, pg_attribute a, pg_type t
1101 WHERE relname='$table' AND a.attrelid=c.oid AND
1102 a.atttypid=t.oid and a.attname='$field'";
1103 $res = $this->query( $sql );
1104 $row = $this->fetchObject( $res );
1105 if ( $row->ftype == 'varchar' ) {
1106 $size = $row->size - 4;
1114 function limitResult( $sql, $limit, $offset = false ) {
1115 return "$sql LIMIT $limit " . ( is_numeric( $offset ) ? " OFFSET {$offset} " : '' );
1118 function wasDeadlock() {
1119 return $this->lastErrno() == '40P01';
1122 function duplicateTableStructure( $oldName, $newName, $temporary = false, $fname = __METHOD__ ) {
1123 $newName = $this->addIdentifierQuotes( $newName );
1124 $oldName = $this->addIdentifierQuotes( $oldName );
1126 return $this->query( 'CREATE ' . ( $temporary ? 'TEMPORARY ' : '' ) . " TABLE $newName " .
1127 "(LIKE $oldName INCLUDING DEFAULTS)", $fname );
1130 function listTables( $prefix = null, $fname = __METHOD__ ) {
1131 $eschema = $this->addQuotes( $this->getCoreSchema() );
1132 $result = $this->query( "SELECT tablename FROM pg_tables WHERE schemaname = $eschema", $fname );
1133 $endArray = array();
1135 foreach ( $result as $table ) {
1136 $vars = get_object_vars( $table );
1137 $table = array_pop( $vars );
1138 if ( !$prefix || strpos( $table, $prefix ) === 0 ) {
1139 $endArray[] = $table;
1146 function timestamp( $ts = 0 ) {
1147 return wfTimestamp( TS_POSTGRES, $ts );
1151 * Posted by cc[plus]php[at]c2se[dot]com on 25-Mar-2009 09:12
1152 * to http://www.php.net/manual/en/ref.pgsql.php
1154 * Parsing a postgres array can be a tricky problem, he's my
1155 * take on this, it handles multi-dimensional arrays plus
1156 * escaping using a nasty regexp to determine the limits of each
1159 * This should really be handled by PHP PostgreSQL module
1162 * @param string $text Postgreql array returned in a text form like {a,b}
1163 * @param string $output
1165 * @param int $offset
1168 function pg_array_parse( $text, &$output, $limit = false, $offset = 1 ) {
1169 if ( false === $limit ) {
1170 $limit = strlen( $text ) - 1;
1173 if ( '{}' == $text ) {
1177 if ( '{' != $text[$offset] ) {
1178 preg_match( "/(\\{?\"([^\"\\\\]|\\\\.)*\"|[^,{}]+)+([,}]+)/",
1179 $text, $match, 0, $offset );
1180 $offset += strlen( $match[0] );
1181 $output[] = ( '"' != $match[1][0]
1183 : stripcslashes( substr( $match[1], 1, -1 ) ) );
1184 if ( '},' == $match[3] ) {
1188 $offset = $this->pg_array_parse( $text, $output, $limit, $offset + 1 );
1190 } while ( $limit > $offset );
1196 * Return aggregated value function call
1198 public function aggregateValue( $valuedata, $valuename = 'value' ) {
1203 * @return string Wikitext of a link to the server software's web site
1205 public function getSoftwareLink() {
1206 return '[{{int:version-db-postgres-url}} PostgreSQL]';
1210 * Return current schema (executes SELECT current_schema())
1214 * @return string Default schema for the current session
1216 function getCurrentSchema() {
1217 $res = $this->query( "SELECT current_schema()", __METHOD__ );
1218 $row = $this->fetchRow( $res );
1224 * Return list of schemas which are accessible without schema name
1225 * This is list does not contain magic keywords like "$user"
1228 * @see getSearchPath()
1229 * @see setSearchPath()
1231 * @return array list of actual schemas for the current sesson
1233 function getSchemas() {
1234 $res = $this->query( "SELECT current_schemas(false)", __METHOD__ );
1235 $row = $this->fetchRow( $res );
1238 /* PHP pgsql support does not support array type, "{a,b}" string is returned */
1240 return $this->pg_array_parse( $row[0], $schemas );
1244 * Return search patch for schemas
1245 * This is different from getSchemas() since it contain magic keywords
1250 * @return array How to search for table names schemas for the current user
1252 function getSearchPath() {
1253 $res = $this->query( "SHOW search_path", __METHOD__ );
1254 $row = $this->fetchRow( $res );
1256 /* PostgreSQL returns SHOW values as strings */
1258 return explode( ",", $row[0] );
1262 * Update search_path, values should already be sanitized
1263 * Values may contain magic keywords like "$user"
1266 * @param array $search_path List of schemas to be searched by default
1268 function setSearchPath( $search_path ) {
1269 $this->query( "SET search_path = " . implode( ", ", $search_path ) );
1273 * Determine default schema for MediaWiki core
1274 * Adjust this session schema search path if desired schema exists
1275 * and is not alread there.
1277 * We need to have name of the core schema stored to be able
1278 * to query database metadata.
1280 * This will be also called by the installer after the schema is created
1284 * @param string $desiredSchema
1286 function determineCoreSchema( $desiredSchema ) {
1287 $this->begin( __METHOD__ );
1288 if ( $this->schemaExists( $desiredSchema ) ) {
1289 if ( in_array( $desiredSchema, $this->getSchemas() ) ) {
1290 $this->mCoreSchema = $desiredSchema;
1291 wfDebug( "Schema \"" . $desiredSchema . "\" already in the search path\n" );
1294 * Prepend our schema (e.g. 'mediawiki') in front
1295 * of the search path
1298 $search_path = $this->getSearchPath();
1299 array_unshift( $search_path,
1300 $this->addIdentifierQuotes( $desiredSchema ) );
1301 $this->setSearchPath( $search_path );
1302 $this->mCoreSchema = $desiredSchema;
1303 wfDebug( "Schema \"" . $desiredSchema . "\" added to the search path\n" );
1306 $this->mCoreSchema = $this->getCurrentSchema();
1307 wfDebug( "Schema \"" . $desiredSchema . "\" not found, using current \"" .
1308 $this->mCoreSchema . "\"\n" );
1310 /* Commit SET otherwise it will be rollbacked on error or IGNORE SELECT */
1311 $this->commit( __METHOD__ );
1315 * Return schema name fore core MediaWiki tables
1318 * @return string core schema name
1320 function getCoreSchema() {
1321 return $this->mCoreSchema;
1325 * @return string Version information from the database
1327 function getServerVersion() {
1328 if ( !isset( $this->numericVersion ) ) {
1329 $versionInfo = pg_version( $this->mConn );
1330 if ( version_compare( $versionInfo['client'], '7.4.0', 'lt' ) ) {
1331 // Old client, abort install
1332 $this->numericVersion = '7.3 or earlier';
1333 } elseif ( isset( $versionInfo['server'] ) ) {
1335 $this->numericVersion = $versionInfo['server'];
1337 // Bug 16937: broken pgsql extension from PHP<5.3
1338 $this->numericVersion = pg_parameter_status( $this->mConn, 'server_version' );
1342 return $this->numericVersion;
1346 * Query whether a given relation exists (in the given schema, or the
1347 * default mw one if not given)
1348 * @param string $table
1349 * @param array|string $types
1350 * @param bool|string $schema
1353 function relationExists( $table, $types, $schema = false ) {
1354 if ( !is_array( $types ) ) {
1355 $types = array( $types );
1358 $schema = $this->getCoreSchema();
1360 $table = $this->realTableName( $table, 'raw' );
1361 $etable = $this->addQuotes( $table );
1362 $eschema = $this->addQuotes( $schema );
1363 $sql = "SELECT 1 FROM pg_catalog.pg_class c, pg_catalog.pg_namespace n "
1364 . "WHERE c.relnamespace = n.oid AND c.relname = $etable AND n.nspname = $eschema "
1365 . "AND c.relkind IN ('" . implode( "','", $types ) . "')";
1366 $res = $this->query( $sql );
1367 $count = $res ? $res->numRows() : 0;
1369 return (bool)$count;
1373 * For backward compatibility, this function checks both tables and
1375 * @param string $table
1376 * @param string $fname
1377 * @param bool|string $schema
1380 function tableExists( $table, $fname = __METHOD__, $schema = false ) {
1381 return $this->relationExists( $table, array( 'r', 'v' ), $schema );
1384 function sequenceExists( $sequence, $schema = false ) {
1385 return $this->relationExists( $sequence, 'S', $schema );
1388 function triggerExists( $table, $trigger ) {
1390 SELECT 1 FROM pg_class, pg_namespace, pg_trigger
1391 WHERE relnamespace=pg_namespace.oid AND relkind='r'
1392 AND tgrelid=pg_class.oid
1393 AND nspname=%s AND relname=%s AND tgname=%s
1395 $res = $this->query(
1398 $this->addQuotes( $this->getCoreSchema() ),
1399 $this->addQuotes( $table ),
1400 $this->addQuotes( $trigger )
1406 $rows = $res->numRows();
1411 function ruleExists( $table, $rule ) {
1412 $exists = $this->selectField( 'pg_rules', 'rulename',
1414 'rulename' => $rule,
1415 'tablename' => $table,
1416 'schemaname' => $this->getCoreSchema()
1420 return $exists === $rule;
1423 function constraintExists( $table, $constraint ) {
1424 $sql = sprintf( "SELECT 1 FROM information_schema.table_constraints " .
1425 "WHERE constraint_schema = %s AND table_name = %s AND constraint_name = %s",
1426 $this->addQuotes( $this->getCoreSchema() ),
1427 $this->addQuotes( $table ),
1428 $this->addQuotes( $constraint )
1430 $res = $this->query( $sql );
1434 $rows = $res->numRows();
1440 * Query whether a given schema exists. Returns true if it does, false if it doesn't.
1441 * @param string $schema
1444 function schemaExists( $schema ) {
1445 $exists = $this->selectField( '"pg_catalog"."pg_namespace"', 1,
1446 array( 'nspname' => $schema ), __METHOD__ );
1448 return (bool)$exists;
1452 * Returns true if a given role (i.e. user) exists, false otherwise.
1453 * @param string $roleName
1456 function roleExists( $roleName ) {
1457 $exists = $this->selectField( '"pg_catalog"."pg_roles"', 1,
1458 array( 'rolname' => $roleName ), __METHOD__ );
1460 return (bool)$exists;
1463 function fieldInfo( $table, $field ) {
1464 return PostgresField::fromText( $this, $table, $field );
1468 * pg_field_type() wrapper
1469 * @param ResultWrapper|resource $res ResultWrapper or PostgreSQL query result resource
1470 * @param int $index Field number, starting from 0
1473 function fieldType( $res, $index ) {
1474 if ( $res instanceof ResultWrapper ) {
1475 $res = $res->result;
1478 return pg_field_type( $res, $index );
1485 function encodeBlob( $b ) {
1486 return new Blob( pg_escape_bytea( $this->mConn, $b ) );
1489 function decodeBlob( $b ) {
1490 if ( $b instanceof Blob ) {
1494 return pg_unescape_bytea( $b );
1497 function strencode( $s ) { # Should not be called by us
1498 return pg_escape_string( $this->mConn, $s );
1502 * @param null|bool|Blob $s
1503 * @return int|string
1505 function addQuotes( $s ) {
1506 if ( is_null( $s ) ) {
1508 } elseif ( is_bool( $s ) ) {
1509 return intval( $s );
1510 } elseif ( $s instanceof Blob ) {
1511 return "'" . $s->fetch( $s ) . "'";
1514 return "'" . pg_escape_string( $this->mConn, $s ) . "'";
1518 * Postgres specific version of replaceVars.
1519 * Calls the parent version in Database.php
1521 * @param string $ins SQL string, read from a stream (usually tables.sql)
1522 * @return string SQL string
1524 protected function replaceVars( $ins ) {
1525 $ins = parent::replaceVars( $ins );
1527 if ( $this->numericVersion >= 8.3 ) {
1528 // Thanks for not providing backwards-compatibility, 8.3
1529 $ins = preg_replace( "/to_tsvector\s*\(\s*'default'\s*,/", 'to_tsvector(', $ins );
1532 if ( $this->numericVersion <= 8.1 ) { // Our minimum version
1533 $ins = str_replace( 'USING gin', 'USING gist', $ins );
1540 * Various select options
1542 * @param array $options an associative array of options to be turned into
1543 * an SQL query, valid keys are listed in the function.
1546 function makeSelectOptions( $options ) {
1547 $preLimitTail = $postLimitTail = '';
1548 $startOpts = $useIndex = '';
1550 $noKeyOptions = array();
1551 foreach ( $options as $key => $option ) {
1552 if ( is_numeric( $key ) ) {
1553 $noKeyOptions[$option] = true;
1557 $preLimitTail .= $this->makeGroupByWithHaving( $options );
1559 $preLimitTail .= $this->makeOrderBy( $options );
1561 //if ( isset( $options['LIMIT'] ) ) {
1562 // $tailOpts .= $this->limitResult( '', $options['LIMIT'],
1563 // isset( $options['OFFSET'] ) ? $options['OFFSET']
1567 if ( isset( $options['FOR UPDATE'] ) ) {
1568 $postLimitTail .= ' FOR UPDATE OF ' . implode( ', ', $options['FOR UPDATE'] );
1569 } elseif ( isset( $noKeyOptions['FOR UPDATE'] ) ) {
1570 $postLimitTail .= ' FOR UPDATE';
1573 if ( isset( $noKeyOptions['DISTINCT'] ) || isset( $noKeyOptions['DISTINCTROW'] ) ) {
1574 $startOpts .= 'DISTINCT';
1577 return array( $startOpts, $useIndex, $preLimitTail, $postLimitTail );
1580 function getDBname() {
1581 return $this->mDBname;
1584 function getServer() {
1585 return $this->mServer;
1588 function buildConcat( $stringList ) {
1589 return implode( ' || ', $stringList );
1592 public function buildGroupConcatField(
1593 $delimiter, $table, $field, $conds = '', $options = array(), $join_conds = array()
1595 $fld = "array_to_string(array_agg($field)," . $this->addQuotes( $delimiter ) . ')';
1597 return '(' . $this->selectSQLText( $table, $fld, $conds, null, array(), $join_conds ) . ')';
1600 public function getSearchEngine() {
1601 return 'SearchPostgres';
1604 public function streamStatementEnd( &$sql, &$newLine ) {
1605 # Allow dollar quoting for function declarations
1606 if ( substr( $newLine, 0, 4 ) == '$mw$' ) {
1607 if ( $this->delimiter ) {
1608 $this->delimiter = false;
1610 $this->delimiter = ';';
1614 return parent::streamStatementEnd( $sql, $newLine );
1618 * Check to see if a named lock is available. This is non-blocking.
1619 * See http://www.postgresql.org/docs/8.2/static/functions-admin.html#FUNCTIONS-ADVISORY-LOCKS
1621 * @param string $lockName Name of lock to poll
1622 * @param string $method Name of method calling us
1626 public function lockIsFree( $lockName, $method ) {
1627 $key = $this->addQuotes( $this->bigintFromLockName( $lockName ) );
1628 $result = $this->query( "SELECT (CASE(pg_try_advisory_lock($key))
1629 WHEN 'f' THEN 'f' ELSE pg_advisory_unlock($key) END) AS lockstatus", $method );
1630 $row = $this->fetchObject( $result );
1632 return ( $row->lockstatus === 't' );
1636 * See http://www.postgresql.org/docs/8.2/static/functions-admin.html#FUNCTIONS-ADVISORY-LOCKS
1637 * @param string $lockName
1638 * @param string $method
1639 * @param int $timeout
1642 public function lock( $lockName, $method, $timeout = 5 ) {
1643 $key = $this->addQuotes( $this->bigintFromLockName( $lockName ) );
1644 for ( $attempts = 1; $attempts <= $timeout; ++$attempts ) {
1645 $result = $this->query(
1646 "SELECT pg_try_advisory_lock($key) AS lockstatus", $method );
1647 $row = $this->fetchObject( $result );
1648 if ( $row->lockstatus === 't' ) {
1654 wfDebug( __METHOD__ . " failed to acquire lock\n" );
1660 * See http://www.postgresql.org/docs/8.2/static/functions-admin.html#FUNCTIONS-ADVISORY-LOCKSFROM
1661 * PG DOCS: http://www.postgresql.org/docs/8.2/static/functions-admin.html#FUNCTIONS-ADVISORY-LOCKS
1662 * @param string $lockName
1663 * @param string $method
1666 public function unlock( $lockName, $method ) {
1667 $key = $this->addQuotes( $this->bigintFromLockName( $lockName ) );
1668 $result = $this->query( "SELECT pg_advisory_unlock($key) as lockstatus", $method );
1669 $row = $this->fetchObject( $result );
1671 return ( $row->lockstatus === 't' );
1675 * @param string $lockName
1676 * @return string Integer
1678 private function bigintFromLockName( $lockName ) {
1679 return wfBaseConvert( substr( sha1( $lockName ), 0, 15 ), 16, 10 );
1681 } // end DatabasePostgres class