File: Postgres72.php

package info (click to toggle)
phppgadmin 4.2.3-1.1squeeze2
  • links: PTS, VCS
  • area: main
  • in suites: squeeze
  • size: 5,396 kB
  • ctags: 6,174
  • sloc: php: 68,599; makefile: 215; sh: 41; sql: 16; awk: 9
file content (688 lines) | stat: -rw-r--r-- 20,008 bytes parent folder | download
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
316
317
318
319
320
321
322
323
324
325
326
327
328
329
330
331
332
333
334
335
336
337
338
339
340
341
342
343
344
345
346
347
348
349
350
351
352
353
354
355
356
357
358
359
360
361
362
363
364
365
366
367
368
369
370
371
372
373
374
375
376
377
378
379
380
381
382
383
384
385
386
387
388
389
390
391
392
393
394
395
396
397
398
399
400
401
402
403
404
405
406
407
408
409
410
411
412
413
414
415
416
417
418
419
420
421
422
423
424
425
426
427
428
429
430
431
432
433
434
435
436
437
438
439
440
441
442
443
444
445
446
447
448
449
450
451
452
453
454
455
456
457
458
459
460
461
462
463
464
465
466
467
468
469
470
471
472
473
474
475
476
477
478
479
480
481
482
483
484
485
486
487
488
489
490
491
492
493
494
495
496
497
498
499
500
501
502
503
504
505
506
507
508
509
510
511
512
513
514
515
516
517
518
519
520
521
522
523
524
525
526
527
528
529
530
531
532
533
534
535
536
537
538
539
540
541
542
543
544
545
546
547
548
549
550
551
552
553
554
555
556
557
558
559
560
561
562
563
564
565
566
567
568
569
570
571
572
573
574
575
576
577
578
579
580
581
582
583
584
585
586
587
588
589
590
591
592
593
594
595
596
597
598
599
600
601
602
603
604
605
606
607
608
609
610
611
612
613
614
615
616
617
618
619
620
621
622
623
624
625
626
627
628
629
630
631
632
633
634
635
636
637
638
639
640
641
642
643
644
645
646
647
648
649
650
651
652
653
654
655
656
657
658
659
660
661
662
663
664
665
666
667
668
669
670
671
672
673
674
675
676
677
678
679
680
681
682
683
684
685
686
687
688
<?php

/**
 * A class that implements the DB interface for Postgres
 * Note: This class uses ADODB and returns RecordSets.
 *
 * $Id: Postgres72.php,v 1.94 2007/12/12 04:11:10 xzilla Exp $
 */


include_once('./classes/database/Postgres71.php');

class Postgres72 extends Postgres71 {

	var $major_version = 7.2;

	// Set the maximum built-in ID.
	var $_lastSystemOID = 16554;

	// List of all legal privileges that can be applied to different types
	// of objects.
	var $privlist = array(
		'table' => array('SELECT', 'INSERT', 'UPDATE', 'DELETE', 'RULE', 'REFERENCES', 'TRIGGER', 'ALL PRIVILEGES'),
		'view' => array('SELECT', 'INSERT', 'UPDATE', 'DELETE', 'RULE', 'REFERENCES', 'TRIGGER', 'ALL PRIVILEGES'),
		'sequence' => array('SELECT', 'UPDATE', 'ALL PRIVILEGES')
	);

	// Extra "magic" types.  BIGSERIAL was added in PostgreSQL 7.2.
	var $extraTypes = array('SERIAL', 'BIGSERIAL');

	/**
	 * Constructor
	 * @param $conn The database connection
	 */
	function Postgres72($conn) {
		$this->Postgres71($conn);

		// Correct the error in the encoding tables, that was
		// fixed in PostgreSQL 7.2
		$this->codemap['LATIN5'] = 'ISO-8859-9';
	}

	// Help functions

	function getHelpPages() {
		include_once('./help/PostgresDoc72.php');
		return $this->help_page;
	}

	// User functions

	/**
	 * Helper function that computes encypted PostgreSQL passwords
	 * @param $username The username
	 * @param $password The password
	 */
	function _encryptPassword($username, $password) {
		return 'md5' . md5($password . $username);
	}

