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