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