Merge branch 'MDL-68067' of https://github.com/Chocolate-lightning/moodle
[moodle.git] / lib / dml / oci_native_moodle_database.php
blobb752b18f4c89944a8c86df1d6d5e256c45f7ae8e
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 oci 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__.'/oci_native_moodle_recordset.php');
29 require_once(__DIR__.'/oci_native_moodle_temptables.php');
31 /**
32 * Native oci class representing moodle database interface.
34 * One complete reference for PHP + OCI:
35 * http://www.oracle.com/technology/tech/php/underground-php-oracle-manual.html
37 * @package core_dml
38 * @copyright 2008 Petr Skoda (http://skodak.org)
39 * @license http://www.gnu.org/copyleft/gpl.html GNU GPL v3 or later
41 class oci_native_moodle_database extends moodle_database {
43 protected $oci = null;
45 /** @var To store stmt errors and enable get_last_error() to detect them.*/
46 private $last_stmt_error = null;
47 /** @var Default value initialised in connect method, we need the driver to be present.*/
48 private $commit_status = null;
50 /** @var null|int To handle oci driver default verbosity.*/
51 private $last_error_reporting;
52 /** @var To store unique_session_id. Needed for temp tables unique naming.*/
53 private $unique_session_id;
55 /**
56 * Detects if all needed PHP stuff installed.
57 * Note: can be used before connect()
58 * @return mixed true if ok, string if something
60 public function driver_installed() {
61 if (!extension_loaded('oci8')) {
62 return get_string('ociextensionisnotpresentinphp', 'install');
64 return true;
67 /**
68 * Returns database family type - describes SQL dialect
69 * Note: can be used before connect()
70 * @return string db family name (mysql, postgres, mssql, oracle, etc.)
72 public function get_dbfamily() {
73 return 'oracle';
76 /**
77 * Returns more specific database driver type
78 * Note: can be used before connect()
79 * @return string db type mysqli, pgsql, oci, mssql, sqlsrv
81 protected function get_dbtype() {
82 return 'oci';
85 /**
86 * Returns general database library name
87 * Note: can be used before connect()
88 * @return string db type pdo, native
90 protected function get_dblibrary() {
91 return 'native';
94 /**
95 * Returns localised database type name
96 * Note: can be used before connect()
97 * @return string
99 public function get_name() {
100 return get_string('nativeoci', 'install');
104 * Returns localised database configuration help.
105 * Note: can be used before connect()
106 * @return string
108 public function get_configuration_help() {
109 return get_string('nativeocihelp', 'install');
113 * Diagnose database and tables, this function is used
114 * to verify database and driver settings, db engine types, etc.
116 * @return string null means everything ok, string means problem found.
118 public function diagnose() {
119 return null;
123 * Connect to db
124 * Must be called before other methods.
125 * @param string $dbhost The database host.
126 * @param string $dbuser The database username.
127 * @param string $dbpass The database username's password.
128 * @param string $dbname The name of the database being connected to.
129 * @param mixed $prefix string means moodle db prefix, false used for external databases where prefix not used
130 * @param array $dboptions driver specific options
131 * @return bool true
132 * @throws dml_connection_exception if error
134 public function connect($dbhost, $dbuser, $dbpass, $dbname, $prefix, array $dboptions=null) {
135 if ($prefix == '' and !$this->external) {
136 //Enforce prefixes for everybody but mysql
137 throw new dml_exception('prefixcannotbeempty', $this->get_dbfamily());
139 if (!$this->external and strlen($prefix) > 2) {
140 //Max prefix length for Oracle is 2cc
141 $a = (object)array('dbfamily'=>'oracle', 'maxlength'=>2);
142 throw new dml_exception('prefixtoolong', $a);
145 $driverstatus = $this->driver_installed();
147 if ($driverstatus !== true) {
148 throw new dml_exception('dbdriverproblem', $driverstatus);
151 // Autocommit ON by default.
152 // Switching to OFF (OCI_DEFAULT), when playing with transactions
153 // please note this thing is not defined if oracle driver not present in PHP
154 // which means it can not be used as default value of object property!
155 $this->commit_status = OCI_COMMIT_ON_SUCCESS;
157 $this->store_settings($dbhost, $dbuser, $dbpass, $dbname, $prefix, $dboptions);
158 unset($this->dboptions['dbsocket']);
160 // NOTE: use of ', ", / and \ is very problematic, even native oracle tools seem to have
161 // problems with these, so just forget them and do not report problems into tracker...
163 if (empty($this->dbhost)) {
164 // old style full address (TNS)
165 $dbstring = $this->dbname;
166 } else {
167 if (empty($this->dboptions['dbport'])) {
168 $this->dboptions['dbport'] = 1521;
170 $dbstring = '//'.$this->dbhost.':'.$this->dboptions['dbport'].'/'.$this->dbname;
173 ob_start();
174 if (empty($this->dboptions['dbpersist'])) {
175 $this->oci = oci_new_connect($this->dbuser, $this->dbpass, $dbstring, 'AL32UTF8');
176 } else {
177 $this->oci = oci_pconnect($this->dbuser, $this->dbpass, $dbstring, 'AL32UTF8');
179 $dberr = ob_get_contents();
180 ob_end_clean();
183 if ($this->oci === false) {
184 $this->oci = null;
185 $e = oci_error();
186 if (isset($e['message'])) {
187 $dberr = $e['message'];
189 throw new dml_connection_exception($dberr);
192 // Disable logging until we are fully setup.
193 $this->query_log_prevent();
195 // Make sure moodle package is installed - now required.
196 if (!$this->oci_package_installed()) {
197 try {
198 $this->attempt_oci_package_install();
199 } catch (Exception $e) {
200 // Ignore problems, only the result counts,
201 // admins have to fix it manually if necessary.
203 if (!$this->oci_package_installed()) {
204 throw new dml_exception('dbdriverproblem', 'Oracle PL/SQL Moodle support package MOODLELIB is not installed! Database administrator has to execute /lib/dml/oci_native_moodle_package.sql script.');
208 // get unique session id, to be used later for temp tables stuff
209 $sql = 'SELECT DBMS_SESSION.UNIQUE_SESSION_ID() FROM DUAL';
210 $this->query_start($sql, null, SQL_QUERY_AUX);
211 $stmt = $this->parse_query($sql);
212 $result = oci_execute($stmt, $this->commit_status);
213 $this->query_end($result, $stmt);
214 $records = null;
215 oci_fetch_all($stmt, $records, 0, -1, OCI_FETCHSTATEMENT_BY_ROW);
216 oci_free_statement($stmt);
217 $this->unique_session_id = reset($records[0]);
219 //note: do not send "ALTER SESSION SET NLS_NUMERIC_CHARACTERS='.,'" !
220 // instead fix our PHP code to convert "," to "." properly!
222 // We can enable logging now.
223 $this->query_log_allow();
225 // Connection stabilised and configured, going to instantiate the temptables controller
226 $this->temptables = new oci_native_moodle_temptables($this, $this->unique_session_id);
228 return true;
232 * Close database connection and release all resources
233 * and memory (especially circular memory references).
234 * Do NOT use connect() again, create a new instance if needed.
236 public function dispose() {
237 parent::dispose(); // Call parent dispose to write/close session and other common stuff before closing connection
238 if ($this->oci) {
239 oci_close($this->oci);
240 $this->oci = null;
246 * Called before each db query.
247 * @param string $sql
248 * @param array|null $params An array of parameters.
249 * @param int $type type of query
250 * @param mixed $extrainfo driver specific extra information
251 * @return void
253 protected function query_start($sql, ?array $params, $type, $extrainfo=null) {
254 parent::query_start($sql, $params, $type, $extrainfo);
255 // oci driver tents to send debug to output, we do not need that ;-)
256 $this->last_error_reporting = error_reporting(0);
260 * Called immediately after each db query.
261 * @param mixed db specific result
262 * @return void
264 protected function query_end($result, $stmt=null) {
265 // reset original debug level
266 error_reporting($this->last_error_reporting);
267 if ($stmt and $result === false) {
268 // Look for stmt error and store it
269 if (is_resource($stmt)) {
270 $e = oci_error($stmt);
271 if ($e !== false) {
272 $this->last_stmt_error = $e['message'];
275 oci_free_statement($stmt);
277 parent::query_end($result);
281 * Returns database server info array
282 * @return array Array containing 'description' and 'version' info
284 public function get_server_info() {
285 static $info = null; // TODO: move to real object property
287 if (is_null($info)) {
288 $this->query_start("--oci_server_version()", null, SQL_QUERY_AUX);
289 $description = oci_server_version($this->oci);
290 $this->query_end(true);
291 preg_match('/(\d+\.)+\d+/', $description, $matches);
292 $info = array('description'=>$description, 'version'=>$matches[0]);
295 return $info;
299 * Converts short table name {tablename} to real table name
300 * supporting temp tables ($this->unique_session_id based) if detected
302 * @param string sql
303 * @return string sql
305 protected function fix_table_names($sql) {
306 if (preg_match_all('/\{([a-z][a-z0-9_]*)\}/', $sql, $matches)) {
307 foreach($matches[0] as $key=>$match) {
308 $name = $matches[1][$key];
309 if ($this->temptables && $this->temptables->is_temptable($name)) {
310 $sql = str_replace($match, $this->temptables->get_correct_name($name), $sql);
311 } else {
312 $sql = str_replace($match, $this->prefix.$name, $sql);
316 return $sql;
320 * Returns supported query parameter types
321 * @return int bitmask of accepted SQL_PARAMS_*
323 protected function allowed_param_types() {
324 return SQL_PARAMS_NAMED;
328 * Returns last error reported by database engine.
329 * @return string error message
331 public function get_last_error() {
332 $error = false;
333 // First look for any previously saved stmt error
334 if (!empty($this->last_stmt_error)) {
335 $error = $this->last_stmt_error;
336 $this->last_stmt_error = null;
337 } else { // Now try connection error
338 $e = oci_error($this->oci);
339 if ($e !== false) {
340 $error = $e['message'];
343 return $error;
347 * Prepare the statement for execution
349 * @param string $sql
350 * @return resource
352 * @throws dml_exception
354 protected function parse_query($sql) {
355 $stmt = oci_parse($this->oci, $sql);
356 if ($stmt == false) {
357 throw new dml_exception('dmlparseexception', null, $this->get_last_error());
359 return $stmt;
363 * Make sure there are no reserved words in param names...
364 * @param string $sql
365 * @param array $params
366 * @return array ($sql, $params) updated query and parameters
368 protected function tweak_param_names($sql, array $params) {
369 if (empty($params)) {
370 return array($sql, $params);
373 $newparams = array();
374 $searcharr = array(); // search => replace pairs
375 foreach ($params as $name => $value) {
376 // Keep the name within the 30 chars limit always (prefixing/replacing)
377 if (strlen($name) <= 28) {
378 $newname = 'o_' . $name;
379 } else {
380 $newname = 'o_' . substr($name, 2);
382 $newparams[$newname] = $value;
383 $searcharr[':' . $name] = ':' . $newname;
385 // sort by length desc to avoid potential str_replace() overlap
386 uksort($searcharr, array('oci_native_moodle_database', 'compare_by_length_desc'));
388 $sql = str_replace(array_keys($searcharr), $searcharr, $sql);
389 return array($sql, $newparams);
393 * Return tables in database WITHOUT current prefix
394 * @param bool $usecache if true, returns list of cached tables.
395 * @return array of table names in lowercase and without prefix
397 public function get_tables($usecache=true) {
398 if ($usecache and $this->tables !== null) {
399 return $this->tables;
401 $this->tables = array();
402 $prefix = str_replace('_', "\\_", strtoupper($this->prefix));
403 $sql = "SELECT TABLE_NAME
404 FROM CAT
405 WHERE TABLE_TYPE='TABLE'
406 AND TABLE_NAME NOT LIKE 'BIN\$%'
407 AND TABLE_NAME LIKE '$prefix%' ESCAPE '\\'";
408 $this->query_start($sql, null, SQL_QUERY_AUX);
409 $stmt = $this->parse_query($sql);
410 $result = oci_execute($stmt, $this->commit_status);
411 $this->query_end($result, $stmt);
412 $records = null;
413 oci_fetch_all($stmt, $records, 0, -1, OCI_ASSOC);
414 oci_free_statement($stmt);
415 $records = array_map('strtolower', $records['TABLE_NAME']);
416 foreach ($records as $tablename) {
417 if ($this->prefix !== false && $this->prefix !== '') {
418 if (strpos($tablename, $this->prefix) !== 0) {
419 continue;
421 $tablename = substr($tablename, strlen($this->prefix));
423 $this->tables[$tablename] = $tablename;
426 // Add the currently available temptables
427 $this->tables = array_merge($this->tables, $this->temptables->get_temptables());
429 return $this->tables;
433 * Return table indexes - everything lowercased.
434 * @param string $table The table we want to get indexes from.
435 * @return array An associative array of indexes containing 'unique' flag and 'columns' being indexed
437 public function get_indexes($table) {
438 $indexes = array();
439 $tablename = strtoupper($this->prefix.$table);
441 $sql = "SELECT i.INDEX_NAME, i.INDEX_TYPE, i.UNIQUENESS, c.COLUMN_POSITION, c.COLUMN_NAME, e.COLUMN_EXPRESSION, ac.CONSTRAINT_TYPE
442 FROM ALL_INDEXES i
443 JOIN ALL_IND_COLUMNS c ON c.INDEX_NAME=i.INDEX_NAME
444 LEFT JOIN ALL_IND_EXPRESSIONS e ON (e.INDEX_NAME = c.INDEX_NAME AND e.COLUMN_POSITION = c.COLUMN_POSITION)
445 LEFT JOIN ALL_CONSTRAINTS ac ON (ac.TABLE_NAME=i.TABLE_NAME AND ac.CONSTRAINT_NAME=i.INDEX_NAME AND ac.CONSTRAINT_TYPE='P')
446 WHERE i.TABLE_NAME = '$tablename'
447 ORDER BY i.INDEX_NAME, c.COLUMN_POSITION";
449 $stmt = $this->parse_query($sql);
450 $result = oci_execute($stmt, $this->commit_status);
451 $this->query_end($result, $stmt);
452 $records = null;
453 oci_fetch_all($stmt, $records, 0, -1, OCI_FETCHSTATEMENT_BY_ROW);
454 oci_free_statement($stmt);
456 foreach ($records as $record) {
457 if ($record['CONSTRAINT_TYPE'] === 'P') {
458 //ignore for now;
459 continue;
461 $indexname = strtolower($record['INDEX_NAME']);
462 if (!isset($indexes[$indexname])) {
463 $indexes[$indexname] = array('primary' => ($record['CONSTRAINT_TYPE'] === 'P'),
464 'unique' => ($record['UNIQUENESS'] === 'UNIQUE'),
465 'columns' => array());
468 // If this is an unique, function-based, index, then we have to look to the expression
469 // and calculate the column name by parsing it.
470 if ($record['UNIQUENESS'] === 'UNIQUE' && $record['INDEX_TYPE'] === 'FUNCTION-BASED NORMAL') {
471 // Only if there is an expression to look.
472 if (!empty($record['COLUMN_EXPRESSION'])) {
473 // Let's parse the usual code used for these unique indexes.
474 $regex = '/^CASE *WHEN .* THEN "(?<column_name>[^"]+)" ELSE NULL END *$/';
475 if (preg_match($regex, $record['COLUMN_EXPRESSION'], $matches)) {
476 $record['COLUMN_NAME'] = $matches['column_name'] ?? $record['COLUMN_NAME'];
481 $indexes[$indexname]['columns'][] = strtolower($record['COLUMN_NAME']);
484 return $indexes;
488 * Fetches detailed information about columns in table.
490 * @param string $table name
491 * @return array array of database_column_info objects indexed with column names
493 protected function fetch_columns(string $table): array {
494 $structure = array();
496 // We give precedence to CHAR_LENGTH for VARCHAR2 columns over WIDTH because the former is always
497 // BYTE based and, for cross-db operations, we want CHAR based results. See MDL-29415
498 // Instead of guessing sequence based exclusively on name, check tables against user_triggers to
499 // ensure the table has a 'before each row' trigger to assume 'id' is auto_increment. MDL-32365
500 $sql = "SELECT CNAME, COLTYPE, nvl(CHAR_LENGTH, WIDTH) AS WIDTH, SCALE, PRECISION, NULLS, DEFAULTVAL,
501 DECODE(NVL(TRIGGER_NAME, '0'), '0', '0', '1') HASTRIGGER
502 FROM COL c
503 LEFT JOIN USER_TAB_COLUMNS u ON (u.TABLE_NAME = c.TNAME AND u.COLUMN_NAME = c.CNAME AND u.DATA_TYPE = 'VARCHAR2')
504 LEFT JOIN USER_TRIGGERS t ON (t.TABLE_NAME = c.TNAME AND TRIGGER_TYPE = 'BEFORE EACH ROW' AND c.CNAME = 'ID')
505 WHERE TNAME = UPPER('{" . $table . "}')
506 ORDER BY COLNO";
508 list($sql, $params, $type) = $this->fix_sql_params($sql, null);
510 $this->query_start($sql, null, SQL_QUERY_AUX);
511 $stmt = $this->parse_query($sql);
512 $result = oci_execute($stmt, $this->commit_status);
513 $this->query_end($result, $stmt);
514 $records = null;
515 oci_fetch_all($stmt, $records, 0, -1, OCI_FETCHSTATEMENT_BY_ROW);
516 oci_free_statement($stmt);
518 if (!$records) {
519 return array();
521 foreach ($records as $rawcolumn) {
522 $rawcolumn = (object)$rawcolumn;
524 $info = new stdClass();
525 $info->name = strtolower($rawcolumn->CNAME);
526 $info->auto_increment = ((int)$rawcolumn->HASTRIGGER) ? true : false;
527 $matches = null;
529 if ($rawcolumn->COLTYPE === 'VARCHAR2'
530 or $rawcolumn->COLTYPE === 'VARCHAR'
531 or $rawcolumn->COLTYPE === 'NVARCHAR2'
532 or $rawcolumn->COLTYPE === 'NVARCHAR'
533 or $rawcolumn->COLTYPE === 'CHAR'
534 or $rawcolumn->COLTYPE === 'NCHAR') {
535 $info->type = $rawcolumn->COLTYPE;
536 $info->meta_type = 'C';
537 $info->max_length = $rawcolumn->WIDTH;
538 $info->scale = null;
539 $info->not_null = ($rawcolumn->NULLS === 'NOT NULL');
540 $info->has_default = !is_null($rawcolumn->DEFAULTVAL);
541 if ($info->has_default) {
543 // this is hacky :-(
544 if ($rawcolumn->DEFAULTVAL === 'NULL') {
545 $info->default_value = null;
546 } else if ($rawcolumn->DEFAULTVAL === "' ' ") { // Sometimes it's stored with trailing space
547 $info->default_value = "";
548 } else if ($rawcolumn->DEFAULTVAL === "' '") { // Sometimes it's stored without trailing space
549 $info->default_value = "";
550 } else {
551 $info->default_value = trim($rawcolumn->DEFAULTVAL); // remove trailing space
552 $info->default_value = substr($info->default_value, 1, strlen($info->default_value)-2); //trim ''
554 } else {
555 $info->default_value = null;
557 $info->primary_key = false;
558 $info->binary = false;
559 $info->unsigned = null;
560 $info->unique = null;
562 } else if ($rawcolumn->COLTYPE === 'NUMBER') {
563 $info->type = $rawcolumn->COLTYPE;
564 $info->max_length = $rawcolumn->PRECISION;
565 $info->binary = false;
566 if (!is_null($rawcolumn->SCALE) && $rawcolumn->SCALE == 0) { // null in oracle scale allows decimals => not integer
567 // integer
568 if ($info->name === 'id') {
569 $info->primary_key = true;
570 $info->meta_type = 'R';
571 $info->unique = true;
572 $info->has_default = false;
573 } else {
574 $info->primary_key = false;
575 $info->meta_type = 'I';
576 $info->unique = null;
578 $info->scale = 0;
580 } else {
581 //float
582 $info->meta_type = 'N';
583 $info->primary_key = false;
584 $info->unsigned = null;
585 $info->unique = null;
586 $info->scale = $rawcolumn->SCALE;
588 $info->not_null = ($rawcolumn->NULLS === 'NOT NULL');
589 $info->has_default = !is_null($rawcolumn->DEFAULTVAL);
590 if ($info->has_default) {
591 $info->default_value = trim($rawcolumn->DEFAULTVAL); // remove trailing space
592 } else {
593 $info->default_value = null;
596 } else if ($rawcolumn->COLTYPE === 'FLOAT') {
597 $info->type = $rawcolumn->COLTYPE;
598 $info->max_length = (int)($rawcolumn->PRECISION * 3.32193);
599 $info->primary_key = false;
600 $info->meta_type = 'N';
601 $info->unique = null;
602 $info->not_null = ($rawcolumn->NULLS === 'NOT NULL');
603 $info->has_default = !is_null($rawcolumn->DEFAULTVAL);
604 if ($info->has_default) {
605 $info->default_value = trim($rawcolumn->DEFAULTVAL); // remove trailing space
606 } else {
607 $info->default_value = null;
610 } else if ($rawcolumn->COLTYPE === 'CLOB'
611 or $rawcolumn->COLTYPE === 'NCLOB') {
612 $info->type = $rawcolumn->COLTYPE;
613 $info->meta_type = 'X';
614 $info->max_length = -1;
615 $info->scale = null;
616 $info->scale = null;
617 $info->not_null = ($rawcolumn->NULLS === 'NOT NULL');
618 $info->has_default = !is_null($rawcolumn->DEFAULTVAL);
619 if ($info->has_default) {
620 // this is hacky :-(
621 if ($rawcolumn->DEFAULTVAL === 'NULL') {
622 $info->default_value = null;
623 } else if ($rawcolumn->DEFAULTVAL === "' ' ") { // Sometimes it's stored with trailing space
624 $info->default_value = "";
625 } else if ($rawcolumn->DEFAULTVAL === "' '") { // Other times it's stored without trailing space
626 $info->default_value = "";
627 } else {
628 $info->default_value = trim($rawcolumn->DEFAULTVAL); // remove trailing space
629 $info->default_value = substr($info->default_value, 1, strlen($info->default_value)-2); //trim ''
631 } else {
632 $info->default_value = null;
634 $info->primary_key = false;
635 $info->binary = false;
636 $info->unsigned = null;
637 $info->unique = null;
639 } else if ($rawcolumn->COLTYPE === 'BLOB') {
640 $info->type = $rawcolumn->COLTYPE;
641 $info->meta_type = 'B';
642 $info->max_length = -1;
643 $info->scale = null;
644 $info->scale = null;
645 $info->not_null = ($rawcolumn->NULLS === 'NOT NULL');
646 $info->has_default = !is_null($rawcolumn->DEFAULTVAL);
647 if ($info->has_default) {
648 // this is hacky :-(
649 if ($rawcolumn->DEFAULTVAL === 'NULL') {
650 $info->default_value = null;
651 } else if ($rawcolumn->DEFAULTVAL === "' ' ") { // Sometimes it's stored with trailing space
652 $info->default_value = "";
653 } else if ($rawcolumn->DEFAULTVAL === "' '") { // Sometimes it's stored without trailing space
654 $info->default_value = "";
655 } else {
656 $info->default_value = trim($rawcolumn->DEFAULTVAL); // remove trailing space
657 $info->default_value = substr($info->default_value, 1, strlen($info->default_value)-2); //trim ''
659 } else {
660 $info->default_value = null;
662 $info->primary_key = false;
663 $info->binary = true;
664 $info->unsigned = null;
665 $info->unique = null;
667 } else {
668 // unknown type - sorry
669 $info->type = $rawcolumn->COLTYPE;
670 $info->meta_type = '?';
673 $structure[$info->name] = new database_column_info($info);
676 return $structure;
680 * Normalise values based in RDBMS dependencies (booleans, LOBs...)
682 * @param database_column_info $column column metadata corresponding with the value we are going to normalise
683 * @param mixed $value value we are going to normalise
684 * @return mixed the normalised value
686 protected function normalise_value($column, $value) {
687 $this->detect_objects($value);
689 if (is_bool($value)) { // Always, convert boolean to int
690 $value = (int)$value;
692 } else if ($column->meta_type == 'B' && !is_null($value)) {
693 // Not null BLOB detected, we return 'blob' array instead for later handing on binding.
694 $value = array('blob' => $value);
696 } else if ($column->meta_type == 'X' && !is_null($value) && strlen($value) > 4000) {
697 // Not null CLOB detected (>4000 optimisation), we return 'clob' array instead for later handing on binding.
698 $value = array('clob' => (string)$value);
700 } else if ($value === '') {
701 if ($column->meta_type == 'I' or $column->meta_type == 'F' or $column->meta_type == 'N') {
702 $value = 0; // prevent '' problems in numeric fields
705 return $value;
709 * This function will handle all the column values before being inserted/updated to DB for Oracle
710 * installations. This is because the "special feature" of Oracle where the empty string is
711 * equal to NULL and this presents a problem with all our currently NOT NULL default '' fields.
712 * (and with empties handling in general)
714 * Note that this function is 100% private and should be used, exclusively by DML functions
715 * in this file. Also, this is considered a DIRTY HACK to be removed when possible.
717 * This function is private and must not be used outside this driver at all
719 * @param $table string the table where the record is going to be inserted/updated (without prefix)
720 * @param $field string the field where the record is going to be inserted/updated
721 * @param $value mixed the value to be inserted/updated
723 private function oracle_dirty_hack ($table, $field, $value) {
725 // General bound parameter, just hack the spaces and pray it will work.
726 if (!$table) {
727 if ($value === '') {
728 return ' ';
729 } else if (is_bool($value)) {
730 return (int)$value;
731 } else {
732 return $value;
736 // Get metadata
737 $columns = $this->get_columns($table);
738 if (!isset($columns[$field])) {
739 if ($value === '') {
740 return ' ';
741 } else if (is_bool($value)) {
742 return (int)$value;
743 } else {
744 return $value;
747 $column = $columns[$field];
749 // !! This paragraph explains behaviour before Moodle 2.0:
751 // For Oracle DB, empty strings are converted to NULLs in DB
752 // and this breaks a lot of NOT NULL columns currently Moodle. In the future it's
753 // planned to move some of them to NULL, if they must accept empty values and this
754 // piece of code will become less and less used. But, for now, we need it.
755 // What we are going to do is to examine all the data being inserted and if it's
756 // an empty string (NULL for Oracle) and the field is defined as NOT NULL, we'll modify
757 // such data in the best form possible ("0" for booleans and numbers and " " for the
758 // rest of strings. It isn't optimal, but the only way to do so.
759 // In the opposite, when retrieving records from Oracle, we'll decode " " back to
760 // empty strings to allow everything to work properly. DIRTY HACK.
762 // !! These paragraphs explain the rationale about the change for Moodle 2.5:
764 // Before Moodle 2.0, we only used to apply this DIRTY HACK to NOT NULL columns, as
765 // stated above, but it causes one problem in NULL columns where both empty strings
766 // and real NULLs are stored as NULLs, being impossible to differentiate them when
767 // being retrieved from DB.
769 // So, starting with Moodle 2.0, we are going to apply the DIRTY HACK to all the
770 // CHAR/CLOB columns no matter of their nullability. That way, when retrieving
771 // NULLABLE fields we'll get proper empties and NULLs differentiated, so we'll be able
772 // to rely in NULL/empty/content contents without problems, until now that wasn't
773 // possible at all.
775 // One space DIRTY HACK is now applied automatically for all query parameters
776 // and results. The only problem is string concatenation where the glue must
777 // be specified as "' '" sql fragment.
779 // !! Conclusions:
781 // From Moodle 2.5 onwards, ALL empty strings in Oracle DBs will be stored as
782 // 1-whitespace char, ALL NULLs as NULLs and, obviously, content as content. And
783 // those 1-whitespace chars will be converted back to empty strings by all the
784 // get_field/record/set() functions transparently and any SQL needing direct handling
785 // of empties will have to use placeholders or sql_isempty() helper function.
787 // If the field isn't VARCHAR or CLOB, skip
788 if ($column->meta_type != 'C' and $column->meta_type != 'X') {
789 return $value;
792 // If the value isn't empty, skip
793 if (!empty($value)) {
794 return $value;
797 // Now, we have one empty value, going to be inserted to one VARCHAR2 or CLOB field
798 // Try to get the best value to be inserted
800 // The '0' string doesn't need any transformation, skip
801 if ($value === '0') {
802 return $value;
805 // Transformations start
806 if (gettype($value) == 'boolean') {
807 return '0'; // Transform false to '0' that evaluates the same for PHP
809 } else if (gettype($value) == 'integer') {
810 return '0'; // Transform 0 to '0' that evaluates the same for PHP
812 } else if ($value === '') {
813 return ' '; // Transform '' to ' ' that DON'T EVALUATE THE SAME
814 // (we'll transform back again on get_records_XXX functions and others)!!
817 // Fail safe to original value
818 return $value;
822 * Helper function to order by string length desc
824 * @param $a string first element to compare
825 * @param $b string second element to compare
826 * @return int < 0 $a goes first (is less), 0 $b goes first, 0 doesn't matter
828 private function compare_by_length_desc($a, $b) {
829 return strlen($b) - strlen($a);
833 * Is db in unicode mode?
834 * @return bool
836 public function setup_is_unicodedb() {
837 $sql = "SELECT VALUE
838 FROM NLS_DATABASE_PARAMETERS
839 WHERE PARAMETER = 'NLS_CHARACTERSET'";
840 $this->query_start($sql, null, SQL_QUERY_AUX);
841 $stmt = $this->parse_query($sql);
842 $result = oci_execute($stmt, $this->commit_status);
843 $this->query_end($result, $stmt);
844 $records = null;
845 oci_fetch_all($stmt, $records, 0, -1, OCI_FETCHSTATEMENT_BY_COLUMN);
846 oci_free_statement($stmt);
848 return (isset($records['VALUE'][0]) and $records['VALUE'][0] === 'AL32UTF8');
852 * Do NOT use in code, to be used by database_manager only!
853 * @param string|array $sql query
854 * @param array|null $tablenames an array of xmldb table names affected by this request.
855 * @return bool true
856 * @throws ddl_change_structure_exception A DDL specific exception is thrown for any errors.
858 public function change_database_structure($sql, $tablenames = null) {
859 $this->get_manager(); // Includes DDL exceptions classes ;-)
860 $sqls = (array)$sql;
862 try {
863 foreach ($sqls as $sql) {
864 $this->query_start($sql, null, SQL_QUERY_STRUCTURE);
865 $stmt = $this->parse_query($sql);
866 $result = oci_execute($stmt, $this->commit_status);
867 $this->query_end($result, $stmt);
868 oci_free_statement($stmt);
870 } catch (ddl_change_structure_exception $e) {
871 $this->reset_caches($tablenames);
872 throw $e;
875 $this->reset_caches($tablenames);
876 return true;
879 protected function bind_params($stmt, array &$params=null, $tablename=null, array &$descriptors = null) {
880 if ($params) {
881 $columns = array();
882 if ($tablename) {
883 $columns = $this->get_columns($tablename);
885 foreach($params as $key => $value) {
886 // Decouple column name and param name as far as sometimes they aren't the same
887 if ($key == 'o_newfieldtoset') { // found case where column and key diverge, handle that
888 $columnname = key($value); // columnname is the key of the array
889 $params[$key] = $value[$columnname]; // set the proper value in the $params array and
890 $value = $value[$columnname]; // set the proper value in the $value variable
891 } else {
892 $columnname = preg_replace('/^o_/', '', $key); // Default columnname (for DB introspecting is key), but...
894 // Continue processing
895 // Now, handle already detected LOBs
896 if (is_array($value)) { // Let's go to bind special cases (lob descriptors)
897 if (isset($value['clob'])) {
898 $lob = oci_new_descriptor($this->oci, OCI_DTYPE_LOB);
899 if ($descriptors === null) {
900 throw new coding_exception('moodle_database::bind_params() $descriptors not specified for clob');
902 $descriptors[] = $lob;
903 oci_bind_by_name($stmt, $key, $lob, -1, SQLT_CLOB);
904 $lob->writeTemporary($this->oracle_dirty_hack($tablename, $columnname, $params[$key]['clob']), OCI_TEMP_CLOB);
905 continue; // Column binding finished, go to next one
906 } else if (isset($value['blob'])) {
907 $lob = oci_new_descriptor($this->oci, OCI_DTYPE_LOB);
908 if ($descriptors === null) {
909 throw new coding_exception('moodle_database::bind_params() $descriptors not specified for clob');
911 $descriptors[] = $lob;
912 oci_bind_by_name($stmt, $key, $lob, -1, SQLT_BLOB);
913 $lob->writeTemporary($params[$key]['blob'], OCI_TEMP_BLOB);
914 continue; // Column binding finished, go to next one
916 } else {
917 // If, at this point, the param value > 4000 (bytes), let's assume it's a clob
918 // passed in an arbitrary sql (not processed by normalise_value() ever,
919 // and let's handle it as such. This will provide proper binding of CLOBs in
920 // conditions and other raw SQLs not covered by the above function.
921 if (!is_null($value) && strlen($value) > 4000) {
922 $lob = oci_new_descriptor($this->oci, OCI_DTYPE_LOB);
923 if ($descriptors === null) {
924 throw new coding_exception('moodle_database::bind_params() $descriptors not specified for clob');
926 $descriptors[] = $lob;
927 oci_bind_by_name($stmt, $key, $lob, -1, SQLT_CLOB);
928 $lob->writeTemporary($this->oracle_dirty_hack($tablename, $columnname, $params[$key]), OCI_TEMP_CLOB);
929 continue; // Param binding finished, go to next one.
932 // TODO: Put proper types and length is possible (enormous speedup)
933 // Arrived here, continue with standard processing, using metadata if possible
934 if (isset($columns[$columnname])) {
935 $type = $columns[$columnname]->meta_type;
936 $maxlength = $columns[$columnname]->max_length;
937 } else {
938 $type = '?';
939 $maxlength = -1;
941 switch ($type) {
942 case 'I':
943 case 'R':
944 // TODO: Optimise
945 oci_bind_by_name($stmt, $key, $params[$key]);
946 break;
948 case 'N':
949 case 'F':
950 // TODO: Optimise
951 oci_bind_by_name($stmt, $key, $params[$key]);
952 break;
954 case 'B':
955 // TODO: Only arrive here if BLOB is null: Bind if so, else exception!
956 // don't break here
958 case 'X':
959 // TODO: Only arrive here if CLOB is null or <= 4000 cc, else exception
960 // don't break here
962 default: // Bind as CHAR (applying dirty hack)
963 // TODO: Optimise
964 $params[$key] = $this->oracle_dirty_hack($tablename, $columnname, $params[$key]);
965 // Because of PHP7 bug (https://bugs.php.net/bug.php?id=72524) it seems that it's
966 // impossible to bind NULL values in a reliable way, let's use empty string
967 // instead in the mean time.
968 if ($params[$key] === null && version_compare(PHP_VERSION, '7.0.0', '>=')) {
969 $params[$key] = '';
971 oci_bind_by_name($stmt, $key, $params[$key]);
975 return $descriptors;
978 protected function free_descriptors($descriptors) {
979 foreach ($descriptors as $descriptor) {
980 // Because all descriptors used in the driver come from LOB::writeTemporary() calls
981 // we can safely close them here unconditionally.
982 $descriptor->close();
983 // Free resources.
984 oci_free_descriptor($descriptor);
989 * This function is used to convert all the Oracle 1-space defaults to the empty string
990 * like a really DIRTY HACK to allow it to work better until all those NOT NULL DEFAULT ''
991 * fields will be out from Moodle.
992 * @param string the string to be converted to '' (empty string) if it's ' ' (one space)
993 * @param mixed the key of the array in case we are using this function from array_walk,
994 * defaults to null for other (direct) uses
995 * @return boolean always true (the converted variable is returned by reference)
997 public static function onespace2empty(&$item, $key=null) {
998 $item = ($item === ' ') ? '' : $item;
999 return true;
1003 * Execute general sql query. Should be used only when no other method suitable.
1004 * Do NOT use this to make changes in db structure, use database_manager methods instead!
1005 * @param string $sql query
1006 * @param array $params query parameters
1007 * @return bool true
1008 * @throws dml_exception A DML specific exception is thrown for any errors.
1010 public function execute($sql, array $params=null) {
1011 list($sql, $params, $type) = $this->fix_sql_params($sql, $params);
1013 if (strpos($sql, ';') !== false) {
1014 throw new coding_exception('moodle_database::execute() Multiple sql statements found or bound parameters not used properly in query!');
1017 list($sql, $params) = $this->tweak_param_names($sql, $params);
1018 $this->query_start($sql, $params, SQL_QUERY_UPDATE);
1019 $stmt = $this->parse_query($sql);
1020 $descriptors = array();
1021 $this->bind_params($stmt, $params, null, $descriptors);
1022 $result = oci_execute($stmt, $this->commit_status);
1023 $this->free_descriptors($descriptors);
1024 $this->query_end($result, $stmt);
1025 oci_free_statement($stmt);
1027 return true;
1031 * Get a single database record as an object using a SQL statement.
1033 * The SQL statement should normally only return one record.
1034 * It is recommended to use get_records_sql() if more matches possible!
1036 * @param string $sql The SQL string you wish to be executed, should normally only return one record.
1037 * @param array $params array of sql parameters
1038 * @param int $strictness IGNORE_MISSING means compatible mode, false returned if record not found, debug message if more found;
1039 * IGNORE_MULTIPLE means return first, ignore multiple records found(not recommended);
1040 * MUST_EXIST means throw exception if no record or multiple records found
1041 * @return mixed a fieldset object containing the first matching record, false or exception if error not found depending on mode
1042 * @throws dml_exception A DML specific exception is thrown for any errors.
1044 public function get_record_sql($sql, array $params=null, $strictness=IGNORE_MISSING) {
1045 $strictness = (int)$strictness;
1046 if ($strictness == IGNORE_MULTIPLE) {
1047 // do not limit here - ORA does not like that
1048 $rs = $this->get_recordset_sql($sql, $params);
1049 $result = false;
1050 foreach ($rs as $rec) {
1051 $result = $rec;
1052 break;
1054 $rs->close();
1055 return $result;
1057 return parent::get_record_sql($sql, $params, $strictness);
1061 * Get a number of records as a moodle_recordset using a SQL statement.
1063 * Since this method is a little less readable, use of it should be restricted to
1064 * code where it's possible there might be large datasets being returned. For known
1065 * small datasets use get_records_sql - it leads to simpler code.
1067 * The return type is like:
1068 * @see function get_recordset.
1070 * @param string $sql the SQL select query to execute.
1071 * @param array $params array of sql parameters
1072 * @param int $limitfrom return a subset of records, starting at this point (optional, required if $limitnum is set).
1073 * @param int $limitnum return a subset comprising this many records (optional, required if $limitfrom is set).
1074 * @return moodle_recordset instance
1075 * @throws dml_exception A DML specific exception is thrown for any errors.
1077 public function get_recordset_sql($sql, array $params=null, $limitfrom=0, $limitnum=0) {
1079 list($limitfrom, $limitnum) = $this->normalise_limit_from_num($limitfrom, $limitnum);
1081 if ($limitfrom) {
1082 $sql .= " OFFSET $limitfrom ROWS";
1084 if ($limitnum) {
1085 $sql .= " FETCH NEXT $limitnum ROWS ONLY";
1088 list($rawsql, $params, $type) = $this->fix_sql_params($sql, $params);
1090 list($rawsql, $params) = $this->tweak_param_names($rawsql, $params);
1091 $this->query_start($rawsql, $params, SQL_QUERY_SELECT);
1092 $stmt = $this->parse_query($rawsql);
1093 $descriptors = array();
1094 $this->bind_params($stmt, $params, null, $descriptors);
1095 $result = oci_execute($stmt, $this->commit_status);
1096 $this->free_descriptors($descriptors);
1097 $this->query_end($result, $stmt);
1099 return $this->create_recordset($stmt);
1102 protected function create_recordset($stmt) {
1103 return new oci_native_moodle_recordset($stmt);
1107 * Get a number of records as an array of objects using a SQL statement.
1109 * Return value is like:
1110 * @see function get_records.
1112 * @param string $sql the SQL select query to execute. The first column of this SELECT statement
1113 * must be a unique value (usually the 'id' field), as it will be used as the key of the
1114 * returned array.
1115 * @param array $params array of sql parameters
1116 * @param int $limitfrom return a subset of records, starting at this point (optional, required if $limitnum is set).
1117 * @param int $limitnum return a subset comprising this many records (optional, required if $limitfrom is set).
1118 * @return array of objects, or empty array if no records were found
1119 * @throws dml_exception A DML specific exception is thrown for any errors.
1121 public function get_records_sql($sql, array $params=null, $limitfrom=0, $limitnum=0) {
1123 list($limitfrom, $limitnum) = $this->normalise_limit_from_num($limitfrom, $limitnum);
1125 if ($limitfrom) {
1126 $sql .= " OFFSET $limitfrom ROWS";
1128 if ($limitnum) {
1129 $sql .= " FETCH NEXT $limitnum ROWS ONLY";
1132 list($rawsql, $params, $type) = $this->fix_sql_params($sql, $params);
1134 list($rawsql, $params) = $this->tweak_param_names($rawsql, $params);
1135 $this->query_start($rawsql, $params, SQL_QUERY_SELECT);
1136 $stmt = $this->parse_query($rawsql);
1137 $descriptors = array();
1138 $this->bind_params($stmt, $params, null, $descriptors);
1139 $result = oci_execute($stmt, $this->commit_status);
1140 $this->free_descriptors($descriptors);
1141 $this->query_end($result, $stmt);
1143 $records = null;
1144 oci_fetch_all($stmt, $records, 0, -1, OCI_FETCHSTATEMENT_BY_ROW);
1145 oci_free_statement($stmt);
1147 $return = array();
1149 foreach ($records as $row) {
1150 $row = array_change_key_case($row, CASE_LOWER);
1151 unset($row['oracle_rownum']);
1152 array_walk($row, array('oci_native_moodle_database', 'onespace2empty'));
1153 $id = reset($row);
1154 if (isset($return[$id])) {
1155 $colname = key($row);
1156 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);
1158 $return[$id] = (object)$row;
1161 return $return;
1165 * Selects records and return values (first field) as an array using a SQL statement.
1167 * @param string $sql The SQL query
1168 * @param array $params array of sql parameters
1169 * @return array of values
1170 * @throws dml_exception A DML specific exception is thrown for any errors.
1172 public function get_fieldset_sql($sql, array $params=null) {
1173 list($sql, $params, $type) = $this->fix_sql_params($sql, $params);
1175 list($sql, $params) = $this->tweak_param_names($sql, $params);
1176 $this->query_start($sql, $params, SQL_QUERY_SELECT);
1177 $stmt = $this->parse_query($sql);
1178 $descriptors = array();
1179 $this->bind_params($stmt, $params, null, $descriptors);
1180 $result = oci_execute($stmt, $this->commit_status);
1181 $this->free_descriptors($descriptors);
1182 $this->query_end($result, $stmt);
1184 $records = null;
1185 oci_fetch_all($stmt, $records, 0, -1, OCI_FETCHSTATEMENT_BY_COLUMN);
1186 oci_free_statement($stmt);
1188 $return = reset($records);
1189 array_walk($return, array('oci_native_moodle_database', 'onespace2empty'));
1191 return $return;
1195 * Insert new record into database, as fast as possible, no safety checks, lobs not supported.
1196 * @param string $table name
1197 * @param mixed $params data record as object or array
1198 * @param bool $returnit return it of inserted record
1199 * @param bool $bulk true means repeated inserts expected
1200 * @param bool $customsequence true if 'id' included in $params, disables $returnid
1201 * @return bool|int true or new id
1202 * @throws dml_exception A DML specific exception is thrown for any errors.
1204 public function insert_record_raw($table, $params, $returnid=true, $bulk=false, $customsequence=false) {
1205 if (!is_array($params)) {
1206 $params = (array)$params;
1209 $returning = "";
1211 if ($customsequence) {
1212 if (!isset($params['id'])) {
1213 throw new coding_exception('moodle_database::insert_record_raw() id field must be specified if custom sequences used.');
1215 $returnid = false;
1216 } else {
1217 unset($params['id']);
1218 if ($returnid) {
1219 $returning = " RETURNING id INTO :oracle_id"; // crazy name nobody is ever going to use or parameter ;-)
1223 if (empty($params)) {
1224 throw new coding_exception('moodle_database::insert_record_raw() no fields found.');
1227 $fields = implode(',', array_keys($params));
1228 $values = array();
1229 foreach ($params as $pname => $value) {
1230 $values[] = ":$pname";
1232 $values = implode(',', $values);
1234 $sql = "INSERT INTO {" . $table . "} ($fields) VALUES ($values)";
1235 list($sql, $params, $type) = $this->fix_sql_params($sql, $params);
1236 $sql .= $returning;
1238 $id = 0;
1240 // note we don't need tweak_param_names() here. Placeholders are safe column names. MDL-28080
1241 // list($sql, $params) = $this->tweak_param_names($sql, $params);
1242 $this->query_start($sql, $params, SQL_QUERY_INSERT);
1243 $stmt = $this->parse_query($sql);
1244 if ($returning) {
1245 oci_bind_by_name($stmt, ":oracle_id", $id, 10, SQLT_INT);
1247 $descriptors = array();
1248 $this->bind_params($stmt, $params, $table, $descriptors);
1249 $result = oci_execute($stmt, $this->commit_status);
1250 $this->free_descriptors($descriptors);
1251 $this->query_end($result, $stmt);
1252 oci_free_statement($stmt);
1254 if (!$returnid) {
1255 return true;
1258 if (!$returning) {
1259 die('TODO - implement oracle 9.2 insert support'); //TODO
1262 return (int)$id;
1266 * Insert a record into a table and return the "id" field if required.
1268 * Some conversions and safety checks are carried out. Lobs are supported.
1269 * If the return ID isn't required, then this just reports success as true/false.
1270 * $data is an object containing needed data
1271 * @param string $table The database table to be inserted into
1272 * @param object|array $dataobject A data object with values for one or more fields in the record
1273 * @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.
1274 * @return bool|int true or new id
1275 * @throws dml_exception A DML specific exception is thrown for any errors.
1277 public function insert_record($table, $dataobject, $returnid=true, $bulk=false) {
1278 $dataobject = (array)$dataobject;
1280 $columns = $this->get_columns($table);
1281 if (empty($columns)) {
1282 throw new dml_exception('ddltablenotexist', $table);
1285 $cleaned = array();
1287 foreach ($dataobject as $field=>$value) {
1288 if ($field === 'id') {
1289 continue;
1291 if (!isset($columns[$field])) { // Non-existing table field, skip it
1292 continue;
1294 $column = $columns[$field];
1295 $cleaned[$field] = $this->normalise_value($column, $value);
1298 return $this->insert_record_raw($table, $cleaned, $returnid, $bulk);
1302 * Import a record into a table, id field is required.
1303 * Safety checks are NOT carried out. Lobs are supported.
1305 * @param string $table name of database table to be inserted into
1306 * @param object $dataobject A data object with values for one or more fields in the record
1307 * @return bool true
1308 * @throws dml_exception A DML specific exception is thrown for any errors.
1310 public function import_record($table, $dataobject) {
1311 $dataobject = (array)$dataobject;
1313 $columns = $this->get_columns($table);
1314 $cleaned = array();
1316 foreach ($dataobject as $field=>$value) {
1317 if (!isset($columns[$field])) {
1318 continue;
1320 $column = $columns[$field];
1321 $cleaned[$field] = $this->normalise_value($column, $value);
1324 return $this->insert_record_raw($table, $cleaned, false, true, true);
1328 * Update record in database, as fast as possible, no safety checks, lobs not supported.
1329 * @param string $table name
1330 * @param stdClass|array $params data record as object or array
1331 * @param bool true means repeated updates expected
1332 * @return bool true
1333 * @throws dml_exception A DML specific exception is thrown for any errors.
1335 public function update_record_raw($table, $params, $bulk=false) {
1336 $params = (array)$params;
1338 if (!isset($params['id'])) {
1339 throw new coding_exception('moodle_database::update_record_raw() id field must be specified.');
1342 if (empty($params)) {
1343 throw new coding_exception('moodle_database::update_record_raw() no fields found.');
1346 $sets = array();
1347 foreach ($params as $field=>$value) {
1348 if ($field == 'id') {
1349 continue;
1351 $sets[] = "$field = :$field";
1354 $sets = implode(',', $sets);
1355 $sql = "UPDATE {" . $table . "} SET $sets WHERE id=:id";
1356 list($sql, $params, $type) = $this->fix_sql_params($sql, $params);
1358 // note we don't need tweak_param_names() here. Placeholders are safe column names. MDL-28080
1359 // list($sql, $params) = $this->tweak_param_names($sql, $params);
1360 $this->query_start($sql, $params, SQL_QUERY_UPDATE);
1361 $stmt = $this->parse_query($sql);
1362 $descriptors = array();
1363 $this->bind_params($stmt, $params, $table, $descriptors);
1364 $result = oci_execute($stmt, $this->commit_status);
1365 $this->free_descriptors($descriptors);
1366 $this->query_end($result, $stmt);
1367 oci_free_statement($stmt);
1369 return true;
1373 * Update a record in a table
1375 * $dataobject is an object containing needed data
1376 * Relies on $dataobject having a variable "id" to
1377 * specify the record to update
1379 * @param string $table The database table to be checked against.
1380 * @param stdClass|array $dataobject An object with contents equal to fieldname=>fieldvalue.
1381 * Must have an entry for 'id' to map to the table specified.
1382 * @param bool true means repeated updates expected
1383 * @return bool true
1384 * @throws dml_exception A DML specific exception is thrown for any errors.
1386 public function update_record($table, $dataobject, $bulk=false) {
1387 $dataobject = (array)$dataobject;
1389 $columns = $this->get_columns($table);
1390 $cleaned = array();
1392 foreach ($dataobject as $field=>$value) {
1393 if (!isset($columns[$field])) {
1394 continue;
1396 $column = $columns[$field];
1397 $cleaned[$field] = $this->normalise_value($column, $value);
1400 $this->update_record_raw($table, $cleaned, $bulk);
1402 return true;
1406 * Set a single field in every table record which match a particular WHERE clause.
1408 * @param string $table The database table to be checked against.
1409 * @param string $newfield the field to set.
1410 * @param string $newvalue the value to set the field to.
1411 * @param string $select A fragment of SQL to be used in a where clause in the SQL call.
1412 * @param array $params array of sql parameters
1413 * @return bool true
1414 * @throws dml_exception A DML specific exception is thrown for any errors.
1416 public function set_field_select($table, $newfield, $newvalue, $select, array $params=null) {
1418 if ($select) {
1419 $select = "WHERE $select";
1421 if (is_null($params)) {
1422 $params = array();
1425 // Get column metadata
1426 $columns = $this->get_columns($table);
1427 $column = $columns[$newfield];
1429 $newvalue = $this->normalise_value($column, $newvalue);
1431 list($select, $params, $type) = $this->fix_sql_params($select, $params);
1433 if (is_bool($newvalue)) {
1434 $newvalue = (int)$newvalue; // prevent "false" problems
1436 if (is_null($newvalue)) {
1437 $newsql = "$newfield = NULL";
1438 } else {
1439 // Set the param to array ($newfield => $newvalue) and key to 'newfieldtoset'
1440 // name in the build sql. Later, bind_params() will detect the value array and
1441 // perform the needed modifications to allow the query to work. Note that
1442 // 'newfieldtoset' is one arbitrary name that hopefully won't be used ever
1443 // in order to avoid problems where the same field is used both in the set clause and in
1444 // the conditions. This was breaking badly in drivers using NAMED params like oci.
1445 $params['newfieldtoset'] = array($newfield => $newvalue);
1446 $newsql = "$newfield = :newfieldtoset";
1448 $sql = "UPDATE {" . $table . "} SET $newsql $select";
1449 list($sql, $params, $type) = $this->fix_sql_params($sql, $params);
1451 list($sql, $params) = $this->tweak_param_names($sql, $params);
1452 $this->query_start($sql, $params, SQL_QUERY_UPDATE);
1453 $stmt = $this->parse_query($sql);
1454 $descriptors = array();
1455 $this->bind_params($stmt, $params, $table, $descriptors);
1456 $result = oci_execute($stmt, $this->commit_status);
1457 $this->free_descriptors($descriptors);
1458 $this->query_end($result, $stmt);
1459 oci_free_statement($stmt);
1461 return true;
1465 * Delete one or more records from a table which match a particular WHERE clause.
1467 * @param string $table The database table to be checked against.
1468 * @param string $select A fragment of SQL to be used in a where clause in the SQL call (used to define the selection criteria).
1469 * @param array $params array of sql parameters
1470 * @return bool true
1471 * @throws dml_exception A DML specific exception is thrown for any errors.
1473 public function delete_records_select($table, $select, array $params=null) {
1475 if ($select) {
1476 $select = "WHERE $select";
1479 $sql = "DELETE FROM {" . $table . "} $select";
1481 list($sql, $params, $type) = $this->fix_sql_params($sql, $params);
1483 list($sql, $params) = $this->tweak_param_names($sql, $params);
1484 $this->query_start($sql, $params, SQL_QUERY_UPDATE);
1485 $stmt = $this->parse_query($sql);
1486 $descriptors = array();
1487 $this->bind_params($stmt, $params, null, $descriptors);
1488 $result = oci_execute($stmt, $this->commit_status);
1489 $this->free_descriptors($descriptors);
1490 $this->query_end($result, $stmt);
1491 oci_free_statement($stmt);
1493 return true;
1496 function sql_null_from_clause() {
1497 return ' FROM dual';
1500 public function sql_bitand($int1, $int2) {
1501 return 'bitand((' . $int1 . '), (' . $int2 . '))';
1504 public function sql_bitnot($int1) {
1505 return '((0 - (' . $int1 . ')) - 1)';
1508 public function sql_bitor($int1, $int2) {
1509 return 'MOODLELIB.BITOR(' . $int1 . ', ' . $int2 . ')';
1512 public function sql_bitxor($int1, $int2) {
1513 return 'MOODLELIB.BITXOR(' . $int1 . ', ' . $int2 . ')';
1517 * Returns the SQL text to be used in order to perform module '%'
1518 * operation - remainder after division
1520 * @param integer int1 first integer in the operation
1521 * @param integer int2 second integer in the operation
1522 * @return string the piece of SQL code to be used in your statement.
1524 public function sql_modulo($int1, $int2) {
1525 return 'MOD(' . $int1 . ', ' . $int2 . ')';
1529 * Return SQL for casting to char of given field/expression
1531 * @param string $field Table field or SQL expression to be cast
1532 * @return string
1534 public function sql_cast_to_char(string $field): string {
1535 return "TO_CHAR({$field})";
1538 public function sql_cast_char2int($fieldname, $text=false) {
1539 if (!$text) {
1540 return ' CAST(' . $fieldname . ' AS INT) ';
1541 } else {
1542 return ' CAST(' . $this->sql_compare_text($fieldname) . ' AS INT) ';
1546 public function sql_cast_char2real($fieldname, $text=false) {
1547 if (!$text) {
1548 return ' CAST(' . $fieldname . ' AS FLOAT) ';
1549 } else {
1550 return ' CAST(' . $this->sql_compare_text($fieldname) . ' AS FLOAT) ';
1555 * Returns 'LIKE' part of a query.
1557 * @param string $fieldname usually name of the table column
1558 * @param string $param usually bound query parameter (?, :named)
1559 * @param bool $casesensitive use case sensitive search
1560 * @param bool $accensensitive use accent sensitive search (not all databases support accent insensitive)
1561 * @param bool $notlike true means "NOT LIKE"
1562 * @param string $escapechar escape char for '%' and '_'
1563 * @return string SQL code fragment
1565 public function sql_like($fieldname, $param, $casesensitive = true, $accentsensitive = true, $notlike = false, $escapechar = '\\') {
1566 if (strpos($param, '%') !== false) {
1567 debugging('Potential SQL injection detected, sql_like() expects bound parameters (? or :named)');
1570 $LIKE = $notlike ? 'NOT LIKE' : 'LIKE';
1572 // no accent sensitiveness here for now, sorry
1574 if ($casesensitive) {
1575 return "$fieldname $LIKE $param ESCAPE '$escapechar'";
1576 } else {
1577 return "LOWER($fieldname) $LIKE LOWER($param) ESCAPE '$escapechar'";
1581 public function sql_concat() {
1582 $arr = func_get_args();
1583 if (empty($arr)) {
1584 return " ' ' ";
1586 foreach ($arr as $k => $v) {
1587 if ($v === "' '") {
1588 $arr[$k] = "'*OCISP*'"; // New mega hack.
1591 $s = $this->recursive_concat($arr);
1592 return " MOODLELIB.UNDO_MEGA_HACK($s) ";
1595 public function sql_concat_join($separator="' '", $elements = array()) {
1596 if ($separator === "' '") {
1597 $separator = "'*OCISP*'"; // New mega hack.
1599 foreach ($elements as $k => $v) {
1600 if ($v === "' '") {
1601 $elements[$k] = "'*OCISP*'"; // New mega hack.
1604 for ($n = count($elements)-1; $n > 0 ; $n--) {
1605 array_splice($elements, $n, 0, $separator);
1607 if (empty($elements)) {
1608 return " ' ' ";
1610 $s = $this->recursive_concat($elements);
1611 return " MOODLELIB.UNDO_MEGA_HACK($s) ";
1615 * Return SQL for performing group concatenation on given field/expression
1617 * @param string $field
1618 * @param string $separator
1619 * @param string $sort
1620 * @return string
1622 public function sql_group_concat(string $field, string $separator = ', ', string $sort = ''): string {
1623 $fieldsort = $sort ?: '1';
1624 return "LISTAGG({$field}, '{$separator}') WITHIN GROUP (ORDER BY {$fieldsort})";
1628 * Returns the SQL text to be used to order by columns, standardising the return
1629 * pattern of null values across database types to sort nulls first when ascending
1630 * and last when descending.
1632 * @param string $fieldname The name of the field we need to sort by.
1633 * @param int $sort An order to sort the results in.
1634 * @return string The piece of SQL code to be used in your statement.
1636 public function sql_order_by_null(string $fieldname, int $sort = SORT_ASC): string {
1637 return parent::sql_order_by_null($fieldname, $sort) . ' NULLS ' . ($sort == SORT_ASC ? 'FIRST' : 'LAST');
1641 * Constructs 'IN()' or '=' sql fragment
1643 * Method overriding {@link moodle_database::get_in_or_equal} to be able to get
1644 * more than 1000 elements working, to avoid ORA-01795. We use a pivoting technique
1645 * to be able to transform the params into virtual rows, so the original IN()
1646 * expression gets transformed into a subquery. Once more, be noted that we shouldn't
1647 * be using ever get_in_or_equal() with such number of parameters (proper subquery and/or
1648 * chunking should be used instead).
1650 * @param mixed $items A single value or array of values for the expression.
1651 * @param int $type Parameter bounding type : SQL_PARAMS_QM or SQL_PARAMS_NAMED.
1652 * @param string $prefix Named parameter placeholder prefix (a unique counter value is appended to each parameter name).
1653 * @param bool $equal True means we want to equate to the constructed expression, false means we don't want to equate to it.
1654 * @param mixed $onemptyitems This defines the behavior when the array of items provided is empty. Defaults to false,
1655 * meaning throw exceptions. Other values will become part of the returned SQL fragment.
1656 * @throws coding_exception | dml_exception
1657 * @return array A list containing the constructed sql fragment and an array of parameters.
1659 public function get_in_or_equal($items, $type=SQL_PARAMS_QM, $prefix='param', $equal=true, $onemptyitems=false) {
1660 list($sql, $params) = parent::get_in_or_equal($items, $type, $prefix, $equal, $onemptyitems);
1662 // Less than 1000 elements, nothing to do.
1663 if (count($params) < 1000) {
1664 return array($sql, $params); // Return unmodified.
1667 // Extract the interesting parts of the sql to rewrite.
1668 if (preg_match('!(^.*IN \()([^\)]*)(.*)$!', $sql, $matches) === false) {
1669 return array($sql, $params); // Return unmodified.
1672 $instart = $matches[1];
1673 $insql = $matches[2];
1674 $inend = $matches[3];
1675 $newsql = '';
1677 // Some basic verification about the matching going ok.
1678 $insqlarr = explode(',', $insql);
1679 if (count($insqlarr) !== count($params)) {
1680 return array($sql, $params); // Return unmodified.
1683 // Arrived here, we need to chunk and pivot the params, building a new sql (params remain the same).
1684 $addunionclause = false;
1685 while ($chunk = array_splice($insqlarr, 0, 125)) { // Each chunk will handle up to 125 (+125 +1) elements (DECODE max is 255).
1686 $chunksize = count($chunk);
1687 if ($addunionclause) {
1688 $newsql .= "\n UNION ALL";
1690 $newsql .= "\n SELECT DECODE(pivot";
1691 $counter = 1;
1692 foreach ($chunk as $element) {
1693 $newsql .= ",\n {$counter}, " . trim($element);
1694 $counter++;
1696 $newsql .= ")";
1697 $newsql .= "\n FROM dual";
1698 $newsql .= "\n CROSS JOIN (SELECT LEVEL AS pivot FROM dual CONNECT BY LEVEL <= {$chunksize})";
1699 $addunionclause = true;
1702 // Rebuild the complete IN() clause and return it.
1703 return array($instart . $newsql . $inend, $params);
1707 * Mega hacky magic to work around crazy Oracle NULL concats.
1708 * @param array $args
1709 * @return string
1711 protected function recursive_concat(array $args) {
1712 $count = count($args);
1713 if ($count == 1) {
1714 $arg = reset($args);
1715 return $arg;
1717 if ($count == 2) {
1718 $args[] = "' '";
1719 // No return here intentionally.
1721 $first = array_shift($args);
1722 $second = array_shift($args);
1723 $third = $this->recursive_concat($args);
1724 return "MOODLELIB.TRICONCAT($first, $second, $third)";
1728 * Returns the SQL for returning searching one string for the location of another.
1730 public function sql_position($needle, $haystack) {
1731 return "INSTR(($haystack), ($needle))";
1735 * Returns the SQL to know if one field is empty.
1737 * @param string $tablename Name of the table (without prefix). Not used for now but can be
1738 * necessary in the future if we want to use some introspection using
1739 * meta information against the DB.
1740 * @param string $fieldname Name of the field we are going to check
1741 * @param bool $nullablefield For specifying if the field is nullable (true) or no (false) in the DB.
1742 * @param bool $textfield For specifying if it is a text (also called clob) field (true) or a varchar one (false)
1743 * @return string the sql code to be added to check for empty values
1745 public function sql_isempty($tablename, $fieldname, $nullablefield, $textfield) {
1746 if ($textfield) {
1747 return " (".$this->sql_compare_text($fieldname)." = ' ') ";
1748 } else {
1749 return " ($fieldname = ' ') ";
1753 public function sql_order_by_text($fieldname, $numchars=32) {
1754 return 'dbms_lob.substr(' . $fieldname . ', ' . $numchars . ',1)';
1758 * Is the required OCI server package installed?
1759 * @return bool
1761 protected function oci_package_installed() {
1762 $sql = "SELECT 1
1763 FROM user_objects
1764 WHERE object_type = 'PACKAGE BODY'
1765 AND object_name = 'MOODLELIB'
1766 AND status = 'VALID'";
1767 $this->query_start($sql, null, SQL_QUERY_AUX);
1768 $stmt = $this->parse_query($sql);
1769 $result = oci_execute($stmt, $this->commit_status);
1770 $this->query_end($result, $stmt);
1771 $records = null;
1772 oci_fetch_all($stmt, $records, 0, -1, OCI_FETCHSTATEMENT_BY_ROW);
1773 oci_free_statement($stmt);
1774 return isset($records[0]) && reset($records[0]) ? true : false;
1778 * Try to add required moodle package into oracle server.
1780 protected function attempt_oci_package_install() {
1781 $sqls = file_get_contents(__DIR__.'/oci_native_moodle_package.sql');
1782 $sqls = preg_split('/^\/$/sm', $sqls);
1783 foreach ($sqls as $sql) {
1784 $sql = trim($sql);
1785 if ($sql === '' or $sql === 'SHOW ERRORS') {
1786 continue;
1788 $this->change_database_structure($sql);
1793 * Does this driver support tool_replace?
1795 * @since Moodle 2.8
1796 * @return bool
1798 public function replace_all_text_supported() {
1799 return true;
1802 public function session_lock_supported() {
1803 return true;
1807 * Obtain session lock
1808 * @param int $rowid id of the row with session record
1809 * @param int $timeout max allowed time to wait for the lock in seconds
1810 * @return void
1812 public function get_session_lock($rowid, $timeout) {
1813 parent::get_session_lock($rowid, $timeout);
1815 $fullname = $this->dbname.'-'.$this->prefix.'-session-'.$rowid;
1816 $sql = 'SELECT MOODLELIB.GET_LOCK(:lockname, :locktimeout) FROM DUAL';
1817 $params = array('lockname' => $fullname , 'locktimeout' => $timeout);
1818 $this->query_start($sql, $params, SQL_QUERY_AUX);
1819 $stmt = $this->parse_query($sql);
1820 $this->bind_params($stmt, $params);
1821 $result = oci_execute($stmt, $this->commit_status);
1822 if ($result === false) { // Any failure in get_lock() raises error, causing return of bool false
1823 throw new dml_sessionwait_exception();
1825 $this->query_end($result, $stmt);
1826 oci_free_statement($stmt);
1829 public function release_session_lock($rowid) {
1830 if (!$this->used_for_db_sessions) {
1831 return;
1834 parent::release_session_lock($rowid);
1836 $fullname = $this->dbname.'-'.$this->prefix.'-session-'.$rowid;
1837 $params = array('lockname' => $fullname);
1838 $sql = 'SELECT MOODLELIB.RELEASE_LOCK(:lockname) FROM DUAL';
1839 $this->query_start($sql, $params, SQL_QUERY_AUX);
1840 $stmt = $this->parse_query($sql);
1841 $this->bind_params($stmt, $params);
1842 $result = oci_execute($stmt, $this->commit_status);
1843 $this->query_end($result, $stmt);
1844 oci_free_statement($stmt);
1848 * Driver specific start of real database transaction,
1849 * this can not be used directly in code.
1850 * @return void
1852 protected function begin_transaction() {
1853 $this->commit_status = OCI_DEFAULT; //Done! ;-)
1857 * Driver specific commit of real database transaction,
1858 * this can not be used directly in code.
1859 * @return void
1861 protected function commit_transaction() {
1862 $this->query_start('--oracle_commit', NULL, SQL_QUERY_AUX);
1863 $result = oci_commit($this->oci);
1864 $this->commit_status = OCI_COMMIT_ON_SUCCESS;
1865 $this->query_end($result);
1869 * Driver specific abort of real database transaction,
1870 * this can not be used directly in code.
1871 * @return void
1873 protected function rollback_transaction() {
1874 $this->query_start('--oracle_rollback', NULL, SQL_QUERY_AUX);
1875 $result = oci_rollback($this->oci);
1876 $this->commit_status = OCI_COMMIT_ON_SUCCESS;
1877 $this->query_end($result);