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