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