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