3 // This file is part of Moodle - http://moodle.org/
5 // Moodle is free software: you can redistribute it and/or modify
6 // it under the terms of the GNU General Public License as published by
7 // the Free Software Foundation, either version 3 of the License, or
8 // (at your option) any later version.
10 // Moodle is distributed in the hope that it will be useful,
11 // but WITHOUT ANY WARRANTY; without even the implied warranty of
12 // MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the
13 // GNU General Public License for more details.
15 // You should have received a copy of the GNU General Public License
16 // along with Moodle. If not, see <http://www.gnu.org/licenses/>.
20 * Native pgsql class representing moodle database interface.
23 * @subpackage dml_driver
24 * @copyright 2008 Petr Skoda (http://skodak.org)
25 * @license http://www.gnu.org/copyleft/gpl.html GNU GPL v3 or later
28 defined('MOODLE_INTERNAL') || die();
30 require_once($CFG->libdir.'/dml/moodle_database.php');
31 require_once($CFG->libdir.'/dml/pgsql_native_moodle_recordset.php');
32 require_once($CFG->libdir.'/dml/pgsql_native_moodle_temptables.php');
35 * Native pgsql class representing moodle database interface.
38 * @subpackage dml_driver
39 * @copyright 2008 Petr Skoda (http://skodak.org)
40 * @license http://www.gnu.org/copyleft/gpl.html GNU GPL v3 or later
42 class pgsql_native_moodle_database extends moodle_database {
44 protected $pgsql = null;
45 protected $bytea_oid = null;
47 protected $last_error_reporting; // To handle pgsql driver default verbosity
50 * Detects if all needed PHP stuff installed.
51 * Note: can be used before connect()
52 * @return mixed true if ok, string if something
54 public function driver_installed() {
55 if (!extension_loaded('pgsql')) {
56 return get_string('pgsqlextensionisnotpresentinphp', 'install');
62 * Returns database family type - describes SQL dialect
63 * Note: can be used before connect()
64 * @return string db family name (mysql, postgres, mssql, oracle, etc.)
66 public function get_dbfamily() {
71 * Returns more specific database driver type
72 * Note: can be used before connect()
73 * @return string db type mysqli, pgsql, oci, mssql, sqlsrv
75 protected function get_dbtype() {
80 * Returns general database library name
81 * Note: can be used before connect()
82 * @return string db type pdo, native
84 protected function get_dblibrary() {
89 * Returns localised database type name
90 * Note: can be used before connect()
93 public function get_name() {
94 return get_string('nativepgsql', 'install');
98 * Returns localised database configuration help.
99 * Note: can be used before connect()
102 public function get_configuration_help() {
103 return get_string('nativepgsqlhelp', 'install');
107 * Returns localised database description
108 * Note: can be used before connect()
111 public function get_configuration_hints() {
112 return get_string('databasesettingssub_postgres7', 'install');
117 * Must be called before other methods.
118 * @param string $dbhost The database host.
119 * @param string $dbuser The database username.
120 * @param string $dbpass The database username's password.
121 * @param string $dbname The name of the database being connected to.
122 * @param mixed $prefix string means moodle db prefix, false used for external databases where prefix not used
123 * @param array $dboptions driver specific options
125 * @throws dml_connection_exception if error
127 public function connect($dbhost, $dbuser, $dbpass, $dbname, $prefix, array $dboptions=null) {
128 if ($prefix == '' and !$this->external) {
129 //Enforce prefixes for everybody but mysql
130 throw new dml_exception('prefixcannotbeempty', $this->get_dbfamily());
133 $driverstatus = $this->driver_installed();
135 if ($driverstatus !== true) {
136 throw new dml_exception('dbdriverproblem', $driverstatus);
139 $this->store_settings($dbhost, $dbuser, $dbpass, $dbname, $prefix, $dboptions);
141 $pass = addcslashes($this->dbpass, "'\\");
143 // Unix socket connections should have lower overhead
144 if (!empty($this->dboptions['dbsocket']) and ($this->dbhost === 'localhost' or $this->dbhost === '127.0.0.1')) {
145 $connection = "user='$this->dbuser' password='$pass' dbname='$this->dbname'";
146 if (strpos($this->dboptions['dbsocket'], '/') !== false) {
147 $connection = $connection." host='".$this->dboptions['dbsocket']."'";
150 $this->dboptions['dbsocket'] = '';
151 if (empty($this->dbname)) {
152 // probably old style socket connection - do not add port
154 } else if (empty($this->dboptions['dbport'])) {
155 $port = "port ='5432'";
157 $port = "port ='".$this->dboptions['dbport']."'";
159 $connection = "host='$this->dbhost' $port user='$this->dbuser' password='$pass' dbname='$this->dbname'";
163 if (empty($this->dboptions['dbpersist'])) {
164 $this->pgsql = pg_connect($connection, PGSQL_CONNECT_FORCE_NEW);
166 $this->pgsql = pg_pconnect($connection, PGSQL_CONNECT_FORCE_NEW);
168 $dberr = ob_get_contents();
171 $status = pg_connection_status($this->pgsql);
173 if ($status === false or $status === PGSQL_CONNECTION_BAD) {
175 throw new dml_connection_exception($dberr);
178 $this->query_start("--pg_set_client_encoding()", null, SQL_QUERY_AUX);
179 pg_set_client_encoding($this->pgsql, 'utf8');
180 $this->query_end(true);
182 // find out the bytea oid
183 $sql = "SELECT oid FROM pg_type WHERE typname = 'bytea'";
184 $this->query_start($sql, null, SQL_QUERY_AUX);
185 $result = pg_query($this->pgsql, $sql);
186 $this->query_end($result);
188 $this->bytea_oid = pg_fetch_result($result, 0, 0);
189 pg_free_result($result);
190 if ($this->bytea_oid === false) {
192 throw new dml_connection_exception('Can not read bytea type.');
195 // Connection stabilised and configured, going to instantiate the temptables controller
196 $this->temptables = new pgsql_native_moodle_temptables($this);
202 * Close database connection and release all resources
203 * and memory (especially circular memory references).
204 * Do NOT use connect() again, create a new instance if needed.
206 public function dispose() {
207 parent::dispose(); // Call parent dispose to write/close session and other common stuff before closing connection
209 pg_close($this->pgsql);
216 * Called before each db query.
218 * @param array array of parameters
219 * @param int $type type of query
220 * @param mixed $extrainfo driver specific extra information
223 protected function query_start($sql, array $params=null, $type, $extrainfo=null) {
224 parent::query_start($sql, $params, $type, $extrainfo);
225 // pgsql driver tents to send debug to output, we do not need that ;-)
226 $this->last_error_reporting = error_reporting(0);
230 * Called immediately after each db query.
231 * @param mixed db specific result
234 protected function query_end($result) {
235 // reset original debug level
236 error_reporting($this->last_error_reporting);
237 parent::query_end($result);
241 * Returns database server info array
242 * @return array Array containing 'description' and 'version' info
244 public function get_server_info() {
247 $this->query_start("--pg_version()", null, SQL_QUERY_AUX);
248 $info = pg_version($this->pgsql);
249 $this->query_end(true);
251 return array('description'=>$info['server'], 'version'=>$info['server']);
254 protected function is_min_version($version) {
255 $server = $this->get_server_info();
256 $server = $server['version'];
257 return version_compare($server, $version, '>=');
261 * Returns supported query parameter types
262 * @return int bitmask of accepted SQL_PARAMS_*
264 protected function allowed_param_types() {
265 return SQL_PARAMS_DOLLAR;
269 * Returns last error reported by database engine.
270 * @return string error message
272 public function get_last_error() {
273 return pg_last_error($this->pgsql);
277 * Return tables in database WITHOUT current prefix.
278 * @param bool $usecache if true, returns list of cached tables.
279 * @return array of table names in lowercase and without prefix
281 public function get_tables($usecache=true) {
282 if ($usecache and $this->tables !== null) {
283 return $this->tables;
285 $this->tables = array();
286 $prefix = str_replace('_', '|_', $this->prefix);
287 // Get them from information_schema instead of catalog as far as
288 // we want to get only own session temp objects (catalog returns all)
289 $sql = "SELECT table_name
290 FROM information_schema.tables
291 WHERE table_name LIKE '$prefix%' ESCAPE '|'
292 AND table_type IN ('BASE TABLE', 'LOCAL TEMPORARY')";
293 $this->query_start($sql, null, SQL_QUERY_AUX);
294 $result = pg_query($this->pgsql, $sql);
295 $this->query_end($result);
298 while ($row = pg_fetch_row($result)) {
299 $tablename = reset($row);
300 if (strpos($tablename, $this->prefix) !== 0) {
303 $tablename = substr($tablename, strlen($this->prefix));
304 $this->tables[$tablename] = $tablename;
306 pg_free_result($result);
308 return $this->tables;
312 * Return table indexes - everything lowercased.
313 * @param string $table The table we want to get indexes from.
314 * @return array of arrays
316 public function get_indexes($table) {
318 $tablename = $this->prefix.$table;
321 FROM pg_catalog.pg_indexes
322 WHERE tablename = '$tablename'";
324 $this->query_start($sql, null, SQL_QUERY_AUX);
325 $result = pg_query($this->pgsql, $sql);
326 $this->query_end($result);
329 while ($row = pg_fetch_assoc($result)) {
330 if (!preg_match('/CREATE (|UNIQUE )INDEX ([^\s]+) ON '.$tablename.' USING ([^\s]+) \(([^\)]+)\)/i', $row['indexdef'], $matches)) {
333 if ($matches[4] === 'id') {
336 $columns = explode(',', $matches[4]);
337 $columns = array_map(array($this, 'trim_quotes'), $columns);
338 $indexes[$row['indexname']] = array('unique'=>!empty($matches[1]),
339 'columns'=>$columns);
341 pg_free_result($result);
347 * Returns detailed information about columns in table. This information is cached internally.
348 * @param string $table name
349 * @param bool $usecache
350 * @return array array of database_column_info objects indexed with column names
352 public function get_columns($table, $usecache=true) {
353 if ($usecache and isset($this->columns[$table])) {
354 return $this->columns[$table];
357 $this->columns[$table] = array();
359 $tablename = $this->prefix.$table;
361 $sql = "SELECT a.attnum, a.attname AS field, t.typname AS type, a.attlen, a.atttypmod, a.attnotnull, a.atthasdef, d.adsrc
362 FROM pg_catalog.pg_class c
363 JOIN pg_catalog.pg_attribute a ON a.attrelid = c.oid
364 JOIN pg_catalog.pg_type t ON t.oid = a.atttypid
365 LEFT JOIN pg_catalog.pg_attrdef d ON (d.adrelid = c.oid AND d.adnum = a.attnum)
366 WHERE relkind = 'r' AND c.relname = '$tablename' AND c.reltype > 0 AND a.attnum > 0
369 $this->query_start($sql, null, SQL_QUERY_AUX);
370 $result = pg_query($this->pgsql, $sql);
371 $this->query_end($result);
376 while ($rawcolumn = pg_fetch_object($result)) {
378 $info = new stdClass();
379 $info->name = $rawcolumn->field;
382 if ($rawcolumn->type === 'varchar') {
383 $info->type = 'varchar';
384 $info->meta_type = 'C';
385 $info->max_length = $rawcolumn->atttypmod - 4;
387 $info->not_null = ($rawcolumn->attnotnull === 't');
388 $info->has_default = ($rawcolumn->atthasdef === 't');
389 if ($info->has_default) {
390 $parts = explode('::', $rawcolumn->adsrc);
391 if (count($parts) > 1) {
392 $info->default_value = reset($parts);
393 $info->default_value = trim($info->default_value, "'");
395 $info->default_value = $rawcolumn->adsrc;
398 $info->default_value = null;
400 $info->primary_key = false;
401 $info->binary = false;
402 $info->unsigned = null;
403 $info->auto_increment= false;
404 $info->unique = null;
406 } else if (preg_match('/int(\d)/i', $rawcolumn->type, $matches)) {
408 if (strpos($rawcolumn->adsrc, 'nextval') === 0) {
409 $info->primary_key = true;
410 $info->meta_type = 'R';
411 $info->unique = true;
412 $info->auto_increment= true;
413 $info->has_default = false;
415 $info->primary_key = false;
416 $info->meta_type = 'I';
417 $info->unique = null;
418 $info->auto_increment= false;
419 $info->has_default = ($rawcolumn->atthasdef === 't');
421 $info->max_length = $matches[1];
423 $info->not_null = ($rawcolumn->attnotnull === 't');
424 if ($info->has_default) {
425 $info->default_value = trim($rawcolumn->adsrc, '()');
427 $info->default_value = null;
429 $info->binary = false;
430 $info->unsigned = false;
432 } else if ($rawcolumn->type === 'numeric') {
433 $info->type = $rawcolumn->type;
434 $info->meta_type = 'N';
435 $info->primary_key = false;
436 $info->binary = false;
437 $info->unsigned = null;
438 $info->auto_increment= false;
439 $info->unique = null;
440 $info->not_null = ($rawcolumn->attnotnull === 't');
441 $info->has_default = ($rawcolumn->atthasdef === 't');
442 if ($info->has_default) {
443 $info->default_value = trim($rawcolumn->adsrc, '()');
445 $info->default_value = null;
447 $info->max_length = $rawcolumn->atttypmod >> 16;
448 $info->scale = ($rawcolumn->atttypmod & 0xFFFF) - 4;
450 } else if (preg_match('/float(\d)/i', $rawcolumn->type, $matches)) {
451 $info->type = 'float';
452 $info->meta_type = 'N';
453 $info->primary_key = false;
454 $info->binary = false;
455 $info->unsigned = null;
456 $info->auto_increment= false;
457 $info->unique = null;
458 $info->not_null = ($rawcolumn->attnotnull === 't');
459 $info->has_default = ($rawcolumn->atthasdef === 't');
460 if ($info->has_default) {
461 $info->default_value = trim($rawcolumn->adsrc, '()');
463 $info->default_value = null;
465 // just guess expected number of deciaml places :-(
466 if ($matches[1] == 8) {
468 $info->max_length = 8;
472 $info->max_length = 4;
476 } else if ($rawcolumn->type === 'text') {
477 $info->type = $rawcolumn->type;
478 $info->meta_type = 'X';
479 $info->max_length = -1;
481 $info->not_null = ($rawcolumn->attnotnull === 't');
482 $info->has_default = ($rawcolumn->atthasdef === 't');
483 if ($info->has_default) {
484 $parts = explode('::', $rawcolumn->adsrc);
485 if (count($parts) > 1) {
486 $info->default_value = reset($parts);
487 $info->default_value = trim($info->default_value, "'");
489 $info->default_value = $rawcolumn->adsrc;
492 $info->default_value = null;
494 $info->primary_key = false;
495 $info->binary = false;
496 $info->unsigned = null;
497 $info->auto_increment= false;
498 $info->unique = null;
500 } else if ($rawcolumn->type === 'bytea') {
501 $info->type = $rawcolumn->type;
502 $info->meta_type = 'B';
503 $info->max_length = -1;
505 $info->not_null = ($rawcolumn->attnotnull === 't');
506 $info->has_default = false;
507 $info->default_value = null;
508 $info->primary_key = false;
509 $info->binary = true;
510 $info->unsigned = null;
511 $info->auto_increment= false;
512 $info->unique = null;
516 $this->columns[$table][$info->name] = new database_column_info($info);
519 pg_free_result($result);
521 return $this->columns[$table];
525 * Normalise values based in RDBMS dependencies (booleans, LOBs...)
527 * @param database_column_info $column column metadata corresponding with the value we are going to normalise
528 * @param mixed $value value we are going to normalise
529 * @return mixed the normalised value
531 protected function normalise_value($column, $value) {
532 $this->detect_objects($value);
534 if (is_bool($value)) { // Always, convert boolean to int
535 $value = (int)$value;
537 } else if ($column->meta_type === 'B') { // BLOB detected, we return 'blob' array instead of raw value to allow
538 if (!is_null($value)) { // binding/executing code later to know about its nature
539 $value = array('blob' => $value);
542 } else if ($value === '') {
543 if ($column->meta_type === 'I' or $column->meta_type === 'F' or $column->meta_type === 'N') {
544 $value = 0; // prevent '' problems in numeric fields
551 * Is db in unicode mode?
554 public function setup_is_unicodedb() {
555 /// Get PostgreSQL server_encoding value
556 $sql = "SHOW server_encoding";
557 $this->query_start($sql, null, SQL_QUERY_AUX);
558 $result = pg_query($this->pgsql, $sql);
559 $this->query_end($result);
564 $rawcolumn = pg_fetch_object($result);
565 $encoding = $rawcolumn->server_encoding;
566 pg_free_result($result);
568 return (strtoupper($encoding) == 'UNICODE' || strtoupper($encoding) == 'UTF8');
572 * Do NOT use in code, to be used by database_manager only!
573 * @param string $sql query
575 * @throws dml_exception A DML specific exception is thrown for any errors.
577 public function change_database_structure($sql) {
578 $this->reset_caches();
580 $this->query_start($sql, null, SQL_QUERY_STRUCTURE);
581 $result = pg_query($this->pgsql, $sql);
582 $this->query_end($result);
584 pg_free_result($result);
589 * Execute general sql query. Should be used only when no other method suitable.
590 * Do NOT use this to make changes in db structure, use database_manager methods instead!
591 * @param string $sql query
592 * @param array $params query parameters
594 * @throws dml_exception A DML specific exception is thrown for any errors.
596 public function execute($sql, array $params=null) {
597 list($sql, $params, $type) = $this->fix_sql_params($sql, $params);
599 if (strpos($sql, ';') !== false) {
600 throw new coding_exception('moodle_database::execute() Multiple sql statements found or bound parameters not used properly in query!');
603 $this->query_start($sql, $params, SQL_QUERY_UPDATE);
604 $result = pg_query_params($this->pgsql, $sql, $params);
605 $this->query_end($result);
607 pg_free_result($result);
612 * Get a number of records as a moodle_recordset using a SQL statement.
614 * Since this method is a little less readable, use of it should be restricted to
615 * code where it's possible there might be large datasets being returned. For known
616 * small datasets use get_records_sql - it leads to simpler code.
618 * The return type is like:
619 * @see function get_recordset.
621 * @param string $sql the SQL select query to execute.
622 * @param array $params array of sql parameters
623 * @param int $limitfrom return a subset of records, starting at this point (optional, required if $limitnum is set).
624 * @param int $limitnum return a subset comprising this many records (optional, required if $limitfrom is set).
625 * @return moodle_recordset instance
626 * @throws dml_exception A DML specific exception is thrown for any errors.
628 public function get_recordset_sql($sql, array $params=null, $limitfrom=0, $limitnum=0) {
629 $limitfrom = (int)$limitfrom;
630 $limitnum = (int)$limitnum;
631 $limitfrom = ($limitfrom < 0) ? 0 : $limitfrom;
632 $limitnum = ($limitnum < 0) ? 0 : $limitnum;
633 if ($limitfrom or $limitnum) {
636 } else if (PHP_INT_MAX - $limitnum < $limitfrom) {
637 // this is a workaround for weird max int problem
640 $sql .= " LIMIT $limitnum OFFSET $limitfrom";
643 list($sql, $params, $type) = $this->fix_sql_params($sql, $params);
645 $this->query_start($sql, $params, SQL_QUERY_SELECT);
646 $result = pg_query_params($this->pgsql, $sql, $params);
647 $this->query_end($result);
649 return $this->create_recordset($result);
652 protected function create_recordset($result) {
653 return new pgsql_native_moodle_recordset($result, $this->bytea_oid);
657 * Get a number of records as an array of objects using a SQL statement.
659 * Return value is like:
660 * @see function get_records.
662 * @param string $sql the SQL select query to execute. The first column of this SELECT statement
663 * must be a unique value (usually the 'id' field), as it will be used as the key of the
665 * @param array $params array of sql parameters
666 * @param int $limitfrom return a subset of records, starting at this point (optional, required if $limitnum is set).
667 * @param int $limitnum return a subset comprising this many records (optional, required if $limitfrom is set).
668 * @return array of objects, or empty array if no records were found
669 * @throws dml_exception A DML specific exception is thrown for any errors.
671 public function get_records_sql($sql, array $params=null, $limitfrom=0, $limitnum=0) {
672 $limitfrom = (int)$limitfrom;
673 $limitnum = (int)$limitnum;
674 $limitfrom = ($limitfrom < 0) ? 0 : $limitfrom;
675 $limitnum = ($limitnum < 0) ? 0 : $limitnum;
676 if ($limitfrom or $limitnum) {
679 } else if (PHP_INT_MAX - $limitnum < $limitfrom) {
680 // this is a workaround for weird max int problem
683 $sql .= " LIMIT $limitnum OFFSET $limitfrom";
686 list($sql, $params, $type) = $this->fix_sql_params($sql, $params);
687 $this->query_start($sql, $params, SQL_QUERY_SELECT);
688 $result = pg_query_params($this->pgsql, $sql, $params);
689 $this->query_end($result);
691 // find out if there are any blobs
692 $numrows = pg_num_fields($result);
694 for($i=0; $i<$numrows; $i++) {
695 $type_oid = pg_field_type_oid($result, $i);
696 if ($type_oid == $this->bytea_oid) {
697 $blobs[] = pg_field_name($result, $i);
701 $rows = pg_fetch_all($result);
702 pg_free_result($result);
706 foreach ($rows as $row) {
709 foreach ($blobs as $blob) {
710 // 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
711 $row[$blob] = $row[$blob] !== null ? pg_unescape_bytea($row[$blob]) : null;
714 if (isset($return[$id])) {
715 $colname = key($row);
716 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);
718 $return[$id] = (object)$row;
726 * Selects records and return values (first field) as an array using a SQL statement.
728 * @param string $sql The SQL query
729 * @param array $params array of sql parameters
730 * @return array of values
731 * @throws dml_exception A DML specific exception is thrown for any errors.
733 public function get_fieldset_sql($sql, array $params=null) {
734 list($sql, $params, $type) = $this->fix_sql_params($sql, $params);
736 $this->query_start($sql, $params, SQL_QUERY_SELECT);
737 $result = pg_query_params($this->pgsql, $sql, $params);
738 $this->query_end($result);
740 $return = pg_fetch_all_columns($result, 0);
741 pg_free_result($result);
747 * Insert new record into database, as fast as possible, no safety checks, lobs not supported.
748 * @param string $table name
749 * @param mixed $params data record as object or array
750 * @param bool $returnit return it of inserted record
751 * @param bool $bulk true means repeated inserts expected
752 * @param bool $customsequence true if 'id' included in $params, disables $returnid
753 * @return bool|int true or new id
754 * @throws dml_exception A DML specific exception is thrown for any errors.
756 public function insert_record_raw($table, $params, $returnid=true, $bulk=false, $customsequence=false) {
757 if (!is_array($params)) {
758 $params = (array)$params;
763 if ($customsequence) {
764 if (!isset($params['id'])) {
765 throw new coding_exception('moodle_database::insert_record_raw() id field must be specified if custom sequences used.');
770 $returning = "RETURNING id";
771 unset($params['id']);
773 unset($params['id']);
777 if (empty($params)) {
778 throw new coding_exception('moodle_database::insert_record_raw() no fields found.');
781 $fields = implode(',', array_keys($params));
784 foreach ($params as $value) {
785 $this->detect_objects($value);
786 $values[] = "\$".$i++;
788 $values = implode(',', $values);
790 $sql = "INSERT INTO {$this->prefix}$table ($fields) VALUES($values) $returning";
791 $this->query_start($sql, $params, SQL_QUERY_INSERT);
792 $result = pg_query_params($this->pgsql, $sql, $params);
793 $this->query_end($result);
795 if ($returning !== "") {
796 $row = pg_fetch_assoc($result);
797 $params['id'] = reset($row);
799 pg_free_result($result);
805 return (int)$params['id'];
809 * Insert a record into a table and return the "id" field if required.
811 * Some conversions and safety checks are carried out. Lobs are supported.
812 * If the return ID isn't required, then this just reports success as true/false.
813 * $data is an object containing needed data
814 * @param string $table The database table to be inserted into
815 * @param object $data A data object with values for one or more fields in the record
816 * @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.
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($table, $dataobject, $returnid=true, $bulk=false) {
821 $dataobject = (array)$dataobject;
823 $columns = $this->get_columns($table);
827 foreach ($dataobject as $field=>$value) {
828 if ($field === 'id') {
831 if (!isset($columns[$field])) {
834 $column = $columns[$field];
835 $normalised_value = $this->normalise_value($column, $value);
836 if (is_array($normalised_value) && array_key_exists('blob', $normalised_value)) {
837 $cleaned[$field] = '@#BLOB#@';
838 $blobs[$field] = $normalised_value['blob'];
840 $cleaned[$field] = $normalised_value;
845 return $this->insert_record_raw($table, $cleaned, $returnid, $bulk);
848 $id = $this->insert_record_raw($table, $cleaned, true, $bulk);
850 foreach ($blobs as $key=>$value) {
851 $value = pg_escape_bytea($this->pgsql, $value);
852 $sql = "UPDATE {$this->prefix}$table SET $key = '$value'::bytea WHERE id = $id";
853 $this->query_start($sql, NULL, SQL_QUERY_UPDATE);
854 $result = pg_query($this->pgsql, $sql);
855 $this->query_end($result);
856 if ($result !== false) {
857 pg_free_result($result);
861 return ($returnid ? $id : true);
866 * Import a record into a table, id field is required.
867 * Safety checks are NOT carried out. Lobs are supported.
869 * @param string $table name of database table to be inserted into
870 * @param object $dataobject A data object with values for one or more fields in the record
872 * @throws dml_exception A DML specific exception is thrown for any errors.
874 public function import_record($table, $dataobject) {
875 $dataobject = (array)$dataobject;
877 $columns = $this->get_columns($table);
881 foreach ($dataobject as $field=>$value) {
882 $this->detect_objects($value);
883 if (!isset($columns[$field])) {
886 if ($columns[$field]->meta_type === 'B') {
887 if (!is_null($value)) {
888 $cleaned[$field] = '@#BLOB#@';
889 $blobs[$field] = $value;
894 $cleaned[$field] = $value;
897 $this->insert_record_raw($table, $cleaned, false, true, true);
898 $id = $dataobject['id'];
900 foreach ($blobs as $key=>$value) {
901 $value = pg_escape_bytea($this->pgsql, $value);
902 $sql = "UPDATE {$this->prefix}$table SET $key = '$value'::bytea WHERE id = $id";
903 $this->query_start($sql, NULL, SQL_QUERY_UPDATE);
904 $result = pg_query($this->pgsql, $sql);
905 $this->query_end($result);
906 if ($result !== false) {
907 pg_free_result($result);
915 * Update record in database, as fast as possible, no safety checks, lobs not supported.
916 * @param string $table name
917 * @param mixed $params data record as object or array
918 * @param bool true means repeated updates expected
920 * @throws dml_exception A DML specific exception is thrown for any errors.
922 public function update_record_raw($table, $params, $bulk=false) {
923 $params = (array)$params;
925 if (!isset($params['id'])) {
926 throw new coding_exception('moodle_database::update_record_raw() id field must be specified.');
929 unset($params['id']);
931 if (empty($params)) {
932 throw new coding_exception('moodle_database::update_record_raw() no fields found.');
938 foreach ($params as $field=>$value) {
939 $this->detect_objects($value);
940 $sets[] = "$field = \$".$i++;
943 $params[] = $id; // last ? in WHERE condition
945 $sets = implode(',', $sets);
946 $sql = "UPDATE {$this->prefix}$table SET $sets WHERE id=\$".$i;
948 $this->query_start($sql, $params, SQL_QUERY_UPDATE);
949 $result = pg_query_params($this->pgsql, $sql, $params);
950 $this->query_end($result);
952 pg_free_result($result);
957 * Update a record in a table
959 * $dataobject is an object containing needed data
960 * Relies on $dataobject having a variable "id" to
961 * specify the record to update
963 * @param string $table The database table to be checked against.
964 * @param object $dataobject An object with contents equal to fieldname=>fieldvalue. Must have an entry for 'id' to map to the table specified.
965 * @param bool true means repeated updates expected
967 * @throws dml_exception A DML specific exception is thrown for any errors.
969 public function update_record($table, $dataobject, $bulk=false) {
970 $dataobject = (array)$dataobject;
972 $columns = $this->get_columns($table);
976 foreach ($dataobject as $field=>$value) {
977 if (!isset($columns[$field])) {
980 $column = $columns[$field];
981 $normalised_value = $this->normalise_value($column, $value);
982 if (is_array($normalised_value) && array_key_exists('blob', $normalised_value)) {
983 $cleaned[$field] = '@#BLOB#@';
984 $blobs[$field] = $normalised_value['blob'];
986 $cleaned[$field] = $normalised_value;
990 $this->update_record_raw($table, $cleaned, $bulk);
996 $id = (int)$dataobject['id'];
998 foreach ($blobs as $key=>$value) {
999 $value = pg_escape_bytea($this->pgsql, $value);
1000 $sql = "UPDATE {$this->prefix}$table SET $key = '$value'::bytea WHERE id = $id";
1001 $this->query_start($sql, NULL, SQL_QUERY_UPDATE);
1002 $result = pg_query($this->pgsql, $sql);
1003 $this->query_end($result);
1005 pg_free_result($result);
1012 * Set a single field in every table record which match a particular WHERE clause.
1014 * @param string $table The database table to be checked against.
1015 * @param string $newfield the field to set.
1016 * @param string $newvalue the value to set the field to.
1017 * @param string $select A fragment of SQL to be used in a where clause in the SQL call.
1018 * @param array $params array of sql parameters
1020 * @throws dml_exception A DML specific exception is thrown for any errors.
1022 public function set_field_select($table, $newfield, $newvalue, $select, array $params=null) {
1025 $select = "WHERE $select";
1027 if (is_null($params)) {
1030 list($select, $params, $type) = $this->fix_sql_params($select, $params);
1031 $i = count($params)+1;
1033 /// Get column metadata
1034 $columns = $this->get_columns($table);
1035 $column = $columns[$newfield];
1037 $normalised_value = $this->normalise_value($column, $newvalue);
1038 if (is_array($normalised_value) && array_key_exists('blob', $normalised_value)) {
1039 /// Update BYTEA and return
1040 $normalised_value = pg_escape_bytea($this->pgsql, $normalised_value['blob']);
1041 $sql = "UPDATE {$this->prefix}$table SET $newfield = '$normalised_value'::bytea $select";
1042 $this->query_start($sql, NULL, SQL_QUERY_UPDATE);
1043 $result = pg_query_params($this->pgsql, $sql, $params);
1044 $this->query_end($result);
1045 pg_free_result($result);
1049 if (is_null($normalised_value)) {
1050 $newfield = "$newfield = NULL";
1052 $newfield = "$newfield = \$".$i;
1053 $params[] = $normalised_value;
1055 $sql = "UPDATE {$this->prefix}$table SET $newfield $select";
1057 $this->query_start($sql, $params, SQL_QUERY_UPDATE);
1058 $result = pg_query_params($this->pgsql, $sql, $params);
1059 $this->query_end($result);
1061 pg_free_result($result);
1067 * Delete one or more records from a table which match a particular WHERE clause.
1069 * @param string $table The database table to be checked against.
1070 * @param string $select A fragment of SQL to be used in a where clause in the SQL call (used to define the selection criteria).
1071 * @param array $params array of sql parameters
1073 * @throws dml_exception A DML specific exception is thrown for any errors.
1075 public function delete_records_select($table, $select, array $params=null) {
1077 $select = "WHERE $select";
1079 $sql = "DELETE FROM {$this->prefix}$table $select";
1081 list($sql, $params, $type) = $this->fix_sql_params($sql, $params);
1083 $this->query_start($sql, $params, SQL_QUERY_UPDATE);
1084 $result = pg_query_params($this->pgsql, $sql, $params);
1085 $this->query_end($result);
1087 pg_free_result($result);
1093 * Returns 'LIKE' part of a query.
1095 * @param string $fieldname usually name of the table column
1096 * @param string $param usually bound query parameter (?, :named)
1097 * @param bool $casesensitive use case sensitive search
1098 * @param bool $accensensitive use accent sensitive search (not all databases support accent insensitive)
1099 * @param bool $notlike true means "NOT LIKE"
1100 * @param string $escapechar escape char for '%' and '_'
1101 * @return string SQL code fragment
1103 public function sql_like($fieldname, $param, $casesensitive = true, $accentsensitive = true, $notlike = false, $escapechar = '\\') {
1104 if (strpos($param, '%') !== false) {
1105 debugging('Potential SQL injection detected, sql_ilike() expects bound parameters (? or :named)');
1107 $escapechar = pg_escape_string($this->pgsql, $escapechar); // prevents problems with C-style escapes of enclosing '\'
1109 // postgresql does not support accent insensitive text comparisons, sorry
1110 if ($casesensitive) {
1111 $LIKE = $notlike ? 'NOT LIKE' : 'LIKE';
1113 $LIKE = $notlike ? 'NOT ILIKE' : 'ILIKE';
1115 return "$fieldname $LIKE $param ESCAPE '$escapechar'";
1118 public function sql_ilike() {
1119 debugging('sql_ilike() is deprecated, please use sql_like() instead');
1123 public function sql_bitxor($int1, $int2) {
1124 return '((' . $int1 . ') # (' . $int2 . '))';
1127 public function sql_cast_char2int($fieldname, $text=false) {
1128 return ' CAST(' . $fieldname . ' AS INT) ';
1131 public function sql_cast_char2real($fieldname, $text=false) {
1132 return " $fieldname::real ";
1135 public function sql_concat() {
1136 $arr = func_get_args();
1137 $s = implode(' || ', $arr);
1141 // Add always empty string element so integer-exclusive concats
1142 // will work without needing to cast each element explicity
1143 return " '' || $s ";
1146 public function sql_concat_join($separator="' '", $elements=array()) {
1147 for ($n=count($elements)-1; $n > 0 ; $n--) {
1148 array_splice($elements, $n, 0, $separator);
1150 $s = implode(' || ', $elements);
1157 public function sql_regex_supported() {
1161 public function sql_regex($positivematch=true) {
1162 return $positivematch ? '~*' : '!~*';
1166 public function session_lock_supported() {
1171 * Obtain session lock
1172 * @param int $rowid id of the row with session record
1173 * @param int $timeout max allowed time to wait for the lock in seconds
1174 * @return bool success
1176 public function get_session_lock($rowid, $timeout) {
1177 // NOTE: there is a potential locking problem for database running
1178 // multiple instances of moodle, we could try to use pg_advisory_lock(int, int),
1179 // luckily there is not a big chance that they would collide
1180 if (!$this->session_lock_supported()) {
1184 parent::get_session_lock($rowid, $timeout);
1186 $timeoutmilli = $timeout * 1000;
1188 $sql = "SET statement_timeout TO $timeoutmilli";
1189 $this->query_start($sql, null, SQL_QUERY_AUX);
1190 $result = pg_query($this->pgsql, $sql);
1191 $this->query_end($result);
1194 pg_free_result($result);
1197 $sql = "SELECT pg_advisory_lock($rowid)";
1198 $this->query_start($sql, null, SQL_QUERY_AUX);
1200 $result = pg_query($this->pgsql, $sql);
1203 $this->query_end($result);
1204 } catch (dml_exception $ex) {
1205 if ($end - $start >= $timeout) {
1206 throw new dml_sessionwait_exception();
1213 pg_free_result($result);
1216 $sql = "SET statement_timeout TO DEFAULT";
1217 $this->query_start($sql, null, SQL_QUERY_AUX);
1218 $result = pg_query($this->pgsql, $sql);
1219 $this->query_end($result);
1222 pg_free_result($result);
1226 public function release_session_lock($rowid) {
1227 if (!$this->session_lock_supported()) {
1230 parent::release_session_lock($rowid);
1232 $sql = "SELECT pg_advisory_unlock($rowid)";
1233 $this->query_start($sql, null, SQL_QUERY_AUX);
1234 $result = pg_query($this->pgsql, $sql);
1235 $this->query_end($result);
1238 pg_free_result($result);
1244 * Driver specific start of real database transaction,
1245 * this can not be used directly in code.
1248 protected function begin_transaction() {
1249 $sql = "BEGIN ISOLATION LEVEL READ COMMITTED";
1250 $this->query_start($sql, NULL, SQL_QUERY_AUX);
1251 $result = pg_query($this->pgsql, $sql);
1252 $this->query_end($result);
1254 pg_free_result($result);
1258 * Driver specific commit of real database transaction,
1259 * this can not be used directly in code.
1262 protected function commit_transaction() {
1264 $this->query_start($sql, NULL, SQL_QUERY_AUX);
1265 $result = pg_query($this->pgsql, $sql);
1266 $this->query_end($result);
1268 pg_free_result($result);
1272 * Driver specific abort of real database transaction,
1273 * this can not be used directly in code.
1276 protected function rollback_transaction() {
1278 $this->query_start($sql, NULL, SQL_QUERY_AUX);
1279 $result = pg_query($this->pgsql, $sql);
1280 $this->query_end($result);
1282 pg_free_result($result);
1286 * Helper function trimming (whitespace + quotes) any string
1287 * needed because PG uses to enclose with double quotes some
1288 * fields in indexes definition and others
1290 * @param string $str string to apply whitespace + quotes trim
1291 * @return string trimmed string
1293 private function trim_quotes($str) {
1294 return trim(trim($str), "'\"");