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