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