	/**
	 * Changes a user's password
	 * @param $username The username
	 * @param $password The new password
	 * @return 0 success
	 */
	function changePassword($username, $password) {
		$enc = $this->_encryptPassword($username, $password);
		$this->fieldClean($username);
		$this->clean($enc);

		$sql = "ALTER USER \"{$username}\" WITH ENCRYPTED PASSWORD '{$enc}'";

		return $this->execute($sql);
	}

	/**
	 * Creates a new user
	 * @param $username The username of the user to create
	 * @param $password A password for the user
	 * @param $createdb boolean Whether or not the user can create databases
	 * @param $createuser boolean Whether or not the user can create other users
	 * @param $expiry string Format 'YYYY-MM-DD HH:MM:SS'.  '' means never expire
	 * @param $group (array) The groups to create the user in
	 * @return 0 success
	 */
	function createUser($username, $password, $createdb, $createuser, $expiry, $groups) {
		$enc = $this->_encryptPassword($username, $password);
		$this->fieldClean($username);
		$this->clean($enc);
		$this->clean($expiry);
		$this->fieldArrayClean($groups);

		$sql = "CREATE USER \"{$username}\"";
		if ($password != '') $sql .= " WITH ENCRYPTED PASSWORD '{$enc}'";
		$sql .= ($createdb) ? ' CREATEDB' : ' NOCREATEDB';
		$sql .= ($createuser) ? ' CREATEUSER' : ' NOCREATEUSER';
		if (is_array($groups) && sizeof($groups) > 0) $sql .= " IN GROUP \"" . join('", "', $groups) . "\"";
		if ($expiry != '') $sql .= " VALID UNTIL '{$expiry}'";
		else $sql .= " VALID UNTIL 'infinity'";

		return $this->execute($sql);
	}

	/**
	 * Adjusts a user's info
	 * @param $username The username of the user to modify
	 * @param $password A new password for the user
	 * @param $createdb boolean Whether or not the user can create databases
	 * @param $createuser boolean Whether or not the user can create other users
	 * @param $expiry string Format 'YYYY-MM-DD HH:MM:SS'.  '' means never expire.
	 * @return 0 success
	 */
	function setUser($username, $password, $createdb, $createuser, $expiry) {
		$enc = $this->_encryptPassword($username, $password);
		$this->fieldClean($username);
		$this->clean($enc);
		$this->clean($expiry);

		$sql = "ALTER USER \"{$username}\"";
		if ($password != '') $sql .= " WITH ENCRYPTED PASSWORD '{$enc}'";
		$sql .= ($createdb) ? ' CREATEDB' : ' NOCREATEDB';
		$sql .= ($createuser) ? ' CREATEUSER' : ' NOCREATEUSER';
		if ($expiry != '') $sql .= " VALID UNTIL '{$expiry}'";
		else $sql .= " VALID UNTIL 'infinity'";

		return $this->execute($sql);
	}

	/**
	 * Returns all available process information.
	 * @param $database (optional) Find only connections to specified database
	 * @return A recordset
	 */
	function getProcesses($database = null) {
		if ($database === null)
			$sql = "SELECT * FROM pg_stat_activity ORDER BY datname, usename, procpid";
		else {
			$this->clean($database);
			$sql = "SELECT * FROM pg_stat_activity WHERE datname='{$database}' ORDER BY usename, procpid";
		}

		return $this->selectSet($sql);
	}

	// Table functions

	/**
	 * Returns the SQL for changing the current user
	 * @param $user The user to change to
	 * @return The SQL
	 */
	function getChangeUserSQL($user) {
		$this->clean($user);
		return "SET SESSION AUTHORIZATION '{$user}';";
	}

	/**
	 * Checks to see whether or not a table has a unique id column
	 * @param $table The table name
	 * @return True if it has a unique id, false otherwise
	 * @return null error
	 */
	function hasObjectID($table) {
		$this->clean($table);

		$sql = "SELECT relhasoids FROM pg_class WHERE relname='{$table}'";

		$rs = $this->selectSet($sql);
		if ($rs->recordCount() != 1) return null;
		else {
			$rs->fields['relhasoids'] = $this->phpBool($rs->fields['relhasoids']);
			return $rs->fields['relhasoids'];
		}
	}

