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 $db DatabaseBase
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
;
89 function tableName() {
90 return $this->tablename
;
97 function isNullable() {
98 return $this->nullable
;
101 function maxLength() {
102 return $this->max_length
;
105 function is_deferrable() {
106 return $this->deferrable
;
109 function is_deferred() {
110 return $this->deferred
;
114 return $this->conname
;
119 function defaultValue() {
120 if ( $this->has_default
) {
121 return $this->default;
130 * Used to debug transaction processing
131 * Only used if $wgDebugDBTransactions is true
136 class PostgresTransactionState
{
138 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"
158 public function __construct( $conn ) {
159 $this->mConn
= $conn;
161 $this->mCurrentState
= $this->mNewState
;
164 public function update() {
165 $this->mNewState
= array(
166 pg_connection_status( $this->mConn
),
167 pg_transaction_status( $this->mConn
)
171 public function check() {
172 global $wgDebugDBTransactions;
174 if ( $wgDebugDBTransactions ) {
175 if ( $this->mCurrentState
!== $this->mNewState
) {
176 $old = reset( $this->mCurrentState
);
177 $new = reset( $this->mNewState
);
178 foreach ( self
::$WATCHED as $watched ) {
179 if ( $old !== $new ) {
180 $this->log_changed( $old, $new, $watched );
182 $old = next( $this->mCurrentState
);
183 $new = next( $this->mNewState
);
188 $this->mCurrentState
= $this->mNewState
;
191 protected function describe_changed( $status, $desc_table ) {
192 if ( isset( $desc_table[$status] ) ) {
193 return $desc_table[$status];
195 return "STATUS " . $status;
199 protected function log_changed( $old, $new, $watched ) {
200 wfDebug( sprintf( $watched["desc"],
202 $this->describe_changed( $old, $watched["states"] ),
203 $this->describe_changed( $new, $watched["states"] )
209 * Manage savepoints within a transaction
213 class SavepointPostgres
{
215 * Establish a savepoint within a transaction
221 public function __construct( $dbw, $id ) {
224 $this->didbegin
= false;
225 /* If we are not in a transaction, we need to be for savepoint trickery */
226 if ( !$dbw->trxLevel() ) {
227 $dbw->begin( "FOR SAVEPOINT" );
228 $this->didbegin
= true;
232 public function __destruct() {
233 if ( $this->didbegin
) {
234 $this->dbw
->rollback();
235 $this->didbegin
= false;
239 public function commit() {
240 if ( $this->didbegin
) {
241 $this->dbw
->commit();
242 $this->didbegin
= false;
246 protected function query( $keyword, $msg_ok, $msg_failed ) {
247 global $wgDebugDBTransactions;
248 if ( $this->dbw
->doQuery( $keyword . " " . $this->id
) !== false ) {
249 if ( $wgDebugDBTransactions ) {
250 wfDebug( sprintf ( $msg_ok, $this->id
) );
253 wfDebug( sprintf ( $msg_failed, $this->id
) );
257 public function savepoint() {
258 $this->query( "SAVEPOINT",
259 "Transaction state: savepoint \"%s\" established.\n",
260 "Transaction state: establishment of savepoint \"%s\" FAILED.\n"
264 public function release() {
265 $this->query( "RELEASE",
266 "Transaction state: savepoint \"%s\" released.\n",
267 "Transaction state: release of savepoint \"%s\" FAILED.\n"
271 public function rollback() {
272 $this->query( "ROLLBACK TO",
273 "Transaction state: savepoint \"%s\" rolled back.\n",
274 "Transaction state: rollback of savepoint \"%s\" FAILED.\n"
278 public function __toString() {
279 return (string)$this->id
;
286 class DatabasePostgres
extends DatabaseBase
{
287 var $mInsertId = null;
288 var $mLastResult = null;
289 var $numeric_version = null;
290 var $mAffectedRows = null;
296 function cascadingDeletes() {
299 function cleanupTriggers() {
302 function strictIPs() {
305 function realTimestamps() {
308 function implicitGroupby() {
311 function implicitOrderby() {
314 function searchableIPs() {
317 function functionalIndexes() {
321 function hasConstraint( $name ) {
322 $SQL = "SELECT 1 FROM pg_catalog.pg_constraint c, pg_catalog.pg_namespace n WHERE c.connamespace = n.oid AND conname = '" .
323 pg_escape_string( $this->mConn
, $name ) . "' AND n.nspname = '" . pg_escape_string( $this->mConn
, $this->getCoreSchema() ) . "'";
324 $res = $this->doQuery( $SQL );
325 return $this->numRows( $res );
329 * Usually aborts on failure
330 * @param string $server
331 * @param string $user
332 * @param string $password
333 * @param string $dbName
334 * @throws DBConnectionError
335 * @return DatabaseBase|null
337 function open( $server, $user, $password, $dbName ) {
338 # Test for Postgres support, to avoid suppressed fatal error
339 if ( !function_exists( 'pg_connect' ) ) {
340 throw new DBConnectionError( $this, "Postgres functions missing, have you compiled PHP with the --with-pgsql option?\n (Note: if you recently installed PHP, you may need to restart your webserver and database)\n" );
345 if ( !strlen( $user ) ) { # e.g. the class is being loaded
349 $this->mServer
= $server;
351 $this->mUser
= $user;
352 $this->mPassword
= $password;
353 $this->mDBname
= $dbName;
355 $connectVars = array(
358 'password' => $password
360 if ( $server != false && $server != '' ) {
361 $connectVars['host'] = $server;
363 if ( $port != false && $port != '' ) {
364 $connectVars['port'] = $port;
366 if ( $this->mFlags
& DBO_SSL
) {
367 $connectVars['sslmode'] = 1;
370 $this->connectString
= $this->makeConnectionString( $connectVars, PGSQL_CONNECT_FORCE_NEW
);
372 $this->installErrorHandler();
373 $this->mConn
= pg_connect( $this->connectString
);
374 $phpError = $this->restoreErrorHandler();
376 if ( !$this->mConn
) {
377 wfDebug( "DB connection error\n" );
378 wfDebug( "Server: $server, Database: $dbName, User: $user, Password: " . substr( $password, 0, 3 ) . "...\n" );
379 wfDebug( $this->lastError() . "\n" );
380 throw new DBConnectionError( $this, str_replace( "\n", ' ', $phpError ) );
383 $this->mOpened
= true;
384 $this->mTransactionState
= new PostgresTransactionState( $this->mConn
);
386 global $wgCommandLineMode;
387 # If called from the command-line (e.g. importDump), only show errors
388 if ( $wgCommandLineMode ) {
389 $this->doQuery( "SET client_min_messages = 'ERROR'" );
392 $this->query( "SET client_encoding='UTF8'", __METHOD__
);
393 $this->query( "SET datestyle = 'ISO, YMD'", __METHOD__
);
394 $this->query( "SET timezone = 'GMT'", __METHOD__
);
395 $this->query( "SET standard_conforming_strings = on", __METHOD__
);
396 if ( $this->getServerVersion() >= 9.0 ) {
397 $this->query( "SET bytea_output = 'escape'", __METHOD__
); // PHP bug 53127
400 global $wgDBmwschema;
401 $this->determineCoreSchema( $wgDBmwschema );
407 * Postgres doesn't support selectDB in the same way MySQL does. So if the
408 * DB name doesn't match the open connection, open a new one
411 function selectDB( $db ) {
412 if ( $this->mDBname
!== $db ) {
413 return (bool)$this->open( $this->mServer
, $this->mUser
, $this->mPassword
, $db );
419 function makeConnectionString( $vars ) {
421 foreach ( $vars as $name => $value ) {
422 $s .= "$name='" . str_replace( "'", "\\'", $value ) . "' ";
428 * Closes a database connection, if it is open
429 * Returns success, true if already closed
432 protected function closeConnection() {
433 return pg_close( $this->mConn
);
436 public function doQuery( $sql ) {
437 if ( function_exists( 'mb_convert_encoding' ) ) {
438 $sql = mb_convert_encoding( $sql, 'UTF-8' );
440 $this->mTransactionState
->check();
441 if ( pg_send_query( $this->mConn
, $sql ) === false ) {
442 throw new DBUnexpectedError( $this, "Unable to post new query to PostgreSQL\n" );
444 $this->mLastResult
= pg_get_result( $this->mConn
);
445 $this->mTransactionState
->check();
446 $this->mAffectedRows
= null;
447 if ( pg_result_error( $this->mLastResult
) ) {
450 return $this->mLastResult
;
453 protected function dumpError() {
454 $diags = array( PGSQL_DIAG_SEVERITY
,
456 PGSQL_DIAG_MESSAGE_PRIMARY
,
457 PGSQL_DIAG_MESSAGE_DETAIL
,
458 PGSQL_DIAG_MESSAGE_HINT
,
459 PGSQL_DIAG_STATEMENT_POSITION
,
460 PGSQL_DIAG_INTERNAL_POSITION
,
461 PGSQL_DIAG_INTERNAL_QUERY
,
463 PGSQL_DIAG_SOURCE_FILE
,
464 PGSQL_DIAG_SOURCE_LINE
,
465 PGSQL_DIAG_SOURCE_FUNCTION
);
466 foreach ( $diags as $d ) {
467 wfDebug( sprintf( "PgSQL ERROR(%d): %s\n", $d, pg_result_error_field( $this->mLastResult
, $d ) ) );
471 function reportQueryError( $error, $errno, $sql, $fname, $tempIgnore = false ) {
472 /* Transaction stays in the ERROR state until rolledback */
474 /* Check for constraint violation */
475 if ( $errno === '23505' ) {
476 parent
::reportQueryError( $error, $errno, $sql, $fname, $tempIgnore );
480 /* Don't ignore serious errors */
481 $this->rollback( __METHOD__
);
482 parent
::reportQueryError( $error, $errno, $sql, $fname, false );
485 function queryIgnore( $sql, $fname = __METHOD__
) {
486 return $this->query( $sql, $fname, true );
489 function freeResult( $res ) {
490 if ( $res instanceof ResultWrapper
) {
493 wfSuppressWarnings();
494 $ok = pg_free_result( $res );
497 throw new DBUnexpectedError( $this, "Unable to free Postgres result\n" );
501 function fetchObject( $res ) {
502 if ( $res instanceof ResultWrapper
) {
505 wfSuppressWarnings();
506 $row = pg_fetch_object( $res );
508 # @todo FIXME: HACK HACK HACK HACK debug
510 # @todo hashar: not sure if the following test really trigger if the object
512 if ( pg_last_error( $this->mConn
) ) {
513 throw new DBUnexpectedError( $this, 'SQL error: ' . htmlspecialchars( pg_last_error( $this->mConn
) ) );
518 function fetchRow( $res ) {
519 if ( $res instanceof ResultWrapper
) {
522 wfSuppressWarnings();
523 $row = pg_fetch_array( $res );
525 if ( pg_last_error( $this->mConn
) ) {
526 throw new DBUnexpectedError( $this, 'SQL error: ' . htmlspecialchars( pg_last_error( $this->mConn
) ) );
531 function numRows( $res ) {
532 if ( $res instanceof ResultWrapper
) {
535 wfSuppressWarnings();
536 $n = pg_num_rows( $res );
538 if ( pg_last_error( $this->mConn
) ) {
539 throw new DBUnexpectedError( $this, 'SQL error: ' . htmlspecialchars( pg_last_error( $this->mConn
) ) );
544 function numFields( $res ) {
545 if ( $res instanceof ResultWrapper
) {
548 return pg_num_fields( $res );
551 function fieldName( $res, $n ) {
552 if ( $res instanceof ResultWrapper
) {
555 return pg_field_name( $res, $n );
559 * Return the result of the last call to nextSequenceValue();
560 * This must be called after nextSequenceValue().
562 * @return integer|null
564 function insertId() {
565 return $this->mInsertId
;
568 function dataSeek( $res, $row ) {
569 if ( $res instanceof ResultWrapper
) {
572 return pg_result_seek( $res, $row );
575 function lastError() {
576 if ( $this->mConn
) {
577 if ( $this->mLastResult
) {
578 return pg_result_error( $this->mLastResult
);
580 return pg_last_error();
583 return 'No database connection';
586 function lastErrno() {
587 if ( $this->mLastResult
) {
588 return pg_result_error_field( $this->mLastResult
, PGSQL_DIAG_SQLSTATE
);
594 function affectedRows() {
595 if ( !is_null( $this->mAffectedRows
) ) {
596 // Forced result for simulated queries
597 return $this->mAffectedRows
;
599 if ( empty( $this->mLastResult
) ) {
602 return pg_affected_rows( $this->mLastResult
);
606 * Estimate rows in dataset
607 * Returns estimated count, based on EXPLAIN output
608 * This is not necessarily an accurate estimate, so use sparingly
609 * Returns -1 if count cannot be found
610 * Takes same arguments as Database::select()
613 function estimateRowCount( $table, $vars = '*', $conds = '', $fname = __METHOD__
, $options = array() ) {
614 $options['EXPLAIN'] = true;
615 $res = $this->select( $table, $vars, $conds, $fname, $options );
618 $row = $this->fetchRow( $res );
620 if ( preg_match( '/rows=(\d+)/', $row[0], $count ) ) {
628 * Returns information about an index
629 * If errors are explicitly ignored, returns NULL on failure
632 function indexInfo( $table, $index, $fname = __METHOD__
) {
633 $sql = "SELECT indexname FROM pg_indexes WHERE tablename='$table'";
634 $res = $this->query( $sql, $fname );
638 foreach ( $res as $row ) {
639 if ( $row->indexname
== $this->indexName( $index ) ) {
647 * Returns is of attributes used in index
652 function indexAttributes( $index, $schema = false ) {
653 if ( $schema === false ) {
654 $schema = $this->getCoreSchema();
657 * A subquery would be not needed if we didn't care about the order
658 * of attributes, but we do
660 $sql = <<<__INDEXATTR__
664 i.indoption[s.g] as option,
667 (SELECT generate_series(array_lower(isub.indkey,1), array_upper(isub.indkey,1)) AS g
671 ON cis.oid=isub.indexrelid
673 ON cis.relnamespace = ns.oid
674 WHERE cis.relname='$index' AND ns.nspname='$schema') AS s,
680 ON ci.oid=i.indexrelid
682 ON ct.oid = i.indrelid
684 ON ci.relnamespace = n.oid
686 ci.relname='$index' AND n.nspname='$schema'
687 AND attrelid = ct.oid
688 AND i.indkey[s.g] = attnum
689 AND i.indclass[s.g] = opcls.oid
690 AND pg_am.oid = opcls.opcmethod
692 $res = $this->query( $sql, __METHOD__ );
695 foreach ( $res as $row ) {
708 function indexUnique( $table, $index, $fname = __METHOD__ ) {
709 $sql = "SELECT indexname FROM pg_indexes WHERE tablename='{$table}'" .
710 " AND indexdef LIKE 'CREATE UNIQUE%(" .
711 $this->strencode( $this->indexName( $index ) ) .
713 $res = $this->query( $sql, $fname );
717 foreach ( $res as $row ) {
724 * INSERT wrapper, inserts an array into a table
726 * $args may be a single associative array, or an array of these with numeric keys,
727 * for multi-row insert (Postgres version 8.2 and above only).
729 * @param $table String: Name of the table to insert to.
730 * @param $args Array: Items to insert into the table.
731 * @param $fname String: Name of the function, for profiling
732 * @param string $options or Array. Valid options: IGNORE
734 * @return bool Success of insert operation. IGNORE always returns true.
736 function insert( $table, $args, $fname = __METHOD__, $options = array() ) {
737 if ( !count( $args ) ) {
741 $table = $this->tableName( $table );
742 if ( !isset( $this->numeric_version ) ) {
743 $this->getServerVersion();
746 if ( !is_array( $options ) ) {
747 $options = array( $options );
750 if ( isset( $args[0] ) && is_array( $args[0] ) ) {
752 $keys = array_keys( $args[0] );
755 $keys = array_keys( $args );
758 // If IGNORE is set, we use savepoints to emulate mysql's behavior
760 if ( in_array( 'IGNORE', $options ) ) {
761 $savepoint = new SavepointPostgres( $this, 'mw' );
762 $olde = error_reporting( 0 );
763 // For future use, we may want to track the number of actual inserts
764 // Right now, insert (all writes) simply return true/false
765 $numrowsinserted = 0;
768 $sql = "INSERT INTO $table (" . implode( ',', $keys ) . ') VALUES ';
771 if ( $this->numeric_version >= 8.2 && !$savepoint ) {
773 foreach ( $args as $row ) {
779 $sql .= '(' . $this->makeList( $row ) . ')';
781 $res = (bool)$this->query( $sql, $fname, $savepoint );
785 foreach ( $args as $row ) {
787 $tempsql .= '(' . $this->makeList( $row ) . ')';
790 $savepoint->savepoint();
793 $tempres = (bool)$this->query( $tempsql, $fname, $savepoint );
796 $bar = pg_last_error();
797 if ( $bar != false ) {
798 $savepoint->rollback();
800 $savepoint->release();
805 // If any of them fail, we fail overall for this function call
806 // Note that this will be ignored if IGNORE is set
813 // Not multi, just a lone insert
815 $savepoint->savepoint();
818 $sql .= '(' . $this->makeList( $args ) . ')';
819 $res = (bool)$this->query( $sql, $fname, $savepoint );
821 $bar = pg_last_error();
822 if ( $bar != false ) {
823 $savepoint->rollback();
825 $savepoint->release();
831 $olde = error_reporting( $olde );
832 $savepoint->commit();
834 // Set the affected row count for the whole operation
835 $this->mAffectedRows = $numrowsinserted;
837 // IGNORE always returns true
845 * INSERT SELECT wrapper
846 * $varMap must be an associative array of the form array( 'dest1' => 'source1', ...)
847 * Source items may be literals rather then field names, but strings should be quoted with Database::addQuotes()
848 * $conds may be "*" to copy the whole table
849 * srcTable may be an array of tables.
850 * @todo FIXME: Implement this a little better (seperate select/insert)?
853 function insertSelect( $destTable, $srcTable, $varMap, $conds, $fname = __METHOD__,
854 $insertOptions = array(), $selectOptions = array() )
856 $destTable = $this->tableName( $destTable );
858 if ( !is_array( $insertOptions ) ) {
859 $insertOptions = array( $insertOptions );
863 * If IGNORE is set, we use savepoints to emulate mysql's behavior
864 * Ignore LOW PRIORITY option, since it is MySQL-specific
867 if ( in_array( 'IGNORE', $insertOptions ) ) {
868 $savepoint = new SavepointPostgres( $this, 'mw' );
869 $olde = error_reporting( 0 );
870 $numrowsinserted = 0;
871 $savepoint->savepoint();
874 if ( !is_array( $selectOptions ) ) {
875 $selectOptions = array( $selectOptions );
877 list( $startOpts, $useIndex, $tailOpts ) = $this->makeSelectOptions( $selectOptions );
878 if ( is_array( $srcTable ) ) {
879 $srcTable = implode( ',', array_map( array( &$this, 'tableName' ), $srcTable ) );
881 $srcTable = $this->tableName( $srcTable );
884 $sql = "INSERT INTO $destTable (" . implode( ',', array_keys( $varMap ) ) . ')' .
885 " SELECT $startOpts " . implode( ',', $varMap ) .
886 " FROM $srcTable $useIndex";
888 if ( $conds != '*' ) {
889 $sql .= ' WHERE ' . $this->makeList( $conds, LIST_AND );
892 $sql .= " $tailOpts";
894 $res = (bool)$this->query( $sql, $fname, $savepoint );
896 $bar = pg_last_error();
897 if ( $bar != false ) {
898 $savepoint->rollback();
900 $savepoint->release();
903 $olde = error_reporting( $olde );
904 $savepoint->commit();
906 // Set the affected row count for the whole operation
907 $this->mAffectedRows = $numrowsinserted;
909 // IGNORE always returns true
916 function tableName( $name, $format = 'quoted' ) {
917 # Replace reserved words with better ones
920 return $this->realTableName( 'mwuser', $format );
922 return $this->realTableName( 'pagecontent', $format );
924 return $this->realTableName( $name, $format );
928 /* Don't cheat on installer */
929 function realTableName( $name, $format = 'quoted' ) {
930 return parent::tableName( $name, $format );
934 * Return the next in a sequence, save the value for retrieval via insertId()
937 function nextSequenceValue( $seqName ) {
938 $safeseq = str_replace( "'", "''", $seqName );
939 $res = $this->query( "SELECT nextval('$safeseq')" );
940 $row = $this->fetchRow( $res );
941 $this->mInsertId = $row[0];
942 return $this->mInsertId;
946 * Return the current value of a sequence. Assumes it has been nextval'ed in this session.
949 function currentSequenceValue( $seqName ) {
950 $safeseq = str_replace( "'", "''", $seqName );
951 $res = $this->query( "SELECT currval('$safeseq')" );
952 $row = $this->fetchRow( $res );
957 # Returns the size of a text field, or -1 for "unlimited"
958 function textFieldSize( $table, $field ) {
959 $table = $this->tableName( $table );
960 $sql = "SELECT t.typname as ftype,a.atttypmod as size
961 FROM pg_class c, pg_attribute a, pg_type t
962 WHERE relname='$table' AND a.attrelid=c.oid AND
963 a.atttypid=t.oid and a.attname='$field'";
964 $res = $this->query( $sql );
965 $row = $this->fetchObject( $res );
966 if ( $row->ftype == 'varchar' ) {
967 $size = $row->size - 4;
974 function limitResult( $sql, $limit, $offset = false ) {
975 return "$sql LIMIT $limit " . ( is_numeric( $offset ) ? " OFFSET {$offset} " : '' );
978 function wasDeadlock() {
979 return $this->lastErrno() == '40P01';
982 function duplicateTableStructure( $oldName, $newName, $temporary = false, $fname = __METHOD__ ) {
983 $newName = $this->addIdentifierQuotes( $newName );
984 $oldName = $this->addIdentifierQuotes( $oldName );
985 return $this->query( 'CREATE ' . ( $temporary ? 'TEMPORARY ' : '' ) . " TABLE $newName (LIKE $oldName INCLUDING DEFAULTS)", $fname );
988 function listTables( $prefix = null, $fname = __METHOD__ ) {
989 $eschema = $this->addQuotes( $this->getCoreSchema() );
990 $result = $this->query( "SELECT tablename FROM pg_tables WHERE schemaname = $eschema", $fname );
993 foreach ( $result as $table ) {
994 $vars = get_object_vars( $table );
995 $table = array_pop( $vars );
996 if ( !$prefix || strpos( $table, $prefix ) === 0 ) {
997 $endArray[] = $table;
1004 function timestamp( $ts = 0 ) {
1005 return wfTimestamp( TS_POSTGRES, $ts );
1009 * Posted by cc[plus]php[at]c2se[dot]com on 25-Mar-2009 09:12
1010 * to http://www.php.net/manual/en/ref.pgsql.php
1012 * Parsing a postgres array can be a tricky problem, he's my
1013 * take on this, it handles multi-dimensional arrays plus
1014 * escaping using a nasty regexp to determine the limits of each
1017 * This should really be handled by PHP PostgreSQL module
1020 * @param $text string: postgreql array returned in a text form like {a,b}
1021 * @param $output string
1023 * @param $offset int
1026 function pg_array_parse( $text, &$output, $limit = false, $offset = 1 ) {
1027 if ( false === $limit ) {
1028 $limit = strlen( $text ) - 1;
1031 if ( '{}' == $text ) {
1035 if ( '{' != $text[$offset] ) {
1036 preg_match( "/(\\{?\"([^\"\\\\]|\\\\.)*\"|[^,{}]+)+([,}]+)/",
1037 $text, $match, 0, $offset );
1038 $offset += strlen( $match[0] );
1039 $output[] = ( '"' != $match[1][0]
1041 : stripcslashes( substr( $match[1], 1, -1 ) ) );
1042 if ( '},' == $match[3] ) {
1046 $offset = $this->pg_array_parse( $text, $output, $limit, $offset + 1 );
1048 } while ( $limit > $offset );
1053 * Return aggregated value function call
1055 public function aggregateValue( $valuedata, $valuename = 'value' ) {
1060 * @return string wikitext of a link to the server software's web site
1062 public function getSoftwareLink() {
1063 return '[http://www.postgresql.org/ PostgreSQL]';
1067 * Return current schema (executes SELECT current_schema())
1071 * @return string return default schema for the current session
1073 function getCurrentSchema() {
1074 $res = $this->query( "SELECT current_schema()", __METHOD__ );
1075 $row = $this->fetchRow( $res );
1080 * Return list of schemas which are accessible without schema name
1081 * This is list does not contain magic keywords like "$user"
1084 * @see getSearchPath()
1085 * @see setSearchPath()
1087 * @return array list of actual schemas for the current sesson
1089 function getSchemas() {
1090 $res = $this->query( "SELECT current_schemas(false)", __METHOD__ );
1091 $row = $this->fetchRow( $res );
1093 /* PHP pgsql support does not support array type, "{a,b}" string is returned */
1094 return $this->pg_array_parse( $row[0], $schemas );
1098 * Return search patch for schemas
1099 * This is different from getSchemas() since it contain magic keywords
1104 * @return array how to search for table names schemas for the current user
1106 function getSearchPath() {
1107 $res = $this->query( "SHOW search_path", __METHOD__ );
1108 $row = $this->fetchRow( $res );
1109 /* PostgreSQL returns SHOW values as strings */
1110 return explode( ",", $row[0] );
1114 * Update search_path, values should already be sanitized
1115 * Values may contain magic keywords like "$user"
1118 * @param $search_path array list of schemas to be searched by default
1120 function setSearchPath( $search_path ) {
1121 $this->query( "SET search_path = " . implode( ", ", $search_path ) );
1125 * Determine default schema for MediaWiki core
1126 * Adjust this session schema search path if desired schema exists
1127 * and is not alread there.
1129 * We need to have name of the core schema stored to be able
1130 * to query database metadata.
1132 * This will be also called by the installer after the schema is created
1135 * @param $desired_schema string
1137 function determineCoreSchema( $desired_schema ) {
1138 $this->begin( __METHOD__ );
1139 if ( $this->schemaExists( $desired_schema ) ) {
1140 if ( in_array( $desired_schema, $this->getSchemas() ) ) {
1141 $this->mCoreSchema = $desired_schema;
1142 wfDebug( "Schema \"" . $desired_schema . "\" already in the search path\n" );
1145 * Prepend our schema (e.g. 'mediawiki') in front
1146 * of the search path
1149 $search_path = $this->getSearchPath();
1150 array_unshift( $search_path,
1151 $this->addIdentifierQuotes( $desired_schema ));
1152 $this->setSearchPath( $search_path );
1153 $this->mCoreSchema = $desired_schema;
1154 wfDebug( "Schema \"" . $desired_schema . "\" added to the search path\n" );
1157 $this->mCoreSchema = $this->getCurrentSchema();
1158 wfDebug( "Schema \"" . $desired_schema . "\" not found, using current \"" . $this->mCoreSchema . "\"\n" );
1160 /* Commit SET otherwise it will be rollbacked on error or IGNORE SELECT */
1161 $this->commit( __METHOD__ );
1165 * Return schema name fore core MediaWiki tables
1168 * @return string core schema name
1170 function getCoreSchema() {
1171 return $this->mCoreSchema;
1175 * @return string Version information from the database
1177 function getServerVersion() {
1178 if ( !isset( $this->numeric_version ) ) {
1179 $versionInfo = pg_version( $this->mConn );
1180 if ( version_compare( $versionInfo['client'], '7.4.0', 'lt' ) ) {
1181 // Old client, abort install
1182 $this->numeric_version = '7.3 or earlier';
1183 } elseif ( isset( $versionInfo['server'] ) ) {
1185 $this->numeric_version = $versionInfo['server'];
1187 // Bug 16937: broken pgsql extension from PHP<5.3
1188 $this->numeric_version = pg_parameter_status( $this->mConn, 'server_version' );
1191 return $this->numeric_version;
1195 * Query whether a given relation exists (in the given schema, or the
1196 * default mw one if not given)
1199 function relationExists( $table, $types, $schema = false ) {
1200 if ( !is_array( $types ) ) {
1201 $types = array( $types );
1204 $schema = $this->getCoreSchema();
1206 $table = $this->realTableName( $table, 'raw' );
1207 $etable = $this->addQuotes( $table );
1208 $eschema = $this->addQuotes( $schema );
1209 $SQL = "SELECT 1 FROM pg_catalog.pg_class c, pg_catalog.pg_namespace n "
1210 . "WHERE c.relnamespace = n.oid AND c.relname = $etable AND n.nspname = $eschema "
1211 . "AND c.relkind IN ('" . implode( "','", $types ) . "')";
1212 $res = $this->query( $SQL );
1213 $count = $res ? $res->numRows() : 0;
1214 return (bool)$count;
1218 * For backward compatibility, this function checks both tables and
1222 function tableExists( $table, $fname = __METHOD__, $schema = false ) {
1223 return $this->relationExists( $table, array( 'r', 'v' ), $schema );
1226 function sequenceExists( $sequence, $schema = false ) {
1227 return $this->relationExists( $sequence, 'S', $schema );
1230 function triggerExists( $table, $trigger ) {
1232 SELECT 1 FROM pg_class, pg_namespace, pg_trigger
1233 WHERE relnamespace=pg_namespace.oid AND relkind='r'
1234 AND tgrelid=pg_class.oid
1235 AND nspname=%s AND relname=%s AND tgname=%s
1237 $res = $this->query(
1240 $this->addQuotes( $this->getCoreSchema() ),
1241 $this->addQuotes( $table ),
1242 $this->addQuotes( $trigger )
1248 $rows = $res->numRows();
1252 function ruleExists( $table, $rule ) {
1253 $exists = $this->selectField( 'pg_rules', 'rulename',
1255 'rulename' => $rule,
1256 'tablename' => $table,
1257 'schemaname' => $this->getCoreSchema()
1260 return $exists === $rule;
1263 function constraintExists( $table, $constraint ) {
1264 $SQL = sprintf( "SELECT 1 FROM information_schema.table_constraints " .
1265 "WHERE constraint_schema = %s AND table_name = %s AND constraint_name = %s",
1266 $this->addQuotes( $this->getCoreSchema() ),
1267 $this->addQuotes( $table ),
1268 $this->addQuotes( $constraint )
1270 $res = $this->query( $SQL );
1274 $rows = $res->numRows();
1279 * Query whether a given schema exists. Returns true if it does, false if it doesn't.
1282 function schemaExists( $schema ) {
1283 $exists = $this->selectField( '"pg_catalog"."pg_namespace"', 1,
1284 array( 'nspname' => $schema ), __METHOD__ );
1285 return (bool)$exists;
1289 * Returns true if a given role (i.e. user) exists, false otherwise.
1292 function roleExists( $roleName ) {
1293 $exists = $this->selectField( '"pg_catalog"."pg_roles"', 1,
1294 array( 'rolname' => $roleName ), __METHOD__ );
1295 return (bool)$exists;
1298 function fieldInfo( $table, $field ) {
1299 return PostgresField::fromText( $this, $table, $field );
1303 * pg_field_type() wrapper
1306 function fieldType( $res, $index ) {
1307 if ( $res instanceof ResultWrapper ) {
1308 $res = $res->result;
1310 return pg_field_type( $res, $index );
1317 function encodeBlob( $b ) {
1318 return new Blob( pg_escape_bytea( $this->mConn, $b ) );
1321 function decodeBlob( $b ) {
1322 if ( $b instanceof Blob ) {
1325 return pg_unescape_bytea( $b );
1328 function strencode( $s ) { # Should not be called by us
1329 return pg_escape_string( $this->mConn, $s );
1333 * @param $s null|bool|Blob
1334 * @return int|string
1336 function addQuotes( $s ) {
1337 if ( is_null( $s ) ) {
1339 } elseif ( is_bool( $s ) ) {
1340 return intval( $s );
1341 } elseif ( $s instanceof Blob ) {
1342 return "'" . $s->fetch( $s ) . "'";
1344 return "'" . pg_escape_string( $this->mConn, $s ) . "'";
1348 * Postgres specific version of replaceVars.
1349 * Calls the parent version in Database.php
1353 * @param string $ins SQL string, read from a stream (usually tables.sql)
1355 * @return string SQL string
1357 protected function replaceVars( $ins ) {
1358 $ins = parent::replaceVars( $ins );
1360 if ( $this->numeric_version >= 8.3 ) {
1361 // Thanks for not providing backwards-compatibility, 8.3
1362 $ins = preg_replace( "/to_tsvector\s*\(\s*'default'\s*,/", 'to_tsvector(', $ins );
1365 if ( $this->numeric_version <= 8.1 ) { // Our minimum version
1366 $ins = str_replace( 'USING gin', 'USING gist', $ins );
1373 * Various select options
1377 * @param array $options an associative array of options to be turned into
1378 * an SQL query, valid keys are listed in the function.
1381 function makeSelectOptions( $options ) {
1382 $preLimitTail = $postLimitTail = '';
1383 $startOpts = $useIndex = '';
1385 $noKeyOptions = array();
1386 foreach ( $options as $key => $option ) {
1387 if ( is_numeric( $key ) ) {
1388 $noKeyOptions[$option] = true;
1392 $preLimitTail .= $this->makeGroupByWithHaving( $options );
1394 $preLimitTail .= $this->makeOrderBy( $options );
1396 //if ( isset( $options['LIMIT'] ) ) {
1397 // $tailOpts .= $this->limitResult( '', $options['LIMIT'],
1398 // isset( $options['OFFSET'] ) ? $options['OFFSET']
1402 if ( isset( $noKeyOptions['FOR UPDATE'] ) ) {
1403 $postLimitTail .= ' FOR UPDATE';
1405 if ( isset( $noKeyOptions['DISTINCT'] ) || isset( $noKeyOptions['DISTINCTROW'] ) ) {
1406 $startOpts .= 'DISTINCT';
1409 return array( $startOpts, $useIndex, $preLimitTail, $postLimitTail );
1412 function setFakeMaster( $enabled = true ) {
1415 function getDBname() {
1416 return $this->mDBname;
1419 function getServer() {
1420 return $this->mServer;
1423 function buildConcat( $stringList ) {
1424 return implode( ' || ', $stringList );
1427 public function getSearchEngine() {
1428 return 'SearchPostgres';
1431 public function streamStatementEnd( &$sql, &$newLine ) {
1432 # Allow dollar quoting for function declarations
1433 if ( substr( $newLine, 0, 4 ) == '$mw$' ) {
1434 if ( $this->delimiter ) {
1435 $this->delimiter = false;
1438 $this->delimiter = ';';
1441 return parent::streamStatementEnd( $sql, $newLine );
1445 * Check to see if a named lock is available. This is non-blocking.
1446 * See http://www.postgresql.org/docs/8.2/static/functions-admin.html#FUNCTIONS-ADVISORY-LOCKS
1448 * @param string $lockName name of lock to poll
1449 * @param string $method name of method calling us
1453 public function lockIsFree( $lockName, $method ) {
1454 $key = $this->addQuotes( $this->bigintFromLockName( $lockName ) );
1455 $result = $this->query( "SELECT (CASE(pg_try_advisory_lock($key))
1456 WHEN 'f' THEN 'f' ELSE pg_advisory_unlock($key) END) AS lockstatus", $method );
1457 $row = $this->fetchObject( $result );
1458 return ( $row->lockstatus === 't' );
1462 * See http://www.postgresql.org/docs/8.2/static/functions-admin.html#FUNCTIONS-ADVISORY-LOCKS
1463 * @param $lockName string
1464 * @param $method string
1465 * @param $timeout int
1468 public function lock( $lockName, $method, $timeout = 5 ) {
1469 $key = $this->addQuotes( $this->bigintFromLockName( $lockName ) );
1470 for ( $attempts = 1; $attempts <= $timeout; ++$attempts ) {
1471 $result = $this->query(
1472 "SELECT pg_try_advisory_lock($key) AS lockstatus", $method );
1473 $row = $this->fetchObject( $result );
1474 if ( $row->lockstatus === 't' ) {
1480 wfDebug( __METHOD__ . " failed to acquire lock\n" );
1485 * See http://www.postgresql.org/docs/8.2/static/functions-admin.html#FUNCTIONS-ADVISORY-LOCKSFROM PG DOCS: http://www.postgresql.org/docs/8.2/static/functions-admin.html#FUNCTIONS-ADVISORY-LOCKS
1486 * @param $lockName string
1487 * @param $method string
1490 public function unlock( $lockName, $method ) {
1491 $key = $this->addQuotes( $this->bigintFromLockName( $lockName ) );
1492 $result = $this->query( "SELECT pg_advisory_unlock($key) as lockstatus", $method );
1493 $row = $this->fetchObject( $result );
1494 return ( $row->lockstatus === 't' );
1498 * @param string $lockName
1499 * @return string Integer
1501 private function bigintFromLockName( $lockName ) {
1502 return wfBaseConvert( substr( sha1( $lockName ), 0, 15 ), 16, 10 );
1504 } // end DatabasePostgres class