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