MDL-36204 Improve moodle1 conversion of embedded files
[moodle.git] / lib / dml / pgsql_native_moodle_database.php
blob9c43a16e54b3267becad7ccef694a012bb84cd4a
1 <?php
2 // This file is part of Moodle - http://moodle.org/
3 //
4 // Moodle is free software: you can redistribute it and/or modify
5 // it under the terms of the GNU General Public License as published by
6 // the Free Software Foundation, either version 3 of the License, or
7 // (at your option) any later version.
8 //
9 // Moodle is distributed in the hope that it will be useful,
10 // but WITHOUT ANY WARRANTY; without even the implied warranty of
11 // MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the
12 // GNU General Public License for more details.
14 // You should have received a copy of the GNU General Public License
15 // along with Moodle. If not, see <http://www.gnu.org/licenses/>.
17 /**
18 * Native pgsql class representing moodle database interface.
20 * @package core_dml
21 * @copyright 2008 Petr Skoda (http://skodak.org)
22 * @license http://www.gnu.org/copyleft/gpl.html GNU GPL v3 or later
25 defined('MOODLE_INTERNAL') || die();
27 require_once(__DIR__.'/moodle_database.php');
28 require_once(__DIR__.'/pgsql_native_moodle_recordset.php');
29 require_once(__DIR__.'/pgsql_native_moodle_temptables.php');
31 /**
32 * Native pgsql class representing moodle database interface.
34 * @package core_dml
35 * @copyright 2008 Petr Skoda (http://skodak.org)
36 * @license http://www.gnu.org/copyleft/gpl.html GNU GPL v3 or later
38 class pgsql_native_moodle_database extends moodle_database {
40 protected $pgsql = null;
41 protected $bytea_oid = null;
43 protected $last_error_reporting; // To handle pgsql driver default verbosity
45 /** @var bool savepoint hack for MDL-35506 - workaround for automatic transaction rollback on error */
46 protected $savepointpresent = false;
48 /**
49 * Detects if all needed PHP stuff installed.
50 * Note: can be used before connect()
51 * @return mixed true if ok, string if something
53 public function driver_installed() {
54 if (!extension_loaded('pgsql')) {
55 return get_string('pgsqlextensionisnotpresentinphp', 'install');
57 return true;
60 /**
61 * Returns database family type - describes SQL dialect
62 * Note: can be used before connect()
63 * @return string db family name (mysql, postgres, mssql, oracle, etc.)
65 public function get_dbfamily() {
66 return 'postgres';
69 /**
70 * Returns more specific database driver type
71 * Note: can be used before connect()
72 * @return string db type mysqli, pgsql, oci, mssql, sqlsrv
74 protected function get_dbtype() {
75 return 'pgsql';
78 /**
79 * Returns general database library name
80 * Note: can be used before connect()
81 * @return string db type pdo, native
83 protected function get_dblibrary() {
84 return 'native';
87 /**
88 * Returns localised database type name
89 * Note: can be used before connect()
90 * @return string
92 public function get_name() {
93 return get_string('nativepgsql', 'install');
96 /**
97 * Returns localised database configuration help.
98 * Note: can be used before connect()
99 * @return string
101 public function get_configuration_help() {
102 return get_string('nativepgsqlhelp', 'install');
106 * Returns localised database description
107 * Note: can be used before connect()
108 * @return string
110 public function get_configuration_hints() {
111 return get_string('databasesettingssub_postgres7', 'install');
115 * Connect to db
116 * Must be called before other methods.
117 * @param string $dbhost The database host.
118 * @param string $dbuser The database username.
119 * @param string $dbpass The database username's password.
120 * @param string $dbname The name of the database being connected to.
121 * @param mixed $prefix string means moodle db prefix, false used for external databases where prefix not used
122 * @param array $dboptions driver specific options
123 * @return bool true
124 * @throws dml_connection_exception if error
126 public function connect($dbhost, $dbuser, $dbpass, $dbname, $prefix, array $dboptions=null) {
127 if ($prefix == '' and !$this->external) {
128 //Enforce prefixes for everybody but mysql
129 throw new dml_exception('prefixcannotbeempty', $this->get_dbfamily());
132 $driverstatus = $this->driver_installed();
134 if ($driverstatus !== true) {
135 throw new dml_exception('dbdriverproblem', $driverstatus);
138 $this->store_settings($dbhost, $dbuser, $dbpass, $dbname, $prefix, $dboptions);
140 $pass = addcslashes($this->dbpass, "'\\");
142 // Unix socket connections should have lower overhead
143 if (!empty($this->dboptions['dbsocket']) and ($this->dbhost === 'localhost' or $this->dbhost === '127.0.0.1')) {
144 $connection = "user='$this->dbuser' password='$pass' dbname='$this->dbname'";
145 if (strpos($this->dboptions['dbsocket'], '/') !== false) {
146 $connection = $connection." host='".$this->dboptions['dbsocket']."'";
148 } else {
149 $this->dboptions['dbsocket'] = '';
150 if (empty($this->dbname)) {
151 // probably old style socket connection - do not add port
152 $port = "";
153 } else if (empty($this->dboptions['dbport'])) {
154 $port = "port ='5432'";
155 } else {
156 $port = "port ='".$this->dboptions['dbport']."'";
158 $connection = "host='$this->dbhost' $port user='$this->dbuser' password='$pass' dbname='$this->dbname'";
161 ob_start();
162 if (empty($this->dboptions['dbpersist'])) {
163 $this->pgsql = pg_connect($connection, PGSQL_CONNECT_FORCE_NEW);
164 } else {
165 $this->pgsql = pg_pconnect($connection, PGSQL_CONNECT_FORCE_NEW);
167 $dberr = ob_get_contents();
168 ob_end_clean();
170 $status = pg_connection_status($this->pgsql);
172 if ($status === false or $status === PGSQL_CONNECTION_BAD) {
173 $this->pgsql = null;
174 throw new dml_connection_exception($dberr);
177 $this->query_start("--pg_set_client_encoding()", null, SQL_QUERY_AUX);
178 pg_set_client_encoding($this->pgsql, 'utf8');
179 $this->query_end(true);
181 $sql = '';
182 // Only for 9.0 and upwards, set bytea encoding to old format.
183 if ($this->is_min_version('9.0')) {
184 $sql = "SET bytea_output = 'escape'; ";
187 // Find out the bytea oid.
188 $sql .= "SELECT oid FROM pg_type WHERE typname = 'bytea'";
189 $this->query_start($sql, null, SQL_QUERY_AUX);
190 $result = pg_query($this->pgsql, $sql);
191 $this->query_end($result);
193 $this->bytea_oid = pg_fetch_result($result, 0, 0);
194 pg_free_result($result);
195 if ($this->bytea_oid === false) {
196 $this->pgsql = null;
197 throw new dml_connection_exception('Can not read bytea type.');
200 // Connection stabilised and configured, going to instantiate the temptables controller
201 $this->temptables = new pgsql_native_moodle_temptables($this);
203 return true;
207 * Close database connection and release all resources
208 * and memory (especially circular memory references).
209 * Do NOT use connect() again, create a new instance if needed.
211 public function dispose() {
212 parent::dispose(); // Call parent dispose to write/close session and other common stuff before closing connection
213 if ($this->pgsql) {
214 pg_close($this->pgsql);
215 $this->pgsql = null;
221 * Called before each db query.
222 * @param string $sql
223 * @param array array of parameters
224 * @param int $type type of query
225 * @param mixed $extrainfo driver specific extra information
226 * @return void
228 protected function query_start($sql, array $params=null, $type, $extrainfo=null) {
229 parent::query_start($sql, $params, $type, $extrainfo);
230 // pgsql driver tents to send debug to output, we do not need that ;-)
231 $this->last_error_reporting = error_reporting(0);
235 * Called immediately after each db query.
236 * @param mixed db specific result
237 * @return void
239 protected function query_end($result) {
240 // reset original debug level
241 error_reporting($this->last_error_reporting);
242 try {
243 parent::query_end($result);
244 if ($this->savepointpresent and $this->last_type != SQL_QUERY_AUX and $this->last_type != SQL_QUERY_SELECT) {
245 $res = @pg_query($this->pgsql, "RELEASE SAVEPOINT moodle_pg_savepoint; SAVEPOINT moodle_pg_savepoint");
246 if ($res) {
247 pg_free_result($res);
250 } catch (Exception $e) {
251 if ($this->savepointpresent) {
252 $res = @pg_query($this->pgsql, "ROLLBACK TO SAVEPOINT moodle_pg_savepoint; SAVEPOINT moodle_pg_savepoint");
253 if ($res) {
254 pg_free_result($res);
257 throw $e;
262 * Returns database server info array
263 * @return array Array containing 'description' and 'version' info
265 public function get_server_info() {
266 static $info;
267 if (!$info) {
268 $this->query_start("--pg_version()", null, SQL_QUERY_AUX);
269 $info = pg_version($this->pgsql);
270 $this->query_end(true);
272 return array('description'=>$info['server'], 'version'=>$info['server']);
276 * Returns if the RDBMS server fulfills the required version
278 * @param string $version version to check against
279 * @return bool returns if the version is fulfilled (true) or no (false)
281 private function is_min_version($version) {
282 $server = $this->get_server_info();
283 $server = $server['version'];
284 return version_compare($server, $version, '>=');
288 * Returns supported query parameter types
289 * @return int bitmask of accepted SQL_PARAMS_*
291 protected function allowed_param_types() {
292 return SQL_PARAMS_DOLLAR;
296 * Returns last error reported by database engine.
297 * @return string error message
299 public function get_last_error() {
300 return pg_last_error($this->pgsql);
304 * Return tables in database WITHOUT current prefix.
305 * @param bool $usecache if true, returns list of cached tables.
306 * @return array of table names in lowercase and without prefix
308 public function get_tables($usecache=true) {
309 if ($usecache and $this->tables !== null) {
310 return $this->tables;
312 $this->tables = array();
313 $prefix = str_replace('_', '|_', $this->prefix);
314 if ($this->is_min_version('9.1')) {
315 // Use ANSI standard information_schema in recent versions where it is fast enough.
316 $sql = "SELECT table_name
317 FROM information_schema.tables
318 WHERE table_name LIKE '$prefix%' ESCAPE '|'
319 AND table_type IN ('BASE TABLE', 'LOCAL TEMPORARY')";
320 } else {
321 // information_schema is horribly slow in <= 9.0, so use pg internals.
322 // Note the pg_is_other_temp_schema. We only want temp objects from our own session.
323 $sql = "SELECT c.relname
324 FROM pg_class c
325 WHERE c.relname LIKE '$prefix%' ESCAPE '|'
326 AND c.relkind = 'r'
327 AND NOT pg_is_other_temp_schema(c.relnamespace)";
329 $this->query_start($sql, null, SQL_QUERY_AUX);
330 $result = pg_query($this->pgsql, $sql);
331 $this->query_end($result);
333 if ($result) {
334 while ($row = pg_fetch_row($result)) {
335 $tablename = reset($row);
336 if ($this->prefix !== '') {
337 if (strpos($tablename, $this->prefix) !== 0) {
338 continue;
340 $tablename = substr($tablename, strlen($this->prefix));
342 $this->tables[$tablename] = $tablename;
344 pg_free_result($result);
346 return $this->tables;
350 * Return table indexes - everything lowercased.
351 * @param string $table The table we want to get indexes from.
352 * @return array of arrays
354 public function get_indexes($table) {
355 $indexes = array();
356 $tablename = $this->prefix.$table;
358 $sql = "SELECT *
359 FROM pg_catalog.pg_indexes
360 WHERE tablename = '$tablename'";
362 $this->query_start($sql, null, SQL_QUERY_AUX);
363 $result = pg_query($this->pgsql, $sql);
364 $this->query_end($result);
366 if ($result) {
367 while ($row = pg_fetch_assoc($result)) {
368 if (!preg_match('/CREATE (|UNIQUE )INDEX ([^\s]+) ON '.$tablename.' USING ([^\s]+) \(([^\)]+)\)/i', $row['indexdef'], $matches)) {
369 continue;
371 if ($matches[4] === 'id') {
372 continue;
374 $columns = explode(',', $matches[4]);
375 foreach ($columns as $k=>$column) {
376 $column = trim($column);
377 if ($pos = strpos($column, ' ')) {
378 // index type is separated by space
379 $column = substr($column, 0, $pos);
381 $columns[$k] = $this->trim_quotes($column);
383 $indexes[$row['indexname']] = array('unique'=>!empty($matches[1]),
384 'columns'=>$columns);
386 pg_free_result($result);
388 return $indexes;
392 * Returns detailed information about columns in table. This information is cached internally.
393 * @param string $table name
394 * @param bool $usecache
395 * @return array array of database_column_info objects indexed with column names
397 public function get_columns($table, $usecache=true) {
398 if ($usecache) {
399 $properties = array('dbfamily' => $this->get_dbfamily(), 'settings' => $this->get_settings_hash());
400 $cache = cache::make('core', 'databasemeta', $properties);
401 if ($data = $cache->get($table)) {
402 return $data;
406 $structure = array();
408 $tablename = $this->prefix.$table;
410 $sql = "SELECT a.attnum, a.attname AS field, t.typname AS type, a.attlen, a.atttypmod, a.attnotnull, a.atthasdef, d.adsrc
411 FROM pg_catalog.pg_class c
412 JOIN pg_catalog.pg_attribute a ON a.attrelid = c.oid
413 JOIN pg_catalog.pg_type t ON t.oid = a.atttypid
414 LEFT JOIN pg_catalog.pg_attrdef d ON (d.adrelid = c.oid AND d.adnum = a.attnum)
415 WHERE relkind = 'r' AND c.relname = '$tablename' AND c.reltype > 0 AND a.attnum > 0
416 ORDER BY a.attnum";
418 $this->query_start($sql, null, SQL_QUERY_AUX);
419 $result = pg_query($this->pgsql, $sql);
420 $this->query_end($result);
422 if (!$result) {
423 return array();
425 while ($rawcolumn = pg_fetch_object($result)) {
427 $info = new stdClass();
428 $info->name = $rawcolumn->field;
429 $matches = null;
431 if ($rawcolumn->type === 'varchar') {
432 $info->type = 'varchar';
433 $info->meta_type = 'C';
434 $info->max_length = $rawcolumn->atttypmod - 4;
435 $info->scale = null;
436 $info->not_null = ($rawcolumn->attnotnull === 't');
437 $info->has_default = ($rawcolumn->atthasdef === 't');
438 if ($info->has_default) {
439 $parts = explode('::', $rawcolumn->adsrc);
440 if (count($parts) > 1) {
441 $info->default_value = reset($parts);
442 $info->default_value = trim($info->default_value, "'");
443 } else {
444 $info->default_value = $rawcolumn->adsrc;
446 } else {
447 $info->default_value = null;
449 $info->primary_key = false;
450 $info->binary = false;
451 $info->unsigned = null;
452 $info->auto_increment= false;
453 $info->unique = null;
455 } else if (preg_match('/int(\d)/i', $rawcolumn->type, $matches)) {
456 $info->type = 'int';
457 if (strpos($rawcolumn->adsrc, 'nextval') === 0) {
458 $info->primary_key = true;
459 $info->meta_type = 'R';
460 $info->unique = true;
461 $info->auto_increment= true;
462 $info->has_default = false;
463 } else {
464 $info->primary_key = false;
465 $info->meta_type = 'I';
466 $info->unique = null;
467 $info->auto_increment= false;
468 $info->has_default = ($rawcolumn->atthasdef === 't');
470 // Return number of decimals, not bytes here.
471 if ($matches[1] >= 8) {
472 $info->max_length = 18;
473 } else if ($matches[1] >= 4) {
474 $info->max_length = 9;
475 } else if ($matches[1] >= 2) {
476 $info->max_length = 4;
477 } else if ($matches[1] >= 1) {
478 $info->max_length = 2;
479 } else {
480 $info->max_length = 0;
482 $info->scale = null;
483 $info->not_null = ($rawcolumn->attnotnull === 't');
484 if ($info->has_default) {
485 $info->default_value = trim($rawcolumn->adsrc, '()');
486 } else {
487 $info->default_value = null;
489 $info->binary = false;
490 $info->unsigned = false;
492 } else if ($rawcolumn->type === 'numeric') {
493 $info->type = $rawcolumn->type;
494 $info->meta_type = 'N';
495 $info->primary_key = false;
496 $info->binary = false;
497 $info->unsigned = null;
498 $info->auto_increment= false;
499 $info->unique = null;
500 $info->not_null = ($rawcolumn->attnotnull === 't');
501 $info->has_default = ($rawcolumn->atthasdef === 't');
502 if ($info->has_default) {
503 $info->default_value = trim($rawcolumn->adsrc, '()');
504 } else {
505 $info->default_value = null;
507 $info->max_length = $rawcolumn->atttypmod >> 16;
508 $info->scale = ($rawcolumn->atttypmod & 0xFFFF) - 4;
510 } else if (preg_match('/float(\d)/i', $rawcolumn->type, $matches)) {
511 $info->type = 'float';
512 $info->meta_type = 'N';
513 $info->primary_key = false;
514 $info->binary = false;
515 $info->unsigned = null;
516 $info->auto_increment= false;
517 $info->unique = null;
518 $info->not_null = ($rawcolumn->attnotnull === 't');
519 $info->has_default = ($rawcolumn->atthasdef === 't');
520 if ($info->has_default) {
521 $info->default_value = trim($rawcolumn->adsrc, '()');
522 } else {
523 $info->default_value = null;
525 // just guess expected number of deciaml places :-(
526 if ($matches[1] == 8) {
527 // total 15 digits
528 $info->max_length = 8;
529 $info->scale = 7;
530 } else {
531 // total 6 digits
532 $info->max_length = 4;
533 $info->scale = 2;
536 } else if ($rawcolumn->type === 'text') {
537 $info->type = $rawcolumn->type;
538 $info->meta_type = 'X';
539 $info->max_length = -1;
540 $info->scale = null;
541 $info->not_null = ($rawcolumn->attnotnull === 't');
542 $info->has_default = ($rawcolumn->atthasdef === 't');
543 if ($info->has_default) {
544 $parts = explode('::', $rawcolumn->adsrc);
545 if (count($parts) > 1) {
546 $info->default_value = reset($parts);
547 $info->default_value = trim($info->default_value, "'");
548 } else {
549 $info->default_value = $rawcolumn->adsrc;
551 } else {
552 $info->default_value = null;
554 $info->primary_key = false;
555 $info->binary = false;
556 $info->unsigned = null;
557 $info->auto_increment= false;
558 $info->unique = null;
560 } else if ($rawcolumn->type === 'bytea') {
561 $info->type = $rawcolumn->type;
562 $info->meta_type = 'B';
563 $info->max_length = -1;
564 $info->scale = null;
565 $info->not_null = ($rawcolumn->attnotnull === 't');
566 $info->has_default = false;
567 $info->default_value = null;
568 $info->primary_key = false;
569 $info->binary = true;
570 $info->unsigned = null;
571 $info->auto_increment= false;
572 $info->unique = null;
576 $structure[$info->name] = new database_column_info($info);
579 pg_free_result($result);
581 if ($usecache) {
582 $result = $cache->set($table, $structure);
585 return $structure;
589 * Normalise values based in RDBMS dependencies (booleans, LOBs...)
591 * @param database_column_info $column column metadata corresponding with the value we are going to normalise
592 * @param mixed $value value we are going to normalise
593 * @return mixed the normalised value
595 protected function normalise_value($column, $value) {
596 $this->detect_objects($value);
598 if (is_bool($value)) { // Always, convert boolean to int
599 $value = (int)$value;
601 } else if ($column->meta_type === 'B') { // BLOB detected, we return 'blob' array instead of raw value to allow
602 if (!is_null($value)) { // binding/executing code later to know about its nature
603 $value = array('blob' => $value);
606 } else if ($value === '') {
607 if ($column->meta_type === 'I' or $column->meta_type === 'F' or $column->meta_type === 'N') {
608 $value = 0; // prevent '' problems in numeric fields
611 return $value;
615 * Is db in unicode mode?
616 * @return bool
618 public function setup_is_unicodedb() {
619 // Get PostgreSQL server_encoding value
620 $sql = "SHOW server_encoding";
621 $this->query_start($sql, null, SQL_QUERY_AUX);
622 $result = pg_query($this->pgsql, $sql);
623 $this->query_end($result);
625 if (!$result) {
626 return false;
628 $rawcolumn = pg_fetch_object($result);
629 $encoding = $rawcolumn->server_encoding;
630 pg_free_result($result);
632 return (strtoupper($encoding) == 'UNICODE' || strtoupper($encoding) == 'UTF8');
636 * Do NOT use in code, to be used by database_manager only!
637 * @param string $sql query
638 * @return bool true
639 * @throws dml_exception A DML specific exception is thrown for any errors.
641 public function change_database_structure($sql) {
642 $this->reset_caches();
644 $this->query_start($sql, null, SQL_QUERY_STRUCTURE);
645 $result = pg_query($this->pgsql, $sql);
646 $this->query_end($result);
648 pg_free_result($result);
649 return true;
653 * Execute general sql query. Should be used only when no other method suitable.
654 * Do NOT use this to make changes in db structure, use database_manager methods instead!
655 * @param string $sql query
656 * @param array $params query parameters
657 * @return bool true
658 * @throws dml_exception A DML specific exception is thrown for any errors.
660 public function execute($sql, array $params=null) {
661 list($sql, $params, $type) = $this->fix_sql_params($sql, $params);
663 if (strpos($sql, ';') !== false) {
664 throw new coding_exception('moodle_database::execute() Multiple sql statements found or bound parameters not used properly in query!');
667 $this->query_start($sql, $params, SQL_QUERY_UPDATE);
668 $result = pg_query_params($this->pgsql, $sql, $params);
669 $this->query_end($result);
671 pg_free_result($result);
672 return true;
676 * Get a number of records as a moodle_recordset using a SQL statement.
678 * Since this method is a little less readable, use of it should be restricted to
679 * code where it's possible there might be large datasets being returned. For known
680 * small datasets use get_records_sql - it leads to simpler code.
682 * The return type is like:
683 * @see function get_recordset.
685 * @param string $sql the SQL select query to execute.
686 * @param array $params array of sql parameters
687 * @param int $limitfrom return a subset of records, starting at this point (optional, required if $limitnum is set).
688 * @param int $limitnum return a subset comprising this many records (optional, required if $limitfrom is set).
689 * @return moodle_recordset instance
690 * @throws dml_exception A DML specific exception is thrown for any errors.
692 public function get_recordset_sql($sql, array $params=null, $limitfrom=0, $limitnum=0) {
693 $limitfrom = (int)$limitfrom;
694 $limitnum = (int)$limitnum;
695 $limitfrom = ($limitfrom < 0) ? 0 : $limitfrom;
696 $limitnum = ($limitnum < 0) ? 0 : $limitnum;
697 if ($limitfrom or $limitnum) {
698 if ($limitnum < 1) {
699 $limitnum = "ALL";
700 } else if (PHP_INT_MAX - $limitnum < $limitfrom) {
701 // this is a workaround for weird max int problem
702 $limitnum = "ALL";
704 $sql .= " LIMIT $limitnum OFFSET $limitfrom";
707 list($sql, $params, $type) = $this->fix_sql_params($sql, $params);
709 $this->query_start($sql, $params, SQL_QUERY_SELECT);
710 $result = pg_query_params($this->pgsql, $sql, $params);
711 $this->query_end($result);
713 return $this->create_recordset($result);
716 protected function create_recordset($result) {
717 return new pgsql_native_moodle_recordset($result, $this->bytea_oid);
721 * Get a number of records as an array of objects using a SQL statement.
723 * Return value is like:
724 * @see function get_records.
726 * @param string $sql the SQL select query to execute. The first column of this SELECT statement
727 * must be a unique value (usually the 'id' field), as it will be used as the key of the
728 * returned array.
729 * @param array $params array of sql parameters
730 * @param int $limitfrom return a subset of records, starting at this point (optional, required if $limitnum is set).
731 * @param int $limitnum return a subset comprising this many records (optional, required if $limitfrom is set).
732 * @return array of objects, or empty array if no records were found
733 * @throws dml_exception A DML specific exception is thrown for any errors.
735 public function get_records_sql($sql, array $params=null, $limitfrom=0, $limitnum=0) {
736 $limitfrom = (int)$limitfrom;
737 $limitnum = (int)$limitnum;
738 $limitfrom = ($limitfrom < 0) ? 0 : $limitfrom;
739 $limitnum = ($limitnum < 0) ? 0 : $limitnum;
740 if ($limitfrom or $limitnum) {
741 if ($limitnum < 1) {
742 $limitnum = "ALL";
743 } else if (PHP_INT_MAX - $limitnum < $limitfrom) {
744 // this is a workaround for weird max int problem
745 $limitnum = "ALL";
747 $sql .= " LIMIT $limitnum OFFSET $limitfrom";
750 list($sql, $params, $type) = $this->fix_sql_params($sql, $params);
751 $this->query_start($sql, $params, SQL_QUERY_SELECT);
752 $result = pg_query_params($this->pgsql, $sql, $params);
753 $this->query_end($result);
755 // find out if there are any blobs
756 $numrows = pg_num_fields($result);
757 $blobs = array();
758 for($i=0; $i<$numrows; $i++) {
759 $type_oid = pg_field_type_oid($result, $i);
760 if ($type_oid == $this->bytea_oid) {
761 $blobs[] = pg_field_name($result, $i);
765 $rows = pg_fetch_all($result);
766 pg_free_result($result);
768 $return = array();
769 if ($rows) {
770 foreach ($rows as $row) {
771 $id = reset($row);
772 if ($blobs) {
773 foreach ($blobs as $blob) {
774 // note: in PostgreSQL 9.0 the returned blobs are hexencoded by default - see http://www.postgresql.org/docs/9.0/static/runtime-config-client.html#GUC-BYTEA-OUTPUT
775 $row[$blob] = $row[$blob] !== null ? pg_unescape_bytea($row[$blob]) : null;
778 if (isset($return[$id])) {
779 $colname = key($row);
780 debugging("Did you remember to make the first column something unique in your call to get_records? Duplicate value '$id' found in column '$colname'.", DEBUG_DEVELOPER);
782 $return[$id] = (object)$row;
786 return $return;
790 * Selects records and return values (first field) as an array using a SQL statement.
792 * @param string $sql The SQL query
793 * @param array $params array of sql parameters
794 * @return array of values
795 * @throws dml_exception A DML specific exception is thrown for any errors.
797 public function get_fieldset_sql($sql, array $params=null) {
798 list($sql, $params, $type) = $this->fix_sql_params($sql, $params);
800 $this->query_start($sql, $params, SQL_QUERY_SELECT);
801 $result = pg_query_params($this->pgsql, $sql, $params);
802 $this->query_end($result);
804 $return = pg_fetch_all_columns($result, 0);
805 pg_free_result($result);
807 return $return;
811 * Insert new record into database, as fast as possible, no safety checks, lobs not supported.
812 * @param string $table name
813 * @param mixed $params data record as object or array
814 * @param bool $returnit return it of inserted record
815 * @param bool $bulk true means repeated inserts expected
816 * @param bool $customsequence true if 'id' included in $params, disables $returnid
817 * @return bool|int true or new id
818 * @throws dml_exception A DML specific exception is thrown for any errors.
820 public function insert_record_raw($table, $params, $returnid=true, $bulk=false, $customsequence=false) {
821 if (!is_array($params)) {
822 $params = (array)$params;
825 $returning = "";
827 if ($customsequence) {
828 if (!isset($params['id'])) {
829 throw new coding_exception('moodle_database::insert_record_raw() id field must be specified if custom sequences used.');
831 $returnid = false;
832 } else {
833 if ($returnid) {
834 $returning = "RETURNING id";
835 unset($params['id']);
836 } else {
837 unset($params['id']);
841 if (empty($params)) {
842 throw new coding_exception('moodle_database::insert_record_raw() no fields found.');
845 $fields = implode(',', array_keys($params));
846 $values = array();
847 $i = 1;
848 foreach ($params as $value) {
849 $this->detect_objects($value);
850 $values[] = "\$".$i++;
852 $values = implode(',', $values);
854 $sql = "INSERT INTO {$this->prefix}$table ($fields) VALUES($values) $returning";
855 $this->query_start($sql, $params, SQL_QUERY_INSERT);
856 $result = pg_query_params($this->pgsql, $sql, $params);
857 $this->query_end($result);
859 if ($returning !== "") {
860 $row = pg_fetch_assoc($result);
861 $params['id'] = reset($row);
863 pg_free_result($result);
865 if (!$returnid) {
866 return true;
869 return (int)$params['id'];
873 * Insert a record into a table and return the "id" field if required.
875 * Some conversions and safety checks are carried out. Lobs are supported.
876 * If the return ID isn't required, then this just reports success as true/false.
877 * $data is an object containing needed data
878 * @param string $table The database table to be inserted into
879 * @param object $data A data object with values for one or more fields in the record
880 * @param bool $returnid Should the id of the newly created record entry be returned? If this option is not requested then true/false is returned.
881 * @return bool|int true or new id
882 * @throws dml_exception A DML specific exception is thrown for any errors.
884 public function insert_record($table, $dataobject, $returnid=true, $bulk=false) {
885 $dataobject = (array)$dataobject;
887 $columns = $this->get_columns($table);
888 $cleaned = array();
889 $blobs = array();
891 foreach ($dataobject as $field=>$value) {
892 if ($field === 'id') {
893 continue;
895 if (!isset($columns[$field])) {
896 continue;
898 $column = $columns[$field];
899 $normalised_value = $this->normalise_value($column, $value);
900 if (is_array($normalised_value) && array_key_exists('blob', $normalised_value)) {
901 $cleaned[$field] = '@#BLOB#@';
902 $blobs[$field] = $normalised_value['blob'];
903 } else {
904 $cleaned[$field] = $normalised_value;
908 if (empty($blobs)) {
909 return $this->insert_record_raw($table, $cleaned, $returnid, $bulk);
912 $id = $this->insert_record_raw($table, $cleaned, true, $bulk);
914 foreach ($blobs as $key=>$value) {
915 $value = pg_escape_bytea($this->pgsql, $value);
916 $sql = "UPDATE {$this->prefix}$table SET $key = '$value'::bytea WHERE id = $id";
917 $this->query_start($sql, NULL, SQL_QUERY_UPDATE);
918 $result = pg_query($this->pgsql, $sql);
919 $this->query_end($result);
920 if ($result !== false) {
921 pg_free_result($result);
925 return ($returnid ? $id : true);
930 * Import a record into a table, id field is required.
931 * Safety checks are NOT carried out. Lobs are supported.
933 * @param string $table name of database table to be inserted into
934 * @param object $dataobject A data object with values for one or more fields in the record
935 * @return bool true
936 * @throws dml_exception A DML specific exception is thrown for any errors.
938 public function import_record($table, $dataobject) {
939 $dataobject = (array)$dataobject;
941 $columns = $this->get_columns($table);
942 $cleaned = array();
943 $blobs = array();
945 foreach ($dataobject as $field=>$value) {
946 $this->detect_objects($value);
947 if (!isset($columns[$field])) {
948 continue;
950 if ($columns[$field]->meta_type === 'B') {
951 if (!is_null($value)) {
952 $cleaned[$field] = '@#BLOB#@';
953 $blobs[$field] = $value;
954 continue;
958 $cleaned[$field] = $value;
961 $this->insert_record_raw($table, $cleaned, false, true, true);
962 $id = $dataobject['id'];
964 foreach ($blobs as $key=>$value) {
965 $value = pg_escape_bytea($this->pgsql, $value);
966 $sql = "UPDATE {$this->prefix}$table SET $key = '$value'::bytea WHERE id = $id";
967 $this->query_start($sql, NULL, SQL_QUERY_UPDATE);
968 $result = pg_query($this->pgsql, $sql);
969 $this->query_end($result);
970 if ($result !== false) {
971 pg_free_result($result);
975 return true;
979 * Update record in database, as fast as possible, no safety checks, lobs not supported.
980 * @param string $table name
981 * @param mixed $params data record as object or array
982 * @param bool true means repeated updates expected
983 * @return bool true
984 * @throws dml_exception A DML specific exception is thrown for any errors.
986 public function update_record_raw($table, $params, $bulk=false) {
987 $params = (array)$params;
989 if (!isset($params['id'])) {
990 throw new coding_exception('moodle_database::update_record_raw() id field must be specified.');
992 $id = $params['id'];
993 unset($params['id']);
995 if (empty($params)) {
996 throw new coding_exception('moodle_database::update_record_raw() no fields found.');
999 $i = 1;
1001 $sets = array();
1002 foreach ($params as $field=>$value) {
1003 $this->detect_objects($value);
1004 $sets[] = "$field = \$".$i++;
1007 $params[] = $id; // last ? in WHERE condition
1009 $sets = implode(',', $sets);
1010 $sql = "UPDATE {$this->prefix}$table SET $sets WHERE id=\$".$i;
1012 $this->query_start($sql, $params, SQL_QUERY_UPDATE);
1013 $result = pg_query_params($this->pgsql, $sql, $params);
1014 $this->query_end($result);
1016 pg_free_result($result);
1017 return true;
1021 * Update a record in a table
1023 * $dataobject is an object containing needed data
1024 * Relies on $dataobject having a variable "id" to
1025 * specify the record to update
1027 * @param string $table The database table to be checked against.
1028 * @param object $dataobject An object with contents equal to fieldname=>fieldvalue. Must have an entry for 'id' to map to the table specified.
1029 * @param bool true means repeated updates expected
1030 * @return bool true
1031 * @throws dml_exception A DML specific exception is thrown for any errors.
1033 public function update_record($table, $dataobject, $bulk=false) {
1034 $dataobject = (array)$dataobject;
1036 $columns = $this->get_columns($table);
1037 $cleaned = array();
1038 $blobs = array();
1040 foreach ($dataobject as $field=>$value) {
1041 if (!isset($columns[$field])) {
1042 continue;
1044 $column = $columns[$field];
1045 $normalised_value = $this->normalise_value($column, $value);
1046 if (is_array($normalised_value) && array_key_exists('blob', $normalised_value)) {
1047 $cleaned[$field] = '@#BLOB#@';
1048 $blobs[$field] = $normalised_value['blob'];
1049 } else {
1050 $cleaned[$field] = $normalised_value;
1054 $this->update_record_raw($table, $cleaned, $bulk);
1056 if (empty($blobs)) {
1057 return true;
1060 $id = (int)$dataobject['id'];
1062 foreach ($blobs as $key=>$value) {
1063 $value = pg_escape_bytea($this->pgsql, $value);
1064 $sql = "UPDATE {$this->prefix}$table SET $key = '$value'::bytea WHERE id = $id";
1065 $this->query_start($sql, NULL, SQL_QUERY_UPDATE);
1066 $result = pg_query($this->pgsql, $sql);
1067 $this->query_end($result);
1069 pg_free_result($result);
1072 return true;
1076 * Set a single field in every table record which match a particular WHERE clause.
1078 * @param string $table The database table to be checked against.
1079 * @param string $newfield the field to set.
1080 * @param string $newvalue the value to set the field to.
1081 * @param string $select A fragment of SQL to be used in a where clause in the SQL call.
1082 * @param array $params array of sql parameters
1083 * @return bool true
1084 * @throws dml_exception A DML specific exception is thrown for any errors.
1086 public function set_field_select($table, $newfield, $newvalue, $select, array $params=null) {
1088 if ($select) {
1089 $select = "WHERE $select";
1091 if (is_null($params)) {
1092 $params = array();
1094 list($select, $params, $type) = $this->fix_sql_params($select, $params);
1095 $i = count($params)+1;
1097 // Get column metadata
1098 $columns = $this->get_columns($table);
1099 $column = $columns[$newfield];
1101 $normalised_value = $this->normalise_value($column, $newvalue);
1102 if (is_array($normalised_value) && array_key_exists('blob', $normalised_value)) {
1103 // Update BYTEA and return
1104 $normalised_value = pg_escape_bytea($this->pgsql, $normalised_value['blob']);
1105 $sql = "UPDATE {$this->prefix}$table SET $newfield = '$normalised_value'::bytea $select";
1106 $this->query_start($sql, NULL, SQL_QUERY_UPDATE);
1107 $result = pg_query_params($this->pgsql, $sql, $params);
1108 $this->query_end($result);
1109 pg_free_result($result);
1110 return true;
1113 if (is_null($normalised_value)) {
1114 $newfield = "$newfield = NULL";
1115 } else {
1116 $newfield = "$newfield = \$".$i;
1117 $params[] = $normalised_value;
1119 $sql = "UPDATE {$this->prefix}$table SET $newfield $select";
1121 $this->query_start($sql, $params, SQL_QUERY_UPDATE);
1122 $result = pg_query_params($this->pgsql, $sql, $params);
1123 $this->query_end($result);
1125 pg_free_result($result);
1127 return true;
1131 * Delete one or more records from a table which match a particular WHERE clause.
1133 * @param string $table The database table to be checked against.
1134 * @param string $select A fragment of SQL to be used in a where clause in the SQL call (used to define the selection criteria).
1135 * @param array $params array of sql parameters
1136 * @return bool true
1137 * @throws dml_exception A DML specific exception is thrown for any errors.
1139 public function delete_records_select($table, $select, array $params=null) {
1140 if ($select) {
1141 $select = "WHERE $select";
1143 $sql = "DELETE FROM {$this->prefix}$table $select";
1145 list($sql, $params, $type) = $this->fix_sql_params($sql, $params);
1147 $this->query_start($sql, $params, SQL_QUERY_UPDATE);
1148 $result = pg_query_params($this->pgsql, $sql, $params);
1149 $this->query_end($result);
1151 pg_free_result($result);
1153 return true;
1157 * Returns 'LIKE' part of a query.
1159 * @param string $fieldname usually name of the table column
1160 * @param string $param usually bound query parameter (?, :named)
1161 * @param bool $casesensitive use case sensitive search
1162 * @param bool $accensensitive use accent sensitive search (not all databases support accent insensitive)
1163 * @param bool $notlike true means "NOT LIKE"
1164 * @param string $escapechar escape char for '%' and '_'
1165 * @return string SQL code fragment
1167 public function sql_like($fieldname, $param, $casesensitive = true, $accentsensitive = true, $notlike = false, $escapechar = '\\') {
1168 if (strpos($param, '%') !== false) {
1169 debugging('Potential SQL injection detected, sql_like() expects bound parameters (? or :named)');
1171 if ($escapechar === '\\') {
1172 // Prevents problems with C-style escapes of enclosing '\',
1173 // E'... bellow prevents compatibility warnings.
1174 $escapechar = '\\\\';
1177 // postgresql does not support accent insensitive text comparisons, sorry
1178 if ($casesensitive) {
1179 $LIKE = $notlike ? 'NOT LIKE' : 'LIKE';
1180 } else {
1181 $LIKE = $notlike ? 'NOT ILIKE' : 'ILIKE';
1183 return "$fieldname $LIKE $param ESCAPE E'$escapechar'";
1186 public function sql_bitxor($int1, $int2) {
1187 return '((' . $int1 . ') # (' . $int2 . '))';
1190 public function sql_cast_char2int($fieldname, $text=false) {
1191 return ' CAST(' . $fieldname . ' AS INT) ';
1194 public function sql_cast_char2real($fieldname, $text=false) {
1195 return " $fieldname::real ";
1198 public function sql_concat() {
1199 $arr = func_get_args();
1200 $s = implode(' || ', $arr);
1201 if ($s === '') {
1202 return " '' ";
1204 // Add always empty string element so integer-exclusive concats
1205 // will work without needing to cast each element explicitly
1206 return " '' || $s ";
1209 public function sql_concat_join($separator="' '", $elements=array()) {
1210 for ($n=count($elements)-1; $n > 0 ; $n--) {
1211 array_splice($elements, $n, 0, $separator);
1213 $s = implode(' || ', $elements);
1214 if ($s === '') {
1215 return " '' ";
1217 return " $s ";
1220 public function sql_regex_supported() {
1221 return true;
1224 public function sql_regex($positivematch=true) {
1225 return $positivematch ? '~*' : '!~*';
1228 public function session_lock_supported() {
1229 return true;
1233 * Obtain session lock
1234 * @param int $rowid id of the row with session record
1235 * @param int $timeout max allowed time to wait for the lock in seconds
1236 * @return bool success
1238 public function get_session_lock($rowid, $timeout) {
1239 // NOTE: there is a potential locking problem for database running
1240 // multiple instances of moodle, we could try to use pg_advisory_lock(int, int),
1241 // luckily there is not a big chance that they would collide
1242 if (!$this->session_lock_supported()) {
1243 return;
1246 parent::get_session_lock($rowid, $timeout);
1248 $timeoutmilli = $timeout * 1000;
1250 $sql = "SET statement_timeout TO $timeoutmilli";
1251 $this->query_start($sql, null, SQL_QUERY_AUX);
1252 $result = pg_query($this->pgsql, $sql);
1253 $this->query_end($result);
1255 if ($result) {
1256 pg_free_result($result);
1259 $sql = "SELECT pg_advisory_lock($rowid)";
1260 $this->query_start($sql, null, SQL_QUERY_AUX);
1261 $start = time();
1262 $result = pg_query($this->pgsql, $sql);
1263 $end = time();
1264 try {
1265 $this->query_end($result);
1266 } catch (dml_exception $ex) {
1267 if ($end - $start >= $timeout) {
1268 throw new dml_sessionwait_exception();
1269 } else {
1270 throw $ex;
1274 if ($result) {
1275 pg_free_result($result);
1278 $sql = "SET statement_timeout TO DEFAULT";
1279 $this->query_start($sql, null, SQL_QUERY_AUX);
1280 $result = pg_query($this->pgsql, $sql);
1281 $this->query_end($result);
1283 if ($result) {
1284 pg_free_result($result);
1288 public function release_session_lock($rowid) {
1289 if (!$this->session_lock_supported()) {
1290 return;
1292 if (!$this->used_for_db_sessions) {
1293 return;
1296 parent::release_session_lock($rowid);
1298 $sql = "SELECT pg_advisory_unlock($rowid)";
1299 $this->query_start($sql, null, SQL_QUERY_AUX);
1300 $result = pg_query($this->pgsql, $sql);
1301 $this->query_end($result);
1303 if ($result) {
1304 pg_free_result($result);
1309 * Driver specific start of real database transaction,
1310 * this can not be used directly in code.
1311 * @return void
1313 protected function begin_transaction() {
1314 $this->savepointpresent = true;
1315 $sql = "BEGIN ISOLATION LEVEL READ COMMITTED; SAVEPOINT moodle_pg_savepoint";
1316 $this->query_start($sql, NULL, SQL_QUERY_AUX);
1317 $result = pg_query($this->pgsql, $sql);
1318 $this->query_end($result);
1320 pg_free_result($result);
1324 * Driver specific commit of real database transaction,
1325 * this can not be used directly in code.
1326 * @return void
1328 protected function commit_transaction() {
1329 $this->savepointpresent = false;
1330 $sql = "RELEASE SAVEPOINT moodle_pg_savepoint; COMMIT";
1331 $this->query_start($sql, NULL, SQL_QUERY_AUX);
1332 $result = pg_query($this->pgsql, $sql);
1333 $this->query_end($result);
1335 pg_free_result($result);
1339 * Driver specific abort of real database transaction,
1340 * this can not be used directly in code.
1341 * @return void
1343 protected function rollback_transaction() {
1344 $this->savepointpresent = false;
1345 $sql = "RELEASE SAVEPOINT moodle_pg_savepoint; ROLLBACK";
1346 $this->query_start($sql, NULL, SQL_QUERY_AUX);
1347 $result = pg_query($this->pgsql, $sql);
1348 $this->query_end($result);
1350 pg_free_result($result);
1354 * Helper function trimming (whitespace + quotes) any string
1355 * needed because PG uses to enclose with double quotes some
1356 * fields in indexes definition and others
1358 * @param string $str string to apply whitespace + quotes trim
1359 * @return string trimmed string
1361 private function trim_quotes($str) {
1362 return trim(trim($str), "'\"");