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
23 use Wikimedia\WaitConditionLoop
;
24 use Wikimedia\Rdbms\Blob
;
25 use Wikimedia\Rdbms\PostgresBlob
;
26 use Wikimedia\Rdbms\PostgresField
;
31 class DatabasePostgres
extends Database
{
36 protected $mLastResult = null;
37 /** @var int The number of rows affected as an integer */
38 protected $mAffectedRows = null;
41 private $mInsertId = null;
42 /** @var float|string */
43 private $numericVersion = null;
44 /** @var string Connect string to open a PostgreSQL connection */
45 private $connectString;
48 /** @var string[] Map of (reserved table name => alternate table name) */
49 private $keywordTableMap = [];
52 * @see Database::__construct()
53 * @param array $params Additional parameters include:
54 * - keywordTableMap : Map of reserved table names to alternative table names to use
56 public function __construct( array $params ) {
57 $this->port
= isset( $params['port'] ) ?
$params['port'] : false;
58 $this->keywordTableMap
= isset( $params['keywordTableMap'] )
59 ?
$params['keywordTableMap']
62 parent
::__construct( $params );
65 public function getType() {
69 public function implicitGroupby() {
73 public function implicitOrderby() {
77 public function hasConstraint( $name ) {
78 $conn = $this->getBindingHandle();
80 $sql = "SELECT 1 FROM pg_catalog.pg_constraint c, pg_catalog.pg_namespace n " .
81 "WHERE c.connamespace = n.oid AND conname = '" .
82 pg_escape_string( $conn, $name ) . "' AND n.nspname = '" .
83 pg_escape_string( $conn, $this->getCoreSchema() ) . "'";
84 $res = $this->doQuery( $sql );
86 return $this->numRows( $res );
89 public function open( $server, $user, $password, $dbName ) {
90 # Test for Postgres support, to avoid suppressed fatal error
91 if ( !function_exists( 'pg_connect' ) ) {
92 throw new DBConnectionError(
94 "Postgres functions missing, have you compiled PHP with the --with-pgsql\n" .
95 "option? (Note: if you recently installed PHP, you may need to restart your\n" .
96 "webserver and database)\n"
100 $this->mServer
= $server;
101 $this->mUser
= $user;
102 $this->mPassword
= $password;
103 $this->mDBname
= $dbName;
108 'password' => $password
110 if ( $server != false && $server != '' ) {
111 $connectVars['host'] = $server;
113 if ( (int)$this->port
> 0 ) {
114 $connectVars['port'] = (int)$this->port
;
116 if ( $this->mFlags
& self
::DBO_SSL
) {
117 $connectVars['sslmode'] = 1;
120 $this->connectString
= $this->makeConnectionString( $connectVars );
122 $this->installErrorHandler();
125 // Use new connections to let LoadBalancer/LBFactory handle reuse
126 $this->mConn
= pg_connect( $this->connectString
, PGSQL_CONNECT_FORCE_NEW
);
127 } catch ( Exception
$ex ) {
128 $this->restoreErrorHandler();
132 $phpError = $this->restoreErrorHandler();
134 if ( !$this->mConn
) {
135 $this->queryLogger
->debug(
136 "DB connection error\n" .
137 "Server: $server, Database: $dbName, User: $user, Password: " .
138 substr( $password, 0, 3 ) . "...\n"
140 $this->queryLogger
->debug( $this->lastError() . "\n" );
141 throw new DBConnectionError( $this, str_replace( "\n", ' ', $phpError ) );
144 $this->mOpened
= true;
146 # If called from the command-line (e.g. importDump), only show errors
147 if ( $this->cliMode
) {
148 $this->doQuery( "SET client_min_messages = 'ERROR'" );
151 $this->query( "SET client_encoding='UTF8'", __METHOD__
);
152 $this->query( "SET datestyle = 'ISO, YMD'", __METHOD__
);
153 $this->query( "SET timezone = 'GMT'", __METHOD__
);
154 $this->query( "SET standard_conforming_strings = on", __METHOD__
);
155 if ( $this->getServerVersion() >= 9.0 ) {
156 $this->query( "SET bytea_output = 'escape'", __METHOD__
); // PHP bug 53127
159 $this->determineCoreSchema( $this->mSchema
);
160 // The schema to be used is now in the search path; no need for explicit qualification
167 * Postgres doesn't support selectDB in the same way MySQL does. So if the
168 * DB name doesn't match the open connection, open a new one
172 public function selectDB( $db ) {
173 if ( $this->mDBname
!== $db ) {
174 return (bool)$this->open( $this->mServer
, $this->mUser
, $this->mPassword
, $db );
181 * @param string[] $vars
184 private function makeConnectionString( $vars ) {
186 foreach ( $vars as $name => $value ) {
187 $s .= "$name='" . str_replace( "'", "\\'", $value ) . "' ";
193 protected function closeConnection() {
194 return $this->mConn ?
pg_close( $this->mConn
) : true;
197 public function doQuery( $sql ) {
198 $conn = $this->getBindingHandle();
200 $sql = mb_convert_encoding( $sql, 'UTF-8' );
201 // Clear previously left over PQresult
202 while ( $res = pg_get_result( $conn ) ) {
203 pg_free_result( $res );
205 if ( pg_send_query( $conn, $sql ) === false ) {
206 throw new DBUnexpectedError( $this, "Unable to post new query to PostgreSQL\n" );
208 $this->mLastResult
= pg_get_result( $conn );
209 $this->mAffectedRows
= null;
210 if ( pg_result_error( $this->mLastResult
) ) {
214 return $this->mLastResult
;
217 protected function dumpError() {
221 PGSQL_DIAG_MESSAGE_PRIMARY
,
222 PGSQL_DIAG_MESSAGE_DETAIL
,
223 PGSQL_DIAG_MESSAGE_HINT
,
224 PGSQL_DIAG_STATEMENT_POSITION
,
225 PGSQL_DIAG_INTERNAL_POSITION
,
226 PGSQL_DIAG_INTERNAL_QUERY
,
228 PGSQL_DIAG_SOURCE_FILE
,
229 PGSQL_DIAG_SOURCE_LINE
,
230 PGSQL_DIAG_SOURCE_FUNCTION
232 foreach ( $diags as $d ) {
233 $this->queryLogger
->debug( sprintf( "PgSQL ERROR(%d): %s\n",
234 $d, pg_result_error_field( $this->mLastResult
, $d ) ) );
238 public function reportQueryError( $error, $errno, $sql, $fname, $tempIgnore = false ) {
240 /* Check for constraint violation */
241 if ( $errno === '23505' ) {
242 parent
::reportQueryError( $error, $errno, $sql, $fname, $tempIgnore );
247 /* Transaction stays in the ERROR state until rolled back */
248 if ( $this->mTrxLevel
) {
249 $this->rollback( __METHOD__
);
251 parent
::reportQueryError( $error, $errno, $sql, $fname, false );
254 public function freeResult( $res ) {
255 if ( $res instanceof ResultWrapper
) {
258 MediaWiki\
suppressWarnings();
259 $ok = pg_free_result( $res );
260 MediaWiki\restoreWarnings
();
262 throw new DBUnexpectedError( $this, "Unable to free Postgres result\n" );
266 public function fetchObject( $res ) {
267 if ( $res instanceof ResultWrapper
) {
270 MediaWiki\
suppressWarnings();
271 $row = pg_fetch_object( $res );
272 MediaWiki\restoreWarnings
();
273 # @todo FIXME: HACK HACK HACK HACK debug
275 # @todo hashar: not sure if the following test really trigger if the object
277 $conn = $this->getBindingHandle();
278 if ( pg_last_error( $conn ) ) {
279 throw new DBUnexpectedError(
281 'SQL error: ' . htmlspecialchars( pg_last_error( $conn ) )
288 public function fetchRow( $res ) {
289 if ( $res instanceof ResultWrapper
) {
292 MediaWiki\
suppressWarnings();
293 $row = pg_fetch_array( $res );
294 MediaWiki\restoreWarnings
();
296 $conn = $this->getBindingHandle();
297 if ( pg_last_error( $conn ) ) {
298 throw new DBUnexpectedError(
300 'SQL error: ' . htmlspecialchars( pg_last_error( $conn ) )
307 public function numRows( $res ) {
308 if ( $res instanceof ResultWrapper
) {
311 MediaWiki\
suppressWarnings();
312 $n = pg_num_rows( $res );
313 MediaWiki\restoreWarnings
();
315 $conn = $this->getBindingHandle();
316 if ( pg_last_error( $conn ) ) {
317 throw new DBUnexpectedError(
319 'SQL error: ' . htmlspecialchars( pg_last_error( $conn ) )
326 public function numFields( $res ) {
327 if ( $res instanceof ResultWrapper
) {
331 return pg_num_fields( $res );
334 public function fieldName( $res, $n ) {
335 if ( $res instanceof ResultWrapper
) {
339 return pg_field_name( $res, $n );
343 * Return the result of the last call to nextSequenceValue();
344 * This must be called after nextSequenceValue().
348 public function insertId() {
349 return $this->mInsertId
;
352 public function dataSeek( $res, $row ) {
353 if ( $res instanceof ResultWrapper
) {
357 return pg_result_seek( $res, $row );
360 public function lastError() {
361 if ( $this->mConn
) {
362 if ( $this->mLastResult
) {
363 return pg_result_error( $this->mLastResult
);
365 return pg_last_error();
369 return $this->getLastPHPError() ?
: 'No database connection';
372 public function lastErrno() {
373 if ( $this->mLastResult
) {
374 return pg_result_error_field( $this->mLastResult
, PGSQL_DIAG_SQLSTATE
);
380 public function affectedRows() {
381 if ( !is_null( $this->mAffectedRows
) ) {
382 // Forced result for simulated queries
383 return $this->mAffectedRows
;
385 if ( empty( $this->mLastResult
) ) {
389 return pg_affected_rows( $this->mLastResult
);
393 * Estimate rows in dataset
394 * Returns estimated count, based on EXPLAIN output
395 * This is not necessarily an accurate estimate, so use sparingly
396 * Returns -1 if count cannot be found
397 * Takes same arguments as Database::select()
399 * @param string $table
400 * @param string $vars
401 * @param string $conds
402 * @param string $fname
403 * @param array $options
406 public function estimateRowCount( $table, $vars = '*', $conds = '',
407 $fname = __METHOD__
, $options = []
409 $options['EXPLAIN'] = true;
410 $res = $this->select( $table, $vars, $conds, $fname, $options );
413 $row = $this->fetchRow( $res );
415 if ( preg_match( '/rows=(\d+)/', $row[0], $count ) ) {
416 $rows = (int)$count[1];
423 public function indexInfo( $table, $index, $fname = __METHOD__
) {
424 $sql = "SELECT indexname FROM pg_indexes WHERE tablename='$table'";
425 $res = $this->query( $sql, $fname );
429 foreach ( $res as $row ) {
430 if ( $row->indexname
== $this->indexName( $index ) ) {
438 public function indexAttributes( $index, $schema = false ) {
439 if ( $schema === false ) {
440 $schema = $this->getCoreSchema();
443 * A subquery would be not needed if we didn't care about the order
444 * of attributes, but we do
446 $sql = <<<__INDEXATTR__
450 i.indoption[s.g] as option,
453 (SELECT generate_series(array_lower(isub.indkey,1), array_upper(isub.indkey,1)) AS g
457 ON cis.oid=isub.indexrelid
459 ON cis.relnamespace = ns.oid
460 WHERE cis.relname='$index' AND ns.nspname='$schema') AS s,
466 ON ci.oid=i.indexrelid
468 ON ct.oid = i.indrelid
470 ON ci.relnamespace = n.oid
472 ci.relname='$index' AND n.nspname='$schema'
473 AND attrelid = ct.oid
474 AND i.indkey[s.g] = attnum
475 AND i.indclass[s.g] = opcls.oid
476 AND pg_am.oid = opcls.opcmethod
478 $res = $this->query( $sql, __METHOD__ );
481 foreach ( $res as $row ) {
495 public function indexUnique( $table, $index, $fname = __METHOD__ ) {
496 $sql = "SELECT indexname FROM pg_indexes WHERE tablename='{$table}'" .
497 " AND indexdef LIKE 'CREATE UNIQUE%(" .
498 $this->strencode( $this->indexName( $index ) ) .
500 $res = $this->query( $sql, $fname );
505 return $res->numRows() > 0;
508 public function selectSQLText(
509 $table, $vars, $conds = '', $fname = __METHOD__, $options = [], $join_conds = []
511 // Change the FOR UPDATE option as necessary based on the join conditions. Then pass
512 // to the parent function to get the actual SQL text.
513 // In Postgres when using FOR UPDATE, only the main table and tables that are inner joined
514 // can be locked. That means tables in an outer join cannot be FOR UPDATE locked. Trying to
515 // do so causes a DB error. This wrapper checks which tables can be locked and adjusts it
517 // MySQL uses "ORDER BY NULL" as an optimization hint, but that is illegal in PostgreSQL.
518 if ( is_array( $options ) ) {
519 $forUpdateKey = array_search( 'FOR UPDATE', $options, true );
520 if ( $forUpdateKey !== false && $join_conds ) {
521 unset( $options[$forUpdateKey] );
523 foreach ( $join_conds as $table_cond => $join_cond ) {
524 if ( 0 === preg_match( '/^(?:LEFT|RIGHT|FULL)(?: OUTER)? JOIN$/i', $join_cond[0] ) ) {
525 $options['FOR UPDATE'][] = $table_cond;
530 if ( isset( $options['ORDER BY'] ) && $options['ORDER BY'] == 'NULL' ) {
531 unset( $options['ORDER BY'] );
535 return parent::selectSQLText( $table, $vars, $conds, $fname, $options, $join_conds );
539 * INSERT wrapper, inserts an array into a table
541 * $args may be a single associative array, or an array of these with numeric keys,
542 * for multi-row insert (Postgres version 8.2 and above only).
544 * @param string $table Name of the table to insert to.
545 * @param array $args Items to insert into the table.
546 * @param string $fname Name of the function, for profiling
547 * @param array|string $options String or array. Valid options: IGNORE
548 * @return bool Success of insert operation. IGNORE always returns true.
550 public function insert( $table, $args, $fname = __METHOD__, $options = [] ) {
551 if ( !count( $args ) ) {
555 $table = $this->tableName( $table );
556 if ( !isset( $this->numericVersion ) ) {
557 $this->getServerVersion();
560 if ( !is_array( $options ) ) {
561 $options = [ $options ];
564 if ( isset( $args[0] ) && is_array( $args[0] ) ) {
566 $keys = array_keys( $args[0] );
569 $keys = array_keys( $args );
572 // If IGNORE is set, we use savepoints to emulate mysql's behavior
573 $savepoint = $olde = null;
574 $numrowsinserted = 0;
575 if ( in_array( 'IGNORE', $options ) ) {
576 $savepoint = new SavepointPostgres( $this, 'mw', $this->queryLogger );
577 $olde = error_reporting( 0 );
578 // For future use, we may want to track the number of actual inserts
579 // Right now, insert (all writes) simply return true/false
582 $sql = "INSERT INTO $table (" . implode( ',', $keys ) . ') VALUES ';
585 if ( $this->numericVersion >= 8.2 && !$savepoint ) {
587 foreach ( $args as $row ) {
593 $sql .= '(' . $this->makeList( $row ) . ')';
595 $res = (bool)$this->query( $sql, $fname, $savepoint );
599 foreach ( $args as $row ) {
601 $tempsql .= '(' . $this->makeList( $row ) . ')';
604 $savepoint->savepoint();
607 $tempres = (bool)$this->query( $tempsql, $fname, $savepoint );
610 $bar = pg_result_error( $this->mLastResult );
611 if ( $bar != false ) {
612 $savepoint->rollback();
614 $savepoint->release();
619 // If any of them fail, we fail overall for this function call
620 // Note that this will be ignored if IGNORE is set
627 // Not multi, just a lone insert
629 $savepoint->savepoint();
632 $sql .= '(' . $this->makeList( $args ) . ')';
633 $res = (bool)$this->query( $sql, $fname, $savepoint );
635 $bar = pg_result_error( $this->mLastResult );
636 if ( $bar != false ) {
637 $savepoint->rollback();
639 $savepoint->release();
645 error_reporting( $olde );
646 $savepoint->commit();
648 // Set the affected row count for the whole operation
649 $this->mAffectedRows = $numrowsinserted;
651 // IGNORE always returns true
659 * INSERT SELECT wrapper
660 * $varMap must be an associative array of the form [ 'dest1' => 'source1', ... ]
661 * Source items may be literals rather then field names, but strings should
662 * be quoted with Database::addQuotes()
663 * $conds may be "*" to copy the whole table
664 * srcTable may be an array of tables.
665 * @todo FIXME: Implement this a little better (seperate select/insert)?
667 * @param string $destTable
668 * @param array|string $srcTable
669 * @param array $varMap
670 * @param array $conds
671 * @param string $fname
672 * @param array $insertOptions
673 * @param array $selectOptions
676 public function nativeInsertSelect(
677 $destTable, $srcTable, $varMap, $conds, $fname = __METHOD__,
678 $insertOptions = [], $selectOptions = []
680 $destTable = $this->tableName( $destTable );
682 if ( !is_array( $insertOptions ) ) {
683 $insertOptions = [ $insertOptions ];
687 * If IGNORE is set, we use savepoints to emulate mysql's behavior
688 * Ignore LOW PRIORITY option, since it is MySQL-specific
690 $savepoint = $olde = null;
691 $numrowsinserted = 0;
692 if ( in_array( 'IGNORE', $insertOptions ) ) {
693 $savepoint = new SavepointPostgres( $this, 'mw', $this->queryLogger );
694 $olde = error_reporting( 0 );
695 $savepoint->savepoint();
698 if ( !is_array( $selectOptions ) ) {
699 $selectOptions = [ $selectOptions ];
701 list( $startOpts, $useIndex, $tailOpts, $ignoreIndex ) =
702 $this->makeSelectOptions( $selectOptions );
703 if ( is_array( $srcTable ) ) {
704 $srcTable = implode( ',', array_map( [ $this, 'tableName' ], $srcTable ) );
706 $srcTable = $this->tableName( $srcTable );
709 $sql = "INSERT INTO $destTable (" . implode( ',', array_keys( $varMap ) ) . ')' .
710 " SELECT $startOpts " . implode( ',', $varMap ) .
711 " FROM $srcTable $useIndex $ignoreIndex ";
713 if ( $conds != '*' ) {
714 $sql .= ' WHERE ' . $this->makeList( $conds, LIST_AND );
717 $sql .= " $tailOpts";
719 $res = (bool)$this->query( $sql, $fname, $savepoint );
721 $bar = pg_result_error( $this->mLastResult );
722 if ( $bar != false ) {
723 $savepoint->rollback();
725 $savepoint->release();
728 error_reporting( $olde );
729 $savepoint->commit();
731 // Set the affected row count for the whole operation
732 $this->mAffectedRows = $numrowsinserted;
734 // IGNORE always returns true
741 public function tableName( $name, $format = 'quoted' ) {
742 // Replace reserved words with better ones
743 $name = $this->remappedTableName( $name );
745 return parent::tableName( $name, $format );
749 * @param string $name
750 * @return string Value of $name or remapped name if $name is a reserved keyword
752 public function remappedTableName( $name ) {
753 return isset( $this->keywordTableMap[$name] ) ? $this->keywordTableMap[$name] : $name;
757 * @param string $name
758 * @param string $format
759 * @return string Qualified and encoded (if requested) table name
761 public function realTableName( $name, $format = 'quoted' ) {
762 return parent::tableName( $name, $format );
765 public function nextSequenceValue( $seqName ) {
766 $safeseq = str_replace( "'", "''", $seqName );
767 $res = $this->query( "SELECT nextval('$safeseq')" );
768 $row = $this->fetchRow( $res );
769 $this->mInsertId = $row[0];
771 return $this->mInsertId;
775 * Return the current value of a sequence. Assumes it has been nextval'ed in this session.
777 * @param string $seqName
780 public function currentSequenceValue( $seqName ) {
781 $safeseq = str_replace( "'", "''", $seqName );
782 $res = $this->query( "SELECT currval('$safeseq')" );
783 $row = $this->fetchRow( $res );
789 public function textFieldSize( $table, $field ) {
790 $table = $this->tableName( $table );
791 $sql = "SELECT t.typname as ftype,a.atttypmod as size
792 FROM pg_class c, pg_attribute a, pg_type t
793 WHERE relname='$table' AND a.attrelid=c.oid AND
794 a.atttypid=t.oid and a.attname='$field'";
795 $res = $this->query( $sql );
796 $row = $this->fetchObject( $res );
797 if ( $row->ftype == 'varchar' ) {
798 $size = $row->size - 4;
806 public function limitResult( $sql, $limit, $offset = false ) {
807 return "$sql LIMIT $limit " . ( is_numeric( $offset ) ? " OFFSET {$offset} " : '' );
810 public function wasDeadlock() {
811 return $this->lastErrno() == '40P01';
814 public function duplicateTableStructure(
815 $oldName, $newName, $temporary = false, $fname = __METHOD__
817 $newName = $this->addIdentifierQuotes( $newName );
818 $oldName = $this->addIdentifierQuotes( $oldName );
820 return $this->query( 'CREATE ' . ( $temporary ? 'TEMPORARY ' : '' ) . " TABLE $newName " .
821 "(LIKE $oldName INCLUDING DEFAULTS)", $fname );
824 public function listTables( $prefix = null, $fname = __METHOD__ ) {
825 $eschema = $this->addQuotes( $this->getCoreSchema() );
826 $result = $this->query(
827 "SELECT tablename FROM pg_tables WHERE schemaname = $eschema", $fname );
830 foreach ( $result as $table ) {
831 $vars = get_object_vars( $table );
832 $table = array_pop( $vars );
833 if ( !$prefix || strpos( $table, $prefix ) === 0 ) {
834 $endArray[] = $table;
841 public function timestamp( $ts = 0 ) {
842 $ct = new ConvertibleTimestamp( $ts );
844 return $ct->getTimestamp( TS_POSTGRES );
848 * Posted by cc[plus]php[at]c2se[dot]com on 25-Mar-2009 09:12
849 * to https://secure.php.net/manual/en/ref.pgsql.php
851 * Parsing a postgres array can be a tricky problem, he's my
852 * take on this, it handles multi-dimensional arrays plus
853 * escaping using a nasty regexp to determine the limits of each
856 * This should really be handled by PHP PostgreSQL module
859 * @param string $text Postgreql array returned in a text form like {a,b}
860 * @param string $output
861 * @param int|bool $limit
865 private function pg_array_parse( $text, &$output, $limit = false, $offset = 1 ) {
866 if ( false === $limit ) {
867 $limit = strlen( $text ) - 1;
870 if ( '{}' == $text ) {
874 if ( '{' != $text[$offset] ) {
875 preg_match( "/(\\{?\"([^\"\\\\]|\\\\.)*\"|[^,{}]+)+([,}]+)/",
876 $text, $match, 0, $offset );
877 $offset += strlen( $match[0] );
878 $output[] = ( '"' != $match[1][0]
880 : stripcslashes( substr( $match[1], 1, -1 ) ) );
881 if ( '},' == $match[3] ) {
885 $offset = $this->pg_array_parse( $text, $output, $limit, $offset + 1 );
887 } while ( $limit > $offset );
892 public function aggregateValue( $valuedata, $valuename = 'value' ) {
896 public function getSoftwareLink() {
897 return '[{{int:version-db-postgres-url}} PostgreSQL]';
901 * Return current schema (executes SELECT current_schema())
905 * @return string Default schema for the current session
907 public function getCurrentSchema() {
908 $res = $this->query( "SELECT current_schema()", __METHOD__ );
909 $row = $this->fetchRow( $res );
915 * Return list of schemas which are accessible without schema name
916 * This is list does not contain magic keywords like "$user"
919 * @see getSearchPath()
920 * @see setSearchPath()
922 * @return array List of actual schemas for the current sesson
924 public function getSchemas() {
925 $res = $this->query( "SELECT current_schemas(false)", __METHOD__ );
926 $row = $this->fetchRow( $res );
929 /* PHP pgsql support does not support array type, "{a,b}" string is returned */
931 return $this->pg_array_parse( $row[0], $schemas );
935 * Return search patch for schemas
936 * This is different from getSchemas() since it contain magic keywords
941 * @return array How to search for table names schemas for the current user
943 public function getSearchPath() {
944 $res = $this->query( "SHOW search_path", __METHOD__ );
945 $row = $this->fetchRow( $res );
947 /* PostgreSQL returns SHOW values as strings */
949 return explode( ",", $row[0] );
953 * Update search_path, values should already be sanitized
954 * Values may contain magic keywords like "$user"
957 * @param array $search_path List of schemas to be searched by default
959 private function setSearchPath( $search_path ) {
960 $this->query( "SET search_path = " . implode( ", ", $search_path ) );
964 * Determine default schema for the current application
965 * Adjust this session schema search path if desired schema exists
966 * and is not alread there.
968 * We need to have name of the core schema stored to be able
969 * to query database metadata.
971 * This will be also called by the installer after the schema is created
975 * @param string $desiredSchema
977 public function determineCoreSchema( $desiredSchema ) {
978 $this->begin( __METHOD__, self::TRANSACTION_INTERNAL );
979 if ( $this->schemaExists( $desiredSchema ) ) {
980 if ( in_array( $desiredSchema, $this->getSchemas() ) ) {
981 $this->mCoreSchema = $desiredSchema;
982 $this->queryLogger->debug(
983 "Schema \"" . $desiredSchema . "\" already in the search path\n" );
986 * Prepend our schema (e.g. 'mediawiki') in front
990 $search_path = $this->getSearchPath();
991 array_unshift( $search_path,
992 $this->addIdentifierQuotes( $desiredSchema ) );
993 $this->setSearchPath( $search_path );
994 $this->mCoreSchema = $desiredSchema;
995 $this->queryLogger->debug(
996 "Schema \"" . $desiredSchema . "\" added to the search path\n" );
999 $this->mCoreSchema = $this->getCurrentSchema();
1000 $this->queryLogger->debug(
1001 "Schema \"" . $desiredSchema . "\" not found, using current \"" .
1002 $this->mCoreSchema . "\"\n" );
1004 /* Commit SET otherwise it will be rollbacked on error or IGNORE SELECT */
1005 $this->commit( __METHOD__, self::FLUSHING_INTERNAL );
1009 * Return schema name for core application tables
1012 * @return string Core schema name
1014 public function getCoreSchema() {
1015 return $this->mCoreSchema;
1018 public function getServerVersion() {
1019 if ( !isset( $this->numericVersion ) ) {
1020 $conn = $this->getBindingHandle();
1021 $versionInfo = pg_version( $conn );
1022 if ( version_compare( $versionInfo['client'], '7.4.0', 'lt' ) ) {
1023 // Old client, abort install
1024 $this->numericVersion = '7.3 or earlier';
1025 } elseif ( isset( $versionInfo['server'] ) ) {
1027 $this->numericVersion = $versionInfo['server'];
1029 // Bug 16937: broken pgsql extension from PHP<5.3
1030 $this->numericVersion = pg_parameter_status( $conn, 'server_version' );
1034 return $this->numericVersion;
1038 * Query whether a given relation exists (in the given schema, or the
1039 * default mw one if not given)
1040 * @param string $table
1041 * @param array|string $types
1042 * @param bool|string $schema
1045 private function relationExists( $table, $types, $schema = false ) {
1046 if ( !is_array( $types ) ) {
1047 $types = [ $types ];
1049 if ( $schema === false ) {
1050 $schema = $this->getCoreSchema();
1052 $etable = $this->addQuotes( $table );
1053 $eschema = $this->addQuotes( $schema );
1054 $sql = "SELECT 1 FROM pg_catalog.pg_class c, pg_catalog.pg_namespace n "
1055 . "WHERE c.relnamespace = n.oid AND c.relname = $etable AND n.nspname = $eschema "
1056 . "AND c.relkind IN ('" . implode( "','", $types ) . "')";
1057 $res = $this->query( $sql );
1058 $count = $res ? $res->numRows() : 0;
1060 return (bool)$count;
1064 * For backward compatibility, this function checks both tables and views.
1065 * @param string $table
1066 * @param string $fname
1067 * @param bool|string $schema
1070 public function tableExists( $table, $fname = __METHOD__, $schema = false ) {
1071 return $this->relationExists( $table, [ 'r', 'v' ], $schema );
1074 public function sequenceExists( $sequence, $schema = false ) {
1075 return $this->relationExists( $sequence, 'S', $schema );
1078 public function triggerExists( $table, $trigger ) {
1080 SELECT 1 FROM pg_class, pg_namespace, pg_trigger
1081 WHERE relnamespace=pg_namespace.oid AND relkind='r'
1082 AND tgrelid=pg_class.oid
1083 AND nspname=%s AND relname=%s AND tgname=%s
1085 $res = $this->query(
1088 $this->addQuotes( $this->getCoreSchema() ),
1089 $this->addQuotes( $table ),
1090 $this->addQuotes( $trigger )
1096 $rows = $res->numRows();
1101 public function ruleExists( $table, $rule ) {
1102 $exists = $this->selectField( 'pg_rules', 'rulename',
1104 'rulename' => $rule,
1105 'tablename' => $table,
1106 'schemaname' => $this->getCoreSchema()
1110 return $exists === $rule;
1113 public function constraintExists( $table, $constraint ) {
1114 $sql = sprintf( "SELECT 1 FROM information_schema.table_constraints " .
1115 "WHERE constraint_schema = %s AND table_name = %s AND constraint_name = %s",
1116 $this->addQuotes( $this->getCoreSchema() ),
1117 $this->addQuotes( $table ),
1118 $this->addQuotes( $constraint )
1120 $res = $this->query( $sql );
1124 $rows = $res->numRows();
1130 * Query whether a given schema exists. Returns true if it does, false if it doesn't.
1131 * @param string $schema
1134 public function schemaExists( $schema ) {
1135 if ( !strlen( $schema ) ) {
1136 return false; // short-circuit
1139 $exists = $this->selectField(
1140 '"pg_catalog"."pg_namespace"', 1, [ 'nspname' => $schema ], __METHOD__ );
1142 return (bool)$exists;
1146 * Returns true if a given role (i.e. user) exists, false otherwise.
1147 * @param string $roleName
1150 public function roleExists( $roleName ) {
1151 $exists = $this->selectField( '"pg_catalog"."pg_roles"', 1,
1152 [ 'rolname' => $roleName ], __METHOD__ );
1154 return (bool)$exists;
1158 * @var string $table
1159 * @var string $field
1160 * @return PostgresField|null
1162 public function fieldInfo( $table, $field ) {
1163 return PostgresField::fromText( $this, $table, $field );
1167 * pg_field_type() wrapper
1168 * @param ResultWrapper|resource $res ResultWrapper or PostgreSQL query result resource
1169 * @param int $index Field number, starting from 0
1172 public function fieldType( $res, $index ) {
1173 if ( $res instanceof ResultWrapper ) {
1174 $res = $res->result;
1177 return pg_field_type( $res, $index );
1180 public function encodeBlob( $b ) {
1181 return new PostgresBlob( pg_escape_bytea( $b ) );
1184 public function decodeBlob( $b ) {
1185 if ( $b instanceof PostgresBlob ) {
1187 } elseif ( $b instanceof Blob ) {
1191 return pg_unescape_bytea( $b );
1194 public function strencode( $s ) {
1195 // Should not be called by us
1196 return pg_escape_string( $this->getBindingHandle(), $s );
1199 public function addQuotes( $s ) {
1200 $conn = $this->getBindingHandle();
1202 if ( is_null( $s ) ) {
1204 } elseif ( is_bool( $s ) ) {
1205 return intval( $s );
1206 } elseif ( $s instanceof Blob ) {
1207 if ( $s instanceof PostgresBlob ) {
1210 $s = pg_escape_bytea( $conn, $s->fetch() );
1215 return "'" . pg_escape_string( $conn, $s ) . "'";
1219 * Postgres specific version of replaceVars.
1220 * Calls the parent version in Database.php
1222 * @param string $ins SQL string, read from a stream (usually tables.sql)
1223 * @return string SQL string
1225 protected function replaceVars( $ins ) {
1226 $ins = parent::replaceVars( $ins );
1228 if ( $this->numericVersion >= 8.3 ) {
1229 // Thanks for not providing backwards-compatibility, 8.3
1230 $ins = preg_replace( "/to_tsvector\s*\(\s*'default'\s*,/", 'to_tsvector(', $ins );
1233 if ( $this->numericVersion <= 8.1 ) { // Our minimum version
1234 $ins = str_replace( 'USING gin', 'USING gist', $ins );
1240 public function makeSelectOptions( $options ) {
1241 $preLimitTail = $postLimitTail = '';
1242 $startOpts = $useIndex = $ignoreIndex = '';
1245 foreach ( $options as $key => $option ) {
1246 if ( is_numeric( $key ) ) {
1247 $noKeyOptions[$option] = true;
1251 $preLimitTail .= $this->makeGroupByWithHaving( $options );
1253 $preLimitTail .= $this->makeOrderBy( $options );
1255 // if ( isset( $options['LIMIT'] ) ) {
1256 // $tailOpts .= $this->limitResult( '', $options['LIMIT'],
1257 // isset( $options['OFFSET'] ) ? $options['OFFSET']
1261 if ( isset( $options['FOR UPDATE'] ) ) {
1262 $postLimitTail .= ' FOR UPDATE OF ' .
1263 implode( ', ', array_map( [ $this, 'tableName' ], $options['FOR UPDATE'] ) );
1264 } elseif ( isset( $noKeyOptions['FOR UPDATE'] ) ) {
1265 $postLimitTail .= ' FOR UPDATE';
1268 if ( isset( $noKeyOptions['DISTINCT'] ) || isset( $noKeyOptions['DISTINCTROW'] ) ) {
1269 $startOpts .= 'DISTINCT';
1272 return [ $startOpts, $useIndex, $preLimitTail, $postLimitTail, $ignoreIndex ];
1275 public function getDBname() {
1276 return $this->mDBname;
1279 public function getServer() {
1280 return $this->mServer;
1283 public function buildConcat( $stringList ) {
1284 return implode( ' || ', $stringList );
1287 public function buildGroupConcatField(
1288 $delimiter, $table, $field, $conds = '', $options = [], $join_conds = []
1290 $fld = "array_to_string(array_agg($field)," . $this->addQuotes( $delimiter ) . ')';
1292 return '(' . $this->selectSQLText( $table, $fld, $conds, null, [], $join_conds ) . ')';
1295 public function buildStringCast( $field ) {
1296 return $field . '::text';
1299 public function streamStatementEnd( &$sql, &$newLine ) {
1300 # Allow dollar quoting for function declarations
1301 if ( substr( $newLine, 0, 4 ) == '$mw$' ) {
1302 if ( $this->delimiter ) {
1303 $this->delimiter = false;
1305 $this->delimiter = ';';
1309 return parent::streamStatementEnd( $sql, $newLine );
1312 public function lockIsFree( $lockName, $method ) {
1313 // http://www.postgresql.org/docs/8.2/static/functions-admin.html#FUNCTIONS-ADVISORY-LOCKS
1314 $key = $this->addQuotes( $this->bigintFromLockName( $lockName ) );
1315 $result = $this->query( "SELECT (CASE(pg_try_advisory_lock($key))
1316 WHEN 'f' THEN 'f' ELSE pg_advisory_unlock($key) END) AS lockstatus", $method );
1317 $row = $this->fetchObject( $result );
1319 return ( $row->lockstatus === 't' );
1322 public function lock( $lockName, $method, $timeout = 5 ) {
1323 // http://www.postgresql.org/docs/8.2/static/functions-admin.html#FUNCTIONS-ADVISORY-LOCKS
1324 $key = $this->addQuotes( $this->bigintFromLockName( $lockName ) );
1325 $loop = new WaitConditionLoop(
1326 function () use ( $lockName, $key, $timeout, $method ) {
1327 $res = $this->query( "SELECT pg_try_advisory_lock($key) AS lockstatus", $method );
1328 $row = $this->fetchObject( $res );
1329 if ( $row->lockstatus === 't' ) {
1330 parent::lock( $lockName, $method, $timeout ); // record
1334 return WaitConditionLoop::CONDITION_CONTINUE;
1339 return ( $loop->invoke() === $loop::CONDITION_REACHED );
1342 public function unlock( $lockName, $method ) {
1343 // http://www.postgresql.org/docs/8.2/static/functions-admin.html#FUNCTIONS-ADVISORY-LOCKS
1344 $key = $this->addQuotes( $this->bigintFromLockName( $lockName ) );
1345 $result = $this->query( "SELECT pg_advisory_unlock($key) as lockstatus", $method );
1346 $row = $this->fetchObject( $result );
1348 if ( $row->lockstatus === 't' ) {
1349 parent::unlock( $lockName, $method ); // record
1353 $this->queryLogger->debug( __METHOD__ . " failed to release lock\n" );
1359 * @param string $lockName
1360 * @return string Integer
1362 private function bigintFromLockName( $lockName ) {
1363 return Wikimedia\base_convert( substr( sha1( $lockName ), 0, 15 ), 16, 10 );