	/**
	 * Returns table information
	 * @param $table The name of the table
	 * @return A recordset
	 */
	function getTable($table) {
		$this->clean($table);

		$sql = "SELECT pc.relname,
			pg_get_userbyid(pc.relowner) AS relowner,
			(SELECT description FROM pg_description pd
                        WHERE pc.oid=pd.objoid AND objsubid = 0) AS relcomment
			FROM pg_class pc
			WHERE pc.relname='{$table}'";

		return $this->selectSet($sql);
	}

	/**
	 * Return all tables in current database
	 * @param $all True to fetch all tables, false for just in current schema
	 * @return All tables, sorted alphabetically
	 */
	function getTables($all = false) {
		global $conf;
		if (!$conf['show_system'] || $all) $where = "AND c.relname NOT LIKE 'pg\\\\_%' ";
		else $where = '';

		$sql = "SELECT NULL AS nspname, c.relname,
					(SELECT usename FROM pg_user u WHERE u.usesysid=c.relowner) AS relowner,
					(SELECT description FROM pg_description pd WHERE c.oid=pd.objoid AND objsubid = 0) AS relcomment,
					reltuples::numeric
			 FROM pg_class c WHERE c.relkind='r' {$where}ORDER BY relname";
		return $this->selectSet($sql);
	}

	/**
	 * Retrieve the attribute definition of a table
	 * @param $table The name of the table
	 * @param $field (optional) The name of a field to return
	 * @return All attributes in order
	 */
	function getTableAttributes($table, $field = '') {
		$this->clean($table);
		$this->clean($field);

		if ($field == '') {
			$sql = "
				SELECT
					a.attname,
					format_type(a.atttypid, a.atttypmod) as type, a.atttypmod,
					a.attnotnull, a.atthasdef, adef.adsrc,
					-1 AS attstattarget, a.attstorage, t.typstorage, false AS attisserial,
                                        description as comment
				FROM
					pg_attribute a LEFT JOIN pg_attrdef adef
					ON a.attrelid=adef.adrelid AND a.attnum=adef.adnum
					LEFT JOIN pg_type t ON a.atttypid=t.oid
                                        LEFT JOIN pg_description d ON (a.attrelid = d.objoid AND a.attnum = d.objsubid)
				WHERE
					a.attrelid = (SELECT oid FROM pg_class WHERE relname='{$table}')
					AND a.attnum > 0
				ORDER BY a.attnum";
		}
		else {
			$sql = "
				SELECT
					a.attname,
					format_type(a.atttypid, a.atttypmod) as type,
					format_type(a.atttypid, NULL) as base_type,
					a.atttypmod,
					a.attnotnull, a.atthasdef, adef.adsrc,
					-1 AS attstattarget, a.attstorage, t.typstorage,
                                        description as comment
				FROM
					pg_attribute a LEFT JOIN pg_attrdef adef
					ON a.attrelid=adef.adrelid AND a.attnum=adef.adnum
					LEFT JOIN pg_type t ON a.atttypid=t.oid
                                        LEFT JOIN pg_description d ON (a.attrelid = d.objoid AND a.attnum = d.objsubid)
				WHERE
					a.attrelid = (SELECT oid FROM pg_class WHERE relname='{$table}')
					AND a.attname = '{$field}'";
		}

		return $this->selectSet($sql);
	}

	// View functions

	/**
	 * Returns a list of all views in the database
	 * @return All views
	 */
	function getViews() {
		global $conf;

		if (!$conf['show_system'])
			$where = " WHERE viewname NOT LIKE 'pg\\\\_%'";
		else
			$where = '';

		$sql = "SELECT viewname AS relname, viewowner AS relowner, definition AS vwdefinition,
			      (SELECT description FROM pg_description pd, pg_class pc
			       WHERE pc.oid=pd.objoid AND pc.relname=v.viewname AND pd.objsubid = 0) AS relcomment
			FROM pg_views v
			{$where}
			ORDER BY relname";

		return $this->selectSet($sql);
	}

