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 * Manage savepoints within a transaction
136 class SavepointPostgres
{
137 /** @var DatabasePostgres Establish a savepoint within a transaction */
143 * @param DatabaseBase $dbw
146 public function __construct( $dbw, $id ) {
149 $this->didbegin
= false;
150 /* If we are not in a transaction, we need to be for savepoint trickery */
151 if ( !$dbw->trxLevel() ) {
152 $dbw->begin( "FOR SAVEPOINT" );
153 $this->didbegin
= true;
157 public function __destruct() {
158 if ( $this->didbegin
) {
159 $this->dbw
->rollback();
160 $this->didbegin
= false;
164 public function commit() {
165 if ( $this->didbegin
) {
166 $this->dbw
->commit();
167 $this->didbegin
= false;
171 protected function query( $keyword, $msg_ok, $msg_failed ) {
172 if ( $this->dbw
->doQuery( $keyword . " " . $this->id
) !== false ) {
174 wfDebug( sprintf( $msg_failed, $this->id
) );
178 public function savepoint() {
179 $this->query( "SAVEPOINT",
180 "Transaction state: savepoint \"%s\" established.\n",
181 "Transaction state: establishment of savepoint \"%s\" FAILED.\n"
185 public function release() {
186 $this->query( "RELEASE",
187 "Transaction state: savepoint \"%s\" released.\n",
188 "Transaction state: release of savepoint \"%s\" FAILED.\n"
192 public function rollback() {
193 $this->query( "ROLLBACK TO",
194 "Transaction state: savepoint \"%s\" rolled back.\n",
195 "Transaction state: rollback of savepoint \"%s\" FAILED.\n"
199 public function __toString() {
200 return (string)$this->id
;
207 class DatabasePostgres
extends Database
{
209 protected $mLastResult = null;
211 /** @var int The number of rows affected as an integer */
212 protected $mAffectedRows = null;
215 private $mInsertId = null;
217 /** @var float|string */
218 private $numericVersion = null;
220 /** @var string Connect string to open a PostgreSQL connection */
221 private $connectString;
224 private $mCoreSchema;
230 function cascadingDeletes() {
234 function cleanupTriggers() {
238 function strictIPs() {
242 function realTimestamps() {
246 function implicitGroupby() {
250 function implicitOrderby() {
254 function searchableIPs() {
258 function functionalIndexes() {
262 function hasConstraint( $name ) {
263 $sql = "SELECT 1 FROM pg_catalog.pg_constraint c, pg_catalog.pg_namespace n " .
264 "WHERE c.connamespace = n.oid AND conname = '" .
265 pg_escape_string( $this->mConn
, $name ) . "' AND n.nspname = '" .
266 pg_escape_string( $this->mConn
, $this->getCoreSchema() ) . "'";
267 $res = $this->doQuery( $sql );
269 return $this->numRows( $res );
273 * Usually aborts on failure
274 * @param string $server
275 * @param string $user
276 * @param string $password
277 * @param string $dbName
278 * @throws DBConnectionError|Exception
279 * @return DatabaseBase|null
281 function open( $server, $user, $password, $dbName ) {
282 # Test for Postgres support, to avoid suppressed fatal error
283 if ( !function_exists( 'pg_connect' ) ) {
284 throw new DBConnectionError(
286 "Postgres functions missing, have you compiled PHP with the --with-pgsql\n" .
287 "option? (Note: if you recently installed PHP, you may need to restart your\n" .
288 "webserver and database)\n"
294 if ( !strlen( $user ) ) { # e.g. the class is being loaded
298 $this->mServer
= $server;
300 $this->mUser
= $user;
301 $this->mPassword
= $password;
302 $this->mDBname
= $dbName;
307 'password' => $password
309 if ( $server != false && $server != '' ) {
310 $connectVars['host'] = $server;
312 if ( $port != false && $port != '' ) {
313 $connectVars['port'] = $port;
315 if ( $this->mFlags
& DBO_SSL
) {
316 $connectVars['sslmode'] = 1;
319 $this->connectString
= $this->makeConnectionString( $connectVars, PGSQL_CONNECT_FORCE_NEW
);
321 $this->installErrorHandler();
324 $this->mConn
= pg_connect( $this->connectString
);
325 } catch ( Exception
$ex ) {
326 $this->restoreErrorHandler();
330 $phpError = $this->restoreErrorHandler();
332 if ( !$this->mConn
) {
333 wfDebug( "DB connection error\n" );
334 wfDebug( "Server: $server, Database: $dbName, User: $user, Password: " .
335 substr( $password, 0, 3 ) . "...\n" );
336 wfDebug( $this->lastError() . "\n" );
337 throw new DBConnectionError( $this, str_replace( "\n", ' ', $phpError ) );
340 $this->mOpened
= true;
342 global $wgCommandLineMode;
343 # If called from the command-line (e.g. importDump), only show errors
344 if ( $wgCommandLineMode ) {
345 $this->doQuery( "SET client_min_messages = 'ERROR'" );
348 $this->query( "SET client_encoding='UTF8'", __METHOD__
);
349 $this->query( "SET datestyle = 'ISO, YMD'", __METHOD__
);
350 $this->query( "SET timezone = 'GMT'", __METHOD__
);
351 $this->query( "SET standard_conforming_strings = on", __METHOD__
);
352 if ( $this->getServerVersion() >= 9.0 ) {
353 $this->query( "SET bytea_output = 'escape'", __METHOD__
); // PHP bug 53127
356 global $wgDBmwschema;
357 $this->determineCoreSchema( $wgDBmwschema );
363 * Postgres doesn't support selectDB in the same way MySQL does. So if the
364 * DB name doesn't match the open connection, open a new one
368 function selectDB( $db ) {
369 if ( $this->mDBname
!== $db ) {
370 return (bool)$this->open( $this->mServer
, $this->mUser
, $this->mPassword
, $db );
376 function makeConnectionString( $vars ) {
378 foreach ( $vars as $name => $value ) {
379 $s .= "$name='" . str_replace( "'", "\\'", $value ) . "' ";
386 * Closes a database connection, if it is open
387 * Returns success, true if already closed
390 protected function closeConnection() {
391 return pg_close( $this->mConn
);
394 public function doQuery( $sql ) {
395 $sql = mb_convert_encoding( $sql, 'UTF-8' );
396 // Clear previously left over PQresult
397 while ( $res = pg_get_result( $this->mConn
) ) {
398 pg_free_result( $res );
400 if ( pg_send_query( $this->mConn
, $sql ) === false ) {
401 throw new DBUnexpectedError( $this, "Unable to post new query to PostgreSQL\n" );
403 $this->mLastResult
= pg_get_result( $this->mConn
);
404 $this->mAffectedRows
= null;
405 if ( pg_result_error( $this->mLastResult
) ) {
409 return $this->mLastResult
;
412 protected function dumpError() {
416 PGSQL_DIAG_MESSAGE_PRIMARY
,
417 PGSQL_DIAG_MESSAGE_DETAIL
,
418 PGSQL_DIAG_MESSAGE_HINT
,
419 PGSQL_DIAG_STATEMENT_POSITION
,
420 PGSQL_DIAG_INTERNAL_POSITION
,
421 PGSQL_DIAG_INTERNAL_QUERY
,
423 PGSQL_DIAG_SOURCE_FILE
,
424 PGSQL_DIAG_SOURCE_LINE
,
425 PGSQL_DIAG_SOURCE_FUNCTION
427 foreach ( $diags as $d ) {
428 wfDebug( sprintf( "PgSQL ERROR(%d): %s\n",
429 $d, pg_result_error_field( $this->mLastResult
, $d ) ) );
433 function reportQueryError( $error, $errno, $sql, $fname, $tempIgnore = false ) {
435 /* Check for constraint violation */
436 if ( $errno === '23505' ) {
437 parent
::reportQueryError( $error, $errno, $sql, $fname, $tempIgnore );
442 /* Transaction stays in the ERROR state until rolled back */
443 if ( $this->mTrxLevel
) {
444 $ignore = $this->ignoreErrors( true );
445 $this->rollback( __METHOD__
);
446 $this->ignoreErrors( $ignore );
448 parent
::reportQueryError( $error, $errno, $sql, $fname, false );
451 function queryIgnore( $sql, $fname = __METHOD__
) {
452 return $this->query( $sql, $fname, true );
456 * @param stdClass|ResultWrapper $res
457 * @throws DBUnexpectedError
459 function freeResult( $res ) {
460 if ( $res instanceof ResultWrapper
) {
463 MediaWiki\
suppressWarnings();
464 $ok = pg_free_result( $res );
465 MediaWiki\restoreWarnings
();
467 throw new DBUnexpectedError( $this, "Unable to free Postgres result\n" );
472 * @param ResultWrapper|stdClass $res
474 * @throws DBUnexpectedError
476 function fetchObject( $res ) {
477 if ( $res instanceof ResultWrapper
) {
480 MediaWiki\
suppressWarnings();
481 $row = pg_fetch_object( $res );
482 MediaWiki\restoreWarnings
();
483 # @todo FIXME: HACK HACK HACK HACK debug
485 # @todo hashar: not sure if the following test really trigger if the object
487 if ( pg_last_error( $this->mConn
) ) {
488 throw new DBUnexpectedError(
490 'SQL error: ' . htmlspecialchars( pg_last_error( $this->mConn
) )
497 function fetchRow( $res ) {
498 if ( $res instanceof ResultWrapper
) {
501 MediaWiki\
suppressWarnings();
502 $row = pg_fetch_array( $res );
503 MediaWiki\restoreWarnings
();
504 if ( pg_last_error( $this->mConn
) ) {
505 throw new DBUnexpectedError(
507 'SQL error: ' . htmlspecialchars( pg_last_error( $this->mConn
) )
514 function numRows( $res ) {
515 if ( $res instanceof ResultWrapper
) {
518 MediaWiki\
suppressWarnings();
519 $n = pg_num_rows( $res );
520 MediaWiki\restoreWarnings
();
521 if ( pg_last_error( $this->mConn
) ) {
522 throw new DBUnexpectedError(
524 'SQL error: ' . htmlspecialchars( pg_last_error( $this->mConn
) )
531 function numFields( $res ) {
532 if ( $res instanceof ResultWrapper
) {
536 return pg_num_fields( $res );
539 function fieldName( $res, $n ) {
540 if ( $res instanceof ResultWrapper
) {
544 return pg_field_name( $res, $n );
548 * Return the result of the last call to nextSequenceValue();
549 * This must be called after nextSequenceValue().
553 function insertId() {
554 return $this->mInsertId
;
562 function dataSeek( $res, $row ) {
563 if ( $res instanceof ResultWrapper
) {
567 return pg_result_seek( $res, $row );
570 function lastError() {
571 if ( $this->mConn
) {
572 if ( $this->mLastResult
) {
573 return pg_result_error( $this->mLastResult
);
575 return pg_last_error();
578 return 'No database connection';
582 function lastErrno() {
583 if ( $this->mLastResult
) {
584 return pg_result_error_field( $this->mLastResult
, PGSQL_DIAG_SQLSTATE
);
590 function affectedRows() {
591 if ( !is_null( $this->mAffectedRows
) ) {
592 // Forced result for simulated queries
593 return $this->mAffectedRows
;
595 if ( empty( $this->mLastResult
) ) {
599 return pg_affected_rows( $this->mLastResult
);
603 * Estimate rows in dataset
604 * Returns estimated count, based on EXPLAIN output
605 * This is not necessarily an accurate estimate, so use sparingly
606 * Returns -1 if count cannot be found
607 * Takes same arguments as Database::select()
609 * @param string $table
610 * @param string $vars
611 * @param string $conds
612 * @param string $fname
613 * @param array $options
616 function estimateRowCount( $table, $vars = '*', $conds = '',
617 $fname = __METHOD__
, $options = []
619 $options['EXPLAIN'] = true;
620 $res = $this->select( $table, $vars, $conds, $fname, $options );
623 $row = $this->fetchRow( $res );
625 if ( preg_match( '/rows=(\d+)/', $row[0], $count ) ) {
626 $rows = (int)$count[1];
634 * Returns information about an index
635 * If errors are explicitly ignored, returns NULL on failure
637 * @param string $table
638 * @param string $index
639 * @param string $fname
642 function indexInfo( $table, $index, $fname = __METHOD__
) {
643 $sql = "SELECT indexname FROM pg_indexes WHERE tablename='$table'";
644 $res = $this->query( $sql, $fname );
648 foreach ( $res as $row ) {
649 if ( $row->indexname
== $this->indexName( $index ) ) {
658 * Returns is of attributes used in index
661 * @param string $index
662 * @param bool|string $schema
665 function indexAttributes( $index, $schema = false ) {
666 if ( $schema === false ) {
667 $schema = $this->getCoreSchema();
670 * A subquery would be not needed if we didn't care about the order
671 * of attributes, but we do
673 $sql = <<<__INDEXATTR__
677 i.indoption[s.g] as option,
680 (SELECT generate_series(array_lower(isub.indkey,1), array_upper(isub.indkey,1)) AS g
684 ON cis.oid=isub.indexrelid
686 ON cis.relnamespace = ns.oid
687 WHERE cis.relname='$index' AND ns.nspname='$schema') AS s,
693 ON ci.oid=i.indexrelid
695 ON ct.oid = i.indrelid
697 ON ci.relnamespace = n.oid
699 ci.relname='$index' AND n.nspname='$schema'
700 AND attrelid = ct.oid
701 AND i.indkey[s.g] = attnum
702 AND i.indclass[s.g] = opcls.oid
703 AND pg_am.oid = opcls.opcmethod
705 $res = $this->query( $sql, __METHOD__ );
708 foreach ( $res as $row ) {
722 function indexUnique( $table, $index, $fname = __METHOD__ ) {
723 $sql = "SELECT indexname FROM pg_indexes WHERE tablename='{$table}'" .
724 " AND indexdef LIKE 'CREATE UNIQUE%(" .
725 $this->strencode( $this->indexName( $index ) ) .
727 $res = $this->query( $sql, $fname );
732 return $res->numRows() > 0;
736 * Change the FOR UPDATE option as necessary based on the join conditions. Then pass
737 * to the parent function to get the actual SQL text.
739 * In Postgres when using FOR UPDATE, only the main table and tables that are inner joined
740 * can be locked. That means tables in an outer join cannot be FOR UPDATE locked. Trying to do
741 * so causes a DB error. This wrapper checks which tables can be locked and adjusts it accordingly.
743 * MySQL uses "ORDER BY NULL" as an optimization hint, but that syntax is illegal in PostgreSQL.
744 * @see DatabaseBase::selectSQLText
746 function selectSQLText( $table, $vars, $conds = '', $fname = __METHOD__,
747 $options = [], $join_conds = []
749 if ( is_array( $options ) ) {
750 $forUpdateKey = array_search( 'FOR UPDATE', $options, true );
751 if ( $forUpdateKey !== false && $join_conds ) {
752 unset( $options[$forUpdateKey] );
754 foreach ( $join_conds as $table_cond => $join_cond ) {
755 if ( 0 === preg_match( '/^(?:LEFT|RIGHT|FULL)(?: OUTER)? JOIN$/i', $join_cond[0] ) ) {
756 $options['FOR UPDATE'][] = $table_cond;
761 if ( isset( $options['ORDER BY'] ) && $options['ORDER BY'] == 'NULL' ) {
762 unset( $options['ORDER BY'] );
766 return parent::selectSQLText( $table, $vars, $conds, $fname, $options, $join_conds );
770 * INSERT wrapper, inserts an array into a table
772 * $args may be a single associative array, or an array of these with numeric keys,
773 * for multi-row insert (Postgres version 8.2 and above only).
775 * @param string $table Name of the table to insert to.
776 * @param array $args Items to insert into the table.
777 * @param string $fname Name of the function, for profiling
778 * @param array|string $options String or array. Valid options: IGNORE
779 * @return bool Success of insert operation. IGNORE always returns true.
781 function insert( $table, $args, $fname = __METHOD__, $options = [] ) {
782 if ( !count( $args ) ) {
786 $table = $this->tableName( $table );
787 if ( !isset( $this->numericVersion ) ) {
788 $this->getServerVersion();
791 if ( !is_array( $options ) ) {
792 $options = [ $options ];
795 if ( isset( $args[0] ) && is_array( $args[0] ) ) {
797 $keys = array_keys( $args[0] );
800 $keys = array_keys( $args );
803 // If IGNORE is set, we use savepoints to emulate mysql's behavior
805 if ( in_array( 'IGNORE', $options ) ) {
806 $savepoint = new SavepointPostgres( $this, 'mw' );
807 $olde = error_reporting( 0 );
808 // For future use, we may want to track the number of actual inserts
809 // Right now, insert (all writes) simply return true/false
810 $numrowsinserted = 0;
813 $sql = "INSERT INTO $table (" . implode( ',', $keys ) . ') VALUES ';
816 if ( $this->numericVersion >= 8.2 && !$savepoint ) {
818 foreach ( $args as $row ) {
824 $sql .= '(' . $this->makeList( $row ) . ')';
826 $res = (bool)$this->query( $sql, $fname, $savepoint );
830 foreach ( $args as $row ) {
832 $tempsql .= '(' . $this->makeList( $row ) . ')';
835 $savepoint->savepoint();
838 $tempres = (bool)$this->query( $tempsql, $fname, $savepoint );
841 $bar = pg_result_error( $this->mLastResult );
842 if ( $bar != false ) {
843 $savepoint->rollback();
845 $savepoint->release();
850 // If any of them fail, we fail overall for this function call
851 // Note that this will be ignored if IGNORE is set
858 // Not multi, just a lone insert
860 $savepoint->savepoint();
863 $sql .= '(' . $this->makeList( $args ) . ')';
864 $res = (bool)$this->query( $sql, $fname, $savepoint );
866 $bar = pg_result_error( $this->mLastResult );
867 if ( $bar != false ) {
868 $savepoint->rollback();
870 $savepoint->release();
876 error_reporting( $olde );
877 $savepoint->commit();
879 // Set the affected row count for the whole operation
880 $this->mAffectedRows = $numrowsinserted;
882 // IGNORE always returns true
890 * INSERT SELECT wrapper
891 * $varMap must be an associative array of the form array( 'dest1' => 'source1', ...)
892 * Source items may be literals rather then field names, but strings should
893 * be quoted with Database::addQuotes()
894 * $conds may be "*" to copy the whole table
895 * srcTable may be an array of tables.
896 * @todo FIXME: Implement this a little better (seperate select/insert)?
898 * @param string $destTable
899 * @param array|string $srcTable
900 * @param array $varMap
901 * @param array $conds
902 * @param string $fname
903 * @param array $insertOptions
904 * @param array $selectOptions
907 function insertSelect( $destTable, $srcTable, $varMap, $conds, $fname = __METHOD__,
908 $insertOptions = [], $selectOptions = [] ) {
909 $destTable = $this->tableName( $destTable );
911 if ( !is_array( $insertOptions ) ) {
912 $insertOptions = [ $insertOptions ];
916 * If IGNORE is set, we use savepoints to emulate mysql's behavior
917 * Ignore LOW PRIORITY option, since it is MySQL-specific
920 if ( in_array( 'IGNORE', $insertOptions ) ) {
921 $savepoint = new SavepointPostgres( $this, 'mw' );
922 $olde = error_reporting( 0 );
923 $numrowsinserted = 0;
924 $savepoint->savepoint();
927 if ( !is_array( $selectOptions ) ) {
928 $selectOptions = [ $selectOptions ];
930 list( $startOpts, $useIndex, $tailOpts ) = $this->makeSelectOptions( $selectOptions );
931 if ( is_array( $srcTable ) ) {
932 $srcTable = implode( ',', array_map( [ &$this, 'tableName' ], $srcTable ) );
934 $srcTable = $this->tableName( $srcTable );
937 $sql = "INSERT INTO $destTable (" . implode( ',', array_keys( $varMap ) ) . ')' .
938 " SELECT $startOpts " . implode( ',', $varMap ) .
939 " FROM $srcTable $useIndex";
941 if ( $conds != '*' ) {
942 $sql .= ' WHERE ' . $this->makeList( $conds, LIST_AND );
945 $sql .= " $tailOpts";
947 $res = (bool)$this->query( $sql, $fname, $savepoint );
949 $bar = pg_result_error( $this->mLastResult );
950 if ( $bar != false ) {
951 $savepoint->rollback();
953 $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
969 function tableName( $name, $format = 'quoted' ) {
970 # Replace reserved words with better ones
973 return $this->realTableName( 'mwuser', $format );
975 return $this->realTableName( 'pagecontent', $format );
977 return $this->realTableName( $name, $format );
981 /* Don't cheat on installer */
982 function realTableName( $name, $format = 'quoted' ) {
983 return parent::tableName( $name, $format );
987 * Return the next in a sequence, save the value for retrieval via insertId()
989 * @param string $seqName
992 function nextSequenceValue( $seqName ) {
993 $safeseq = str_replace( "'", "''", $seqName );
994 $res = $this->query( "SELECT nextval('$safeseq')" );
995 $row = $this->fetchRow( $res );
996 $this->mInsertId = $row[0];
998 return $this->mInsertId;
1002 * Return the current value of a sequence. Assumes it has been nextval'ed in this session.
1004 * @param string $seqName
1007 function currentSequenceValue( $seqName ) {
1008 $safeseq = str_replace( "'", "''", $seqName );
1009 $res = $this->query( "SELECT currval('$safeseq')" );
1010 $row = $this->fetchRow( $res );
1016 # Returns the size of a text field, or -1 for "unlimited"
1017 function textFieldSize( $table, $field ) {
1018 $table = $this->tableName( $table );
1019 $sql = "SELECT t.typname as ftype,a.atttypmod as size
1020 FROM pg_class c, pg_attribute a, pg_type t
1021 WHERE relname='$table' AND a.attrelid=c.oid AND
1022 a.atttypid=t.oid and a.attname='$field'";
1023 $res = $this->query( $sql );
1024 $row = $this->fetchObject( $res );
1025 if ( $row->ftype == 'varchar' ) {
1026 $size = $row->size - 4;
1034 function limitResult( $sql, $limit, $offset = false ) {
1035 return "$sql LIMIT $limit " . ( is_numeric( $offset ) ? " OFFSET {$offset} " : '' );
1038 function wasDeadlock() {
1039 return $this->lastErrno() == '40P01';
1042 function duplicateTableStructure( $oldName, $newName, $temporary = false, $fname = __METHOD__ ) {
1043 $newName = $this->addIdentifierQuotes( $newName );
1044 $oldName = $this->addIdentifierQuotes( $oldName );
1046 return $this->query( 'CREATE ' . ( $temporary ? 'TEMPORARY ' : '' ) . " TABLE $newName " .
1047 "(LIKE $oldName INCLUDING DEFAULTS)", $fname );
1050 function listTables( $prefix = null, $fname = __METHOD__ ) {
1051 $eschema = $this->addQuotes( $this->getCoreSchema() );
1052 $result = $this->query( "SELECT tablename FROM pg_tables WHERE schemaname = $eschema", $fname );
1055 foreach ( $result as $table ) {
1056 $vars = get_object_vars( $table );
1057 $table = array_pop( $vars );
1058 if ( !$prefix || strpos( $table, $prefix ) === 0 ) {
1059 $endArray[] = $table;
1066 function timestamp( $ts = 0 ) {
1067 return wfTimestamp( TS_POSTGRES, $ts );
1071 * Posted by cc[plus]php[at]c2se[dot]com on 25-Mar-2009 09:12
1072 * to http://www.php.net/manual/en/ref.pgsql.php
1074 * Parsing a postgres array can be a tricky problem, he's my
1075 * take on this, it handles multi-dimensional arrays plus
1076 * escaping using a nasty regexp to determine the limits of each
1079 * This should really be handled by PHP PostgreSQL module
1082 * @param string $text Postgreql array returned in a text form like {a,b}
1083 * @param string $output
1085 * @param int $offset
1088 function pg_array_parse( $text, &$output, $limit = false, $offset = 1 ) {
1089 if ( false === $limit ) {
1090 $limit = strlen( $text ) - 1;
1093 if ( '{}' == $text ) {
1097 if ( '{' != $text[$offset] ) {
1098 preg_match( "/(\\{?\"([^\"\\\\]|\\\\.)*\"|[^,{}]+)+([,}]+)/",
1099 $text, $match, 0, $offset );
1100 $offset += strlen( $match[0] );
1101 $output[] = ( '"' != $match[1][0]
1103 : stripcslashes( substr( $match[1], 1, -1 ) ) );
1104 if ( '},' == $match[3] ) {
1108 $offset = $this->pg_array_parse( $text, $output, $limit, $offset + 1 );
1110 } while ( $limit > $offset );
1116 * Return aggregated value function call
1117 * @param array $valuedata
1118 * @param string $valuename
1121 public function aggregateValue( $valuedata, $valuename = 'value' ) {
1126 * @return string Wikitext of a link to the server software's web site
1128 public function getSoftwareLink() {
1129 return '[{{int:version-db-postgres-url}} PostgreSQL]';
1133 * Return current schema (executes SELECT current_schema())
1137 * @return string Default schema for the current session
1139 function getCurrentSchema() {
1140 $res = $this->query( "SELECT current_schema()", __METHOD__ );
1141 $row = $this->fetchRow( $res );
1147 * Return list of schemas which are accessible without schema name
1148 * This is list does not contain magic keywords like "$user"
1151 * @see getSearchPath()
1152 * @see setSearchPath()
1154 * @return array List of actual schemas for the current sesson
1156 function getSchemas() {
1157 $res = $this->query( "SELECT current_schemas(false)", __METHOD__ );
1158 $row = $this->fetchRow( $res );
1161 /* PHP pgsql support does not support array type, "{a,b}" string is returned */
1163 return $this->pg_array_parse( $row[0], $schemas );
1167 * Return search patch for schemas
1168 * This is different from getSchemas() since it contain magic keywords
1173 * @return array How to search for table names schemas for the current user
1175 function getSearchPath() {
1176 $res = $this->query( "SHOW search_path", __METHOD__ );
1177 $row = $this->fetchRow( $res );
1179 /* PostgreSQL returns SHOW values as strings */
1181 return explode( ",", $row[0] );
1185 * Update search_path, values should already be sanitized
1186 * Values may contain magic keywords like "$user"
1189 * @param array $search_path List of schemas to be searched by default
1191 function setSearchPath( $search_path ) {
1192 $this->query( "SET search_path = " . implode( ", ", $search_path ) );
1196 * Determine default schema for MediaWiki core
1197 * Adjust this session schema search path if desired schema exists
1198 * and is not alread there.
1200 * We need to have name of the core schema stored to be able
1201 * to query database metadata.
1203 * This will be also called by the installer after the schema is created
1207 * @param string $desiredSchema
1209 function determineCoreSchema( $desiredSchema ) {
1210 $this->begin( __METHOD__ );
1211 if ( $this->schemaExists( $desiredSchema ) ) {
1212 if ( in_array( $desiredSchema, $this->getSchemas() ) ) {
1213 $this->mCoreSchema = $desiredSchema;
1214 wfDebug( "Schema \"" . $desiredSchema . "\" already in the search path\n" );
1217 * Prepend our schema (e.g. 'mediawiki') in front
1218 * of the search path
1221 $search_path = $this->getSearchPath();
1222 array_unshift( $search_path,
1223 $this->addIdentifierQuotes( $desiredSchema ) );
1224 $this->setSearchPath( $search_path );
1225 $this->mCoreSchema = $desiredSchema;
1226 wfDebug( "Schema \"" . $desiredSchema . "\" added to the search path\n" );
1229 $this->mCoreSchema = $this->getCurrentSchema();
1230 wfDebug( "Schema \"" . $desiredSchema . "\" not found, using current \"" .
1231 $this->mCoreSchema . "\"\n" );
1233 /* Commit SET otherwise it will be rollbacked on error or IGNORE SELECT */
1234 $this->commit( __METHOD__ );
1238 * Return schema name fore core MediaWiki tables
1241 * @return string Core schema name
1243 function getCoreSchema() {
1244 return $this->mCoreSchema;
1248 * @return string Version information from the database
1250 function getServerVersion() {
1251 if ( !isset( $this->numericVersion ) ) {
1252 $versionInfo = pg_version( $this->mConn );
1253 if ( version_compare( $versionInfo['client'], '7.4.0', 'lt' ) ) {
1254 // Old client, abort install
1255 $this->numericVersion = '7.3 or earlier';
1256 } elseif ( isset( $versionInfo['server'] ) ) {
1258 $this->numericVersion = $versionInfo['server'];
1260 // Bug 16937: broken pgsql extension from PHP<5.3
1261 $this->numericVersion = pg_parameter_status( $this->mConn, 'server_version' );
1265 return $this->numericVersion;
1269 * Query whether a given relation exists (in the given schema, or the
1270 * default mw one if not given)
1271 * @param string $table
1272 * @param array|string $types
1273 * @param bool|string $schema
1276 function relationExists( $table, $types, $schema = false ) {
1277 if ( !is_array( $types ) ) {
1278 $types = [ $types ];
1281 $schema = $this->getCoreSchema();
1283 $table = $this->realTableName( $table, 'raw' );
1284 $etable = $this->addQuotes( $table );
1285 $eschema = $this->addQuotes( $schema );
1286 $sql = "SELECT 1 FROM pg_catalog.pg_class c, pg_catalog.pg_namespace n "
1287 . "WHERE c.relnamespace = n.oid AND c.relname = $etable AND n.nspname = $eschema "
1288 . "AND c.relkind IN ('" . implode( "','", $types ) . "')";
1289 $res = $this->query( $sql );
1290 $count = $res ? $res->numRows() : 0;
1292 return (bool)$count;
1296 * For backward compatibility, this function checks both tables and
1298 * @param string $table
1299 * @param string $fname
1300 * @param bool|string $schema
1303 function tableExists( $table, $fname = __METHOD__, $schema = false ) {
1304 return $this->relationExists( $table, [ 'r', 'v' ], $schema );
1307 function sequenceExists( $sequence, $schema = false ) {
1308 return $this->relationExists( $sequence, 'S', $schema );
1311 function triggerExists( $table, $trigger ) {
1313 SELECT 1 FROM pg_class, pg_namespace, pg_trigger
1314 WHERE relnamespace=pg_namespace.oid AND relkind='r'
1315 AND tgrelid=pg_class.oid
1316 AND nspname=%s AND relname=%s AND tgname=%s
1318 $res = $this->query(
1321 $this->addQuotes( $this->getCoreSchema() ),
1322 $this->addQuotes( $table ),
1323 $this->addQuotes( $trigger )
1329 $rows = $res->numRows();
1334 function ruleExists( $table, $rule ) {
1335 $exists = $this->selectField( 'pg_rules', 'rulename',
1337 'rulename' => $rule,
1338 'tablename' => $table,
1339 'schemaname' => $this->getCoreSchema()
1343 return $exists === $rule;
1346 function constraintExists( $table, $constraint ) {
1347 $sql = sprintf( "SELECT 1 FROM information_schema.table_constraints " .
1348 "WHERE constraint_schema = %s AND table_name = %s AND constraint_name = %s",
1349 $this->addQuotes( $this->getCoreSchema() ),
1350 $this->addQuotes( $table ),
1351 $this->addQuotes( $constraint )
1353 $res = $this->query( $sql );
1357 $rows = $res->numRows();
1363 * Query whether a given schema exists. Returns true if it does, false if it doesn't.
1364 * @param string $schema
1367 function schemaExists( $schema ) {
1368 $exists = $this->selectField( '"pg_catalog"."pg_namespace"', 1,
1369 [ 'nspname' => $schema ], __METHOD__ );
1371 return (bool)$exists;
1375 * Returns true if a given role (i.e. user) exists, false otherwise.
1376 * @param string $roleName
1379 function roleExists( $roleName ) {
1380 $exists = $this->selectField( '"pg_catalog"."pg_roles"', 1,
1381 [ 'rolname' => $roleName ], __METHOD__ );
1383 return (bool)$exists;
1387 * @var string $table
1388 * @var string $field
1389 * @return PostgresField|null
1391 function fieldInfo( $table, $field ) {
1392 return PostgresField::fromText( $this, $table, $field );
1396 * pg_field_type() wrapper
1397 * @param ResultWrapper|resource $res ResultWrapper or PostgreSQL query result resource
1398 * @param int $index Field number, starting from 0
1401 function fieldType( $res, $index ) {
1402 if ( $res instanceof ResultWrapper ) {
1403 $res = $res->result;
1406 return pg_field_type( $res, $index );
1413 function encodeBlob( $b ) {
1414 return new PostgresBlob( pg_escape_bytea( $b ) );
1417 function decodeBlob( $b ) {
1418 if ( $b instanceof PostgresBlob ) {
1420 } elseif ( $b instanceof Blob ) {
1424 return pg_unescape_bytea( $b );
1427 function strencode( $s ) {
1428 // Should not be called by us
1430 return pg_escape_string( $this->mConn, $s );
1434 * @param null|bool|Blob $s
1435 * @return int|string
1437 function addQuotes( $s ) {
1438 if ( is_null( $s ) ) {
1440 } elseif ( is_bool( $s ) ) {
1441 return intval( $s );
1442 } elseif ( $s instanceof Blob ) {
1443 if ( $s instanceof PostgresBlob ) {
1446 $s = pg_escape_bytea( $this->mConn, $s->fetch() );
1451 return "'" . pg_escape_string( $this->mConn, $s ) . "'";
1455 * Postgres specific version of replaceVars.
1456 * Calls the parent version in Database.php
1458 * @param string $ins SQL string, read from a stream (usually tables.sql)
1459 * @return string SQL string
1461 protected function replaceVars( $ins ) {
1462 $ins = parent::replaceVars( $ins );
1464 if ( $this->numericVersion >= 8.3 ) {
1465 // Thanks for not providing backwards-compatibility, 8.3
1466 $ins = preg_replace( "/to_tsvector\s*\(\s*'default'\s*,/", 'to_tsvector(', $ins );
1469 if ( $this->numericVersion <= 8.1 ) { // Our minimum version
1470 $ins = str_replace( 'USING gin', 'USING gist', $ins );
1477 * Various select options
1479 * @param array $options An associative array of options to be turned into
1480 * an SQL query, valid keys are listed in the function.
1483 function makeSelectOptions( $options ) {
1484 $preLimitTail = $postLimitTail = '';
1485 $startOpts = $useIndex = '';
1488 foreach ( $options as $key => $option ) {
1489 if ( is_numeric( $key ) ) {
1490 $noKeyOptions[$option] = true;
1494 $preLimitTail .= $this->makeGroupByWithHaving( $options );
1496 $preLimitTail .= $this->makeOrderBy( $options );
1498 // if ( isset( $options['LIMIT'] ) ) {
1499 // $tailOpts .= $this->limitResult( '', $options['LIMIT'],
1500 // isset( $options['OFFSET'] ) ? $options['OFFSET']
1504 if ( isset( $options['FOR UPDATE'] ) ) {
1505 $postLimitTail .= ' FOR UPDATE OF ' .
1506 implode( ', ', array_map( [ &$this, 'tableName' ], $options['FOR UPDATE'] ) );
1507 } elseif ( isset( $noKeyOptions['FOR UPDATE'] ) ) {
1508 $postLimitTail .= ' FOR UPDATE';
1511 if ( isset( $noKeyOptions['DISTINCT'] ) || isset( $noKeyOptions['DISTINCTROW'] ) ) {
1512 $startOpts .= 'DISTINCT';
1515 return [ $startOpts, $useIndex, $preLimitTail, $postLimitTail ];
1518 function getDBname() {
1519 return $this->mDBname;
1522 function getServer() {
1523 return $this->mServer;
1526 function buildConcat( $stringList ) {
1527 return implode( ' || ', $stringList );
1530 public function buildGroupConcatField(
1531 $delimiter, $table, $field, $conds = '', $options = [], $join_conds = []
1533 $fld = "array_to_string(array_agg($field)," . $this->addQuotes( $delimiter ) . ')';
1535 return '(' . $this->selectSQLText( $table, $fld, $conds, null, [], $join_conds ) . ')';
1538 public function getSearchEngine() {
1539 return 'SearchPostgres';
1542 public function streamStatementEnd( &$sql, &$newLine ) {
1543 # Allow dollar quoting for function declarations
1544 if ( substr( $newLine, 0, 4 ) == '$mw$' ) {
1545 if ( $this->delimiter ) {
1546 $this->delimiter = false;
1548 $this->delimiter = ';';
1552 return parent::streamStatementEnd( $sql, $newLine );
1556 * Check to see if a named lock is available. This is non-blocking.
1557 * See http://www.postgresql.org/docs/8.2/static/functions-admin.html#FUNCTIONS-ADVISORY-LOCKS
1559 * @param string $lockName Name of lock to poll
1560 * @param string $method Name of method calling us
1564 public function lockIsFree( $lockName, $method ) {
1565 $key = $this->addQuotes( $this->bigintFromLockName( $lockName ) );
1566 $result = $this->query( "SELECT (CASE(pg_try_advisory_lock($key))
1567 WHEN 'f' THEN 'f' ELSE pg_advisory_unlock($key) END) AS lockstatus", $method );
1568 $row = $this->fetchObject( $result );
1570 return ( $row->lockstatus === 't' );
1574 * See http://www.postgresql.org/docs/8.2/static/functions-admin.html#FUNCTIONS-ADVISORY-LOCKS
1575 * @param string $lockName
1576 * @param string $method
1577 * @param int $timeout
1580 public function lock( $lockName, $method, $timeout = 5 ) {
1581 $key = $this->addQuotes( $this->bigintFromLockName( $lockName ) );
1582 for ( $attempts = 1; $attempts <= $timeout; ++$attempts ) {
1583 $result = $this->query(
1584 "SELECT pg_try_advisory_lock($key) AS lockstatus", $method );
1585 $row = $this->fetchObject( $result );
1586 if ( $row->lockstatus === 't' ) {
1587 parent::lock( $lockName, $method, $timeout ); // record
1594 wfDebug( __METHOD__ . " failed to acquire lock\n" );
1600 * See http://www.postgresql.org/docs/8.2/static/functions-admin.html#FUNCTIONS-ADVISORY-LOCKSFROM
1601 * PG DOCS: http://www.postgresql.org/docs/8.2/static/functions-admin.html#FUNCTIONS-ADVISORY-LOCKS
1602 * @param string $lockName
1603 * @param string $method
1606 public function unlock( $lockName, $method ) {
1607 $key = $this->addQuotes( $this->bigintFromLockName( $lockName ) );
1608 $result = $this->query( "SELECT pg_advisory_unlock($key) as lockstatus", $method );
1609 $row = $this->fetchObject( $result );
1611 if ( $row->lockstatus === 't' ) {
1612 parent::unlock( $lockName, $method ); // record
1616 wfDebug( __METHOD__ . " failed to release lock\n" );
1622 * @param string $lockName
1623 * @return string Integer
1625 private function bigintFromLockName( $lockName ) {
1626 return Wikimedia\base_convert( substr( sha1( $lockName ), 0, 15 ), 16, 10 );
1628 } // end DatabasePostgres class
1630 class PostgresBlob extends Blob {