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