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