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