	/**
	 * Returns all details for a particular view
	 * @param $view The name of the view to retrieve
	 * @return View info
	 */
	function getView($view) {
		$this->clean($view);

		$sql = "SELECT viewname AS relname, NULL AS nspname, viewowner AS relowner, definition AS vwdefinition,
			  (SELECT description FROM pg_description pd, pg_class pc
			    WHERE pc.oid=pd.objoid AND pc.relname=v.viewname AND pd.objsubid = 0) AS relcomment
			FROM pg_views v
			WHERE viewname='{$view}'";

		return $this->selectSet($sql);
	}

	// Constraint functions

	/**
	 * Removes a constraint from a relation
	 * @param $constraint The constraint to drop
	 * @param $relation The relation from which to drop
	 * @param $type The type of constraint (c, f, u or p)
	 * @param $cascade True to cascade drop, false to restrict
	 * @return 0 success
	 * @return -99 dropping foreign keys not supported
	 */
	function dropConstraint($constraint, $relation, $type, $cascade) {
		$this->fieldClean($constraint);
		$this->fieldClean($relation);

		switch ($type) {
			case 'c':
				// CHECK constraint
				$sql = "ALTER TABLE \"{$relation}\" DROP CONSTRAINT \"{$constraint}\" RESTRICT";

				return $this->execute($sql);
				break;
			case 'p':
			case 'u':
				// PRIMARY KEY or UNIQUE constraint
				return $this->dropIndex($constraint, $cascade);
				break;
			case 'f':
				// FOREIGN KEY constraint
				return -99;
		}
	}

	/**
	 * Adds a unique constraint to a table
	 * @param $table The table to which to add the unique key
	 * @param $fields (array) An array of fields over which to add the unique key
	 * @param $name (optional) The name to give the key, otherwise default name is assigned
	 * @param $tablespace (optional) The tablespace for the schema, '' indicates default.
	 * @return 0 success
	 * @return -1 no fields given
	 */
	function addUniqueKey($table, $fields, $name = '', $tablespace = '') {
		if (!is_array($fields) || sizeof($fields) == 0) return -1;
		$this->fieldClean($table);
		$this->fieldArrayClean($fields);
		$this->fieldClean($name);
		$this->fieldClean($tablespace);

		$schema = $this->schema();

		$sql = "ALTER TABLE {$schema}\"{$table}\" ADD ";
		if ($name != '') $sql .= "CONSTRAINT \"{$name}\" ";
		$sql .= "UNIQUE (\"" . join('","', $fields) . "\")";

		if ($tablespace != '' && $this->hasTablespaces())
			$sql .= " USING INDEX TABLESPACE \"{$tablespace}\"";

		return $this->execute($sql);
	}

	/**
	 * Adds a primary key constraint to a table
	 * @param $table The table to which to add the primery key
	 * @param $fields (array) An array of fields over which to add the primary key
	 * @param $name (optional) The name to give the key, otherwise default name is assigned
	 * @param $tablespace (optional) The tablespace for the schema, '' indicates default.
	 * @return 0 success
	 * @return -1 no fields given
	 */
	function addPrimaryKey($table, $fields, $name = '', $tablespace = '') {
		if (!is_array($fields) || sizeof($fields) == 0) return -1;
		$this->fieldClean($table);
		$this->fieldArrayClean($fields);
		$this->fieldClean($name);
		$this->fieldClean($tablespace);

		$schema = $this->schema();

		$sql = "ALTER TABLE {$schema}\"{$table}\" ADD ";
		if ($name != '') $sql .= "CONSTRAINT \"{$name}\" ";
		$sql .= "PRIMARY KEY (\"" . join('","', $fields) . "\")";

		if ($tablespace != '' && $this->hasTablespaces())
			$sql .= " USING INDEX TABLESPACE \"{$tablespace}\"";

		return $this->execute($sql);
	}

	// Function functions

