Per siebrand and Nikerabbit (tweak for r47535):
[lhc/web/wiklou.git] / includes / db / DatabasePostgres.php
1 <?php
2 /**
3 * @ingroup Database
4 * @file
5 * This is the Postgres database abstraction layer.
6 *
7 */
8 class PostgresField {
9 private $name, $tablename, $type, $nullable, $max_length;
10
11 static function fromText($db, $table, $field) {
12 global $wgDBmwschema;
13
14 $q = <<<END
15 SELECT
16 CASE WHEN typname = 'int2' THEN 'smallint'
17 WHEN typname = 'int4' THEN 'integer'
18 WHEN typname = 'int8' THEN 'bigint'
19 WHEN typname = 'bpchar' THEN 'char'
20 ELSE typname END AS typname,
21 attnotnull, attlen
22 FROM pg_class, pg_namespace, pg_attribute, pg_type
23 WHERE relnamespace=pg_namespace.oid
24 AND relkind='r'
25 AND attrelid=pg_class.oid
26 AND atttypid=pg_type.oid
27 AND nspname=%s
28 AND relname=%s
29 AND attname=%s;
30 END;
31 $res = $db->query(sprintf($q,
32 $db->addQuotes($wgDBmwschema),
33 $db->addQuotes($table),
34 $db->addQuotes($field)));
35 $row = $db->fetchObject($res);
36 if (!$row)
37 return null;
38 $n = new PostgresField;
39 $n->type = $row->typname;
40 $n->nullable = ($row->attnotnull == 'f');
41 $n->name = $field;
42 $n->tablename = $table;
43 $n->max_length = $row->attlen;
44 return $n;
45 }
46
47 function name() {
48 return $this->name;
49 }
50
51 function tableName() {
52 return $this->tablename;
53 }
54
55 function type() {
56 return $this->type;
57 }
58
59 function nullable() {
60 return $this->nullable;
61 }
62
63 function maxLength() {
64 return $this->max_length;
65 }
66 }
67
68 /**
69 * @ingroup Database
70 */
71 class DatabasePostgres extends Database {
72 var $mInsertId = NULL;
73 var $mLastResult = NULL;
74 var $numeric_version = NULL;
75 var $mAffectedRows = NULL;
76
77 function DatabasePostgres($server = false, $user = false, $password = false, $dbName = false,
78 $failFunction = false, $flags = 0 )
79 {
80
81 $this->mFailFunction = $failFunction;
82 $this->mFlags = $flags;
83 $this->open( $server, $user, $password, $dbName);
84
85 }
86
87 function cascadingDeletes() {
88 return true;
89 }
90 function cleanupTriggers() {
91 return true;
92 }
93 function strictIPs() {
94 return true;
95 }
96 function realTimestamps() {
97 return true;
98 }
99 function implicitGroupby() {
100 return false;
101 }
102 function implicitOrderby() {
103 return false;
104 }
105 function searchableIPs() {
106 return true;
107 }
108 function functionalIndexes() {
109 return true;
110 }
111
112 function hasConstraint( $name ) {
113 global $wgDBmwschema;
114 $SQL = "SELECT 1 FROM pg_catalog.pg_constraint c, pg_catalog.pg_namespace n WHERE c.connamespace = n.oid AND conname = '" . pg_escape_string( $name ) . "' AND n.nspname = '" . pg_escape_string($wgDBmwschema) ."'";
115 return $this->numRows($res = $this->doQuery($SQL));
116 }
117
118 static function newFromParams( $server, $user, $password, $dbName, $failFunction = false, $flags = 0)
119 {
120 return new DatabasePostgres( $server, $user, $password, $dbName, $failFunction, $flags );
121 }
122
123 /**
124 * Usually aborts on failure
125 * If the failFunction is set to a non-zero integer, returns success
126 */
127 function open( $server, $user, $password, $dbName ) {
128 # Test for Postgres support, to avoid suppressed fatal error
129 if ( !function_exists( 'pg_connect' ) ) {
130 throw new DBConnectionError( $this, "Postgres functions missing, have you compiled PHP with the --with-pgsql option?\n (Note: if you recently installed PHP, you may need to restart your webserver and database)\n" );
131 }
132
133 global $wgDBport;
134
135 if (!strlen($user)) { ## e.g. the class is being loaded
136 return;
137 }
138 $this->close();
139 $this->mServer = $server;
140 $this->mPort = $port = $wgDBport;
141 $this->mUser = $user;
142 $this->mPassword = $password;
143 $this->mDBname = $dbName;
144
145 $connectVars = array(
146 'dbname' => $dbName,
147 'user' => $user,
148 'password' => $password );
149 if ($server!=false && $server!="") {
150 $connectVars['host'] = $server;
151 }
152 if ($port!=false && $port!="") {
153 $connectVars['port'] = $port;
154 }
155 $connectString = $this->makeConnectionString( $connectVars );
156
157 $this->installErrorHandler();
158 $this->mConn = pg_connect( $connectString );
159 $phpError = $this->restoreErrorHandler();
160
161 if ( $this->mConn == false ) {
162 wfDebug( "DB connection error\n" );
163 wfDebug( "Server: $server, Database: $dbName, User: $user, Password: " . substr( $password, 0, 3 ) . "...\n" );
164 wfDebug( $this->lastError()."\n" );
165 if ( !$this->mFailFunction ) {
166 throw new DBConnectionError( $this, $phpError );
167 } else {
168 return false;
169 }
170 }
171
172 $this->mOpened = true;
173
174 global $wgCommandLineMode;
175 ## If called from the command-line (e.g. importDump), only show errors
176 if ($wgCommandLineMode) {
177 $this->doQuery("SET client_min_messages = 'ERROR'");
178 }
179
180 global $wgDBmwschema, $wgDBts2schema;
181 if (isset( $wgDBmwschema ) && isset( $wgDBts2schema )
182 && $wgDBmwschema !== 'mediawiki'
183 && preg_match( '/^\w+$/', $wgDBmwschema )
184 && preg_match( '/^\w+$/', $wgDBts2schema )
185 ) {
186 $safeschema = $this->quote_ident($wgDBmwschema);
187 $safeschema2 = $this->quote_ident($wgDBts2schema);
188 $this->doQuery("SET search_path = $safeschema, $wgDBts2schema, public");
189 }
190
191 return $this->mConn;
192 }
193
194 function makeConnectionString( $vars ) {
195 $s = '';
196 foreach ( $vars as $name => $value ) {
197 $s .= "$name='" . str_replace( "'", "\\'", $value ) . "' ";
198 }
199 return $s;
200 }
201
202
203 function initial_setup($password, $dbName) {
204 // If this is the initial connection, setup the schema stuff and possibly create the user
205 global $wgDBname, $wgDBuser, $wgDBpassword, $wgDBsuperuser, $wgDBmwschema, $wgDBts2schema;
206
207 print "<li>Checking the version of Postgres...";
208 $version = $this->getServerVersion();
209 $PGMINVER = '8.1';
210 if ($version < $PGMINVER) {
211 print "<b>FAILED</b>. Required version is $PGMINVER. You have " . htmlspecialchars( $version ) . "</li>\n";
212 dieout("</ul>");
213 }
214 print "version " . htmlspecialchars( $this->numeric_version ) . " is OK.</li>\n";
215
216 $safeuser = $this->quote_ident($wgDBuser);
217 // Are we connecting as a superuser for the first time?
218 if ($wgDBsuperuser) {
219 // Are we really a superuser? Check out our rights
220 $SQL = "SELECT
221 CASE WHEN usesuper IS TRUE THEN
222 CASE WHEN usecreatedb IS TRUE THEN 3 ELSE 1 END
223 ELSE CASE WHEN usecreatedb IS TRUE THEN 2 ELSE 0 END
224 END AS rights
225 FROM pg_catalog.pg_user WHERE usename = " . $this->addQuotes($wgDBsuperuser);
226 $rows = $this->numRows($res = $this->doQuery($SQL));
227 if (!$rows) {
228 print "<li>ERROR: Could not read permissions for user \"" . htmlspecialchars( $wgDBsuperuser ) . "\"</li>\n";
229 dieout('</ul>');
230 }
231 $perms = pg_fetch_result($res, 0, 0);
232
233 $SQL = "SELECT 1 FROM pg_catalog.pg_user WHERE usename = " . $this->addQuotes($wgDBuser);
234 $rows = $this->numRows($this->doQuery($SQL));
235 if ($rows) {
236 print "<li>User \"" . htmlspecialchars( $wgDBuser ) . "\" already exists, skipping account creation.</li>";
237 }
238 else {
239 if ($perms != 1 and $perms != 3) {
240 print "<li>ERROR: the user \"" . htmlspecialchars( $wgDBsuperuser ) . "\" cannot create other users. ";
241 print 'Please use a different Postgres user.</li>';
242 dieout('</ul>');
243 }
244 print "<li>Creating user <b>" . htmlspecialchars( $wgDBuser ) . "</b>...";
245 $safepass = $this->addQuotes($wgDBpassword);
246 $SQL = "CREATE USER $safeuser NOCREATEDB PASSWORD $safepass";
247 $this->doQuery($SQL);
248 print "OK</li>\n";
249 }
250 // User now exists, check out the database
251 if ($dbName != $wgDBname) {
252 $SQL = "SELECT 1 FROM pg_catalog.pg_database WHERE datname = " . $this->addQuotes($wgDBname);
253 $rows = $this->numRows($this->doQuery($SQL));
254 if ($rows) {
255 print "<li>Database \"" . htmlspecialchars( $wgDBname ) . "\" already exists, skipping database creation.</li>";
256 }
257 else {
258 if ($perms < 2) {
259 print "<li>ERROR: the user \"" . htmlspecialchars( $wgDBsuperuser ) . "\" cannot create databases. ";
260 print 'Please use a different Postgres user.</li>';
261 dieout('</ul>');
262 }
263 print "<li>Creating database <b>" . htmlspecialchars( $wgDBname ) . "</b>...";
264 $safename = $this->quote_ident($wgDBname);
265 $SQL = "CREATE DATABASE $safename OWNER $safeuser ";
266 $this->doQuery($SQL);
267 print "OK</li>\n";
268 // Hopefully tsearch2 and plpgsql are in template1...
269 }
270
271 // Reconnect to check out tsearch2 rights for this user
272 print "<li>Connecting to \"" . htmlspecialchars( $wgDBname ) . "\" as superuser \"" .
273 htmlspecialchars( $wgDBsuperuser ) . "\" to check rights...";
274
275 $connectVars = array();
276 if ($this->mServer!=false && $this->mServer!="") {
277 $connectVars['host'] = $this->mServer;
278 }
279 if ($this->mPort!=false && $this->mPort!="") {
280 $connectVars['port'] = $this->mPort;
281 }
282 $connectVars['dbname'] = $wgDBname;
283 $connectVars['user'] = $wgDBsuperuser;
284 $connectVars['password'] = $password;
285
286 @$this->mConn = pg_connect( $this->makeConnectionString( $connectVars ) );
287 if ( $this->mConn == false ) {
288 print "<b>FAILED TO CONNECT!</b></li>";
289 dieout("</ul>");
290 }
291 print "OK</li>\n";
292 }
293
294 if ($this->numeric_version < 8.3) {
295 // Tsearch2 checks
296 print "<li>Checking that tsearch2 is installed in the database \"" .
297 htmlspecialchars( $wgDBname ) . "\"...";
298 if (! $this->tableExists("pg_ts_cfg", $wgDBts2schema)) {
299 print "<b>FAILED</b>. tsearch2 must be installed in the database \"" .
300 htmlspecialchars( $wgDBname ) . "\".";
301 print "Please see <a href='http://www.devx.com/opensource/Article/21674/0/page/2'>this article</a>";
302 print " for instructions or ask on #postgresql on irc.freenode.net</li>\n";
303 dieout("</ul>");
304 }
305 print "OK</li>\n";
306 print "<li>Ensuring that user \"" . htmlspecialchars( $wgDBuser ) .
307 "\" has select rights on the tsearch2 tables...";
308 foreach (array('cfg','cfgmap','dict','parser') as $table) {
309 $SQL = "GRANT SELECT ON pg_ts_$table TO $safeuser";
310 $this->doQuery($SQL);
311 }
312 print "OK</li>\n";
313 }
314
315 // Setup the schema for this user if needed
316 $result = $this->schemaExists($wgDBmwschema);
317 $safeschema = $this->quote_ident($wgDBmwschema);
318 if (!$result) {
319 print "<li>Creating schema <b>" . htmlspecialchars( $wgDBmwschema ) . "</b> ...";
320 $result = $this->doQuery("CREATE SCHEMA $safeschema AUTHORIZATION $safeuser");
321 if (!$result) {
322 print "<b>FAILED</b>.</li>\n";
323 dieout("</ul>");
324 }
325 print "OK</li>\n";
326 }
327 else {
328 print "<li>Schema already exists, explicitly granting rights...\n";
329 $safeschema2 = $this->addQuotes($wgDBmwschema);
330 $SQL = "SELECT 'GRANT ALL ON '||pg_catalog.quote_ident(relname)||' TO $safeuser;'\n".
331 "FROM pg_catalog.pg_class p, pg_catalog.pg_namespace n\n".
332 "WHERE relnamespace = n.oid AND n.nspname = $safeschema2\n".
333 "AND p.relkind IN ('r','S','v')\n";
334 $SQL .= "UNION\n";
335 $SQL .= "SELECT 'GRANT ALL ON FUNCTION '||pg_catalog.quote_ident(proname)||'('||\n".
336 "pg_catalog.oidvectortypes(p.proargtypes)||') TO $safeuser;'\n".
337 "FROM pg_catalog.pg_proc p, pg_catalog.pg_namespace n\n".
338 "WHERE p.pronamespace = n.oid AND n.nspname = $safeschema2";
339 $res = $this->doQuery($SQL);
340 if (!$res) {
341 print "<b>FAILED</b>. Could not set rights for the user.</li>\n";
342 dieout("</ul>");
343 }
344 $this->doQuery("SET search_path = $safeschema");
345 $rows = $this->numRows($res);
346 while ($rows) {
347 $rows--;
348 $this->doQuery(pg_fetch_result($res, $rows, 0));
349 }
350 print "OK</li>";
351 }
352
353 // Install plpgsql if needed
354 $this->setup_plpgsql();
355
356 $wgDBsuperuser = '';
357 return true; // Reconnect as regular user
358
359 } // end superuser
360
361 if (!defined('POSTGRES_SEARCHPATH')) {
362
363 if ($this->numeric_version < 8.3) {
364 // Do we have the basic tsearch2 table?
365 print "<li>Checking for tsearch2 in the schema \"" . htmlspecialchars( $wgDBts2schema ) . "\"...";
366 if (! $this->tableExists("pg_ts_dict", $wgDBts2schema)) {
367 print "<b>FAILED</b>. Make sure tsearch2 is installed. See <a href=";
368 print "'http://www.devx.com/opensource/Article/21674/0/page/2'>this article</a>";
369 print " for instructions.</li>\n";
370 dieout("</ul>");
371 }
372 print "OK</li>\n";
373
374 // Does this user have the rights to the tsearch2 tables?
375 $ctype = pg_fetch_result($this->doQuery("SHOW lc_ctype"),0,0);
376 print "<li>Checking tsearch2 permissions...";
377 // Let's check all four, just to be safe
378 error_reporting( 0 );
379 $ts2tables = array('cfg','cfgmap','dict','parser');
380 $safetsschema = $this->quote_ident($wgDBts2schema);
381 foreach ( $ts2tables AS $tname ) {
382 $SQL = "SELECT count(*) FROM $safetsschema.pg_ts_$tname";
383 $res = $this->doQuery($SQL);
384 if (!$res) {
385 print "<b>FAILED</b> to access " . htmlspecialchars( "pg_ts_$tname" ) .
386 ". Make sure that the user \"". htmlspecialchars( $wgDBuser ) .
387 "\" has SELECT access to all four tsearch2 tables</li>\n";
388 dieout("</ul>");
389 }
390 }
391 $SQL = "SELECT ts_name FROM $safetsschema.pg_ts_cfg WHERE locale = " . $this->addQuotes( $ctype ) ;
392 $SQL .= " ORDER BY CASE WHEN ts_name <> 'default' THEN 1 ELSE 0 END";
393 $res = $this->doQuery($SQL);
394 error_reporting( E_ALL );
395 if (!$res) {
396 print "<b>FAILED</b>. Could not determine the tsearch2 locale information</li>\n";
397 dieout("</ul>");
398 }
399 print "OK</li>";
400
401 // Will the current locale work? Can we force it to?
402 print "<li>Verifying tsearch2 locale with " . htmlspecialchars( $ctype ) . "...";
403 $rows = $this->numRows($res);
404 $resetlocale = 0;
405 if (!$rows) {
406 print "<b>not found</b></li>\n";
407 print "<li>Attempting to set default tsearch2 locale to \"" . htmlspecialchars( $ctype ) . "\"...";
408 $resetlocale = 1;
409 }
410 else {
411 $tsname = pg_fetch_result($res, 0, 0);
412 if ($tsname != 'default') {
413 print "<b>not set to default (" . htmlspecialchars( $tsname ) . ")</b>";
414 print "<li>Attempting to change tsearch2 default locale to \"" .
415 htmlspecialchars( $ctype ) . "\"...";
416 $resetlocale = 1;
417 }
418 }
419 if ($resetlocale) {
420 $SQL = "UPDATE $safetsschema.pg_ts_cfg SET locale = " . $this->addQuotes( $ctype ) . " WHERE ts_name = 'default'";
421 $res = $this->doQuery($SQL);
422 if (!$res) {
423 print "<b>FAILED</b>. ";
424 print "Please make sure that the locale in pg_ts_cfg for \"default\" is set to \"" .
425 htmlspecialchars( $ctype ) . "\"</li>\n";
426 dieout("</ul>");
427 }
428 print "OK</li>";
429 }
430
431 // Final test: try out a simple tsearch2 query
432 $SQL = "SELECT $safetsschema.to_tsvector('default','MediaWiki tsearch2 testing')";
433 $res = $this->doQuery($SQL);
434 if (!$res) {
435 print "<b>FAILED</b>. Specifically, \"" . htmlspecialchars( $SQL ) . "\" did not work.</li>";
436 dieout("</ul>");
437 }
438 print "OK</li>";
439 }
440
441 // Install plpgsql if needed
442 $this->setup_plpgsql();
443
444 // Does the schema already exist? Who owns it?
445 $result = $this->schemaExists($wgDBmwschema);
446 if (!$result) {
447 print "<li>Creating schema <b>" . htmlspecialchars( $wgDBmwschema ) . "</b> ...";
448 error_reporting( 0 );
449 $safeschema = $this->quote_ident($wgDBmwschema);
450 $result = $this->doQuery("CREATE SCHEMA $safeschema");
451 error_reporting( E_ALL );
452 if (!$result) {
453 print "<b>FAILED</b>. The user \"" . htmlspecialchars( $wgDBuser ) .
454 "\" must be able to access the schema. ".
455 "You can try making them the owner of the database, or try creating the schema with a ".
456 "different user, and then grant access to the \"" .
457 htmlspecialchars( $wgDBuser ) . "\" user.</li>\n";
458 dieout("</ul>");
459 }
460 print "OK</li>\n";
461 }
462 else if ($result != $wgDBuser) {
463 print "<li>Schema \"" . htmlspecialchars( $wgDBmwschema ) . "\" exists but is not owned by \"" .
464 htmlspecialchars( $wgDBuser ) . "\". Not ideal.</li>\n";
465 }
466 else {
467 print "<li>Schema \"" . htmlspecialchars( $wgDBmwschema ) . "\" exists and is owned by \"" .
468 htmlspecialchars( $wgDBuser ) . "\". Excellent.</li>\n";
469 }
470
471 // Always return GMT time to accomodate the existing integer-based timestamp assumption
472 print "<li>Setting the timezone to GMT for user \"" . htmlspecialchars( $wgDBuser ) . "\" ...";
473 $SQL = "ALTER USER $safeuser SET timezone = 'GMT'";
474 $result = pg_query($this->mConn, $SQL);
475 if (!$result) {
476 print "<b>FAILED</b>.</li>\n";
477 dieout("</ul>");
478 }
479 print "OK</li>\n";
480 // Set for the rest of this session
481 $SQL = "SET timezone = 'GMT'";
482 $result = pg_query($this->mConn, $SQL);
483 if (!$result) {
484 print "<li>Failed to set timezone</li>\n";
485 dieout("</ul>");
486 }
487
488 print "<li>Setting the datestyle to ISO, YMD for user \"" . htmlspecialchars( $wgDBuser ) . "\" ...";
489 $SQL = "ALTER USER $safeuser SET datestyle = 'ISO, YMD'";
490 $result = pg_query($this->mConn, $SQL);
491 if (!$result) {
492 print "<b>FAILED</b>.</li>\n";
493 dieout("</ul>");
494 }
495 print "OK</li>\n";
496 // Set for the rest of this session
497 $SQL = "SET datestyle = 'ISO, YMD'";
498 $result = pg_query($this->mConn, $SQL);
499 if (!$result) {
500 print "<li>Failed to set datestyle</li>\n";
501 dieout("</ul>");
502 }
503
504 // Fix up the search paths if needed
505 print "<li>Setting the search path for user \"" . htmlspecialchars( $wgDBuser ) . "\" ...";
506 $path = $this->quote_ident($wgDBmwschema);
507 if ($wgDBts2schema !== $wgDBmwschema)
508 $path .= ", ". $this->quote_ident($wgDBts2schema);
509 if ($wgDBmwschema !== 'public' and $wgDBts2schema !== 'public')
510 $path .= ", public";
511 $SQL = "ALTER USER $safeuser SET search_path = $path";
512 $result = pg_query($this->mConn, $SQL);
513 if (!$result) {
514 print "<b>FAILED</b>.</li>\n";
515 dieout("</ul>");
516 }
517 print "OK</li>\n";
518 // Set for the rest of this session
519 $SQL = "SET search_path = $path";
520 $result = pg_query($this->mConn, $SQL);
521 if (!$result) {
522 print "<li>Failed to set search_path</li>\n";
523 dieout("</ul>");
524 }
525 define( "POSTGRES_SEARCHPATH", $path );
526 }
527 }
528
529
530 function setup_plpgsql() {
531 print "<li>Checking for Pl/Pgsql ...";
532 $SQL = "SELECT 1 FROM pg_catalog.pg_language WHERE lanname = 'plpgsql'";
533 $rows = $this->numRows($this->doQuery($SQL));
534 if ($rows < 1) {
535 // plpgsql is not installed, but if we have a pg_pltemplate table, we should be able to create it
536 print "not installed. Attempting to install Pl/Pgsql ...";
537 $SQL = "SELECT 1 FROM pg_catalog.pg_class c JOIN pg_catalog.pg_namespace n ON (n.oid = c.relnamespace) ".
538 "WHERE relname = 'pg_pltemplate' AND nspname='pg_catalog'";
539 $rows = $this->numRows($this->doQuery($SQL));
540 if ($rows >= 1) {
541 $olde = error_reporting(0);
542 error_reporting($olde - E_WARNING);
543 $result = $this->doQuery("CREATE LANGUAGE plpgsql");
544 error_reporting($olde);
545 if (!$result) {
546 print "<b>FAILED</b>. You need to install the language plpgsql in the database <tt>" .
547 htmlspecialchars( $wgDBname ) . "</tt></li>";
548 dieout("</ul>");
549 }
550 }
551 else {
552 print "<b>FAILED</b>. You need to install the language plpgsql in the database <tt>" .
553 htmlspecialchars( $wgDBname ) . "</tt></li>";
554 dieout("</ul>");
555 }
556 }
557 print "OK</li>\n";
558 }
559
560
561 /**
562 * Closes a database connection, if it is open
563 * Returns success, true if already closed
564 */
565 function close() {
566 $this->mOpened = false;
567 if ( $this->mConn ) {
568 return pg_close( $this->mConn );
569 } else {
570 return true;
571 }
572 }
573
574 function doQuery( $sql ) {
575 if (function_exists('mb_convert_encoding')) {
576 $sql = mb_convert_encoding($sql,'UTF-8');
577 }
578 $this->mLastResult = pg_query( $this->mConn, $sql);
579 $this->mAffectedRows = NULL; // use pg_affected_rows(mLastResult)
580 return $this->mLastResult;
581 }
582
583 function queryIgnore( $sql, $fname = '' ) {
584 return $this->query( $sql, $fname, true );
585 }
586
587 function freeResult( $res ) {
588 if ( $res instanceof ResultWrapper ) {
589 $res = $res->result;
590 }
591 if ( !@pg_free_result( $res ) ) {
592 throw new DBUnexpectedError($this, "Unable to free Postgres result\n" );
593 }
594 }
595
596 function fetchObject( $res ) {
597 if ( $res instanceof ResultWrapper ) {
598 $res = $res->result;
599 }
600 @$row = pg_fetch_object( $res );
601 # FIXME: HACK HACK HACK HACK debug
602
603 # TODO:
604 # hashar : not sure if the following test really trigger if the object
605 # fetching failed.
606 if( pg_last_error($this->mConn) ) {
607 throw new DBUnexpectedError($this, 'SQL error: ' . htmlspecialchars( pg_last_error($this->mConn) ) );
608 }
609 return $row;
610 }
611
612 function fetchRow( $res ) {
613 if ( $res instanceof ResultWrapper ) {
614 $res = $res->result;
615 }
616 @$row = pg_fetch_array( $res );
617 if( pg_last_error($this->mConn) ) {
618 throw new DBUnexpectedError($this, 'SQL error: ' . htmlspecialchars( pg_last_error($this->mConn) ) );
619 }
620 return $row;
621 }
622
623 function numRows( $res ) {
624 if ( $res instanceof ResultWrapper ) {
625 $res = $res->result;
626 }
627 @$n = pg_num_rows( $res );
628 if( pg_last_error($this->mConn) ) {
629 throw new DBUnexpectedError($this, 'SQL error: ' . htmlspecialchars( pg_last_error($this->mConn) ) );
630 }
631 return $n;
632 }
633 function numFields( $res ) {
634 if ( $res instanceof ResultWrapper ) {
635 $res = $res->result;
636 }
637 return pg_num_fields( $res );
638 }
639 function fieldName( $res, $n ) {
640 if ( $res instanceof ResultWrapper ) {
641 $res = $res->result;
642 }
643 return pg_field_name( $res, $n );
644 }
645
646 /**
647 * This must be called after nextSequenceVal
648 */
649 function insertId() {
650 return $this->mInsertId;
651 }
652
653 function dataSeek( $res, $row ) {
654 if ( $res instanceof ResultWrapper ) {
655 $res = $res->result;
656 }
657 return pg_result_seek( $res, $row );
658 }
659
660 function lastError() {
661 if ( $this->mConn ) {
662 return pg_last_error();
663 }
664 else {
665 return "No database connection";
666 }
667 }
668 function lastErrno() {
669 return pg_last_error() ? 1 : 0;
670 }
671
672 function affectedRows() {
673 if ( !is_null( $this->mAffectedRows ) ) {
674 // Forced result for simulated queries
675 return $this->mAffectedRows;
676 }
677 if( empty( $this->mLastResult ) )
678 return 0;
679 return pg_affected_rows( $this->mLastResult );
680 }
681
682 /**
683 * Estimate rows in dataset
684 * Returns estimated count, based on EXPLAIN output
685 * This is not necessarily an accurate estimate, so use sparingly
686 * Returns -1 if count cannot be found
687 * Takes same arguments as Database::select()
688 */
689
690 function estimateRowCount( $table, $vars='*', $conds='', $fname = 'Database::estimateRowCount', $options = array() ) {
691 $options['EXPLAIN'] = true;
692 $res = $this->select( $table, $vars, $conds, $fname, $options );
693 $rows = -1;
694 if ( $res ) {
695 $row = $this->fetchRow( $res );
696 $count = array();
697 if( preg_match( '/rows=(\d+)/', $row[0], $count ) ) {
698 $rows = $count[1];
699 }
700 $this->freeResult($res);
701 }
702 return $rows;
703 }
704
705
706 /**
707 * Returns information about an index
708 * If errors are explicitly ignored, returns NULL on failure
709 */
710 function indexInfo( $table, $index, $fname = 'Database::indexExists' ) {
711 $sql = "SELECT indexname FROM pg_indexes WHERE tablename='$table'";
712 $res = $this->query( $sql, $fname );
713 if ( !$res ) {
714 return NULL;
715 }
716 while ( $row = $this->fetchObject( $res ) ) {
717 if ( $row->indexname == $this->indexName( $index ) ) {
718 return $row;
719 }
720 }
721 return false;
722 }
723
724 function indexUnique ($table, $index, $fname = 'Database::indexUnique' ) {
725 $sql = "SELECT indexname FROM pg_indexes WHERE tablename='{$table}'".
726 " AND indexdef LIKE 'CREATE UNIQUE%(" .
727 $this->strencode( $this->indexName( $index ) ) .
728 ")'";
729 $res = $this->query( $sql, $fname );
730 if ( !$res )
731 return NULL;
732 while ($row = $this->fetchObject( $res ))
733 return true;
734 return false;
735
736 }
737
738 /**
739 * INSERT wrapper, inserts an array into a table
740 *
741 * $args may be a single associative array, or an array of these with numeric keys,
742 * for multi-row insert (Postgres version 8.2 and above only).
743 *
744 * @param $table String: Name of the table to insert to.
745 * @param $args Array: Items to insert into the table.
746 * @param $fname String: Name of the function, for profiling
747 * @param $options String or Array. Valid options: IGNORE
748 *
749 * @return bool Success of insert operation. IGNORE always returns true.
750 */
751 function insert( $table, $args, $fname = 'DatabasePostgres::insert', $options = array() ) {
752 global $wgDBversion;
753
754 if ( !count( $args ) ) {
755 return true;
756 }
757
758 $table = $this->tableName( $table );
759 if (! isset( $wgDBversion ) ) {
760 $wgDBversion = $this->getServerVersion();
761 }
762
763 if ( !is_array( $options ) )
764 $options = array( $options );
765
766 if ( isset( $args[0] ) && is_array( $args[0] ) ) {
767 $multi = true;
768 $keys = array_keys( $args[0] );
769 }
770 else {
771 $multi = false;
772 $keys = array_keys( $args );
773 }
774
775 // If IGNORE is set, we use savepoints to emulate mysql's behavior
776 $ignore = in_array( 'IGNORE', $options ) ? 'mw' : '';
777
778 // If we are not in a transaction, we need to be for savepoint trickery
779 $didbegin = 0;
780 if ( $ignore ) {
781 if (! $this->mTrxLevel) {
782 $this->begin();
783 $didbegin = 1;
784 }
785 $olde = error_reporting( 0 );
786 // For future use, we may want to track the number of actual inserts
787 // Right now, insert (all writes) simply return true/false
788 $numrowsinserted = 0;
789 }
790
791 $sql = "INSERT INTO $table (" . implode( ',', $keys ) . ') VALUES ';
792
793 if ( $multi ) {
794 if ( $wgDBversion >= 8.2 && !$ignore ) {
795 $first = true;
796 foreach ( $args as $row ) {
797 if ( $first ) {
798 $first = false;
799 } else {
800 $sql .= ',';
801 }
802 $sql .= '(' . $this->makeList( $row ) . ')';
803 }
804 $res = (bool)$this->query( $sql, $fname, $ignore );
805 }
806 else {
807 $res = true;
808 $origsql = $sql;
809 foreach ( $args as $row ) {
810 $tempsql = $origsql;
811 $tempsql .= '(' . $this->makeList( $row ) . ')';
812
813 if ( $ignore ) {
814 pg_query($this->mConn, "SAVEPOINT $ignore");
815 }
816
817 $tempres = (bool)$this->query( $tempsql, $fname, $ignore );
818
819 if ( $ignore ) {
820 $bar = pg_last_error();
821 if ($bar != false) {
822 pg_query( $this->mConn, "ROLLBACK TO $ignore" );
823 }
824 else {
825 pg_query( $this->mConn, "RELEASE $ignore" );
826 $numrowsinserted++;
827 }
828 }
829
830 // If any of them fail, we fail overall for this function call
831 // Note that this will be ignored if IGNORE is set
832 if (! $tempres)
833 $res = false;
834 }
835 }
836 }
837 else {
838 // Not multi, just a lone insert
839 if ( $ignore ) {
840 pg_query($this->mConn, "SAVEPOINT $ignore");
841 }
842
843 $sql .= '(' . $this->makeList( $args ) . ')';
844 $res = (bool)$this->query( $sql, $fname, $ignore );
845 if ( $ignore ) {
846 $bar = pg_last_error();
847 if ($bar != false) {
848 pg_query( $this->mConn, "ROLLBACK TO $ignore" );
849 }
850 else {
851 pg_query( $this->mConn, "RELEASE $ignore" );
852 $numrowsinserted++;
853 }
854 }
855 }
856 if ( $ignore ) {
857 $olde = error_reporting( $olde );
858 if ($didbegin) {
859 $this->commit();
860 }
861
862 // Set the affected row count for the whole operation
863 $this->mAffectedRows = $numrowsinserted;
864
865 // IGNORE always returns true
866 return true;
867 }
868
869
870 return $res;
871
872 }
873
874 function tableName( $name ) {
875 # Replace reserved words with better ones
876 switch( $name ) {
877 case 'user':
878 return 'mwuser';
879 case 'text':
880 return 'pagecontent';
881 default:
882 return $name;
883 }
884 }
885
886 /**
887 * Return the next in a sequence, save the value for retrieval via insertId()
888 */
889 function nextSequenceValue( $seqName ) {
890 $safeseq = preg_replace( "/'/", "''", $seqName );
891 $res = $this->query( "SELECT nextval('$safeseq')" );
892 $row = $this->fetchRow( $res );
893 $this->mInsertId = $row[0];
894 $this->freeResult( $res );
895 return $this->mInsertId;
896 }
897
898 /**
899 * Return the current value of a sequence. Assumes it has ben nextval'ed in this session.
900 */
901 function currentSequenceValue( $seqName ) {
902 $safeseq = preg_replace( "/'/", "''", $seqName );
903 $res = $this->query( "SELECT currval('$safeseq')" );
904 $row = $this->fetchRow( $res );
905 $currval = $row[0];
906 $this->freeResult( $res );
907 return $currval;
908 }
909
910 /**
911 * Postgres does not have a "USE INDEX" clause, so return an empty string
912 */
913 function useIndexClause( $index ) {
914 return '';
915 }
916
917 # REPLACE query wrapper
918 # Postgres simulates this with a DELETE followed by INSERT
919 # $row is the row to insert, an associative array
920 # $uniqueIndexes is an array of indexes. Each element may be either a
921 # field name or an array of field names
922 #
923 # It may be more efficient to leave off unique indexes which are unlikely to collide.
924 # However if you do this, you run the risk of encountering errors which wouldn't have
925 # occurred in MySQL
926 function replace( $table, $uniqueIndexes, $rows, $fname = 'Database::replace' ) {
927 $table = $this->tableName( $table );
928
929 if (count($rows)==0) {
930 return;
931 }
932
933 # Single row case
934 if ( !is_array( reset( $rows ) ) ) {
935 $rows = array( $rows );
936 }
937
938 foreach( $rows as $row ) {
939 # Delete rows which collide
940 if ( $uniqueIndexes ) {
941 $sql = "DELETE FROM $table WHERE ";
942 $first = true;
943 foreach ( $uniqueIndexes as $index ) {
944 if ( $first ) {
945 $first = false;
946 $sql .= "(";
947 } else {
948 $sql .= ') OR (';
949 }
950 if ( is_array( $index ) ) {
951 $first2 = true;
952 foreach ( $index as $col ) {
953 if ( $first2 ) {
954 $first2 = false;
955 } else {
956 $sql .= ' AND ';
957 }
958 $sql .= $col.'=' . $this->addQuotes( $row[$col] );
959 }
960 } else {
961 $sql .= $index.'=' . $this->addQuotes( $row[$index] );
962 }
963 }
964 $sql .= ')';
965 $this->query( $sql, $fname );
966 }
967
968 # Now insert the row
969 $sql = "INSERT INTO $table (" . $this->makeList( array_keys( $row ), LIST_NAMES ) .') VALUES (' .
970 $this->makeList( $row, LIST_COMMA ) . ')';
971 $this->query( $sql, $fname );
972 }
973 }
974
975 # DELETE where the condition is a join
976 function deleteJoin( $delTable, $joinTable, $delVar, $joinVar, $conds, $fname = "Database::deleteJoin" ) {
977 if ( !$conds ) {
978 throw new DBUnexpectedError($this, 'Database::deleteJoin() called with empty $conds' );
979 }
980
981 $delTable = $this->tableName( $delTable );
982 $joinTable = $this->tableName( $joinTable );
983 $sql = "DELETE FROM $delTable WHERE $delVar IN (SELECT $joinVar FROM $joinTable ";
984 if ( $conds != '*' ) {
985 $sql .= 'WHERE ' . $this->makeList( $conds, LIST_AND );
986 }
987 $sql .= ')';
988
989 $this->query( $sql, $fname );
990 }
991
992 # Returns the size of a text field, or -1 for "unlimited"
993 function textFieldSize( $table, $field ) {
994 $table = $this->tableName( $table );
995 $sql = "SELECT t.typname as ftype,a.atttypmod as size
996 FROM pg_class c, pg_attribute a, pg_type t
997 WHERE relname='$table' AND a.attrelid=c.oid AND
998 a.atttypid=t.oid and a.attname='$field'";
999 $res =$this->query($sql);
1000 $row=$this->fetchObject($res);
1001 if ($row->ftype=="varchar") {
1002 $size=$row->size-4;
1003 } else {
1004 $size=$row->size;
1005 }
1006 $this->freeResult( $res );
1007 return $size;
1008 }
1009
1010 function lowPriorityOption() {
1011 return '';
1012 }
1013
1014 function limitResult($sql, $limit, $offset=false) {
1015 return "$sql LIMIT $limit ".(is_numeric($offset)?" OFFSET {$offset} ":"");
1016 }
1017
1018 /**
1019 * Returns an SQL expression for a simple conditional.
1020 * Uses CASE on Postgres
1021 *
1022 * @param $cond String: SQL expression which will result in a boolean value
1023 * @param $trueVal String: SQL expression to return if true
1024 * @param $falseVal String: SQL expression to return if false
1025 * @return String: SQL fragment
1026 */
1027 function conditional( $cond, $trueVal, $falseVal ) {
1028 return " (CASE WHEN $cond THEN $trueVal ELSE $falseVal END) ";
1029 }
1030
1031 function wasDeadlock() {
1032 return $this->lastErrno() == '40P01';
1033 }
1034
1035 function timestamp( $ts=0 ) {
1036 return wfTimestamp(TS_POSTGRES,$ts);
1037 }
1038
1039 /**
1040 * Return aggregated value function call
1041 */
1042 function aggregateValue ($valuedata,$valuename='value') {
1043 return $valuedata;
1044 }
1045
1046
1047 function reportQueryError( $error, $errno, $sql, $fname, $tempIgnore = false ) {
1048 // Ignore errors during error handling to avoid infinite recursion
1049 $ignore = $this->ignoreErrors( true );
1050 $this->mErrorCount++;
1051
1052 if ($ignore || $tempIgnore) {
1053 wfDebug("SQL ERROR (ignored): $error\n");
1054 $this->ignoreErrors( $ignore );
1055 }
1056 else {
1057 $message = "A database error has occurred\n" .
1058 "Query: $sql\n" .
1059 "Function: $fname\n" .
1060 "Error: $errno $error\n";
1061 throw new DBUnexpectedError($this, $message);
1062 }
1063 }
1064
1065 /**
1066 * @return string wikitext of a link to the server software's web site
1067 */
1068 function getSoftwareLink() {
1069 return "[http://www.postgresql.org/ PostgreSQL]";
1070 }
1071
1072 /**
1073 * @return string Version information from the database
1074 */
1075 function getServerVersion() {
1076 $versionInfo = pg_version( $this->mConn );
1077 if ( isset( $versionInfo['server'] ) ) {
1078 $this->numeric_version = $versionInfo['server'];
1079 } else {
1080 // There's no way to identify the precise version before 7.4, but
1081 // it doesn't matter anyway since we're just going to give an error.
1082 $this->numeric_version = '7.3 or earlier';
1083 }
1084 return $this->numeric_version;
1085 }
1086
1087 /**
1088 * Query whether a given relation exists (in the given schema, or the
1089 * default mw one if not given)
1090 */
1091 function relationExists( $table, $types, $schema = false ) {
1092 global $wgDBmwschema;
1093 if (!is_array($types))
1094 $types = array($types);
1095 if (! $schema )
1096 $schema = $wgDBmwschema;
1097 $etable = $this->addQuotes($table);
1098 $eschema = $this->addQuotes($schema);
1099 $SQL = "SELECT 1 FROM pg_catalog.pg_class c, pg_catalog.pg_namespace n "
1100 . "WHERE c.relnamespace = n.oid AND c.relname = $etable AND n.nspname = $eschema "
1101 . "AND c.relkind IN ('" . implode("','", $types) . "')";
1102 $res = $this->query( $SQL );
1103 $count = $res ? $res->numRows() : 0;
1104 if ($res)
1105 $this->freeResult( $res );
1106 return $count ? true : false;
1107 }
1108
1109 /*
1110 * For backward compatibility, this function checks both tables and
1111 * views.
1112 */
1113 function tableExists ($table, $schema = false) {
1114 return $this->relationExists($table, array('r', 'v'), $schema);
1115 }
1116
1117 function sequenceExists ($sequence, $schema = false) {
1118 return $this->relationExists($sequence, 'S', $schema);
1119 }
1120
1121 function triggerExists($table, $trigger) {
1122 global $wgDBmwschema;
1123
1124 $q = <<<END
1125 SELECT 1 FROM pg_class, pg_namespace, pg_trigger
1126 WHERE relnamespace=pg_namespace.oid AND relkind='r'
1127 AND tgrelid=pg_class.oid
1128 AND nspname=%s AND relname=%s AND tgname=%s
1129 END;
1130 $res = $this->query(sprintf($q,
1131 $this->addQuotes($wgDBmwschema),
1132 $this->addQuotes($table),
1133 $this->addQuotes($trigger)));
1134 if (!$res)
1135 return NULL;
1136 $rows = $res->numRows();
1137 $this->freeResult($res);
1138 return $rows;
1139 }
1140
1141 function ruleExists($table, $rule) {
1142 global $wgDBmwschema;
1143 $exists = $this->selectField("pg_rules", "rulename",
1144 array( "rulename" => $rule,
1145 "tablename" => $table,
1146 "schemaname" => $wgDBmwschema));
1147 return $exists === $rule;
1148 }
1149
1150 function constraintExists($table, $constraint) {
1151 global $wgDBmwschema;
1152 $SQL = sprintf("SELECT 1 FROM information_schema.table_constraints ".
1153 "WHERE constraint_schema = %s AND table_name = %s AND constraint_name = %s",
1154 $this->addQuotes($wgDBmwschema),
1155 $this->addQuotes($table),
1156 $this->addQuotes($constraint));
1157 $res = $this->query($SQL);
1158 if (!$res)
1159 return NULL;
1160 $rows = $res->numRows();
1161 $this->freeResult($res);
1162 return $rows;
1163 }
1164
1165 /**
1166 * Query whether a given schema exists. Returns the name of the owner
1167 */
1168 function schemaExists( $schema ) {
1169 $eschema = preg_replace("/'/", "''", $schema);
1170 $SQL = "SELECT rolname FROM pg_catalog.pg_namespace n, pg_catalog.pg_roles r "
1171 ."WHERE n.nspowner=r.oid AND n.nspname = '$eschema'";
1172 $res = $this->query( $SQL );
1173 if ( $res && $res->numRows() ) {
1174 $row = $res->fetchObject();
1175 $owner = $row->rolname;
1176 } else {
1177 $owner = false;
1178 }
1179 if ($res)
1180 $this->freeResult($res);
1181 return $owner;
1182 }
1183
1184 /**
1185 * Query whether a given column exists in the mediawiki schema
1186 */
1187 function fieldExists( $table, $field, $fname = 'DatabasePostgres::fieldExists' ) {
1188 global $wgDBmwschema;
1189 $etable = preg_replace("/'/", "''", $table);
1190 $eschema = preg_replace("/'/", "''", $wgDBmwschema);
1191 $ecol = preg_replace("/'/", "''", $field);
1192 $SQL = "SELECT 1 FROM pg_catalog.pg_class c, pg_catalog.pg_namespace n, pg_catalog.pg_attribute a "
1193 . "WHERE c.relnamespace = n.oid AND c.relname = '$etable' AND n.nspname = '$eschema' "
1194 . "AND a.attrelid = c.oid AND a.attname = '$ecol'";
1195 $res = $this->query( $SQL, $fname );
1196 $count = $res ? $res->numRows() : 0;
1197 if ($res)
1198 $this->freeResult( $res );
1199 return $count;
1200 }
1201
1202 function fieldInfo( $table, $field ) {
1203 return PostgresField::fromText($this, $table, $field);
1204 }
1205
1206 /**
1207 * pg_field_type() wrapper
1208 */
1209 function fieldType( $res, $index ) {
1210 if ( $res instanceof ResultWrapper ) {
1211 $res = $res->result;
1212 }
1213 return pg_field_type( $res, $index );
1214 }
1215
1216 function begin( $fname = 'DatabasePostgres::begin' ) {
1217 $this->query( 'BEGIN', $fname );
1218 $this->mTrxLevel = 1;
1219 }
1220 function immediateCommit( $fname = 'DatabasePostgres::immediateCommit' ) {
1221 return true;
1222 }
1223 function commit( $fname = 'DatabasePostgres::commit' ) {
1224 $this->query( 'COMMIT', $fname );
1225 $this->mTrxLevel = 0;
1226 }
1227
1228 /* Not even sure why this is used in the main codebase... */
1229 function limitResultForUpdate($sql, $num) {
1230 return $sql;
1231 }
1232
1233 function setup_database() {
1234 global $wgVersion, $wgDBmwschema, $wgDBts2schema, $wgDBport, $wgDBuser;
1235
1236 // Make sure that we can write to the correct schema
1237 // If not, Postgres will happily and silently go to the next search_path item
1238 $ctest = "mediawiki_test_table";
1239 $safeschema = $this->quote_ident($wgDBmwschema);
1240 if ($this->tableExists($ctest, $wgDBmwschema)) {
1241 $this->doQuery("DROP TABLE $safeschema.$ctest");
1242 }
1243 $SQL = "CREATE TABLE $safeschema.$ctest(a int)";
1244 $olde = error_reporting( 0 );
1245 $res = $this->doQuery($SQL);
1246 error_reporting( $olde );
1247 if (!$res) {
1248 print "<b>FAILED</b>. Make sure that the user \"" . htmlspecialchars( $wgDBuser ) .
1249 "\" can write to the schema \"" . htmlspecialchars( $wgDBmwschema ) . "\"</li>\n";
1250 dieout("</ul>");
1251 }
1252 $this->doQuery("DROP TABLE $safeschema.$ctest");
1253
1254 $res = dbsource( "../maintenance/postgres/tables.sql", $this);
1255
1256 ## Update version information
1257 $mwv = $this->addQuotes($wgVersion);
1258 $pgv = $this->addQuotes($this->getServerVersion());
1259 $pgu = $this->addQuotes($this->mUser);
1260 $mws = $this->addQuotes($wgDBmwschema);
1261 $tss = $this->addQuotes($wgDBts2schema);
1262 $pgp = $this->addQuotes($wgDBport);
1263 $dbn = $this->addQuotes($this->mDBname);
1264 $ctype = $this->addQuotes( pg_fetch_result($this->doQuery("SHOW lc_ctype"),0,0) );
1265
1266 $SQL = "UPDATE mediawiki_version SET mw_version=$mwv, pg_version=$pgv, pg_user=$pgu, ".
1267 "mw_schema = $mws, ts2_schema = $tss, pg_port=$pgp, pg_dbname=$dbn, ".
1268 "ctype = $ctype ".
1269 "WHERE type = 'Creation'";
1270 $this->query($SQL);
1271
1272 ## Avoid the non-standard "REPLACE INTO" syntax
1273 $f = fopen( "../maintenance/interwiki.sql", 'r' );
1274 if ($f == false ) {
1275 dieout( "<li>Could not find the interwiki.sql file");
1276 }
1277 ## We simply assume it is already empty as we have just created it
1278 $SQL = "INSERT INTO interwiki(iw_prefix,iw_url,iw_local) VALUES ";
1279 while ( ! feof( $f ) ) {
1280 $line = fgets($f,1024);
1281 $matches = array();
1282 if (!preg_match('/^\s*(\(.+?),(\d)\)/', $line, $matches)) {
1283 continue;
1284 }
1285 $this->query("$SQL $matches[1],$matches[2])");
1286 }
1287 print " (table interwiki successfully populated)...\n";
1288
1289 $this->doQuery("COMMIT");
1290 }
1291
1292 function encodeBlob( $b ) {
1293 return new Blob ( pg_escape_bytea( $b ) ) ;
1294 }
1295
1296 function decodeBlob( $b ) {
1297 if ($b instanceof Blob) {
1298 $b = $b->fetch();
1299 }
1300 return pg_unescape_bytea( $b );
1301 }
1302
1303 function strencode( $s ) { ## Should not be called by us
1304 return pg_escape_string( $s );
1305 }
1306
1307 function addQuotes( $s ) {
1308 if ( is_null( $s ) ) {
1309 return 'NULL';
1310 } else if ( is_bool( $s ) ) {
1311 return intval( $s );
1312 } else if ($s instanceof Blob) {
1313 return "'".$s->fetch($s)."'";
1314 }
1315 return "'" . pg_escape_string($s) . "'";
1316 }
1317
1318 function quote_ident( $s ) {
1319 return '"' . preg_replace( '/"/', '""', $s) . '"';
1320 }
1321
1322 /* For now, does nothing */
1323 function selectDB( $db ) {
1324 return true;
1325 }
1326
1327 /**
1328 * Postgres specific version of replaceVars.
1329 * Calls the parent version in Database.php
1330 *
1331 * @private
1332 *
1333 * @param $ins String: SQL string, read from a stream (usually tables.sql)
1334 *
1335 * @return string SQL string
1336 */
1337 protected function replaceVars( $ins ) {
1338
1339 $ins = parent::replaceVars( $ins );
1340
1341 if ($this->numeric_version >= 8.3) {
1342 // Thanks for not providing backwards-compatibility, 8.3
1343 $ins = preg_replace( "/to_tsvector\s*\(\s*'default'\s*,/", 'to_tsvector(', $ins );
1344 }
1345
1346 if ($this->numeric_version <= 8.1) { // Our minimum version
1347 $ins = str_replace( 'USING gin', 'USING gist', $ins );
1348 }
1349
1350 return $ins;
1351 }
1352
1353 /**
1354 * Various select options
1355 *
1356 * @private
1357 *
1358 * @param $options Array: an associative array of options to be turned into
1359 * an SQL query, valid keys are listed in the function.
1360 * @return array
1361 */
1362 function makeSelectOptions( $options ) {
1363 $preLimitTail = $postLimitTail = '';
1364 $startOpts = $useIndex = '';
1365
1366 $noKeyOptions = array();
1367 foreach ( $options as $key => $option ) {
1368 if ( is_numeric( $key ) ) {
1369 $noKeyOptions[$option] = true;
1370 }
1371 }
1372
1373 if ( isset( $options['GROUP BY'] ) ) $preLimitTail .= " GROUP BY " . $options['GROUP BY'];
1374 if ( isset( $options['HAVING'] ) ) $preLimitTail .= " HAVING {$options['HAVING']}";
1375 if ( isset( $options['ORDER BY'] ) ) $preLimitTail .= " ORDER BY " . $options['ORDER BY'];
1376
1377 //if (isset($options['LIMIT'])) {
1378 // $tailOpts .= $this->limitResult('', $options['LIMIT'],
1379 // isset($options['OFFSET']) ? $options['OFFSET']
1380 // : false);
1381 //}
1382
1383 if ( isset( $noKeyOptions['FOR UPDATE'] ) ) $postLimitTail .= ' FOR UPDATE';
1384 if ( isset( $noKeyOptions['LOCK IN SHARE MODE'] ) ) $postLimitTail .= ' LOCK IN SHARE MODE';
1385 if ( isset( $noKeyOptions['DISTINCT'] ) || isset( $noKeyOptions['DISTINCTROW'] ) ) $startOpts .= 'DISTINCT';
1386
1387 return array( $startOpts, $useIndex, $preLimitTail, $postLimitTail );
1388 }
1389
1390 public function setTimeout( $timeout ) {
1391 // @todo fixme no-op
1392 }
1393
1394 function ping() {
1395 wfDebug( "Function ping() not written for DatabasePostgres.php yet");
1396 return true;
1397 }
1398
1399 /**
1400 * How lagged is this slave?
1401 *
1402 */
1403 public function getLag() {
1404 # Not implemented for PostgreSQL
1405 return false;
1406 }
1407
1408 function setFakeSlaveLag( $lag ) {}
1409 function setFakeMaster( $enabled = true ) {}
1410
1411 function getDBname() {
1412 return $this->mDBname;
1413 }
1414
1415 function getServer() {
1416 return $this->mServer;
1417 }
1418
1419 function buildConcat( $stringList ) {
1420 return implode( ' || ', $stringList );
1421 }
1422
1423 /* These are not used yet, but we know we don't want the default version */
1424
1425 public function lock( $lockName, $method ) {
1426 return true;
1427 }
1428 public function unlock( $lockName, $method ) {
1429 return true;
1430 }
1431
1432 public function getSearchEngine() {
1433 return "SearchPostgres";
1434 }
1435
1436 } // end DatabasePostgres class