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