	/**
	 * Returns a list of all functions in the database
 	 * @param $all If true, will find all available functions, if false just userland ones
	 * @return All functions
	 */
	function getFunctions($all = false) {
		if ($all)
			$where = '';
		else
			$where = "AND p.oid > '{$this->_lastSystemOID}'";

		$sql = "SELECT
				p.oid AS prooid,
				p.proname,
				false AS proretset,
				format_type(p.prorettype, NULL) AS proresult,
				oidvectortypes(p.proargtypes) AS proarguments,
				pl.lanname AS prolanguage,
				(SELECT description FROM pg_description pd WHERE p.oid=pd.objoid) AS procomment,
				p.proname || ' (' || oidvectortypes(p.proargtypes) || ')' AS proproto,
				format_type(p.prorettype, NULL) AS proreturns
			FROM
				pg_proc p, pg_language pl
			WHERE
				p.prolang = pl.oid AND
				(pronargs = 0 OR oidvectortypes(p.proargtypes) <> '')
				{$where}
			ORDER BY
				p.proname, proresult
			";

		return $this->selectSet($sql);
	}

	/**
	 * Updates (replaces) a function.
	 * @param $function_oid The OID of the function
	 * @param $funcname The name of the function to create
	 * @param $newname The new name for the function
	 * @param $args The array of argument types
	 * @param $returns The return type
	 * @param $definition The definition for the new function
	 * @param $language The language the function is written for
	 * @param $flags An array of optional flags
	 * @param $setof True if returns a set, false otherwise
	 * @param $comment The comment on the function
	 * @return 0 success
	 * @return -1 transaction error
	 * @return -2 drop function error
	 * @return -3 create function error
	 * @return -4 comment error
	 */
	function setFunction($function_oid, $funcname, $newname, $args, $returns, $definition, $language, $flags, $setof, $rows, $cost, $comment) {
		// Begin a transaction
		$status = $this->beginTransaction();
		if ($status != 0) {
			$this->rollbackTransaction();
			return -1;
		}

		// Replace the existing function
		if ($funcname != $newname) {
			$status = $this->dropFunction($function_oid, false);
			if ($status != 0) {
				$this->rollbackTransaction();
				return -2;
			}

			$status = $this->createFunction($newname, $args, $returns, $definition, $language, $flags, $setof, $cost, $rows, false);
			if ($status != 0) {
				$this->rollbackTransaction();
				return -3;
			}
		} else {
			$status = $this->createFunction($funcname, $args, $returns, $definition, $language, $flags, $setof, $cost, $rows, true);
			if ($status != 0) {
				$this->rollbackTransaction();
				return -3;
			}
		}

		// Comment on the function
		$this->fieldClean($newname);
		$this->clean($comment);
		$status = $this->setComment('FUNCTION', "\"{$newname}\"({$args})", null, $comment);
		if ($status != 0) {
			$this->rollbackTransaction();
			return -4;
		}

		return $this->endTransaction();
	}

	// Type functions

	/**
	 * Returns a list of all types in the database
	 * @param $all If true, will find all available functions, if false just those in search path
	 * @param $tabletypes If true, will include table types
	 * @param $domains Ignored
	 * @return A recordet
	 */
	function getTypes($all = false, $tabletypes = false, $domains = false) {
		global $conf;

		if ($all || $conf['show_system']) {
			$where = '';
		} else {
			$where = "AND pt.oid > '{$this->_lastSystemOID}'::oid";
		}
		// Never show system table types
		$where2 = "AND c.oid > '{$this->_lastSystemOID}'::oid";

		// Create type filter
		$tqry = "'c'";
		if ($tabletypes)
			$tqry .= ", 'r', 'v'";

		$sql = "SELECT
				pt.typname AS basename,
				format_type(pt.oid, NULL) AS typname,
				pu.usename AS typowner,
				(SELECT description FROM pg_description pd WHERE pt.oid=pd.objoid) AS typcomment
			FROM
				pg_type pt,
				pg_user pu
			WHERE
				pt.typowner = pu.usesysid
				AND (pt.typrelid = 0 OR (SELECT c.relkind IN ({$tqry}) FROM pg_class c WHERE c.oid = pt.typrelid {$where2}))
				AND typname !~ '^_'
				{$where}
			ORDER BY typname
		";

		return $this->selectSet($sql);
	}

	// Opclass functions

