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 oci 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/oci_native_moodle_recordset.php');
32 require_once($CFG->libdir.'/dml/oci_native_moodle_temptables.php');
35 * Native oci class representing moodle database interface.
37 * One complete reference for PHP + OCI:
38 * http://www.oracle.com/technology/tech/php/underground-php-oracle-manual.html
41 * @subpackage dml_driver
42 * @copyright 2008 Petr Skoda (http://skodak.org)
43 * @license http://www.gnu.org/copyleft/gpl.html GNU GPL v3 or later
45 class oci_native_moodle_database extends moodle_database {
47 protected $oci = null;
49 /** @var To store stmt errors and enable get_last_error() to detect them.*/
50 private $last_stmt_error = null;
51 /** @var Default value initialised in connect method, we need the driver to be present.*/
52 private $commit_status = null;
54 /** @var To handle oci driver default verbosity.*/
55 private $last_error_reporting;
56 /** @var To store unique_session_id. Needed for temp tables unique naming.*/
57 private $unique_session_id;
58 /** @var To cache locks support along the connection life.*/
59 private $dblocks_supported = null;
60 /** @var To cache bitwise operations support along the connection life.*/
61 private $bitwise_supported = null;
64 * Detects if all needed PHP stuff installed.
65 * Note: can be used before connect()
66 * @return mixed true if ok, string if something
68 public function driver_installed() {
69 if (!extension_loaded('oci8')) {
70 return get_string('ociextensionisnotpresentinphp', 'install');
76 * Returns database family type - describes SQL dialect
77 * Note: can be used before connect()
78 * @return string db family name (mysql, postgres, mssql, oracle, etc.)
80 public function get_dbfamily() {
85 * Returns more specific database driver type
86 * Note: can be used before connect()
87 * @return string db type mysqli, pgsql, oci, mssql, sqlsrv
89 protected function get_dbtype() {
94 * Returns general database library name
95 * Note: can be used before connect()
96 * @return string db type pdo, native
98 protected function get_dblibrary() {
103 * Returns localised database type name
104 * Note: can be used before connect()
107 public function get_name() {
108 return get_string('nativeoci', 'install');
112 * Returns localised database configuration help.
113 * Note: can be used before connect()
116 public function get_configuration_help() {
117 return get_string('nativeocihelp', 'install');
121 * Returns localised database description
122 * Note: can be used before connect()
125 public function get_configuration_hints() {
126 return get_string('databasesettingssub_oci', 'install');
130 * Diagnose database and tables, this function is used
131 * to verify database and driver settings, db engine types, etc.
133 * @return string null means everything ok, string means problem found.
135 public function diagnose() {
136 if (!$this->bitwise_supported() or !$this->session_lock_supported()) {
137 return 'Oracle PL/SQL Moodle support packages are not installed! Database administrator has to execute /lib/dml/oci_native_moodle_package.sql script.';
144 * Must be called before other methods.
145 * @param string $dbhost The database host.
146 * @param string $dbuser The database username.
147 * @param string $dbpass The database username's password.
148 * @param string $dbname The name of the database being connected to.
149 * @param mixed $prefix string means moodle db prefix, false used for external databases where prefix not used
150 * @param array $dboptions driver specific options
152 * @throws dml_connection_exception if error
154 public function connect($dbhost, $dbuser, $dbpass, $dbname, $prefix, array $dboptions=null) {
155 if ($prefix == '' and !$this->external) {
156 //Enforce prefixes for everybody but mysql
157 throw new dml_exception('prefixcannotbeempty', $this->get_dbfamily());
159 if (!$this->external and strlen($prefix) > 2) {
160 //Max prefix length for Oracle is 2cc
161 $a = (object)array('dbfamily'=>'oracle', 'maxlength'=>2);
162 throw new dml_exception('prefixtoolong', $a);
165 $driverstatus = $this->driver_installed();
167 if ($driverstatus !== true) {
168 throw new dml_exception('dbdriverproblem', $driverstatus);
171 // Autocommit ON by default.
172 // Switching to OFF (OCI_DEFAULT), when playing with transactions
173 // please note this thing is not defined if oracle driver not present in PHP
174 // which means it can not be used as default value of object property!
175 $this->commit_status = OCI_COMMIT_ON_SUCCESS;
177 $this->store_settings($dbhost, $dbuser, $dbpass, $dbname, $prefix, $dboptions);
178 unset($this->dboptions['dbsocket']);
180 // NOTE: use of ', ", / and \ is very problematic, even native oracle tools seem to have
181 // problems with these, so just forget them and do not report problems into tracker...
183 if (empty($this->dbhost)) {
184 // old style full address (TNS)
185 $dbstring = $this->dbname;
187 if (empty($this->dboptions['dbport'])) {
188 $this->dboptions['dbport'] = 1521;
190 $dbstring = '//'.$this->dbhost.':'.$this->dboptions['dbport'].'/'.$this->dbname;
194 if (empty($this->dboptions['dbpersist'])) {
195 $this->oci = oci_new_connect($this->dbuser, $this->dbpass, $dbstring, 'AL32UTF8');
197 $this->oci = oci_pconnect($this->dbuser, $this->dbpass, $dbstring, 'AL32UTF8');
199 $dberr = ob_get_contents();
203 if ($this->oci === false) {
206 if (isset($e['message'])) {
207 $dberr = $e['message'];
209 throw new dml_connection_exception($dberr);
212 // get unique session id, to be used later for temp tables stuff
213 $sql = 'SELECT DBMS_SESSION.UNIQUE_SESSION_ID() FROM DUAL';
214 $this->query_start($sql, null, SQL_QUERY_AUX);
215 $stmt = $this->parse_query($sql);
216 $result = oci_execute($stmt, $this->commit_status);
217 $this->query_end($result, $stmt);
219 oci_fetch_all($stmt, $records, 0, -1, OCI_FETCHSTATEMENT_BY_ROW);
220 oci_free_statement($stmt);
221 $this->unique_session_id = reset($records[0]);
223 //note: do not send "ALTER SESSION SET NLS_NUMERIC_CHARACTERS='.,'" !
224 // instead fix our PHP code to convert "," to "." properly!
226 // Connection stabilised and configured, going to instantiate the temptables controller
227 $this->temptables = new oci_native_moodle_temptables($this, $this->unique_session_id);
233 * Close database connection and release all resources
234 * and memory (especially circular memory references).
235 * Do NOT use connect() again, create a new instance if needed.
237 public function dispose() {
238 parent::dispose(); // Call parent dispose to write/close session and other common stuff before closing connection
240 oci_close($this->oci);
247 * Called before each db query.
249 * @param array array of parameters
250 * @param int $type type of query
251 * @param mixed $extrainfo driver specific extra information
254 protected function query_start($sql, array $params=null, $type, $extrainfo=null) {
255 parent::query_start($sql, $params, $type, $extrainfo);
256 // oci driver tents to send debug to output, we do not need that ;-)
257 $this->last_error_reporting = error_reporting(0);
261 * Called immediately after each db query.
262 * @param mixed db specific result
265 protected function query_end($result, $stmt=null) {
266 // reset original debug level
267 error_reporting($this->last_error_reporting);
268 if ($stmt and $result === false) {
269 // Look for stmt error and store it
270 if (is_resource($stmt)) {
271 $e = oci_error($stmt);
273 $this->last_stmt_error = $e['message'];
276 oci_free_statement($stmt);
278 parent::query_end($result);
282 * Returns database server info array
283 * @return array Array containing 'description' and 'version' info
285 public function get_server_info() {
286 static $info = null; // TODO: move to real object property
288 if (is_null($info)) {
289 $this->query_start("--oci_server_version()", null, SQL_QUERY_AUX);
290 $description = oci_server_version($this->oci);
291 $this->query_end(true);
292 preg_match('/(\d+\.)+\d+/', $description, $matches);
293 $info = array('description'=>$description, 'version'=>$matches[0]);
299 protected function is_min_version($version) {
300 $server = $this->get_server_info();
301 $server = $server['version'];
302 return version_compare($server, $version, '>=');
306 * Converts short table name {tablename} to real table name
307 * supporting temp tables ($this->unique_session_id based) if detected
312 protected function fix_table_names($sql) {
313 if (preg_match_all('/\{([a-z][a-z0-9_]*)\}/', $sql, $matches)) {
314 foreach($matches[0] as $key=>$match) {
315 $name = $matches[1][$key];
316 if ($this->temptables && $this->temptables->is_temptable($name)) {
317 $sql = str_replace($match, $this->temptables->get_correct_name($name), $sql);
319 $sql = str_replace($match, $this->prefix.$name, $sql);
327 * Returns supported query parameter types
328 * @return int bitmask of accepted SQL_PARAMS_*
330 protected function allowed_param_types() {
331 return SQL_PARAMS_NAMED;
335 * Returns last error reported by database engine.
336 * @return string error message
338 public function get_last_error() {
340 // First look for any previously saved stmt error
341 if (!empty($this->last_stmt_error)) {
342 $error = $this->last_stmt_error;
343 $this->last_stmt_error = null;
344 } else { // Now try connection error
345 $e = oci_error($this->oci);
347 $error = $e['message'];
354 * Prepare the statement for execution
355 * @throws dml_connection_exception
359 protected function parse_query($sql) {
360 $stmt = oci_parse($this->oci, $sql);
361 if ($stmt == false) {
362 throw new dml_connection_exception('Can not parse sql query'); //TODO: maybe add better info
368 * Make sure there are no reserved words in param names...
370 * @param array $params
371 * @return array ($sql, $params) updated query and parameters
373 protected function tweak_param_names($sql, array $params) {
374 if (empty($params)) {
375 return array($sql, $params);
378 $newparams = array();
379 $searcharr = array(); // search => replace pairs
380 foreach ($params as $name => $value) {
381 // Keep the name within the 30 chars limit always (prefixing/replacing)
382 if (strlen($name) <= 28) {
383 $newname = 'o_' . $name;
385 $newname = 'o_' . substr($name, 2);
387 $newparams[$newname] = $value;
388 $searcharr[':' . $name] = ':' . $newname;
390 // sort by length desc to avoid potential str_replace() overlap
391 uksort($searcharr, array('oci_native_moodle_database', 'compare_by_length_desc'));
393 $sql = str_replace(array_keys($searcharr), $searcharr, $sql);
394 return array($sql, $newparams);
398 * Return tables in database WITHOUT current prefix
399 * @param bool $usecache if true, returns list of cached tables.
400 * @return array of table names in lowercase and without prefix
402 public function get_tables($usecache=true) {
403 if ($usecache and $this->tables !== null) {
404 return $this->tables;
406 $this->tables = array();
407 $prefix = str_replace('_', "\\_", strtoupper($this->prefix));
408 $sql = "SELECT TABLE_NAME
410 WHERE TABLE_TYPE='TABLE'
411 AND TABLE_NAME NOT LIKE 'BIN\$%'
412 AND TABLE_NAME LIKE '$prefix%' ESCAPE '\\'";
413 $this->query_start($sql, null, SQL_QUERY_AUX);
414 $stmt = $this->parse_query($sql);
415 $result = oci_execute($stmt, $this->commit_status);
416 $this->query_end($result, $stmt);
418 oci_fetch_all($stmt, $records, 0, -1, OCI_ASSOC);
419 oci_free_statement($stmt);
420 $records = array_map('strtolower', $records['TABLE_NAME']);
421 foreach ($records as $tablename) {
422 if (strpos($tablename, $this->prefix) !== 0) {
425 $tablename = substr($tablename, strlen($this->prefix));
426 $this->tables[$tablename] = $tablename;
429 // Add the currently available temptables
430 $this->tables = array_merge($this->tables, $this->temptables->get_temptables());
432 return $this->tables;
436 * Return table indexes - everything lowercased.
437 * @param string $table The table we want to get indexes from.
438 * @return array An associative array of indexes containing 'unique' flag and 'columns' being indexed
440 public function get_indexes($table) {
442 $tablename = strtoupper($this->prefix.$table);
444 $sql = "SELECT i.INDEX_NAME, i.UNIQUENESS, c.COLUMN_POSITION, c.COLUMN_NAME, ac.CONSTRAINT_TYPE
446 JOIN ALL_IND_COLUMNS c ON c.INDEX_NAME=i.INDEX_NAME
447 LEFT JOIN ALL_CONSTRAINTS ac ON (ac.TABLE_NAME=i.TABLE_NAME AND ac.CONSTRAINT_NAME=i.INDEX_NAME AND ac.CONSTRAINT_TYPE='P')
448 WHERE i.TABLE_NAME = '$tablename'
449 ORDER BY i.INDEX_NAME, c.COLUMN_POSITION";
451 $stmt = $this->parse_query($sql);
452 $result = oci_execute($stmt, $this->commit_status);
453 $this->query_end($result, $stmt);
455 oci_fetch_all($stmt, $records, 0, -1, OCI_FETCHSTATEMENT_BY_ROW);
456 oci_free_statement($stmt);
458 foreach ($records as $record) {
459 if ($record['CONSTRAINT_TYPE'] === 'P') {
463 $indexname = strtolower($record['INDEX_NAME']);
464 if (!isset($indexes[$indexname])) {
465 $indexes[$indexname] = array('primary' => ($record['CONSTRAINT_TYPE'] === 'P'),
466 'unique' => ($record['UNIQUENESS'] === 'UNIQUE'),
467 'columns' => array());
469 $indexes[$indexname]['columns'][] = strtolower($record['COLUMN_NAME']);
476 * Returns detailed information about columns in table. This information is cached internally.
477 * @param string $table name
478 * @param bool $usecache
479 * @return array array of database_column_info objects indexed with column names
481 public function get_columns($table, $usecache=true) {
482 if ($usecache and isset($this->columns[$table])) {
483 return $this->columns[$table];
486 if (!$table) { // table not specified, return empty array directly
490 $this->columns[$table] = array();
492 // We give precedence to CHAR_LENGTH for VARCHAR2 columns over WIDTH because the former is always
493 // BYTE based and, for cross-db operations, we want CHAR based results. See MDL-29415
494 $sql = "SELECT CNAME, COLTYPE, nvl(CHAR_LENGTH, WIDTH) AS WIDTH, SCALE, PRECISION, NULLS, DEFAULTVAL
496 LEFT JOIN USER_TAB_COLUMNS u ON (u.TABLE_NAME = c.TNAME AND u.COLUMN_NAME = c.CNAME AND u.DATA_TYPE = 'VARCHAR2')
497 WHERE TNAME = UPPER('{" . $table . "}')
500 list($sql, $params, $type) = $this->fix_sql_params($sql, null);
502 $this->query_start($sql, null, SQL_QUERY_AUX);
503 $stmt = $this->parse_query($sql);
504 $result = oci_execute($stmt, $this->commit_status);
505 $this->query_end($result, $stmt);
507 oci_fetch_all($stmt, $records, 0, -1, OCI_FETCHSTATEMENT_BY_ROW);
508 oci_free_statement($stmt);
513 foreach ($records as $rawcolumn) {
514 $rawcolumn = (object)$rawcolumn;
516 $info = new stdClass();
517 $info->name = strtolower($rawcolumn->CNAME);
520 if ($rawcolumn->COLTYPE === 'VARCHAR2'
521 or $rawcolumn->COLTYPE === 'VARCHAR'
522 or $rawcolumn->COLTYPE === 'NVARCHAR2'
523 or $rawcolumn->COLTYPE === 'NVARCHAR'
524 or $rawcolumn->COLTYPE === 'CHAR'
525 or $rawcolumn->COLTYPE === 'NCHAR') {
526 $info->type = $rawcolumn->COLTYPE;
527 $info->meta_type = 'C';
528 $info->max_length = $rawcolumn->WIDTH;
530 $info->not_null = ($rawcolumn->NULLS === 'NOT NULL');
531 $info->has_default = !is_null($rawcolumn->DEFAULTVAL);
532 if ($info->has_default) {
535 if ($rawcolumn->DEFAULTVAL === 'NULL') {
536 $info->default_value = null;
537 } else if ($rawcolumn->DEFAULTVAL === "' ' ") { // Sometimes it's stored with trailing space
538 $info->default_value = "";
539 } else if ($rawcolumn->DEFAULTVAL === "' '") { // Sometimes it's stored without trailing space
540 $info->default_value = "";
542 $info->default_value = trim($rawcolumn->DEFAULTVAL); // remove trailing space
543 $info->default_value = substr($info->default_value, 1, strlen($info->default_value)-2); //trim ''
546 $info->default_value = null;
548 $info->primary_key = false;
549 $info->binary = false;
550 $info->unsigned = null;
551 $info->auto_increment= false;
552 $info->unique = null;
554 } else if ($rawcolumn->COLTYPE === 'NUMBER') {
555 $info->type = $rawcolumn->COLTYPE;
556 $info->max_length = $rawcolumn->PRECISION;
557 $info->binary = false;
558 if (!is_null($rawcolumn->SCALE) && $rawcolumn->SCALE == 0) { // null in oracle scale allows decimals => not integer
560 if ($info->name === 'id') {
561 $info->primary_key = true;
562 $info->meta_type = 'R';
563 $info->unique = true;
564 $info->auto_increment= true;
565 $info->has_default = false;
567 $info->primary_key = false;
568 $info->meta_type = 'I';
569 $info->unique = null;
570 $info->auto_increment= false;
576 $info->meta_type = 'N';
577 $info->primary_key = false;
578 $info->unsigned = null;
579 $info->auto_increment= false;
580 $info->unique = null;
581 $info->scale = $rawcolumn->SCALE;
583 $info->not_null = ($rawcolumn->NULLS === 'NOT NULL');
584 $info->has_default = !is_null($rawcolumn->DEFAULTVAL);
585 if ($info->has_default) {
586 $info->default_value = trim($rawcolumn->DEFAULTVAL); // remove trailing space
588 $info->default_value = null;
591 } else if ($rawcolumn->COLTYPE === 'FLOAT') {
592 $info->type = $rawcolumn->COLTYPE;
593 $info->max_length = (int)($rawcolumn->PRECISION * 3.32193);
594 $info->primary_key = false;
595 $info->meta_type = 'N';
596 $info->unique = null;
597 $info->auto_increment= false;
598 $info->not_null = ($rawcolumn->NULLS === 'NOT NULL');
599 $info->has_default = !is_null($rawcolumn->DEFAULTVAL);
600 if ($info->has_default) {
601 $info->default_value = trim($rawcolumn->DEFAULTVAL); // remove trailing space
603 $info->default_value = null;
606 } else if ($rawcolumn->COLTYPE === 'CLOB'
607 or $rawcolumn->COLTYPE === 'NCLOB') {
608 $info->type = $rawcolumn->COLTYPE;
609 $info->meta_type = 'X';
610 $info->max_length = -1;
613 $info->not_null = ($rawcolumn->NULLS === 'NOT NULL');
614 $info->has_default = !is_null($rawcolumn->DEFAULTVAL);
615 if ($info->has_default) {
617 if ($rawcolumn->DEFAULTVAL === 'NULL') {
618 $info->default_value = null;
619 } else if ($rawcolumn->DEFAULTVAL === "' ' ") { // Sometimes it's stored with trailing space
620 $info->default_value = "";
621 } else if ($rawcolumn->DEFAULTVAL === "' '") { // Other times it's stored without trailing space
622 $info->default_value = "";
624 $info->default_value = trim($rawcolumn->DEFAULTVAL); // remove trailing space
625 $info->default_value = substr($info->default_value, 1, strlen($info->default_value)-2); //trim ''
628 $info->default_value = null;
630 $info->primary_key = false;
631 $info->binary = false;
632 $info->unsigned = null;
633 $info->auto_increment= false;
634 $info->unique = null;
636 } else if ($rawcolumn->COLTYPE === 'BLOB') {
637 $info->type = $rawcolumn->COLTYPE;
638 $info->meta_type = 'B';
639 $info->max_length = -1;
642 $info->not_null = ($rawcolumn->NULLS === 'NOT NULL');
643 $info->has_default = !is_null($rawcolumn->DEFAULTVAL);
644 if ($info->has_default) {
646 if ($rawcolumn->DEFAULTVAL === 'NULL') {
647 $info->default_value = null;
648 } else if ($rawcolumn->DEFAULTVAL === "' ' ") { // Sometimes it's stored with trailing space
649 $info->default_value = "";
650 } else if ($rawcolumn->DEFAULTVAL === "' '") { // Sometimes it's stored without trailing space
651 $info->default_value = "";
653 $info->default_value = trim($rawcolumn->DEFAULTVAL); // remove trailing space
654 $info->default_value = substr($info->default_value, 1, strlen($info->default_value)-2); //trim ''
657 $info->default_value = null;
659 $info->primary_key = false;
660 $info->binary = true;
661 $info->unsigned = null;
662 $info->auto_increment= false;
663 $info->unique = null;
666 // unknown type - sorry
667 $info->type = $rawcolumn->COLTYPE;
668 $info->meta_type = '?';
671 $this->columns[$table][$info->name] = new database_column_info($info);
674 return $this->columns[$table];
678 * Normalise values based in RDBMS dependencies (booleans, LOBs...)
680 * @param database_column_info $column column metadata corresponding with the value we are going to normalise
681 * @param mixed $value value we are going to normalise
682 * @return mixed the normalised value
684 protected function normalise_value($column, $value) {
685 if (is_bool($value)) { // Always, convert boolean to int
686 $value = (int)$value;
688 } else if ($column->meta_type == 'B') { // CLOB detected, we return 'blob' array instead of raw value to allow
689 if (!is_null($value)) { // binding/executing code later to know about its nature
690 $value = array('blob' => $value);
693 } else if ($column->meta_type == 'X' && strlen($value) > 4000) { // CLOB detected (>4000 optimisation), we return 'clob'
694 if (!is_null($value)) { // array instead of raw value to allow binding/
695 $value = array('clob' => (string)$value); // executing code later to know about its nature
698 } else if ($value === '') {
699 if ($column->meta_type == 'I' or $column->meta_type == 'F' or $column->meta_type == 'N') {
700 $value = 0; // prevent '' problems in numeric fields
707 * Transforms the sql and params in order to emulate the LIMIT clause available in other DBs
709 * @param string $sql the SQL select query to execute.
710 * @param array $params array of sql parameters
711 * @param int $limitfrom return a subset of records, starting at this point (optional, required if $limitnum is set).
712 * @param int $limitnum return a subset comprising this many records (optional, required if $limitfrom is set).
713 * @return array with the transformed sql and params updated
715 private function get_limit_sql($sql, array $params = null, $limitfrom=0, $limitnum=0) {
717 $limitfrom = (int)$limitfrom;
718 $limitnum = (int)$limitnum;
719 $limitfrom = ($limitfrom < 0) ? 0 : $limitfrom;
720 $limitnum = ($limitnum < 0) ? 0 : $limitnum;
722 // TODO: Add the /*+ FIRST_ROWS */ hint if there isn't another hint
724 if ($limitfrom and $limitnum) {
725 $sql = "SELECT oracle_o.*
726 FROM (SELECT oracle_i.*, rownum AS oracle_rownum
728 WHERE rownum <= :oracle_num_rows
730 WHERE oracle_rownum > :oracle_skip_rows";
731 $params['oracle_num_rows'] = $limitfrom + $limitnum;
732 $params['oracle_skip_rows'] = $limitfrom;
734 } else if ($limitfrom and !$limitnum) {
735 $sql = "SELECT oracle_o.*
736 FROM (SELECT oracle_i.*, rownum AS oracle_rownum
739 WHERE oracle_rownum > :oracle_skip_rows";
740 $params['oracle_skip_rows'] = $limitfrom;
742 } else if (!$limitfrom and $limitnum) {
745 WHERE rownum <= :oracle_num_rows";
746 $params['oracle_num_rows'] = $limitnum;
749 return array($sql, $params);
753 * This function will handle all the column values before being inserted/updated to DB for Oracle
754 * installations. This is because the "special feature" of Oracle where the empty string is
755 * equal to NULL and this presents a problem with all our currently NOT NULL default '' fields.
756 * (and with empties handling in general)
758 * Note that this function is 100% private and should be used, exclusively by DML functions
759 * in this file. Also, this is considered a DIRTY HACK to be removed when possible.
761 * This function is private and must not be used outside this driver at all
763 * @param $table string the table where the record is going to be inserted/updated (without prefix)
764 * @param $field string the field where the record is going to be inserted/updated
765 * @param $value mixed the value to be inserted/updated
767 private function oracle_dirty_hack ($table, $field, $value) {
770 $columns = $this->get_columns($table);
771 if (!isset($columns[$field])) {
774 $column = $columns[$field];
776 // !! This paragraph explains behaviour before Moodle 2.0:
778 // For Oracle DB, empty strings are converted to NULLs in DB
779 // and this breaks a lot of NOT NULL columns currently Moodle. In the future it's
780 // planned to move some of them to NULL, if they must accept empty values and this
781 // piece of code will become less and less used. But, for now, we need it.
782 // What we are going to do is to examine all the data being inserted and if it's
783 // an empty string (NULL for Oracle) and the field is defined as NOT NULL, we'll modify
784 // such data in the best form possible ("0" for booleans and numbers and " " for the
785 // rest of strings. It isn't optimal, but the only way to do so.
786 // In the opposite, when retrieving records from Oracle, we'll decode " " back to
787 // empty strings to allow everything to work properly. DIRTY HACK.
789 // !! These paragraphs explain the rationale about the change for Moodle 2.0:
791 // Before Moodle 2.0, we only used to apply this DIRTY HACK to NOT NULL columns, as
792 // stated above, but it causes one problem in NULL columns where both empty strings
793 // and real NULLs are stored as NULLs, being impossible to differentiate them when
794 // being retrieved from DB.
796 // So, starting with Moodle 2.0, we are going to apply the DIRTY HACK to all the
797 // CHAR/CLOB columns no matter of their nullability. That way, when retrieving
798 // NULLABLE fields we'll get proper empties and NULLs differentiated, so we'll be able
799 // to rely in NULL/empty/content contents without problems, until now that wasn't
802 // No breakage with old data is expected as long as at the time of writing this
803 // (20090922) all the current uses of both sql_empty() and sql_isempty() has been
804 // revised in 2.0 and all them were being performed against NOT NULL columns,
805 // where nothing has changed (the DIRTY HACK was already being applied).
809 // From Moodle 2.0 onwards, ALL empty strings in Oracle DBs will be stored as
810 // 1-whitespace char, ALL NULLs as NULLs and, obviously, content as content. And
811 // those 1-whitespace chars will be converted back to empty strings by all the
812 // get_field/record/set() functions transparently and any SQL needing direct handling
813 // of empties will need to use the sql_empty() and sql_isempty() helper functions.
816 // If the field ins't VARCHAR or CLOB, skip
817 if ($column->meta_type != 'C' and $column->meta_type != 'X') {
821 // If the value isn't empty, skip
822 if (!empty($value)) {
826 // Now, we have one empty value, going to be inserted to one VARCHAR2 or CLOB field
827 // Try to get the best value to be inserted
829 // The '0' string doesn't need any transformation, skip
830 if ($value === '0') {
834 // Transformations start
835 if (gettype($value) == 'boolean') {
836 return '0'; // Transform false to '0' that evaluates the same for PHP
838 } else if (gettype($value) == 'integer') {
839 return '0'; // Transform 0 to '0' that evaluates the same for PHP
841 } else if ($value === '') {
842 return ' '; // Transform '' to ' ' that DONT'T EVALUATE THE SAME
843 // (we'll transform back again on get_records_XXX functions and others)!!
846 // Fail safe to original value
851 * Helper function to order by string length desc
853 * @param $a string first element to compare
854 * @param $b string second element to compare
855 * @return int < 0 $a goes first (is less), 0 $b goes first, 0 doesn't matter
857 private function compare_by_length_desc($a, $b) {
858 return strlen($b) - strlen($a);
862 * Is db in unicode mode?
865 public function setup_is_unicodedb() {
867 FROM NLS_DATABASE_PARAMETERS
868 WHERE PARAMETER = 'NLS_CHARACTERSET'";
869 $this->query_start($sql, null, SQL_QUERY_AUX);
870 $stmt = $this->parse_query($sql);
871 $result = oci_execute($stmt, $this->commit_status);
872 $this->query_end($result, $stmt);
874 oci_fetch_all($stmt, $records, 0, -1, OCI_FETCHSTATEMENT_BY_COLUMN);
875 oci_free_statement($stmt);
877 return (isset($records['VALUE'][0]) and $records['VALUE'][0] === 'AL32UTF8');
881 * Do NOT use in code, to be used by database_manager only!
882 * @param string $sql query
884 * @throws dml_exception A DML specific exception is thrown for any errors.
886 public function change_database_structure($sql) {
887 $this->reset_caches();
889 $this->query_start($sql, null, SQL_QUERY_STRUCTURE);
890 $stmt = $this->parse_query($sql);
891 $result = oci_execute($stmt, $this->commit_status);
892 $this->query_end($result, $stmt);
893 oci_free_statement($stmt);
898 protected function bind_params($stmt, array $params=null, $tablename=null) {
899 $descriptors = array();
903 $columns = $this->get_columns($tablename);
905 foreach($params as $key => $value) {
906 // Decouple column name and param name as far as sometimes they aren't the same
907 if ($key == 'o_newfieldtoset') { // found case where column and key diverge, handle that
908 $columnname = key($value); // columnname is the key of the array
909 $params[$key] = $value[$columnname]; // set the proper value in the $params array and
910 $value = $value[$columnname]; // set the proper value in the $value variable
912 $columnname = preg_replace('/^o_/', '', $key); // Default columnname (for DB introspecting is key), but...
914 // Continue processing
915 // Now, handle already detected LOBs
916 if (is_array($value)) { // Let's go to bind special cases (lob descriptors)
917 if (isset($value['clob'])) {
918 $lob = oci_new_descriptor($this->oci, OCI_DTYPE_LOB);
919 oci_bind_by_name($stmt, $key, $lob, -1, SQLT_CLOB);
920 $lob->writeTemporary($this->oracle_dirty_hack($tablename, $columnname, $params[$key]['clob']), OCI_TEMP_CLOB);
921 $descriptors[] = $lob;
922 continue; // Column binding finished, go to next one
923 } else if (isset($value['blob'])) {
924 $lob = oci_new_descriptor($this->oci, OCI_DTYPE_LOB);
925 oci_bind_by_name($stmt, $key, $lob, -1, SQLT_BLOB);
926 $lob->writeTemporary($params[$key]['blob'], OCI_TEMP_BLOB);
927 $descriptors[] = $lob;
928 continue; // Column binding finished, go to next one
931 // TODO: Put proper types and length is possible (enormous speedup)
932 // Arrived here, continue with standard processing, using metadata if possible
933 if (isset($columns[$columnname])) {
934 $type = $columns[$columnname]->meta_type;
935 $maxlength = $columns[$columnname]->max_length;
944 oci_bind_by_name($stmt, $key, $params[$key]);
950 oci_bind_by_name($stmt, $key, $params[$key]);
954 // TODO: Only arrive here if BLOB is null: Bind if so, else exception!
958 // TODO: Only arrive here if CLOB is null or <= 4000 cc, else exception
961 default: // Bind as CHAR (applying dirty hack)
963 oci_bind_by_name($stmt, $key, $this->oracle_dirty_hack($tablename, $columnname, $params[$key]));
970 protected function free_descriptors($descriptors) {
971 foreach ($descriptors as $descriptor) {
972 oci_free_descriptor($descriptor);
977 * This function is used to convert all the Oracle 1-space defaults to the empty string
978 * like a really DIRTY HACK to allow it to work better until all those NOT NULL DEFAULT ''
979 * fields will be out from Moodle.
980 * @param string the string to be converted to '' (empty string) if it's ' ' (one space)
981 * @param mixed the key of the array in case we are using this function from array_walk,
982 * defaults to null for other (direct) uses
983 * @return boolean always true (the converted variable is returned by reference)
985 public static function onespace2empty(&$item, $key=null) {
986 $item = ($item === ' ') ? '' : $item;
991 * Execute general sql query. Should be used only when no other method suitable.
992 * Do NOT use this to make changes in db structure, use database_manager methods instead!
993 * @param string $sql query
994 * @param array $params query parameters
996 * @throws dml_exception A DML specific exception is thrown for any errors.
998 public function execute($sql, array $params=null) {
999 list($sql, $params, $type) = $this->fix_sql_params($sql, $params);
1001 if (strpos($sql, ';') !== false) {
1002 throw new coding_exception('moodle_database::execute() Multiple sql statements found or bound parameters not used properly in query!');
1005 list($sql, $params) = $this->tweak_param_names($sql, $params);
1006 $this->query_start($sql, $params, SQL_QUERY_UPDATE);
1007 $stmt = $this->parse_query($sql);
1008 $this->bind_params($stmt, $params);
1009 $result = oci_execute($stmt, $this->commit_status);
1010 $this->query_end($result, $stmt);
1011 oci_free_statement($stmt);
1017 * Get a single database record as an object using a SQL statement.
1019 * The SQL statement should normally only return one record.
1020 * It is recommended to use get_records_sql() if more matches possible!
1022 * @param string $sql The SQL string you wish to be executed, should normally only return one record.
1023 * @param array $params array of sql parameters
1024 * @param int $strictness IGNORE_MISSING means compatible mode, false returned if record not found, debug message if more found;
1025 * IGNORE_MULTIPLE means return first, ignore multiple records found(not recommended);
1026 * MUST_EXIST means throw exception if no record or multiple records found
1027 * @return mixed a fieldset object containing the first matching record, false or exception if error not found depending on mode
1028 * @throws dml_exception A DML specific exception is thrown for any errors.
1030 public function get_record_sql($sql, array $params=null, $strictness=IGNORE_MISSING) {
1031 $strictness = (int)$strictness;
1032 if ($strictness == IGNORE_MULTIPLE) {
1033 // do not limit here - ORA does not like that
1034 $rs = $this->get_recordset_sql($sql, $params);
1036 foreach ($rs as $rec) {
1043 return parent::get_record_sql($sql, $params, $strictness);
1047 * Get a number of records as a moodle_recordset using a SQL statement.
1049 * Since this method is a little less readable, use of it should be restricted to
1050 * code where it's possible there might be large datasets being returned. For known
1051 * small datasets use get_records_sql - it leads to simpler code.
1053 * The return type is like:
1054 * @see function get_recordset.
1056 * @param string $sql the SQL select query to execute.
1057 * @param array $params array of sql parameters
1058 * @param int $limitfrom return a subset of records, starting at this point (optional, required if $limitnum is set).
1059 * @param int $limitnum return a subset comprising this many records (optional, required if $limitfrom is set).
1060 * @return moodle_recordset instance
1061 * @throws dml_exception A DML specific exception is thrown for any errors.
1063 public function get_recordset_sql($sql, array $params=null, $limitfrom=0, $limitnum=0) {
1065 list($sql, $params, $type) = $this->fix_sql_params($sql, $params);
1067 list($rawsql, $params) = $this->get_limit_sql($sql, $params, $limitfrom, $limitnum);
1069 list($rawsql, $params) = $this->tweak_param_names($rawsql, $params);
1070 $this->query_start($rawsql, $params, SQL_QUERY_SELECT);
1071 $stmt = $this->parse_query($rawsql);
1072 $this->bind_params($stmt, $params);
1073 $result = oci_execute($stmt, $this->commit_status);
1074 $this->query_end($result, $stmt);
1076 return $this->create_recordset($stmt);
1079 protected function create_recordset($stmt) {
1080 return new oci_native_moodle_recordset($stmt);
1084 * Get a number of records as an array of objects using a SQL statement.
1086 * Return value is like:
1087 * @see function get_records.
1089 * @param string $sql the SQL select query to execute. The first column of this SELECT statement
1090 * must be a unique value (usually the 'id' field), as it will be used as the key of the
1092 * @param array $params array of sql parameters
1093 * @param int $limitfrom return a subset of records, starting at this point (optional, required if $limitnum is set).
1094 * @param int $limitnum return a subset comprising this many records (optional, required if $limitfrom is set).
1095 * @return array of objects, or empty array if no records were found
1096 * @throws dml_exception A DML specific exception is thrown for any errors.
1098 public function get_records_sql($sql, array $params=null, $limitfrom=0, $limitnum=0) {
1100 list($sql, $params, $type) = $this->fix_sql_params($sql, $params);
1102 list($rawsql, $params) = $this->get_limit_sql($sql, $params, $limitfrom, $limitnum);
1104 list($rawsql, $params) = $this->tweak_param_names($rawsql, $params);
1105 $this->query_start($rawsql, $params, SQL_QUERY_SELECT);
1106 $stmt = $this->parse_query($rawsql);
1107 $this->bind_params($stmt, $params);
1108 $result = oci_execute($stmt, $this->commit_status);
1109 $this->query_end($result, $stmt);
1112 oci_fetch_all($stmt, $records, 0, -1, OCI_FETCHSTATEMENT_BY_ROW);
1113 oci_free_statement($stmt);
1117 foreach ($records as $row) {
1118 $row = array_change_key_case($row, CASE_LOWER);
1119 unset($row['oracle_rownum']);
1120 array_walk($row, array('oci_native_moodle_database', 'onespace2empty'));
1122 if (isset($return[$id])) {
1123 $colname = key($row);
1124 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);
1126 $return[$id] = (object)$row;
1133 * Selects records and return values (first field) as an array using a SQL statement.
1135 * @param string $sql The SQL query
1136 * @param array $params array of sql parameters
1137 * @return array of values
1138 * @throws dml_exception A DML specific exception is thrown for any errors.
1140 public function get_fieldset_sql($sql, array $params=null) {
1141 list($sql, $params, $type) = $this->fix_sql_params($sql, $params);
1143 list($sql, $params) = $this->tweak_param_names($sql, $params);
1144 $this->query_start($sql, $params, SQL_QUERY_SELECT);
1145 $stmt = $this->parse_query($sql);
1146 $this->bind_params($stmt, $params);
1147 $result = oci_execute($stmt, $this->commit_status);
1148 $this->query_end($result, $stmt);
1151 oci_fetch_all($stmt, $records, 0, -1, OCI_FETCHSTATEMENT_BY_COLUMN);
1152 oci_free_statement($stmt);
1154 $return = reset($records);
1155 array_walk($return, array('oci_native_moodle_database', 'onespace2empty'));
1161 * Insert new record into database, as fast as possible, no safety checks, lobs not supported.
1162 * @param string $table name
1163 * @param mixed $params data record as object or array
1164 * @param bool $returnit return it of inserted record
1165 * @param bool $bulk true means repeated inserts expected
1166 * @param bool $customsequence true if 'id' included in $params, disables $returnid
1167 * @return bool|int true or new id
1168 * @throws dml_exception A DML specific exception is thrown for any errors.
1170 public function insert_record_raw($table, $params, $returnid=true, $bulk=false, $customsequence=false) {
1171 if (!is_array($params)) {
1172 $params = (array)$params;
1177 if ($customsequence) {
1178 if (!isset($params['id'])) {
1179 throw new coding_exception('moodle_database::insert_record_raw() id field must be specified if custom sequences used.');
1183 unset($params['id']);
1185 $returning = " RETURNING id INTO :oracle_id"; // crazy name nobody is ever going to use or parameter ;-)
1189 if (empty($params)) {
1190 throw new coding_exception('moodle_database::insert_record_raw() no fields found.');
1193 $fields = implode(',', array_keys($params));
1195 foreach ($params as $pname => $value) {
1196 $values[] = ":$pname";
1198 $values = implode(',', $values);
1200 $sql = "INSERT INTO {" . $table . "} ($fields) VALUES ($values)";
1201 list($sql, $params, $type) = $this->fix_sql_params($sql, $params);
1206 // note we don't need tweak_param_names() here. Placeholders are safe column names. MDL-28080
1207 // list($sql, $params) = $this->tweak_param_names($sql, $params);
1208 $this->query_start($sql, $params, SQL_QUERY_INSERT);
1209 $stmt = $this->parse_query($sql);
1210 $descriptors = $this->bind_params($stmt, $params, $table);
1212 oci_bind_by_name($stmt, ":oracle_id", $id, 10, SQLT_INT);
1214 $result = oci_execute($stmt, $this->commit_status);
1215 $this->free_descriptors($descriptors);
1216 $this->query_end($result, $stmt);
1217 oci_free_statement($stmt);
1224 die('TODO - implement oracle 9.2 insert support'); //TODO
1231 * Insert a record into a table and return the "id" field if required.
1233 * Some conversions and safety checks are carried out. Lobs are supported.
1234 * If the return ID isn't required, then this just reports success as true/false.
1235 * $data is an object containing needed data
1236 * @param string $table The database table to be inserted into
1237 * @param object $data A data object with values for one or more fields in the record
1238 * @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.
1239 * @return bool|int true or new id
1240 * @throws dml_exception A DML specific exception is thrown for any errors.
1242 public function insert_record($table, $dataobject, $returnid=true, $bulk=false) {
1243 $dataobject = (array)$dataobject;
1245 $columns = $this->get_columns($table);
1248 foreach ($dataobject as $field=>$value) {
1249 if ($field === 'id') {
1252 if (!isset($columns[$field])) { // Non-existing table field, skip it
1255 $column = $columns[$field];
1256 $cleaned[$field] = $this->normalise_value($column, $value);
1259 return $this->insert_record_raw($table, $cleaned, $returnid, $bulk);
1263 * Import a record into a table, id field is required.
1264 * Safety checks are NOT carried out. Lobs are supported.
1266 * @param string $table name of database table to be inserted into
1267 * @param object $dataobject A data object with values for one or more fields in the record
1269 * @throws dml_exception A DML specific exception is thrown for any errors.
1271 public function import_record($table, $dataobject) {
1272 $dataobject = (array)$dataobject;
1274 $columns = $this->get_columns($table);
1277 foreach ($dataobject as $field=>$value) {
1278 if (!isset($columns[$field])) {
1281 $column = $columns[$field];
1282 $cleaned[$field] = $this->normalise_value($column, $value);
1285 return $this->insert_record_raw($table, $cleaned, false, true, true);
1289 * Update record in database, as fast as possible, no safety checks, lobs not supported.
1290 * @param string $table name
1291 * @param mixed $params data record as object or array
1292 * @param bool true means repeated updates expected
1294 * @throws dml_exception A DML specific exception is thrown for any errors.
1296 public function update_record_raw($table, $params, $bulk=false) {
1297 $params = (array)$params;
1299 if (!isset($params['id'])) {
1300 throw new coding_exception('moodle_database::update_record_raw() id field must be specified.');
1303 if (empty($params)) {
1304 throw new coding_exception('moodle_database::update_record_raw() no fields found.');
1308 foreach ($params as $field=>$value) {
1309 if ($field == 'id') {
1312 $sets[] = "$field = :$field";
1315 $sets = implode(',', $sets);
1316 $sql = "UPDATE {" . $table . "} SET $sets WHERE id=:id";
1317 list($sql, $params, $type) = $this->fix_sql_params($sql, $params);
1319 // note we don't need tweak_param_names() here. Placeholders are safe column names. MDL-28080
1320 // list($sql, $params) = $this->tweak_param_names($sql, $params);
1321 $this->query_start($sql, $params, SQL_QUERY_UPDATE);
1322 $stmt = $this->parse_query($sql);
1323 $descriptors = $this->bind_params($stmt, $params, $table);
1324 $result = oci_execute($stmt, $this->commit_status);
1325 $this->free_descriptors($descriptors);
1326 $this->query_end($result, $stmt);
1327 oci_free_statement($stmt);
1333 * Update a record in a table
1335 * $dataobject is an object containing needed data
1336 * Relies on $dataobject having a variable "id" to
1337 * specify the record to update
1339 * @param string $table The database table to be checked against.
1340 * @param object $dataobject An object with contents equal to fieldname=>fieldvalue. Must have an entry for 'id' to map to the table specified.
1341 * @param bool true means repeated updates expected
1343 * @throws dml_exception A DML specific exception is thrown for any errors.
1345 public function update_record($table, $dataobject, $bulk=false) {
1346 $dataobject = (array)$dataobject;
1348 $columns = $this->get_columns($table);
1351 foreach ($dataobject as $field=>$value) {
1352 if (!isset($columns[$field])) {
1355 $column = $columns[$field];
1356 $cleaned[$field] = $this->normalise_value($column, $value);
1359 $this->update_record_raw($table, $cleaned, $bulk);
1365 * Set a single field in every table record which match a particular WHERE clause.
1367 * @param string $table The database table to be checked against.
1368 * @param string $newfield the field to set.
1369 * @param string $newvalue the value to set the field to.
1370 * @param string $select A fragment of SQL to be used in a where clause in the SQL call.
1371 * @param array $params array of sql parameters
1373 * @throws dml_exception A DML specific exception is thrown for any errors.
1375 public function set_field_select($table, $newfield, $newvalue, $select, array $params=null) {
1378 $select = "WHERE $select";
1380 if (is_null($params)) {
1384 // Get column metadata
1385 $columns = $this->get_columns($table);
1386 $column = $columns[$newfield];
1388 $newvalue = $this->normalise_value($column, $newvalue);
1390 list($select, $params, $type) = $this->fix_sql_params($select, $params);
1392 if (is_bool($newvalue)) {
1393 $newvalue = (int)$newvalue; // prevent "false" problems
1395 if (is_null($newvalue)) {
1396 $newsql = "$newfield = NULL";
1398 // Set the param to array ($newfield => $newvalue) and key to 'newfieldtoset'
1399 // name in the build sql. Later, bind_params() will detect the value array and
1400 // perform the needed modifications to allow the query to work. Note that
1401 // 'newfieldtoset' is one arbitrary name that hopefully won't be used ever
1402 // in order to avoid problems where the same field is used both in the set clause and in
1403 // the conditions. This was breaking badly in drivers using NAMED params like oci.
1404 $params['newfieldtoset'] = array($newfield => $newvalue);
1405 $newsql = "$newfield = :newfieldtoset";
1407 $sql = "UPDATE {" . $table . "} SET $newsql $select";
1408 list($sql, $params, $type) = $this->fix_sql_params($sql, $params);
1410 list($sql, $params) = $this->tweak_param_names($sql, $params);
1411 $this->query_start($sql, $params, SQL_QUERY_UPDATE);
1412 $stmt = $this->parse_query($sql);
1413 $descriptors = $this->bind_params($stmt, $params, $table);
1414 $result = oci_execute($stmt, $this->commit_status);
1415 $this->free_descriptors($descriptors);
1416 $this->query_end($result, $stmt);
1417 oci_free_statement($stmt);
1423 * Delete one or more records from a table which match a particular WHERE clause.
1425 * @param string $table The database table to be checked against.
1426 * @param string $select A fragment of SQL to be used in a where clause in the SQL call (used to define the selection criteria).
1427 * @param array $params array of sql parameters
1429 * @throws dml_exception A DML specific exception is thrown for any errors.
1431 public function delete_records_select($table, $select, array $params=null) {
1434 $select = "WHERE $select";
1437 $sql = "DELETE FROM {" . $table . "} $select";
1439 list($sql, $params, $type) = $this->fix_sql_params($sql, $params);
1441 list($sql, $params) = $this->tweak_param_names($sql, $params);
1442 $this->query_start($sql, $params, SQL_QUERY_UPDATE);
1443 $stmt = $this->parse_query($sql);
1444 $this->bind_params($stmt, $params);
1445 $result = oci_execute($stmt, $this->commit_status);
1446 $this->query_end($result, $stmt);
1447 oci_free_statement($stmt);
1452 function sql_null_from_clause() {
1453 return ' FROM dual';
1456 // Bitwise operations
1457 protected function bitwise_supported() {
1458 if (isset($this->bitwise_supported)) { // Use cached value if available
1459 return $this->bitwise_supported;
1463 WHERE object_type = 'PACKAGE BODY'
1464 AND object_name = 'MOODLE_BITS'
1465 AND status = 'VALID'";
1466 $this->query_start($sql, null, SQL_QUERY_AUX);
1467 $stmt = $this->parse_query($sql);
1468 $result = oci_execute($stmt, $this->commit_status);
1469 $this->query_end($result, $stmt);
1471 oci_fetch_all($stmt, $records, 0, -1, OCI_FETCHSTATEMENT_BY_ROW);
1472 oci_free_statement($stmt);
1473 $this->bitwise_supported = isset($records[0]) && reset($records[0]) ? true : false;
1474 return $this->bitwise_supported;
1477 public function sql_bitand($int1, $int2) {
1478 return 'bitand((' . $int1 . '), (' . $int2 . '))';
1481 public function sql_bitnot($int1) {
1482 return '((0 - (' . $int1 . ')) - 1)';
1485 public function sql_bitor($int1, $int2) {
1486 // Use the MOODLE_BITS package if available
1487 if ($this->bitwise_supported()) {
1488 return 'MOODLE_BITS.BITOR(' . $int1 . ', ' . $int2 . ')';
1490 // fallback to PHP bool operations, can break if using placeholders
1491 return '((' . $int1 . ') + (' . $int2 . ') - ' . $this->sql_bitand($int1, $int2) . ')';
1494 public function sql_bitxor($int1, $int2) {
1495 // Use the MOODLE_BITS package if available
1496 if ($this->bitwise_supported()) {
1497 return 'MOODLE_BITS.BITXOR(' . $int1 . ', ' . $int2 . ')';
1499 // fallback to PHP bool operations, can break if using placeholders
1500 return '(' . $this->sql_bitor($int1, $int2) . ' - ' . $this->sql_bitand($int1, $int2) . ')';
1504 * Returns the SQL text to be used in order to perform module '%'
1505 * operation - remainder after division
1507 * @param integer int1 first integer in the operation
1508 * @param integer int2 second integer in the operation
1509 * @return string the piece of SQL code to be used in your statement.
1511 public function sql_modulo($int1, $int2) {
1512 return 'MOD(' . $int1 . ', ' . $int2 . ')';
1515 public function sql_cast_char2int($fieldname, $text=false) {
1517 return ' CAST(' . $fieldname . ' AS INT) ';
1519 return ' CAST(' . $this->sql_compare_text($fieldname) . ' AS INT) ';
1523 public function sql_cast_char2real($fieldname, $text=false) {
1525 return ' CAST(' . $fieldname . ' AS FLOAT) ';
1527 return ' CAST(' . $this->sql_compare_text($fieldname) . ' AS FLOAT) ';
1532 * Returns 'LIKE' part of a query.
1534 * @param string $fieldname usually name of the table column
1535 * @param string $param usually bound query parameter (?, :named)
1536 * @param bool $casesensitive use case sensitive search
1537 * @param bool $accensensitive use accent sensitive search (not all databases support accent insensitive)
1538 * @param bool $notlike true means "NOT LIKE"
1539 * @param string $escapechar escape char for '%' and '_'
1540 * @return string SQL code fragment
1542 public function sql_like($fieldname, $param, $casesensitive = true, $accentsensitive = true, $notlike = false, $escapechar = '\\') {
1543 if (strpos($param, '%') !== false) {
1544 debugging('Potential SQL injection detected, sql_ilike() expects bound parameters (? or :named)');
1547 $LIKE = $notlike ? 'NOT LIKE' : 'LIKE';
1549 // no accent sensitiveness here for now, sorry
1551 if ($casesensitive) {
1552 return "$fieldname $LIKE $param ESCAPE '$escapechar'";
1554 return "LOWER($fieldname) $LIKE LOWER($param) ESCAPE '$escapechar'";
1558 // NOTE: Oracle concat implementation isn't ANSI compliant when using NULLs (the result of
1559 // any concatenation with NULL must return NULL) because of his inability to differentiate
1560 // NULLs and empty strings. So this function will cause some tests to fail. Hopefully
1561 // it's only a side case and it won't affect normal concatenation operations in Moodle.
1562 public function sql_concat() {
1563 $arr = func_get_args();
1564 $s = implode(' || ', $arr);
1571 public function sql_concat_join($separator="' '", $elements=array()) {
1572 for ($n=count($elements)-1; $n > 0 ; $n--) {
1573 array_splice($elements, $n, 0, $separator);
1575 $s = implode(' || ', $elements);
1583 * Returns the SQL for returning searching one string for the location of another.
1585 public function sql_position($needle, $haystack) {
1586 return "INSTR(($haystack), ($needle))";
1589 public function sql_isempty($tablename, $fieldname, $nullablefield, $textfield) {
1591 return " (".$this->sql_compare_text($fieldname)." = '".$this->sql_empty()."') ";
1593 return " ($fieldname = '".$this->sql_empty()."') ";
1598 * Returns the empty string char used by every supported DB. To be used when
1599 * we are searching for that values in our queries. Only Oracle uses this
1600 * for now (will be out, once we migrate to proper NULLs if that days arrives)
1601 * @return string A string with single whitespace.
1603 public function sql_empty() {
1607 public function sql_order_by_text($fieldname, $numchars=32) {
1608 return 'dbms_lob.substr(' . $fieldname . ', ' . $numchars . ',1)';
1612 public function session_lock_supported() {
1613 if (isset($this->dblocks_supported)) { // Use cached value if available
1614 return $this->dblocks_supported;
1618 WHERE object_type = 'PACKAGE BODY'
1619 AND object_name = 'MOODLE_LOCKS'
1620 AND status = 'VALID'";
1621 $this->query_start($sql, null, SQL_QUERY_AUX);
1622 $stmt = $this->parse_query($sql);
1623 $result = oci_execute($stmt, $this->commit_status);
1624 $this->query_end($result, $stmt);
1626 oci_fetch_all($stmt, $records, 0, -1, OCI_FETCHSTATEMENT_BY_ROW);
1627 oci_free_statement($stmt);
1628 $this->dblocks_supported = isset($records[0]) && reset($records[0]) ? true : false;
1629 return $this->dblocks_supported;
1633 * Obtain session lock
1634 * @param int $rowid id of the row with session record
1635 * @param int $timeout max allowed time to wait for the lock in seconds
1636 * @return bool success
1638 public function get_session_lock($rowid, $timeout) {
1639 if (!$this->session_lock_supported()) {
1642 parent::get_session_lock($rowid, $timeout);
1644 $fullname = $this->dbname.'-'.$this->prefix.'-session-'.$rowid;
1645 $sql = 'SELECT MOODLE_LOCKS.GET_LOCK(:lockname, :locktimeout) FROM DUAL';
1646 $params = array('lockname' => $fullname , 'locktimeout' => $timeout);
1647 $this->query_start($sql, $params, SQL_QUERY_AUX);
1648 $stmt = $this->parse_query($sql);
1649 $this->bind_params($stmt, $params);
1650 $result = oci_execute($stmt, $this->commit_status);
1651 if ($result === false) { // Any failure in get_lock() raises error, causing return of bool false
1652 throw new dml_sessionwait_exception();
1654 $this->query_end($result, $stmt);
1655 oci_free_statement($stmt);
1658 public function release_session_lock($rowid) {
1659 if (!$this->session_lock_supported()) {
1662 parent::release_session_lock($rowid);
1664 $fullname = $this->dbname.'-'.$this->prefix.'-session-'.$rowid;
1665 $params = array('lockname' => $fullname);
1666 $sql = 'SELECT MOODLE_LOCKS.RELEASE_LOCK(:lockname) FROM DUAL';
1667 $this->query_start($sql, $params, SQL_QUERY_AUX);
1668 $stmt = $this->parse_query($sql);
1669 $this->bind_params($stmt, $params);
1670 $result = oci_execute($stmt, $this->commit_status);
1671 $this->query_end($result, $stmt);
1672 oci_free_statement($stmt);
1677 * Driver specific start of real database transaction,
1678 * this can not be used directly in code.
1681 protected function begin_transaction() {
1682 $this->commit_status = OCI_DEFAULT; //Done! ;-)
1686 * Driver specific commit of real database transaction,
1687 * this can not be used directly in code.
1690 protected function commit_transaction() {
1691 $this->query_start('--oracle_commit', NULL, SQL_QUERY_AUX);
1692 $result = oci_commit($this->oci);
1693 $this->commit_status = OCI_COMMIT_ON_SUCCESS;
1694 $this->query_end($result);
1698 * Driver specific abort of real database transaction,
1699 * this can not be used directly in code.
1702 protected function rollback_transaction() {
1703 $this->query_start('--oracle_rollback', NULL, SQL_QUERY_AUX);
1704 $result = oci_rollback($this->oci);
1705 $this->commit_status = OCI_COMMIT_ON_SUCCESS;
1706 $this->query_end($result);