Merge "Fix inconsistent spec of InterwikiLookup::getAllPrefixes."
[lhc/web/wiklou.git] / includes / libs / rdbms / database / DatabasePostgres.php
1 <?php
2 /**
3 * This is the Postgres database abstraction layer.
4 *
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.
9 *
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.
14 *
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
19 *
20 * @file
21 * @ingroup Database
22 */
23 namespace Wikimedia\Rdbms;
24
25 use Wikimedia\Timestamp\ConvertibleTimestamp;
26 use Wikimedia\WaitConditionLoop;
27 use MediaWiki;
28 use Exception;
29
30 /**
31 * @ingroup Database
32 */
33 class DatabasePostgres extends Database {
34 /** @var int|bool */
35 protected $port;
36
37 /** @var resource */
38 protected $mLastResult = null;
39 /** @var int The number of rows affected as an integer */
40 protected $mAffectedRows = null;
41
42 /** @var int */
43 private $mInsertId = null;
44 /** @var float|string */
45 private $numericVersion = null;
46 /** @var string Connect string to open a PostgreSQL connection */
47 private $connectString;
48 /** @var string */
49 private $mCoreSchema;
50 /** @var string[] Map of (reserved table name => alternate table name) */
51 private $keywordTableMap = [];
52
53 /**
54 * @see Database::__construct()
55 * @param array $params Additional parameters include:
56 * - keywordTableMap : Map of reserved table names to alternative table names to use
57 */
58 public function __construct( array $params ) {
59 $this->port = isset( $params['port'] ) ? $params['port'] : false;
60 $this->keywordTableMap = isset( $params['keywordTableMap'] )
61 ? $params['keywordTableMap']
62 : [];
63
64 parent::__construct( $params );
65 }
66
67 public function getType() {
68 return 'postgres';
69 }
70
71 public function implicitGroupby() {
72 return false;
73 }
74
75 public function implicitOrderby() {
76 return false;
77 }
78
79 public function hasConstraint( $name ) {
80 $conn = $this->getBindingHandle();
81
82 $sql = "SELECT 1 FROM pg_catalog.pg_constraint c, pg_catalog.pg_namespace n " .
83 "WHERE c.connamespace = n.oid AND conname = '" .
84 pg_escape_string( $conn, $name ) . "' AND n.nspname = '" .
85 pg_escape_string( $conn, $this->getCoreSchema() ) . "'";
86 $res = $this->doQuery( $sql );
87
88 return $this->numRows( $res );
89 }
90
91 public function open( $server, $user, $password, $dbName ) {
92 # Test for Postgres support, to avoid suppressed fatal error
93 if ( !function_exists( 'pg_connect' ) ) {
94 throw new DBConnectionError(
95 $this,
96 "Postgres functions missing, have you compiled PHP with the --with-pgsql\n" .
97 "option? (Note: if you recently installed PHP, you may need to restart your\n" .
98 "webserver and database)\n"
99 );
100 }
101
102 $this->mServer = $server;
103 $this->mUser = $user;
104 $this->mPassword = $password;
105 $this->mDBname = $dbName;
106
107 $connectVars = [
108 'dbname' => $dbName,
109 'user' => $user,
110 'password' => $password
111 ];
112 if ( $server != false && $server != '' ) {
113 $connectVars['host'] = $server;
114 }
115 if ( (int)$this->port > 0 ) {
116 $connectVars['port'] = (int)$this->port;
117 }
118 if ( $this->mFlags & self::DBO_SSL ) {
119 $connectVars['sslmode'] = 1;
120 }
121
122 $this->connectString = $this->makeConnectionString( $connectVars );
123 $this->close();
124 $this->installErrorHandler();
125
126 try {
127 // Use new connections to let LoadBalancer/LBFactory handle reuse
128 $this->mConn = pg_connect( $this->connectString, PGSQL_CONNECT_FORCE_NEW );
129 } catch ( Exception $ex ) {
130 $this->restoreErrorHandler();
131 throw $ex;
132 }
133
134 $phpError = $this->restoreErrorHandler();
135
136 if ( !$this->mConn ) {
137 $this->queryLogger->debug(
138 "DB connection error\n" .
139 "Server: $server, Database: $dbName, User: $user, Password: " .
140 substr( $password, 0, 3 ) . "...\n"
141 );
142 $this->queryLogger->debug( $this->lastError() . "\n" );
143 throw new DBConnectionError( $this, str_replace( "\n", ' ', $phpError ) );
144 }
145
146 $this->mOpened = true;
147
148 # If called from the command-line (e.g. importDump), only show errors
149 if ( $this->cliMode ) {
150 $this->doQuery( "SET client_min_messages = 'ERROR'" );
151 }
152
153 $this->query( "SET client_encoding='UTF8'", __METHOD__ );
154 $this->query( "SET datestyle = 'ISO, YMD'", __METHOD__ );
155 $this->query( "SET timezone = 'GMT'", __METHOD__ );
156 $this->query( "SET standard_conforming_strings = on", __METHOD__ );
157 if ( $this->getServerVersion() >= 9.0 ) {
158 $this->query( "SET bytea_output = 'escape'", __METHOD__ ); // PHP bug 53127
159 }
160
161 $this->determineCoreSchema( $this->mSchema );
162 // The schema to be used is now in the search path; no need for explicit qualification
163 $this->mSchema = '';
164
165 return $this->mConn;
166 }
167
168 /**
169 * Postgres doesn't support selectDB in the same way MySQL does. So if the
170 * DB name doesn't match the open connection, open a new one
171 * @param string $db
172 * @return bool
173 */
174 public function selectDB( $db ) {
175 if ( $this->mDBname !== $db ) {
176 return (bool)$this->open( $this->mServer, $this->mUser, $this->mPassword, $db );
177 } else {
178 return true;
179 }
180 }
181
182 /**
183 * @param string[] $vars
184 * @return string
185 */
186 private function makeConnectionString( $vars ) {
187 $s = '';
188 foreach ( $vars as $name => $value ) {
189 $s .= "$name='" . str_replace( "'", "\\'", $value ) . "' ";
190 }
191
192 return $s;
193 }
194
195 protected function closeConnection() {
196 return $this->mConn ? pg_close( $this->mConn ) : true;
197 }
198
199 public function doQuery( $sql ) {
200 $conn = $this->getBindingHandle();
201
202 $sql = mb_convert_encoding( $sql, 'UTF-8' );
203 // Clear previously left over PQresult
204 while ( $res = pg_get_result( $conn ) ) {
205 pg_free_result( $res );
206 }
207 if ( pg_send_query( $conn, $sql ) === false ) {
208 throw new DBUnexpectedError( $this, "Unable to post new query to PostgreSQL\n" );
209 }
210 $this->mLastResult = pg_get_result( $conn );
211 $this->mAffectedRows = null;
212 if ( pg_result_error( $this->mLastResult ) ) {
213 return false;
214 }
215
216 return $this->mLastResult;
217 }
218
219 protected function dumpError() {
220 $diags = [
221 PGSQL_DIAG_SEVERITY,
222 PGSQL_DIAG_SQLSTATE,
223 PGSQL_DIAG_MESSAGE_PRIMARY,
224 PGSQL_DIAG_MESSAGE_DETAIL,
225 PGSQL_DIAG_MESSAGE_HINT,
226 PGSQL_DIAG_STATEMENT_POSITION,
227 PGSQL_DIAG_INTERNAL_POSITION,
228 PGSQL_DIAG_INTERNAL_QUERY,
229 PGSQL_DIAG_CONTEXT,
230 PGSQL_DIAG_SOURCE_FILE,
231 PGSQL_DIAG_SOURCE_LINE,
232 PGSQL_DIAG_SOURCE_FUNCTION
233 ];
234 foreach ( $diags as $d ) {
235 $this->queryLogger->debug( sprintf( "PgSQL ERROR(%d): %s\n",
236 $d, pg_result_error_field( $this->mLastResult, $d ) ) );
237 }
238 }
239
240 public function reportQueryError( $error, $errno, $sql, $fname, $tempIgnore = false ) {
241 if ( $tempIgnore ) {
242 /* Check for constraint violation */
243 if ( $errno === '23505' ) {
244 parent::reportQueryError( $error, $errno, $sql, $fname, $tempIgnore );
245
246 return;
247 }
248 }
249 /* Transaction stays in the ERROR state until rolled back */
250 if ( $this->mTrxLevel ) {
251 $this->rollback( __METHOD__ );
252 }
253 parent::reportQueryError( $error, $errno, $sql, $fname, false );
254 }
255
256 public function freeResult( $res ) {
257 if ( $res instanceof ResultWrapper ) {
258 $res = $res->result;
259 }
260 MediaWiki\suppressWarnings();
261 $ok = pg_free_result( $res );
262 MediaWiki\restoreWarnings();
263 if ( !$ok ) {
264 throw new DBUnexpectedError( $this, "Unable to free Postgres result\n" );
265 }
266 }
267
268 public function fetchObject( $res ) {
269 if ( $res instanceof ResultWrapper ) {
270 $res = $res->result;
271 }
272 MediaWiki\suppressWarnings();
273 $row = pg_fetch_object( $res );
274 MediaWiki\restoreWarnings();
275 # @todo FIXME: HACK HACK HACK HACK debug
276
277 # @todo hashar: not sure if the following test really trigger if the object
278 # fetching failed.
279 $conn = $this->getBindingHandle();
280 if ( pg_last_error( $conn ) ) {
281 throw new DBUnexpectedError(
282 $this,
283 'SQL error: ' . htmlspecialchars( pg_last_error( $conn ) )
284 );
285 }
286
287 return $row;
288 }
289
290 public function fetchRow( $res ) {
291 if ( $res instanceof ResultWrapper ) {
292 $res = $res->result;
293 }
294 MediaWiki\suppressWarnings();
295 $row = pg_fetch_array( $res );
296 MediaWiki\restoreWarnings();
297
298 $conn = $this->getBindingHandle();
299 if ( pg_last_error( $conn ) ) {
300 throw new DBUnexpectedError(
301 $this,
302 'SQL error: ' . htmlspecialchars( pg_last_error( $conn ) )
303 );
304 }
305
306 return $row;
307 }
308
309 public function numRows( $res ) {
310 if ( $res instanceof ResultWrapper ) {
311 $res = $res->result;
312 }
313 MediaWiki\suppressWarnings();
314 $n = pg_num_rows( $res );
315 MediaWiki\restoreWarnings();
316
317 $conn = $this->getBindingHandle();
318 if ( pg_last_error( $conn ) ) {
319 throw new DBUnexpectedError(
320 $this,
321 'SQL error: ' . htmlspecialchars( pg_last_error( $conn ) )
322 );
323 }
324
325 return $n;
326 }
327
328 public function numFields( $res ) {
329 if ( $res instanceof ResultWrapper ) {
330 $res = $res->result;
331 }
332
333 return pg_num_fields( $res );
334 }
335
336 public function fieldName( $res, $n ) {
337 if ( $res instanceof ResultWrapper ) {
338 $res = $res->result;
339 }
340
341 return pg_field_name( $res, $n );
342 }
343
344 /**
345 * Return the result of the last call to nextSequenceValue();
346 * This must be called after nextSequenceValue().
347 *
348 * @return int|null
349 */
350 public function insertId() {
351 return $this->mInsertId;
352 }
353
354 public function dataSeek( $res, $row ) {
355 if ( $res instanceof ResultWrapper ) {
356 $res = $res->result;
357 }
358
359 return pg_result_seek( $res, $row );
360 }
361
362 public function lastError() {
363 if ( $this->mConn ) {
364 if ( $this->mLastResult ) {
365 return pg_result_error( $this->mLastResult );
366 } else {
367 return pg_last_error();
368 }
369 }
370
371 return $this->getLastPHPError() ?: 'No database connection';
372 }
373
374 public function lastErrno() {
375 if ( $this->mLastResult ) {
376 return pg_result_error_field( $this->mLastResult, PGSQL_DIAG_SQLSTATE );
377 } else {
378 return false;
379 }
380 }
381
382 public function affectedRows() {
383 if ( !is_null( $this->mAffectedRows ) ) {
384 // Forced result for simulated queries
385 return $this->mAffectedRows;
386 }
387 if ( empty( $this->mLastResult ) ) {
388 return 0;
389 }
390
391 return pg_affected_rows( $this->mLastResult );
392 }
393
394 /**
395 * Estimate rows in dataset
396 * Returns estimated count, based on EXPLAIN output
397 * This is not necessarily an accurate estimate, so use sparingly
398 * Returns -1 if count cannot be found
399 * Takes same arguments as Database::select()
400 *
401 * @param string $table
402 * @param string $vars
403 * @param string $conds
404 * @param string $fname
405 * @param array $options
406 * @return int
407 */
408 public function estimateRowCount( $table, $vars = '*', $conds = '',
409 $fname = __METHOD__, $options = []
410 ) {
411 $options['EXPLAIN'] = true;
412 $res = $this->select( $table, $vars, $conds, $fname, $options );
413 $rows = -1;
414 if ( $res ) {
415 $row = $this->fetchRow( $res );
416 $count = [];
417 if ( preg_match( '/rows=(\d+)/', $row[0], $count ) ) {
418 $rows = (int)$count[1];
419 }
420 }
421
422 return $rows;
423 }
424
425 public function indexInfo( $table, $index, $fname = __METHOD__ ) {
426 $sql = "SELECT indexname FROM pg_indexes WHERE tablename='$table'";
427 $res = $this->query( $sql, $fname );
428 if ( !$res ) {
429 return null;
430 }
431 foreach ( $res as $row ) {
432 if ( $row->indexname == $this->indexName( $index ) ) {
433 return $row;
434 }
435 }
436
437 return false;
438 }
439
440 public function indexAttributes( $index, $schema = false ) {
441 if ( $schema === false ) {
442 $schema = $this->getCoreSchema();
443 }
444 /*
445 * A subquery would be not needed if we didn't care about the order
446 * of attributes, but we do
447 */
448 $sql = <<<__INDEXATTR__
449
450 SELECT opcname,
451 attname,
452 i.indoption[s.g] as option,
453 pg_am.amname
454 FROM
455 (SELECT generate_series(array_lower(isub.indkey,1), array_upper(isub.indkey,1)) AS g
456 FROM
457 pg_index isub
458 JOIN pg_class cis
459 ON cis.oid=isub.indexrelid
460 JOIN pg_namespace ns
461 ON cis.relnamespace = ns.oid
462 WHERE cis.relname='$index' AND ns.nspname='$schema') AS s,
463 pg_attribute,
464 pg_opclass opcls,
465 pg_am,
466 pg_class ci
467 JOIN pg_index i
468 ON ci.oid=i.indexrelid
469 JOIN pg_class ct
470 ON ct.oid = i.indrelid
471 JOIN pg_namespace n
472 ON ci.relnamespace = n.oid
473 WHERE
474 ci.relname='$index' AND n.nspname='$schema'
475 AND attrelid = ct.oid
476 AND i.indkey[s.g] = attnum
477 AND i.indclass[s.g] = opcls.oid
478 AND pg_am.oid = opcls.opcmethod
479 __INDEXATTR__;
480 $res = $this->query( $sql, __METHOD__ );
481 $a = [];
482 if ( $res ) {
483 foreach ( $res as $row ) {
484 $a[] = [
485 $row->attname,
486 $row->opcname,
487 $row->amname,
488 $row->option ];
489 }
490 } else {
491 return null;
492 }
493
494 return $a;
495 }
496
497 public function indexUnique( $table, $index, $fname = __METHOD__ ) {
498 $sql = "SELECT indexname FROM pg_indexes WHERE tablename='{$table}'" .
499 " AND indexdef LIKE 'CREATE UNIQUE%(" .
500 $this->strencode( $this->indexName( $index ) ) .
501 ")'";
502 $res = $this->query( $sql, $fname );
503 if ( !$res ) {
504 return null;
505 }
506
507 return $res->numRows() > 0;
508 }
509
510 public function selectSQLText(
511 $table, $vars, $conds = '', $fname = __METHOD__, $options = [], $join_conds = []
512 ) {
513 // Change the FOR UPDATE option as necessary based on the join conditions. Then pass
514 // to the parent function to get the actual SQL text.
515 // In Postgres when using FOR UPDATE, only the main table and tables that are inner joined
516 // can be locked. That means tables in an outer join cannot be FOR UPDATE locked. Trying to
517 // do so causes a DB error. This wrapper checks which tables can be locked and adjusts it
518 // accordingly.
519 // MySQL uses "ORDER BY NULL" as an optimization hint, but that is illegal in PostgreSQL.
520 if ( is_array( $options ) ) {
521 $forUpdateKey = array_search( 'FOR UPDATE', $options, true );
522 if ( $forUpdateKey !== false && $join_conds ) {
523 unset( $options[$forUpdateKey] );
524
525 foreach ( $join_conds as $table_cond => $join_cond ) {
526 if ( 0 === preg_match( '/^(?:LEFT|RIGHT|FULL)(?: OUTER)? JOIN$/i', $join_cond[0] ) ) {
527 $options['FOR UPDATE'][] = $table_cond;
528 }
529 }
530 }
531
532 if ( isset( $options['ORDER BY'] ) && $options['ORDER BY'] == 'NULL' ) {
533 unset( $options['ORDER BY'] );
534 }
535 }
536
537 return parent::selectSQLText( $table, $vars, $conds, $fname, $options, $join_conds );
538 }
539
540 /**
541 * INSERT wrapper, inserts an array into a table
542 *
543 * $args may be a single associative array, or an array of these with numeric keys,
544 * for multi-row insert (Postgres version 8.2 and above only).
545 *
546 * @param string $table Name of the table to insert to.
547 * @param array $args Items to insert into the table.
548 * @param string $fname Name of the function, for profiling
549 * @param array|string $options String or array. Valid options: IGNORE
550 * @return bool Success of insert operation. IGNORE always returns true.
551 */
552 public function insert( $table, $args, $fname = __METHOD__, $options = [] ) {
553 if ( !count( $args ) ) {
554 return true;
555 }
556
557 $table = $this->tableName( $table );
558 if ( !isset( $this->numericVersion ) ) {
559 $this->getServerVersion();
560 }
561
562 if ( !is_array( $options ) ) {
563 $options = [ $options ];
564 }
565
566 if ( isset( $args[0] ) && is_array( $args[0] ) ) {
567 $multi = true;
568 $keys = array_keys( $args[0] );
569 } else {
570 $multi = false;
571 $keys = array_keys( $args );
572 }
573
574 // If IGNORE is set, we use savepoints to emulate mysql's behavior
575 $savepoint = $olde = null;
576 $numrowsinserted = 0;
577 if ( in_array( 'IGNORE', $options ) ) {
578 $savepoint = new SavepointPostgres( $this, 'mw', $this->queryLogger );
579 $olde = error_reporting( 0 );
580 // For future use, we may want to track the number of actual inserts
581 // Right now, insert (all writes) simply return true/false
582 }
583
584 $sql = "INSERT INTO $table (" . implode( ',', $keys ) . ') VALUES ';
585
586 if ( $multi ) {
587 if ( $this->numericVersion >= 8.2 && !$savepoint ) {
588 $first = true;
589 foreach ( $args as $row ) {
590 if ( $first ) {
591 $first = false;
592 } else {
593 $sql .= ',';
594 }
595 $sql .= '(' . $this->makeList( $row ) . ')';
596 }
597 $res = (bool)$this->query( $sql, $fname, $savepoint );
598 } else {
599 $res = true;
600 $origsql = $sql;
601 foreach ( $args as $row ) {
602 $tempsql = $origsql;
603 $tempsql .= '(' . $this->makeList( $row ) . ')';
604
605 if ( $savepoint ) {
606 $savepoint->savepoint();
607 }
608
609 $tempres = (bool)$this->query( $tempsql, $fname, $savepoint );
610
611 if ( $savepoint ) {
612 $bar = pg_result_error( $this->mLastResult );
613 if ( $bar != false ) {
614 $savepoint->rollback();
615 } else {
616 $savepoint->release();
617 $numrowsinserted++;
618 }
619 }
620
621 // If any of them fail, we fail overall for this function call
622 // Note that this will be ignored if IGNORE is set
623 if ( !$tempres ) {
624 $res = false;
625 }
626 }
627 }
628 } else {
629 // Not multi, just a lone insert
630 if ( $savepoint ) {
631 $savepoint->savepoint();
632 }
633
634 $sql .= '(' . $this->makeList( $args ) . ')';
635 $res = (bool)$this->query( $sql, $fname, $savepoint );
636 if ( $savepoint ) {
637 $bar = pg_result_error( $this->mLastResult );
638 if ( $bar != false ) {
639 $savepoint->rollback();
640 } else {
641 $savepoint->release();
642 $numrowsinserted++;
643 }
644 }
645 }
646 if ( $savepoint ) {
647 error_reporting( $olde );
648 $savepoint->commit();
649
650 // Set the affected row count for the whole operation
651 $this->mAffectedRows = $numrowsinserted;
652
653 // IGNORE always returns true
654 return true;
655 }
656
657 return $res;
658 }
659
660 /**
661 * INSERT SELECT wrapper
662 * $varMap must be an associative array of the form [ 'dest1' => 'source1', ... ]
663 * Source items may be literals rather then field names, but strings should
664 * be quoted with Database::addQuotes()
665 * $conds may be "*" to copy the whole table
666 * srcTable may be an array of tables.
667 * @todo FIXME: Implement this a little better (seperate select/insert)?
668 *
669 * @param string $destTable
670 * @param array|string $srcTable
671 * @param array $varMap
672 * @param array $conds
673 * @param string $fname
674 * @param array $insertOptions
675 * @param array $selectOptions
676 * @return bool
677 */
678 public function nativeInsertSelect(
679 $destTable, $srcTable, $varMap, $conds, $fname = __METHOD__,
680 $insertOptions = [], $selectOptions = []
681 ) {
682 $destTable = $this->tableName( $destTable );
683
684 if ( !is_array( $insertOptions ) ) {
685 $insertOptions = [ $insertOptions ];
686 }
687
688 /*
689 * If IGNORE is set, we use savepoints to emulate mysql's behavior
690 * Ignore LOW PRIORITY option, since it is MySQL-specific
691 */
692 $savepoint = $olde = null;
693 $numrowsinserted = 0;
694 if ( in_array( 'IGNORE', $insertOptions ) ) {
695 $savepoint = new SavepointPostgres( $this, 'mw', $this->queryLogger );
696 $olde = error_reporting( 0 );
697 $savepoint->savepoint();
698 }
699
700 if ( !is_array( $selectOptions ) ) {
701 $selectOptions = [ $selectOptions ];
702 }
703 list( $startOpts, $useIndex, $tailOpts, $ignoreIndex ) =
704 $this->makeSelectOptions( $selectOptions );
705 if ( is_array( $srcTable ) ) {
706 $srcTable = implode( ',', array_map( [ $this, 'tableName' ], $srcTable ) );
707 } else {
708 $srcTable = $this->tableName( $srcTable );
709 }
710
711 $sql = "INSERT INTO $destTable (" . implode( ',', array_keys( $varMap ) ) . ')' .
712 " SELECT $startOpts " . implode( ',', $varMap ) .
713 " FROM $srcTable $useIndex $ignoreIndex ";
714
715 if ( $conds != '*' ) {
716 $sql .= ' WHERE ' . $this->makeList( $conds, LIST_AND );
717 }
718
719 $sql .= " $tailOpts";
720
721 $res = (bool)$this->query( $sql, $fname, $savepoint );
722 if ( $savepoint ) {
723 $bar = pg_result_error( $this->mLastResult );
724 if ( $bar != false ) {
725 $savepoint->rollback();
726 } else {
727 $savepoint->release();
728 $numrowsinserted++;
729 }
730 error_reporting( $olde );
731 $savepoint->commit();
732
733 // Set the affected row count for the whole operation
734 $this->mAffectedRows = $numrowsinserted;
735
736 // IGNORE always returns true
737 return true;
738 }
739
740 return $res;
741 }
742
743 public function tableName( $name, $format = 'quoted' ) {
744 // Replace reserved words with better ones
745 $name = $this->remappedTableName( $name );
746
747 return parent::tableName( $name, $format );
748 }
749
750 /**
751 * @param string $name
752 * @return string Value of $name or remapped name if $name is a reserved keyword
753 */
754 public function remappedTableName( $name ) {
755 return isset( $this->keywordTableMap[$name] ) ? $this->keywordTableMap[$name] : $name;
756 }
757
758 /**
759 * @param string $name
760 * @param string $format
761 * @return string Qualified and encoded (if requested) table name
762 */
763 public function realTableName( $name, $format = 'quoted' ) {
764 return parent::tableName( $name, $format );
765 }
766
767 public function nextSequenceValue( $seqName ) {
768 $safeseq = str_replace( "'", "''", $seqName );
769 $res = $this->query( "SELECT nextval('$safeseq')" );
770 $row = $this->fetchRow( $res );
771 $this->mInsertId = $row[0];
772
773 return $this->mInsertId;
774 }
775
776 /**
777 * Return the current value of a sequence. Assumes it has been nextval'ed in this session.
778 *
779 * @param string $seqName
780 * @return int
781 */
782 public function currentSequenceValue( $seqName ) {
783 $safeseq = str_replace( "'", "''", $seqName );
784 $res = $this->query( "SELECT currval('$safeseq')" );
785 $row = $this->fetchRow( $res );
786 $currval = $row[0];
787
788 return $currval;
789 }
790
791 public function textFieldSize( $table, $field ) {
792 $table = $this->tableName( $table );
793 $sql = "SELECT t.typname as ftype,a.atttypmod as size
794 FROM pg_class c, pg_attribute a, pg_type t
795 WHERE relname='$table' AND a.attrelid=c.oid AND
796 a.atttypid=t.oid and a.attname='$field'";
797 $res = $this->query( $sql );
798 $row = $this->fetchObject( $res );
799 if ( $row->ftype == 'varchar' ) {
800 $size = $row->size - 4;
801 } else {
802 $size = $row->size;
803 }
804
805 return $size;
806 }
807
808 public function limitResult( $sql, $limit, $offset = false ) {
809 return "$sql LIMIT $limit " . ( is_numeric( $offset ) ? " OFFSET {$offset} " : '' );
810 }
811
812 public function wasDeadlock() {
813 return $this->lastErrno() == '40P01';
814 }
815
816 public function duplicateTableStructure(
817 $oldName, $newName, $temporary = false, $fname = __METHOD__
818 ) {
819 $newName = $this->addIdentifierQuotes( $newName );
820 $oldName = $this->addIdentifierQuotes( $oldName );
821
822 return $this->query( 'CREATE ' . ( $temporary ? 'TEMPORARY ' : '' ) . " TABLE $newName " .
823 "(LIKE $oldName INCLUDING DEFAULTS)", $fname );
824 }
825
826 public function listTables( $prefix = null, $fname = __METHOD__ ) {
827 $eschema = $this->addQuotes( $this->getCoreSchema() );
828 $result = $this->query(
829 "SELECT tablename FROM pg_tables WHERE schemaname = $eschema", $fname );
830 $endArray = [];
831
832 foreach ( $result as $table ) {
833 $vars = get_object_vars( $table );
834 $table = array_pop( $vars );
835 if ( !$prefix || strpos( $table, $prefix ) === 0 ) {
836 $endArray[] = $table;
837 }
838 }
839
840 return $endArray;
841 }
842
843 public function timestamp( $ts = 0 ) {
844 $ct = new ConvertibleTimestamp( $ts );
845
846 return $ct->getTimestamp( TS_POSTGRES );
847 }
848
849 /**
850 * Posted by cc[plus]php[at]c2se[dot]com on 25-Mar-2009 09:12
851 * to https://secure.php.net/manual/en/ref.pgsql.php
852 *
853 * Parsing a postgres array can be a tricky problem, he's my
854 * take on this, it handles multi-dimensional arrays plus
855 * escaping using a nasty regexp to determine the limits of each
856 * data-item.
857 *
858 * This should really be handled by PHP PostgreSQL module
859 *
860 * @since 1.19
861 * @param string $text Postgreql array returned in a text form like {a,b}
862 * @param string[] $output
863 * @param int|bool $limit
864 * @param int $offset
865 * @return string[]
866 */
867 private function pg_array_parse( $text, &$output, $limit = false, $offset = 1 ) {
868 if ( false === $limit ) {
869 $limit = strlen( $text ) - 1;
870 $output = [];
871 }
872 if ( '{}' == $text ) {
873 return $output;
874 }
875 do {
876 if ( '{' != $text[$offset] ) {
877 preg_match( "/(\\{?\"([^\"\\\\]|\\\\.)*\"|[^,{}]+)+([,}]+)/",
878 $text, $match, 0, $offset );
879 $offset += strlen( $match[0] );
880 $output[] = ( '"' != $match[1][0]
881 ? $match[1]
882 : stripcslashes( substr( $match[1], 1, -1 ) ) );
883 if ( '},' == $match[3] ) {
884 return $output;
885 }
886 } else {
887 $offset = $this->pg_array_parse( $text, $output, $limit, $offset + 1 );
888 }
889 } while ( $limit > $offset );
890
891 return $output;
892 }
893
894 public function aggregateValue( $valuedata, $valuename = 'value' ) {
895 return $valuedata;
896 }
897
898 public function getSoftwareLink() {
899 return '[{{int:version-db-postgres-url}} PostgreSQL]';
900 }
901
902 /**
903 * Return current schema (executes SELECT current_schema())
904 * Needs transaction
905 *
906 * @since 1.19
907 * @return string Default schema for the current session
908 */
909 public function getCurrentSchema() {
910 $res = $this->query( "SELECT current_schema()", __METHOD__ );
911 $row = $this->fetchRow( $res );
912
913 return $row[0];
914 }
915
916 /**
917 * Return list of schemas which are accessible without schema name
918 * This is list does not contain magic keywords like "$user"
919 * Needs transaction
920 *
921 * @see getSearchPath()
922 * @see setSearchPath()
923 * @since 1.19
924 * @return array List of actual schemas for the current sesson
925 */
926 public function getSchemas() {
927 $res = $this->query( "SELECT current_schemas(false)", __METHOD__ );
928 $row = $this->fetchRow( $res );
929 $schemas = [];
930
931 /* PHP pgsql support does not support array type, "{a,b}" string is returned */
932
933 return $this->pg_array_parse( $row[0], $schemas );
934 }
935
936 /**
937 * Return search patch for schemas
938 * This is different from getSchemas() since it contain magic keywords
939 * (like "$user").
940 * Needs transaction
941 *
942 * @since 1.19
943 * @return array How to search for table names schemas for the current user
944 */
945 public function getSearchPath() {
946 $res = $this->query( "SHOW search_path", __METHOD__ );
947 $row = $this->fetchRow( $res );
948
949 /* PostgreSQL returns SHOW values as strings */
950
951 return explode( ",", $row[0] );
952 }
953
954 /**
955 * Update search_path, values should already be sanitized
956 * Values may contain magic keywords like "$user"
957 * @since 1.19
958 *
959 * @param array $search_path List of schemas to be searched by default
960 */
961 private function setSearchPath( $search_path ) {
962 $this->query( "SET search_path = " . implode( ", ", $search_path ) );
963 }
964
965 /**
966 * Determine default schema for the current application
967 * Adjust this session schema search path if desired schema exists
968 * and is not alread there.
969 *
970 * We need to have name of the core schema stored to be able
971 * to query database metadata.
972 *
973 * This will be also called by the installer after the schema is created
974 *
975 * @since 1.19
976 *
977 * @param string $desiredSchema
978 */
979 public function determineCoreSchema( $desiredSchema ) {
980 $this->begin( __METHOD__, self::TRANSACTION_INTERNAL );
981 if ( $this->schemaExists( $desiredSchema ) ) {
982 if ( in_array( $desiredSchema, $this->getSchemas() ) ) {
983 $this->mCoreSchema = $desiredSchema;
984 $this->queryLogger->debug(
985 "Schema \"" . $desiredSchema . "\" already in the search path\n" );
986 } else {
987 /**
988 * Prepend our schema (e.g. 'mediawiki') in front
989 * of the search path
990 * Fixes T17816
991 */
992 $search_path = $this->getSearchPath();
993 array_unshift( $search_path,
994 $this->addIdentifierQuotes( $desiredSchema ) );
995 $this->setSearchPath( $search_path );
996 $this->mCoreSchema = $desiredSchema;
997 $this->queryLogger->debug(
998 "Schema \"" . $desiredSchema . "\" added to the search path\n" );
999 }
1000 } else {
1001 $this->mCoreSchema = $this->getCurrentSchema();
1002 $this->queryLogger->debug(
1003 "Schema \"" . $desiredSchema . "\" not found, using current \"" .
1004 $this->mCoreSchema . "\"\n" );
1005 }
1006 /* Commit SET otherwise it will be rollbacked on error or IGNORE SELECT */
1007 $this->commit( __METHOD__, self::FLUSHING_INTERNAL );
1008 }
1009
1010 /**
1011 * Return schema name for core application tables
1012 *
1013 * @since 1.19
1014 * @return string Core schema name
1015 */
1016 public function getCoreSchema() {
1017 return $this->mCoreSchema;
1018 }
1019
1020 public function getServerVersion() {
1021 if ( !isset( $this->numericVersion ) ) {
1022 $conn = $this->getBindingHandle();
1023 $versionInfo = pg_version( $conn );
1024 if ( version_compare( $versionInfo['client'], '7.4.0', 'lt' ) ) {
1025 // Old client, abort install
1026 $this->numericVersion = '7.3 or earlier';
1027 } elseif ( isset( $versionInfo['server'] ) ) {
1028 // Normal client
1029 $this->numericVersion = $versionInfo['server'];
1030 } else {
1031 // T18937: broken pgsql extension from PHP<5.3
1032 $this->numericVersion = pg_parameter_status( $conn, 'server_version' );
1033 }
1034 }
1035
1036 return $this->numericVersion;
1037 }
1038
1039 /**
1040 * Query whether a given relation exists (in the given schema, or the
1041 * default mw one if not given)
1042 * @param string $table
1043 * @param array|string $types
1044 * @param bool|string $schema
1045 * @return bool
1046 */
1047 private function relationExists( $table, $types, $schema = false ) {
1048 if ( !is_array( $types ) ) {
1049 $types = [ $types ];
1050 }
1051 if ( $schema === false ) {
1052 $schema = $this->getCoreSchema();
1053 }
1054 $etable = $this->addQuotes( $table );
1055 $eschema = $this->addQuotes( $schema );
1056 $sql = "SELECT 1 FROM pg_catalog.pg_class c, pg_catalog.pg_namespace n "
1057 . "WHERE c.relnamespace = n.oid AND c.relname = $etable AND n.nspname = $eschema "
1058 . "AND c.relkind IN ('" . implode( "','", $types ) . "')";
1059 $res = $this->query( $sql );
1060 $count = $res ? $res->numRows() : 0;
1061
1062 return (bool)$count;
1063 }
1064
1065 /**
1066 * For backward compatibility, this function checks both tables and views.
1067 * @param string $table
1068 * @param string $fname
1069 * @param bool|string $schema
1070 * @return bool
1071 */
1072 public function tableExists( $table, $fname = __METHOD__, $schema = false ) {
1073 return $this->relationExists( $table, [ 'r', 'v' ], $schema );
1074 }
1075
1076 public function sequenceExists( $sequence, $schema = false ) {
1077 return $this->relationExists( $sequence, 'S', $schema );
1078 }
1079
1080 public function triggerExists( $table, $trigger ) {
1081 $q = <<<SQL
1082 SELECT 1 FROM pg_class, pg_namespace, pg_trigger
1083 WHERE relnamespace=pg_namespace.oid AND relkind='r'
1084 AND tgrelid=pg_class.oid
1085 AND nspname=%s AND relname=%s AND tgname=%s
1086 SQL;
1087 $res = $this->query(
1088 sprintf(
1089 $q,
1090 $this->addQuotes( $this->getCoreSchema() ),
1091 $this->addQuotes( $table ),
1092 $this->addQuotes( $trigger )
1093 )
1094 );
1095 if ( !$res ) {
1096 return null;
1097 }
1098 $rows = $res->numRows();
1099
1100 return $rows;
1101 }
1102
1103 public function ruleExists( $table, $rule ) {
1104 $exists = $this->selectField( 'pg_rules', 'rulename',
1105 [
1106 'rulename' => $rule,
1107 'tablename' => $table,
1108 'schemaname' => $this->getCoreSchema()
1109 ]
1110 );
1111
1112 return $exists === $rule;
1113 }
1114
1115 public function constraintExists( $table, $constraint ) {
1116 $sql = sprintf( "SELECT 1 FROM information_schema.table_constraints " .
1117 "WHERE constraint_schema = %s AND table_name = %s AND constraint_name = %s",
1118 $this->addQuotes( $this->getCoreSchema() ),
1119 $this->addQuotes( $table ),
1120 $this->addQuotes( $constraint )
1121 );
1122 $res = $this->query( $sql );
1123 if ( !$res ) {
1124 return null;
1125 }
1126 $rows = $res->numRows();
1127
1128 return $rows;
1129 }
1130
1131 /**
1132 * Query whether a given schema exists. Returns true if it does, false if it doesn't.
1133 * @param string $schema
1134 * @return bool
1135 */
1136 public function schemaExists( $schema ) {
1137 if ( !strlen( $schema ) ) {
1138 return false; // short-circuit
1139 }
1140
1141 $exists = $this->selectField(
1142 '"pg_catalog"."pg_namespace"', 1, [ 'nspname' => $schema ], __METHOD__ );
1143
1144 return (bool)$exists;
1145 }
1146
1147 /**
1148 * Returns true if a given role (i.e. user) exists, false otherwise.
1149 * @param string $roleName
1150 * @return bool
1151 */
1152 public function roleExists( $roleName ) {
1153 $exists = $this->selectField( '"pg_catalog"."pg_roles"', 1,
1154 [ 'rolname' => $roleName ], __METHOD__ );
1155
1156 return (bool)$exists;
1157 }
1158
1159 /**
1160 * @var string $table
1161 * @var string $field
1162 * @return PostgresField|null
1163 */
1164 public function fieldInfo( $table, $field ) {
1165 return PostgresField::fromText( $this, $table, $field );
1166 }
1167
1168 /**
1169 * pg_field_type() wrapper
1170 * @param ResultWrapper|resource $res ResultWrapper or PostgreSQL query result resource
1171 * @param int $index Field number, starting from 0
1172 * @return string
1173 */
1174 public function fieldType( $res, $index ) {
1175 if ( $res instanceof ResultWrapper ) {
1176 $res = $res->result;
1177 }
1178
1179 return pg_field_type( $res, $index );
1180 }
1181
1182 public function encodeBlob( $b ) {
1183 return new PostgresBlob( pg_escape_bytea( $b ) );
1184 }
1185
1186 public function decodeBlob( $b ) {
1187 if ( $b instanceof PostgresBlob ) {
1188 $b = $b->fetch();
1189 } elseif ( $b instanceof Blob ) {
1190 return $b->fetch();
1191 }
1192
1193 return pg_unescape_bytea( $b );
1194 }
1195
1196 public function strencode( $s ) {
1197 // Should not be called by us
1198 return pg_escape_string( $this->getBindingHandle(), $s );
1199 }
1200
1201 public function addQuotes( $s ) {
1202 $conn = $this->getBindingHandle();
1203
1204 if ( is_null( $s ) ) {
1205 return 'NULL';
1206 } elseif ( is_bool( $s ) ) {
1207 return intval( $s );
1208 } elseif ( $s instanceof Blob ) {
1209 if ( $s instanceof PostgresBlob ) {
1210 $s = $s->fetch();
1211 } else {
1212 $s = pg_escape_bytea( $conn, $s->fetch() );
1213 }
1214 return "'$s'";
1215 }
1216
1217 return "'" . pg_escape_string( $conn, $s ) . "'";
1218 }
1219
1220 /**
1221 * Postgres specific version of replaceVars.
1222 * Calls the parent version in Database.php
1223 *
1224 * @param string $ins SQL string, read from a stream (usually tables.sql)
1225 * @return string SQL string
1226 */
1227 protected function replaceVars( $ins ) {
1228 $ins = parent::replaceVars( $ins );
1229
1230 if ( $this->numericVersion >= 8.3 ) {
1231 // Thanks for not providing backwards-compatibility, 8.3
1232 $ins = preg_replace( "/to_tsvector\s*\(\s*'default'\s*,/", 'to_tsvector(', $ins );
1233 }
1234
1235 if ( $this->numericVersion <= 8.1 ) { // Our minimum version
1236 $ins = str_replace( 'USING gin', 'USING gist', $ins );
1237 }
1238
1239 return $ins;
1240 }
1241
1242 public function makeSelectOptions( $options ) {
1243 $preLimitTail = $postLimitTail = '';
1244 $startOpts = $useIndex = $ignoreIndex = '';
1245
1246 $noKeyOptions = [];
1247 foreach ( $options as $key => $option ) {
1248 if ( is_numeric( $key ) ) {
1249 $noKeyOptions[$option] = true;
1250 }
1251 }
1252
1253 $preLimitTail .= $this->makeGroupByWithHaving( $options );
1254
1255 $preLimitTail .= $this->makeOrderBy( $options );
1256
1257 if ( isset( $options['FOR UPDATE'] ) ) {
1258 $postLimitTail .= ' FOR UPDATE OF ' .
1259 implode( ', ', array_map( [ $this, 'tableName' ], $options['FOR UPDATE'] ) );
1260 } elseif ( isset( $noKeyOptions['FOR UPDATE'] ) ) {
1261 $postLimitTail .= ' FOR UPDATE';
1262 }
1263
1264 if ( isset( $noKeyOptions['DISTINCT'] ) || isset( $noKeyOptions['DISTINCTROW'] ) ) {
1265 $startOpts .= 'DISTINCT';
1266 }
1267
1268 return [ $startOpts, $useIndex, $preLimitTail, $postLimitTail, $ignoreIndex ];
1269 }
1270
1271 public function getDBname() {
1272 return $this->mDBname;
1273 }
1274
1275 public function getServer() {
1276 return $this->mServer;
1277 }
1278
1279 public function buildConcat( $stringList ) {
1280 return implode( ' || ', $stringList );
1281 }
1282
1283 public function buildGroupConcatField(
1284 $delimiter, $table, $field, $conds = '', $options = [], $join_conds = []
1285 ) {
1286 $fld = "array_to_string(array_agg($field)," . $this->addQuotes( $delimiter ) . ')';
1287
1288 return '(' . $this->selectSQLText( $table, $fld, $conds, null, [], $join_conds ) . ')';
1289 }
1290
1291 public function buildStringCast( $field ) {
1292 return $field . '::text';
1293 }
1294
1295 public function streamStatementEnd( &$sql, &$newLine ) {
1296 # Allow dollar quoting for function declarations
1297 if ( substr( $newLine, 0, 4 ) == '$mw$' ) {
1298 if ( $this->delimiter ) {
1299 $this->delimiter = false;
1300 } else {
1301 $this->delimiter = ';';
1302 }
1303 }
1304
1305 return parent::streamStatementEnd( $sql, $newLine );
1306 }
1307
1308 public function doLockTables( array $read, array $write, $method ) {
1309 $tablesWrite = [];
1310 foreach ( $write as $table ) {
1311 $tablesWrite[] = $this->tableName( $table );
1312 }
1313 $tablesRead = [];
1314 foreach ( $read as $table ) {
1315 $tablesRead[] = $this->tableName( $table );
1316 }
1317
1318 // Acquire locks for the duration of the current transaction...
1319 if ( $tablesWrite ) {
1320 $this->query(
1321 'LOCK TABLE ONLY ' . implode( ',', $tablesWrite ) . ' IN EXCLUSIVE MODE',
1322 $method
1323 );
1324 }
1325 if ( $tablesRead ) {
1326 $this->query(
1327 'LOCK TABLE ONLY ' . implode( ',', $tablesRead ) . ' IN SHARE MODE',
1328 $method
1329 );
1330 }
1331
1332 return true;
1333 }
1334
1335 public function lockIsFree( $lockName, $method ) {
1336 // http://www.postgresql.org/docs/8.2/static/functions-admin.html#FUNCTIONS-ADVISORY-LOCKS
1337 $key = $this->addQuotes( $this->bigintFromLockName( $lockName ) );
1338 $result = $this->query( "SELECT (CASE(pg_try_advisory_lock($key))
1339 WHEN 'f' THEN 'f' ELSE pg_advisory_unlock($key) END) AS lockstatus", $method );
1340 $row = $this->fetchObject( $result );
1341
1342 return ( $row->lockstatus === 't' );
1343 }
1344
1345 public function lock( $lockName, $method, $timeout = 5 ) {
1346 // http://www.postgresql.org/docs/8.2/static/functions-admin.html#FUNCTIONS-ADVISORY-LOCKS
1347 $key = $this->addQuotes( $this->bigintFromLockName( $lockName ) );
1348 $loop = new WaitConditionLoop(
1349 function () use ( $lockName, $key, $timeout, $method ) {
1350 $res = $this->query( "SELECT pg_try_advisory_lock($key) AS lockstatus", $method );
1351 $row = $this->fetchObject( $res );
1352 if ( $row->lockstatus === 't' ) {
1353 parent::lock( $lockName, $method, $timeout ); // record
1354 return true;
1355 }
1356
1357 return WaitConditionLoop::CONDITION_CONTINUE;
1358 },
1359 $timeout
1360 );
1361
1362 return ( $loop->invoke() === $loop::CONDITION_REACHED );
1363 }
1364
1365 public function unlock( $lockName, $method ) {
1366 // http://www.postgresql.org/docs/8.2/static/functions-admin.html#FUNCTIONS-ADVISORY-LOCKS
1367 $key = $this->addQuotes( $this->bigintFromLockName( $lockName ) );
1368 $result = $this->query( "SELECT pg_advisory_unlock($key) as lockstatus", $method );
1369 $row = $this->fetchObject( $result );
1370
1371 if ( $row->lockstatus === 't' ) {
1372 parent::unlock( $lockName, $method ); // record
1373 return true;
1374 }
1375
1376 $this->queryLogger->debug( __METHOD__ . " failed to release lock\n" );
1377
1378 return false;
1379 }
1380
1381 /**
1382 * @param string $lockName
1383 * @return string Integer
1384 */
1385 private function bigintFromLockName( $lockName ) {
1386 return \Wikimedia\base_convert( substr( sha1( $lockName ), 0, 15 ), 16, 10 );
1387 }
1388 }
1389
1390 class_alias( DatabasePostgres::class, 'DatabasePostgres' );