	/**
	 * Gets all opclasses
	 * @return A recordset
	 */
	function getOpClasses() {
		global $conf;

		if ($conf['show_system'])
			$where = '';
		else
			$where = "AND po.oid > '{$this->_lastSystemOID}'::oid";

		$sql = "
			SELECT DISTINCT
				pa.amname,
				po.opcname,
				format_type(po.opcintype, NULL) AS opcintype,
				TRUE AS opcdefault,
				NULL::text AS opccomment
			FROM
				pg_opclass po, pg_am pa
			WHERE
				po.opcamid=pa.oid
				{$where}
			ORDER BY 1,2
		";

		return $this->selectSet($sql);
	}

	// Administration functions

	/**
	 * Vacuums a database
	 * @param $table The table to vacuum
 	 * @param $analyze If true, also does analyze
	 * @param $full If true, selects "full" vacuum (PostgreSQL >= 7.2)
	 * @param $freeze If true, selects aggressive "freezing" of tuples (PostgreSQL >= 7.2)
	 */
	function vacuumDB($table = '', $analyze = false, $full = false, $freeze = false) {
		$sql = "VACUUM";
		if ($full) $sql .= " FULL";
		if ($freeze) $sql .= " FREEZE";
		if ($analyze) $sql .= " ANALYZE";
		if ($table != '') {
			$this->fieldClean($table);
			$sql .= " \"{$table}\"";
		}

		return $this->execute($sql);
	}

	/**
	 * Analyze a database
	 * @note PostgreSQL 7.2 finally had an independent ANALYZE command
	 * @param $table (optional) The table to analyze
	 */
	function analyzeDB($table = '') {
		if ($table != '') {
			$this->fieldClean($table);
			$sql = "ANALYZE \"{$table}\"";
		}
		else
			$sql = "ANALYZE";

		return $this->execute($sql);
	}

	// Statistics collector functions

	/**
	 * Fetches statistics for a database
	 * @param $database The database to fetch stats for
	 * @return A recordset
	 */
	function getStatsDatabase($database) {
		$this->clean($database);

		$sql = "SELECT * FROM pg_stat_database WHERE datname='{$database}'";

		return $this->selectSet($sql);
	}

	/**
	 * Fetches tuple statistics for a table
	 * @param $table The table to fetch stats for
	 * @return A recordset
	 */
	function getStatsTableTuples($table) {
		$this->clean($table);

		$sql = 'SELECT * FROM pg_stat_all_tables WHERE';
		if ($this->hasSchemas()) $sql .= " schemaname='{$this->_schema}' AND";
		$sql .= " relname='{$table}'";

		return $this->selectSet($sql);
	}

	/**
	 * Fetches I/0 statistics for a table
	 * @param $table The table to fetch stats for
	 * @return A recordset
	 */
	function getStatsTableIO($table) {
		$this->clean($table);

		$sql = 'SELECT * FROM pg_statio_all_tables WHERE';
		if ($this->hasSchemas()) $sql .= " schemaname='{$this->_schema}' AND";
		$sql .= " relname='{$table}'";

		return $this->selectSet($sql);
	}

	/**
	 * Fetches tuple statistics for all indexes on a table
	 * @param $table The table to fetch index stats for
	 * @return A recordset
	 */
	function getStatsIndexTuples($table) {
		$this->clean($table);

		$sql = 'SELECT * FROM pg_stat_all_indexes WHERE';
		if ($this->hasSchemas()) $sql .= " schemaname='{$this->_schema}' AND";
		$sql .= " relname='{$table}' ORDER BY indexrelname";

		return $this->selectSet($sql);
	}

	/**
	 * Fetches I/0 statistics for all indexes on a table
	 * @param $table The table to fetch index stats for
	 * @return A recordset
	 */
	function getStatsIndexIO($table) {
		$this->clean($table);

		$sql = 'SELECT * FROM pg_statio_all_indexes WHERE';
		if ($this->hasSchemas()) $sql .= " schemaname='{$this->_schema}' AND";
		$sql .= " relname='{$table}' ORDER BY indexrelname";

		return $this->selectSet($sql);
	}

	// Capabilities
	function hasWithoutOIDs() { return true; }
	function hasPartialIndexes() { return true; }
	function hasProcesses() { return true; }
	function hasStatsCollector() { return true; }
	function hasFullVacuum() { return true; }
	function hasAnalyze() { return true; }

}

?>