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