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.
13//
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/>.
16
17/**
18 * Native oci class representing moodle database interface.
19 *
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
23 */
24
25defined('MOODLE_INTERNAL') || die();
26
27require_once(__DIR__.'/moodle_database.php');
28require_once(__DIR__.'/oci_native_moodle_recordset.php');
29require_once(__DIR__.'/oci_native_moodle_temptables.php');
30
31/**
32 * Native oci class representing moodle database interface.
33 *
34 * One complete reference for PHP + OCI:
35 * http://www.oracle.com/technology/tech/php/underground-php-oracle-manual.html
36 *
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
40 */
41class oci_native_moodle_database extends moodle_database {
42
43    protected $oci     = null;
44
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;
49
50    /** @var 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;
54
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
59     */
60    public function driver_installed() {
61        if (!extension_loaded('oci8')) {
62            return get_string('ociextensionisnotpresentinphp', 'install');
63        }
64        return true;
65    }
66
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.)
71     */
72    public function get_dbfamily() {
73        return 'oracle';
74    }
75
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
80     */
81    protected function get_dbtype() {
82        return 'oci';
83    }
84
85    /**
86     * Returns general database library name
87     * Note: can be used before connect()
88     * @return string db type pdo, native
89     */
90    protected function get_dblibrary() {
91        return 'native';
92    }
93
94    /**
95     * Returns localised database type name
96     * Note: can be used before connect()
97     * @return string
98     */
99    public function get_name() {
100        return get_string('nativeoci', 'install');
101    }
102
103    /**
104     * Returns localised database configuration help.
105     * Note: can be used before connect()
106     * @return string
107     */
108    public function get_configuration_help() {
109        return get_string('nativeocihelp', 'install');
110    }
111
112    /**
113     * Diagnose database and tables, this function is used
114     * to verify database and driver settings, db engine types, etc.
115     *
116     * @return string null means everything ok, string means problem found.
117     */
118    public function diagnose() {
119        return null;
120    }
121
122    /**
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
133     */
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());
138        }
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);
143        }
144
145        $driverstatus = $this->driver_installed();
146
147        if ($driverstatus !== true) {
148            throw new dml_exception('dbdriverproblem', $driverstatus);
149        }
150
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;
156
157        $this->store_settings($dbhost, $dbuser, $dbpass, $dbname, $prefix, $dboptions);
158        unset($this->dboptions['dbsocket']);
159
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...
162
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;
169            }
170            $dbstring = '//'.$this->dbhost.':'.$this->dboptions['dbport'].'/'.$this->dbname;
171        }
172
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');
178        }
179        $dberr = ob_get_contents();
180        ob_end_clean();
181
182
183        if ($this->oci === false) {
184            $this->oci = null;
185            $e = oci_error();
186            if (isset($e['message'])) {
187                $dberr = $e['message'];
188            }
189            throw new dml_connection_exception($dberr);
190        }
191
192        // Disable logging until we are fully setup.
193        $this->query_log_prevent();
194
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.
202            }
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.');
205            }
206        }
207
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]);
218
219        //note: do not send "ALTER SESSION SET NLS_NUMERIC_CHARACTERS='.,'" !
220        //      instead fix our PHP code to convert "," to "." properly!
221
222        // We can enable logging now.
223        $this->query_log_allow();
224
225        // Connection stabilised and configured, going to instantiate the temptables controller
226        $this->temptables = new oci_native_moodle_temptables($this, $this->unique_session_id);
227
228        return true;
229    }
230
231    /**
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.
235     */
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;
241        }
242    }
243
244
245    /**
246     * Called before each db query.
247     * @param string $sql
248     * @param array array of parameters
249     * @param int $type type of query
250     * @param mixed $extrainfo driver specific extra information
251     * @return void
252     */
253    protected function query_start($sql, array $params=null, $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);
257    }
258
259    /**
260     * Called immediately after each db query.
261     * @param mixed db specific result
262     * @return void
263     */
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'];
273                }
274            }
275            oci_free_statement($stmt);
276        }
277        parent::query_end($result);
278    }
279
280    /**
281     * Returns database server info array
282     * @return array Array containing 'description' and 'version' info
283     */
284    public function get_server_info() {
285        static $info = null; // TODO: move to real object property
286
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]);
293        }
294
295        return $info;
296    }
297
298    /**
299     * Converts short table name {tablename} to real table name
300     * supporting temp tables ($this->unique_session_id based) if detected
301     *
302     * @param string sql
303     * @return string sql
304     */
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);
313                }
314            }
315        }
316        return $sql;
317    }
318
319    /**
320     * Returns supported query parameter types
321     * @return int bitmask of accepted SQL_PARAMS_*
322     */
323    protected function allowed_param_types() {
324        return SQL_PARAMS_NAMED;
325    }
326
327    /**
328     * Returns last error reported by database engine.
329     * @return string error message
330     */
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'];
341            }
342        }
343        return $error;
344    }
345
346    /**
347     * Prepare the statement for execution
348     *
349     * @param string $sql
350     * @return resource
351     *
352     * @throws dml_exception
353     */
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());
358        }
359        return $stmt;
360    }
361
362    /**
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
367     */
368    protected function tweak_param_names($sql, array $params) {
369        if (empty($params)) {
370            return array($sql, $params);
371        }
372
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);
381            }
382            $newparams[$newname] = $value;
383            $searcharr[':' . $name] = ':' . $newname;
384        }
385        // sort by length desc to avoid potential str_replace() overlap
386        uksort($searcharr, array('oci_native_moodle_database', 'compare_by_length_desc'));
387
388        $sql = str_replace(array_keys($searcharr), $searcharr, $sql);
389        return array($sql, $newparams);
390    }
391
392    /**
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
396     */
397    public function get_tables($usecache=true) {
398        if ($usecache and $this->tables !== null) {
399            return $this->tables;
400        }
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;
420                }
421                $tablename = substr($tablename, strlen($this->prefix));
422            }
423            $this->tables[$tablename] = $tablename;
424        }
425
426        // Add the currently available temptables
427        $this->tables = array_merge($this->tables, $this->temptables->get_temptables());
428
429        return $this->tables;
430    }
431
432    /**
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
436     */
437    public function get_indexes($table) {
438        $indexes = array();
439        $tablename = strtoupper($this->prefix.$table);
440
441        $sql = "SELECT i.INDEX_NAME, i.UNIQUENESS, c.COLUMN_POSITION, c.COLUMN_NAME, 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_CONSTRAINTS ac ON (ac.TABLE_NAME=i.TABLE_NAME AND ac.CONSTRAINT_NAME=i.INDEX_NAME AND ac.CONSTRAINT_TYPE='P')
445                 WHERE i.TABLE_NAME = '$tablename'
446              ORDER BY i.INDEX_NAME, c.COLUMN_POSITION";
447
448        $stmt = $this->parse_query($sql);
449        $result = oci_execute($stmt, $this->commit_status);
450        $this->query_end($result, $stmt);
451        $records = null;
452        oci_fetch_all($stmt, $records, 0, -1, OCI_FETCHSTATEMENT_BY_ROW);
453        oci_free_statement($stmt);
454
455        foreach ($records as $record) {
456            if ($record['CONSTRAINT_TYPE'] === 'P') {
457                //ignore for now;
458                continue;
459            }
460            $indexname = strtolower($record['INDEX_NAME']);
461            if (!isset($indexes[$indexname])) {
462                $indexes[$indexname] = array('primary' => ($record['CONSTRAINT_TYPE'] === 'P'),
463                                             'unique'  => ($record['UNIQUENESS'] === 'UNIQUE'),
464                                             'columns' => array());
465            }
466            $indexes[$indexname]['columns'][] = strtolower($record['COLUMN_NAME']);
467        }
468
469        return $indexes;
470    }
471
472    /**
473     * Fetches detailed information about columns in table.
474     *
475     * @param string $table name
476     * @return array array of database_column_info objects indexed with column names
477     */
478    protected function fetch_columns(string $table): array {
479        $structure = array();
480
481        // We give precedence to CHAR_LENGTH for VARCHAR2 columns over WIDTH because the former is always
482        // BYTE based and, for cross-db operations, we want CHAR based results. See MDL-29415
483        // Instead of guessing sequence based exclusively on name, check tables against user_triggers to
484        // ensure the table has a 'before each row' trigger to assume 'id' is auto_increment. MDL-32365
485        $sql = "SELECT CNAME, COLTYPE, nvl(CHAR_LENGTH, WIDTH) AS WIDTH, SCALE, PRECISION, NULLS, DEFAULTVAL,
486                  DECODE(NVL(TRIGGER_NAME, '0'), '0', '0', '1') HASTRIGGER
487                  FROM COL c
488             LEFT JOIN USER_TAB_COLUMNS u ON (u.TABLE_NAME = c.TNAME AND u.COLUMN_NAME = c.CNAME AND u.DATA_TYPE = 'VARCHAR2')
489             LEFT JOIN USER_TRIGGERS t ON (t.TABLE_NAME = c.TNAME AND TRIGGER_TYPE = 'BEFORE EACH ROW' AND c.CNAME = 'ID')
490                 WHERE TNAME = UPPER('{" . $table . "}')
491              ORDER BY COLNO";
492
493        list($sql, $params, $type) = $this->fix_sql_params($sql, null);
494
495        $this->query_start($sql, null, SQL_QUERY_AUX);
496        $stmt = $this->parse_query($sql);
497        $result = oci_execute($stmt, $this->commit_status);
498        $this->query_end($result, $stmt);
499        $records = null;
500        oci_fetch_all($stmt, $records, 0, -1, OCI_FETCHSTATEMENT_BY_ROW);
501        oci_free_statement($stmt);
502
503        if (!$records) {
504            return array();
505        }
506        foreach ($records as $rawcolumn) {
507            $rawcolumn = (object)$rawcolumn;
508
509            $info = new stdClass();
510            $info->name = strtolower($rawcolumn->CNAME);
511            $info->auto_increment = ((int)$rawcolumn->HASTRIGGER) ? true : false;
512            $matches = null;
513
514            if ($rawcolumn->COLTYPE === 'VARCHAR2'
515             or $rawcolumn->COLTYPE === 'VARCHAR'
516             or $rawcolumn->COLTYPE === 'NVARCHAR2'
517             or $rawcolumn->COLTYPE === 'NVARCHAR'
518             or $rawcolumn->COLTYPE === 'CHAR'
519             or $rawcolumn->COLTYPE === 'NCHAR') {
520                $info->type          = $rawcolumn->COLTYPE;
521                $info->meta_type     = 'C';
522                $info->max_length    = $rawcolumn->WIDTH;
523                $info->scale         = null;
524                $info->not_null      = ($rawcolumn->NULLS === 'NOT NULL');
525                $info->has_default   = !is_null($rawcolumn->DEFAULTVAL);
526                if ($info->has_default) {
527
528                    // this is hacky :-(
529                    if ($rawcolumn->DEFAULTVAL === 'NULL') {
530                        $info->default_value = null;
531                    } else if ($rawcolumn->DEFAULTVAL === "' ' ") { // Sometimes it's stored with trailing space
532                        $info->default_value = "";
533                    } else if ($rawcolumn->DEFAULTVAL === "' '") { // Sometimes it's stored without trailing space
534                        $info->default_value = "";
535                    } else {
536                        $info->default_value = trim($rawcolumn->DEFAULTVAL); // remove trailing space
537                        $info->default_value = substr($info->default_value, 1, strlen($info->default_value)-2); //trim ''
538                    }
539                } else {
540                    $info->default_value = null;
541                }
542                $info->primary_key   = false;
543                $info->binary        = false;
544                $info->unsigned      = null;
545                $info->unique        = null;
546
547            } else if ($rawcolumn->COLTYPE === 'NUMBER') {
548                $info->type       = $rawcolumn->COLTYPE;
549                $info->max_length = $rawcolumn->PRECISION;
550                $info->binary     = false;
551                if (!is_null($rawcolumn->SCALE) && $rawcolumn->SCALE == 0) { // null in oracle scale allows decimals => not integer
552                    // integer
553                    if ($info->name === 'id') {
554                        $info->primary_key   = true;
555                        $info->meta_type     = 'R';
556                        $info->unique        = true;
557                        $info->has_default   = false;
558                    } else {
559                        $info->primary_key   = false;
560                        $info->meta_type     = 'I';
561                        $info->unique        = null;
562                    }
563                    $info->scale = 0;
564
565                } else {
566                    //float
567                    $info->meta_type     = 'N';
568                    $info->primary_key   = false;
569                    $info->unsigned      = null;
570                    $info->unique        = null;
571                    $info->scale         = $rawcolumn->SCALE;
572                }
573                $info->not_null      = ($rawcolumn->NULLS === 'NOT NULL');
574                $info->has_default   = !is_null($rawcolumn->DEFAULTVAL);
575                if ($info->has_default) {
576                    $info->default_value = trim($rawcolumn->DEFAULTVAL); // remove trailing space
577                } else {
578                    $info->default_value = null;
579                }
580
581            } else if ($rawcolumn->COLTYPE === 'FLOAT') {
582                $info->type       = $rawcolumn->COLTYPE;
583                $info->max_length = (int)($rawcolumn->PRECISION * 3.32193);
584                $info->primary_key   = false;
585                $info->meta_type     = 'N';
586                $info->unique        = null;
587                $info->not_null      = ($rawcolumn->NULLS === 'NOT NULL');
588                $info->has_default   = !is_null($rawcolumn->DEFAULTVAL);
589                if ($info->has_default) {
590                    $info->default_value = trim($rawcolumn->DEFAULTVAL); // remove trailing space
591                } else {
592                    $info->default_value = null;
593                }
594
595            } else if ($rawcolumn->COLTYPE === 'CLOB'
596                    or $rawcolumn->COLTYPE === 'NCLOB') {
597                $info->type          = $rawcolumn->COLTYPE;
598                $info->meta_type     = 'X';
599                $info->max_length    = -1;
600                $info->scale         = null;
601                $info->scale         = null;
602                $info->not_null      = ($rawcolumn->NULLS === 'NOT NULL');
603                $info->has_default   = !is_null($rawcolumn->DEFAULTVAL);
604                if ($info->has_default) {
605                    // this is hacky :-(
606                    if ($rawcolumn->DEFAULTVAL === 'NULL') {
607                        $info->default_value = null;
608                    } else if ($rawcolumn->DEFAULTVAL === "' ' ") { // Sometimes it's stored with trailing space
609                        $info->default_value = "";
610                    } else if ($rawcolumn->DEFAULTVAL === "' '") { // Other times it's stored without trailing space
611                        $info->default_value = "";
612                    } else {
613                        $info->default_value = trim($rawcolumn->DEFAULTVAL); // remove trailing space
614                        $info->default_value = substr($info->default_value, 1, strlen($info->default_value)-2); //trim ''
615                    }
616                } else {
617                    $info->default_value = null;
618                }
619                $info->primary_key   = false;
620                $info->binary        = false;
621                $info->unsigned      = null;
622                $info->unique        = null;
623
624            } else if ($rawcolumn->COLTYPE === 'BLOB') {
625                $info->type          = $rawcolumn->COLTYPE;
626                $info->meta_type     = 'B';
627                $info->max_length    = -1;
628                $info->scale         = null;
629                $info->scale         = null;
630                $info->not_null      = ($rawcolumn->NULLS === 'NOT NULL');
631                $info->has_default   = !is_null($rawcolumn->DEFAULTVAL);
632                if ($info->has_default) {
633                    // this is hacky :-(
634                    if ($rawcolumn->DEFAULTVAL === 'NULL') {
635                        $info->default_value = null;
636                    } else if ($rawcolumn->DEFAULTVAL === "' ' ") { // Sometimes it's stored with trailing space
637                        $info->default_value = "";
638                    } else if ($rawcolumn->DEFAULTVAL === "' '") { // Sometimes it's stored without trailing space
639                        $info->default_value = "";
640                    } else {
641                        $info->default_value = trim($rawcolumn->DEFAULTVAL); // remove trailing space
642                        $info->default_value = substr($info->default_value, 1, strlen($info->default_value)-2); //trim ''
643                    }
644                } else {
645                    $info->default_value = null;
646                }
647                $info->primary_key   = false;
648                $info->binary        = true;
649                $info->unsigned      = null;
650                $info->unique        = null;
651
652            } else {
653                // unknown type - sorry
654                $info->type          = $rawcolumn->COLTYPE;
655                $info->meta_type     = '?';
656            }
657
658            $structure[$info->name] = new database_column_info($info);
659        }
660
661        return $structure;
662    }
663
664    /**
665     * Normalise values based in RDBMS dependencies (booleans, LOBs...)
666     *
667     * @param database_column_info $column column metadata corresponding with the value we are going to normalise
668     * @param mixed $value value we are going to normalise
669     * @return mixed the normalised value
670     */
671    protected function normalise_value($column, $value) {
672        $this->detect_objects($value);
673
674        if (is_bool($value)) { // Always, convert boolean to int
675            $value = (int)$value;
676
677        } else if ($column->meta_type == 'B') { // BLOB detected, we return 'blob' array instead of raw value to allow
678            if (!is_null($value)) {             // binding/executing code later to know about its nature
679                $value = array('blob' => $value);
680            }
681
682        } else if ($column->meta_type == 'X' && strlen($value) > 4000) { // CLOB detected (>4000 optimisation), we return 'clob'
683            if (!is_null($value)) {                                      // array instead of raw value to allow binding/
684                $value = array('clob' => (string)$value);                // executing code later to know about its nature
685            }
686
687        } else if ($value === '') {
688            if ($column->meta_type == 'I' or $column->meta_type == 'F' or $column->meta_type == 'N') {
689                $value = 0; // prevent '' problems in numeric fields
690            }
691        }
692        return $value;
693    }
694
695    /**
696     * Transforms the sql and params in order to emulate the LIMIT clause available in other DBs
697     *
698     * @param string $sql the SQL select query to execute.
699     * @param array $params array of sql parameters
700     * @param int $limitfrom return a subset of records, starting at this point (optional, required if $limitnum is set).
701     * @param int $limitnum return a subset comprising this many records (optional, required if $limitfrom is set).
702     * @return array with the transformed sql and params updated
703     */
704    private function get_limit_sql($sql, array $params = null, $limitfrom=0, $limitnum=0) {
705
706        list($limitfrom, $limitnum) = $this->normalise_limit_from_num($limitfrom, $limitnum);
707        // TODO: Add the /*+ FIRST_ROWS */ hint if there isn't another hint
708
709        if ($limitfrom and $limitnum) {
710            $sql = "SELECT oracle_o.*
711                      FROM (SELECT oracle_i.*, rownum AS oracle_rownum
712                              FROM ($sql) oracle_i
713                             WHERE rownum <= :oracle_num_rows
714                            ) oracle_o
715                     WHERE oracle_rownum > :oracle_skip_rows";
716            $params['oracle_num_rows'] = $limitfrom + $limitnum;
717            $params['oracle_skip_rows'] = $limitfrom;
718
719        } else if ($limitfrom and !$limitnum) {
720            $sql = "SELECT oracle_o.*
721                      FROM (SELECT oracle_i.*, rownum AS oracle_rownum
722                              FROM ($sql) oracle_i
723                            ) oracle_o
724                     WHERE oracle_rownum > :oracle_skip_rows";
725            $params['oracle_skip_rows'] = $limitfrom;
726
727        } else if (!$limitfrom and $limitnum) {
728            $sql = "SELECT *
729                      FROM ($sql)
730                     WHERE rownum <= :oracle_num_rows";
731            $params['oracle_num_rows'] = $limitnum;
732        }
733
734        return array($sql, $params);
735    }
736
737    /**
738     * This function will handle all the column values before being inserted/updated to DB for Oracle
739     * installations. This is because the "special feature" of Oracle where the empty string is
740     * equal to NULL and this presents a problem with all our currently NOT NULL default '' fields.
741     * (and with empties handling in general)
742     *
743     * Note that this function is 100% private and should be used, exclusively by DML functions
744     * in this file. Also, this is considered a DIRTY HACK to be removed when possible.
745     *
746     * This function is private and must not be used outside this driver at all
747     *
748     * @param $table string the table where the record is going to be inserted/updated (without prefix)
749     * @param $field string the field where the record is going to be inserted/updated
750     * @param $value mixed the value to be inserted/updated
751     */
752    private function oracle_dirty_hack ($table, $field, $value) {
753
754        // General bound parameter, just hack the spaces and pray it will work.
755        if (!$table) {
756            if ($value === '') {
757                return ' ';
758            } else if (is_bool($value)) {
759                return (int)$value;
760            } else {
761                return $value;
762            }
763        }
764
765        // Get metadata
766        $columns = $this->get_columns($table);
767        if (!isset($columns[$field])) {
768            if ($value === '') {
769                return ' ';
770            } else if (is_bool($value)) {
771                return (int)$value;
772            } else {
773                return $value;
774            }
775        }
776        $column = $columns[$field];
777
778        // !! This paragraph explains behaviour before Moodle 2.0:
779        //
780        // For Oracle DB, empty strings are converted to NULLs in DB
781        // and this breaks a lot of NOT NULL columns currently Moodle. In the future it's
782        // planned to move some of them to NULL, if they must accept empty values and this
783        // piece of code will become less and less used. But, for now, we need it.
784        // What we are going to do is to examine all the data being inserted and if it's
785        // an empty string (NULL for Oracle) and the field is defined as NOT NULL, we'll modify
786        // such data in the best form possible ("0" for booleans and numbers and " " for the
787        // rest of strings. It isn't optimal, but the only way to do so.
788        // In the opposite, when retrieving records from Oracle, we'll decode " " back to
789        // empty strings to allow everything to work properly. DIRTY HACK.
790
791        // !! These paragraphs explain the rationale about the change for Moodle 2.5:
792        //
793        // Before Moodle 2.0, we only used to apply this DIRTY HACK to NOT NULL columns, as
794        // stated above, but it causes one problem in NULL columns where both empty strings
795        // and real NULLs are stored as NULLs, being impossible to differentiate them when
796        // being retrieved from DB.
797        //
798        // So, starting with Moodle 2.0, we are going to apply the DIRTY HACK to all the
799        // CHAR/CLOB columns no matter of their nullability. That way, when retrieving
800        // NULLABLE fields we'll get proper empties and NULLs differentiated, so we'll be able
801        // to rely in NULL/empty/content contents without problems, until now that wasn't
802        // possible at all.
803        //
804        // One space DIRTY HACK is now applied automatically for all query parameters
805        // and results. The only problem is string concatenation where the glue must
806        // be specified as "' '" sql fragment.
807        //
808        // !! Conclusions:
809        //
810        // From Moodle 2.5 onwards, ALL empty strings in Oracle DBs will be stored as
811        // 1-whitespace char, ALL NULLs as NULLs and, obviously, content as content. And
812        // those 1-whitespace chars will be converted back to empty strings by all the
813        // get_field/record/set() functions transparently and any SQL needing direct handling
814        // of empties will have to use placeholders or sql_isempty() helper function.
815
816        // If the field isn't VARCHAR or CLOB, skip
817        if ($column->meta_type != 'C' and $column->meta_type != 'X') {
818            return $value;
819        }
820
821        // If the value isn't empty, skip
822        if (!empty($value)) {
823            return $value;
824        }
825
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
828
829        // The '0' string doesn't need any transformation, skip
830        if ($value === '0') {
831            return $value;
832        }
833
834        // Transformations start
835        if (gettype($value) == 'boolean') {
836            return '0'; // Transform false to '0' that evaluates the same for PHP
837
838        } else if (gettype($value) == 'integer') {
839            return '0'; // Transform 0 to '0' that evaluates the same for PHP
840
841        } else if ($value === '') {
842            return ' '; // Transform '' to ' ' that DON'T EVALUATE THE SAME
843                        // (we'll transform back again on get_records_XXX functions and others)!!
844        }
845
846        // Fail safe to original value
847        return $value;
848    }
849
850    /**
851     * Helper function to order by string length desc
852     *
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
856     */
857    private function compare_by_length_desc($a, $b) {
858        return strlen($b) - strlen($a);
859    }
860
861    /**
862     * Is db in unicode mode?
863     * @return bool
864     */
865    public function setup_is_unicodedb() {
866        $sql = "SELECT VALUE
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);
873        $records = null;
874        oci_fetch_all($stmt, $records, 0, -1, OCI_FETCHSTATEMENT_BY_COLUMN);
875        oci_free_statement($stmt);
876
877        return (isset($records['VALUE'][0]) and $records['VALUE'][0] === 'AL32UTF8');
878    }
879
880    /**
881     * Do NOT use in code, to be used by database_manager only!
882     * @param string|array $sql query
883     * @param array|null $tablenames an array of xmldb table names affected by this request.
884     * @return bool true
885     * @throws ddl_change_structure_exception A DDL specific exception is thrown for any errors.
886     */
887    public function change_database_structure($sql, $tablenames = null) {
888        $this->get_manager(); // Includes DDL exceptions classes ;-)
889        $sqls = (array)$sql;
890
891        try {
892            foreach ($sqls as $sql) {
893                $this->query_start($sql, null, SQL_QUERY_STRUCTURE);
894                $stmt = $this->parse_query($sql);
895                $result = oci_execute($stmt, $this->commit_status);
896                $this->query_end($result, $stmt);
897                oci_free_statement($stmt);
898            }
899        } catch (ddl_change_structure_exception $e) {
900            $this->reset_caches($tablenames);
901            throw $e;
902        }
903
904        $this->reset_caches($tablenames);
905        return true;
906    }
907
908    protected function bind_params($stmt, array &$params=null, $tablename=null, array &$descriptors = null) {
909        if ($params) {
910            $columns = array();
911            if ($tablename) {
912                $columns = $this->get_columns($tablename);
913            }
914            foreach($params as $key => $value) {
915                // Decouple column name and param name as far as sometimes they aren't the same
916                if ($key == 'o_newfieldtoset') { // found case where column and key diverge, handle that
917                    $columnname   = key($value);    // columnname is the key of the array
918                    $params[$key] = $value[$columnname]; // set the proper value in the $params array and
919                    $value        = $value[$columnname]; // set the proper value in the $value variable
920                } else {
921                    $columnname = preg_replace('/^o_/', '', $key); // Default columnname (for DB introspecting is key), but...
922                }
923                // Continue processing
924                // Now, handle already detected LOBs
925                if (is_array($value)) { // Let's go to bind special cases (lob descriptors)
926                    if (isset($value['clob'])) {
927                        $lob = oci_new_descriptor($this->oci, OCI_DTYPE_LOB);
928                        if ($descriptors === null) {
929                            throw new coding_exception('moodle_database::bind_params() $descriptors not specified for clob');
930                        }
931                        $descriptors[] = $lob;
932                        oci_bind_by_name($stmt, $key, $lob, -1, SQLT_CLOB);
933                        $lob->writeTemporary($this->oracle_dirty_hack($tablename, $columnname, $params[$key]['clob']), OCI_TEMP_CLOB);
934                        continue; // Column binding finished, go to next one
935                    } else if (isset($value['blob'])) {
936                        $lob = oci_new_descriptor($this->oci, OCI_DTYPE_LOB);
937                        if ($descriptors === null) {
938                            throw new coding_exception('moodle_database::bind_params() $descriptors not specified for clob');
939                        }
940                        $descriptors[] = $lob;
941                        oci_bind_by_name($stmt, $key, $lob, -1, SQLT_BLOB);
942                        $lob->writeTemporary($params[$key]['blob'], OCI_TEMP_BLOB);
943                        continue; // Column binding finished, go to next one
944                    }
945                } else {
946                    // If, at this point, the param value > 4000 (bytes), let's assume it's a clob
947                    // passed in an arbitrary sql (not processed by normalise_value() ever,
948                    // and let's handle it as such. This will provide proper binding of CLOBs in
949                    // conditions and other raw SQLs not covered by the above function.
950                    if (strlen($value) > 4000) {
951                        $lob = oci_new_descriptor($this->oci, OCI_DTYPE_LOB);
952                        if ($descriptors === null) {
953                            throw new coding_exception('moodle_database::bind_params() $descriptors not specified for clob');
954                        }
955                        $descriptors[] = $lob;
956                        oci_bind_by_name($stmt, $key, $lob, -1, SQLT_CLOB);
957                        $lob->writeTemporary($this->oracle_dirty_hack($tablename, $columnname, $params[$key]), OCI_TEMP_CLOB);
958                        continue; // Param binding finished, go to next one.
959                    }
960                }
961                // TODO: Put proper types and length is possible (enormous speedup)
962                // Arrived here, continue with standard processing, using metadata if possible
963                if (isset($columns[$columnname])) {
964                    $type = $columns[$columnname]->meta_type;
965                    $maxlength = $columns[$columnname]->max_length;
966                } else {
967                    $type = '?';
968                    $maxlength = -1;
969                }
970                switch ($type) {
971                    case 'I':
972                    case 'R':
973                        // TODO: Optimise
974                        oci_bind_by_name($stmt, $key, $params[$key]);
975                        break;
976
977                    case 'N':
978                    case 'F':
979                        // TODO: Optimise
980                        oci_bind_by_name($stmt, $key, $params[$key]);
981                        break;
982
983                    case 'B':
984                        // TODO: Only arrive here if BLOB is null: Bind if so, else exception!
985                        // don't break here
986
987                    case 'X':
988                        // TODO: Only arrive here if CLOB is null or <= 4000 cc, else exception
989                        // don't break here
990
991                    default: // Bind as CHAR (applying dirty hack)
992                        // TODO: Optimise
993                        $params[$key] = $this->oracle_dirty_hack($tablename, $columnname, $params[$key]);
994                        // Because of PHP7 bug (https://bugs.php.net/bug.php?id=72524) it seems that it's
995                        // impossible to bind NULL values in a reliable way, let's use empty string
996                        // instead in the mean time.
997                        if ($params[$key] === null && version_compare(PHP_VERSION, '7.0.0', '>=')) {
998                            $params[$key] = '';
999                        }
1000                        oci_bind_by_name($stmt, $key, $params[$key]);
1001                }
1002            }
1003        }
1004        return $descriptors;
1005    }
1006
1007    protected function free_descriptors($descriptors) {
1008        foreach ($descriptors as $descriptor) {
1009            // Because all descriptors used in the driver come from LOB::writeTemporary() calls
1010            // we can safely close them here unconditionally.
1011            $descriptor->close();
1012            // Free resources.
1013            oci_free_descriptor($descriptor);
1014        }
1015    }
1016
1017    /**
1018     * This function is used to convert all the Oracle 1-space defaults to the empty string
1019     * like a really DIRTY HACK to allow it to work better until all those NOT NULL DEFAULT ''
1020     * fields will be out from Moodle.
1021     * @param string the string to be converted to '' (empty string) if it's ' ' (one space)
1022     * @param mixed the key of the array in case we are using this function from array_walk,
1023     *              defaults to null for other (direct) uses
1024     * @return boolean always true (the converted variable is returned by reference)
1025     */
1026    public static function onespace2empty(&$item, $key=null) {
1027        $item = ($item === ' ') ? '' : $item;
1028        return true;
1029    }
1030
1031    /**
1032     * Execute general sql query. Should be used only when no other method suitable.
1033     * Do NOT use this to make changes in db structure, use database_manager methods instead!
1034     * @param string $sql query
1035     * @param array $params query parameters
1036     * @return bool true
1037     * @throws dml_exception A DML specific exception is thrown for any errors.
1038     */
1039    public function execute($sql, array $params=null) {
1040        list($sql, $params, $type) = $this->fix_sql_params($sql, $params);
1041
1042        if (strpos($sql, ';') !== false) {
1043            throw new coding_exception('moodle_database::execute() Multiple sql statements found or bound parameters not used properly in query!');
1044        }
1045
1046        list($sql, $params) = $this->tweak_param_names($sql, $params);
1047        $this->query_start($sql, $params, SQL_QUERY_UPDATE);
1048        $stmt = $this->parse_query($sql);
1049        $descriptors = array();
1050        $this->bind_params($stmt, $params, null, $descriptors);
1051        $result = oci_execute($stmt, $this->commit_status);
1052        $this->free_descriptors($descriptors);
1053        $this->query_end($result, $stmt);
1054        oci_free_statement($stmt);
1055
1056        return true;
1057    }
1058
1059    /**
1060     * Get a single database record as an object using a SQL statement.
1061     *
1062     * The SQL statement should normally only return one record.
1063     * It is recommended to use get_records_sql() if more matches possible!
1064     *
1065     * @param string $sql The SQL string you wish to be executed, should normally only return one record.
1066     * @param array $params array of sql parameters
1067     * @param int $strictness IGNORE_MISSING means compatible mode, false returned if record not found, debug message if more found;
1068     *                        IGNORE_MULTIPLE means return first, ignore multiple records found(not recommended);
1069     *                        MUST_EXIST means throw exception if no record or multiple records found
1070     * @return mixed a fieldset object containing the first matching record, false or exception if error not found depending on mode
1071     * @throws dml_exception A DML specific exception is thrown for any errors.
1072     */
1073    public function get_record_sql($sql, array $params=null, $strictness=IGNORE_MISSING) {
1074        $strictness = (int)$strictness;
1075        if ($strictness == IGNORE_MULTIPLE) {
1076            // do not limit here - ORA does not like that
1077            $rs = $this->get_recordset_sql($sql, $params);
1078            $result = false;
1079            foreach ($rs as $rec) {
1080                $result = $rec;
1081                break;
1082            }
1083            $rs->close();
1084            return $result;
1085        }
1086        return parent::get_record_sql($sql, $params, $strictness);
1087    }
1088
1089    /**
1090     * Get a number of records as a moodle_recordset using a SQL statement.
1091     *
1092     * Since this method is a little less readable, use of it should be restricted to
1093     * code where it's possible there might be large datasets being returned.  For known
1094     * small datasets use get_records_sql - it leads to simpler code.
1095     *
1096     * The return type is like:
1097     * @see function get_recordset.
1098     *
1099     * @param string $sql the SQL select query to execute.
1100     * @param array $params array of sql parameters
1101     * @param int $limitfrom return a subset of records, starting at this point (optional, required if $limitnum is set).
1102     * @param int $limitnum return a subset comprising this many records (optional, required if $limitfrom is set).
1103     * @return moodle_recordset instance
1104     * @throws dml_exception A DML specific exception is thrown for any errors.
1105     */
1106    public function get_recordset_sql($sql, array $params=null, $limitfrom=0, $limitnum=0) {
1107
1108        list($sql, $params, $type) = $this->fix_sql_params($sql, $params);
1109
1110        list($rawsql, $params) = $this->get_limit_sql($sql, $params, $limitfrom, $limitnum);
1111
1112        list($rawsql, $params) = $this->tweak_param_names($rawsql, $params);
1113        $this->query_start($rawsql, $params, SQL_QUERY_SELECT);
1114        $stmt = $this->parse_query($rawsql);
1115        $descriptors = array();
1116        $this->bind_params($stmt, $params, null, $descriptors);
1117        $result = oci_execute($stmt, $this->commit_status);
1118        $this->free_descriptors($descriptors);
1119        $this->query_end($result, $stmt);
1120
1121        return $this->create_recordset($stmt);
1122    }
1123
1124    protected function create_recordset($stmt) {
1125        return new oci_native_moodle_recordset($stmt);
1126    }
1127
1128    /**
1129     * Get a number of records as an array of objects using a SQL statement.
1130     *
1131     * Return value is like:
1132     * @see function get_records.
1133     *
1134     * @param string $sql the SQL select query to execute. The first column of this SELECT statement
1135     *   must be a unique value (usually the 'id' field), as it will be used as the key of the
1136     *   returned array.
1137     * @param array $params array of sql parameters
1138     * @param int $limitfrom return a subset of records, starting at this point (optional, required if $limitnum is set).
1139     * @param int $limitnum return a subset comprising this many records (optional, required if $limitfrom is set).
1140     * @return array of objects, or empty array if no records were found
1141     * @throws dml_exception A DML specific exception is thrown for any errors.
1142     */
1143    public function get_records_sql($sql, array $params=null, $limitfrom=0, $limitnum=0) {
1144
1145        list($sql, $params, $type) = $this->fix_sql_params($sql, $params);
1146
1147        list($rawsql, $params) = $this->get_limit_sql($sql, $params, $limitfrom, $limitnum);
1148
1149        list($rawsql, $params) = $this->tweak_param_names($rawsql, $params);
1150        $this->query_start($rawsql, $params, SQL_QUERY_SELECT);
1151        $stmt = $this->parse_query($rawsql);
1152        $descriptors = array();
1153        $this->bind_params($stmt, $params, null, $descriptors);
1154        $result = oci_execute($stmt, $this->commit_status);
1155        $this->free_descriptors($descriptors);
1156        $this->query_end($result, $stmt);
1157
1158        $records = null;
1159        oci_fetch_all($stmt, $records, 0, -1, OCI_FETCHSTATEMENT_BY_ROW);
1160        oci_free_statement($stmt);
1161
1162        $return = array();
1163
1164        foreach ($records as $row) {
1165            $row = array_change_key_case($row, CASE_LOWER);
1166            unset($row['oracle_rownum']);
1167            array_walk($row, array('oci_native_moodle_database', 'onespace2empty'));
1168            $id = reset($row);
1169            if (isset($return[$id])) {
1170                $colname = key($row);
1171                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);
1172            }
1173            $return[$id] = (object)$row;
1174        }
1175
1176        return $return;
1177    }
1178
1179    /**
1180     * Selects records and return values (first field) as an array using a SQL statement.
1181     *
1182     * @param string $sql The SQL query
1183     * @param array $params array of sql parameters
1184     * @return array of values
1185     * @throws dml_exception A DML specific exception is thrown for any errors.
1186     */
1187    public function get_fieldset_sql($sql, array $params=null) {
1188        list($sql, $params, $type) = $this->fix_sql_params($sql, $params);
1189
1190        list($sql, $params) = $this->tweak_param_names($sql, $params);
1191        $this->query_start($sql, $params, SQL_QUERY_SELECT);
1192        $stmt = $this->parse_query($sql);
1193        $descriptors = array();
1194        $this->bind_params($stmt, $params, null, $descriptors);
1195        $result = oci_execute($stmt, $this->commit_status);
1196        $this->free_descriptors($descriptors);
1197        $this->query_end($result, $stmt);
1198
1199        $records = null;
1200        oci_fetch_all($stmt, $records, 0, -1, OCI_FETCHSTATEMENT_BY_COLUMN);
1201        oci_free_statement($stmt);
1202
1203        $return = reset($records);
1204        array_walk($return, array('oci_native_moodle_database', 'onespace2empty'));
1205
1206        return $return;
1207    }
1208
1209    /**
1210     * Insert new record into database, as fast as possible, no safety checks, lobs not supported.
1211     * @param string $table name
1212     * @param mixed $params data record as object or array
1213     * @param bool $returnit return it of inserted record
1214     * @param bool $bulk true means repeated inserts expected
1215     * @param bool $customsequence true if 'id' included in $params, disables $returnid
1216     * @return bool|int true or new id
1217     * @throws dml_exception A DML specific exception is thrown for any errors.
1218     */
1219    public function insert_record_raw($table, $params, $returnid=true, $bulk=false, $customsequence=false) {
1220        if (!is_array($params)) {
1221            $params = (array)$params;
1222        }
1223
1224        $returning = "";
1225
1226        if ($customsequence) {
1227            if (!isset($params['id'])) {
1228                throw new coding_exception('moodle_database::insert_record_raw() id field must be specified if custom sequences used.');
1229            }
1230            $returnid = false;
1231        } else {
1232            unset($params['id']);
1233            if ($returnid) {
1234                $returning = " RETURNING id INTO :oracle_id"; // crazy name nobody is ever going to use or parameter ;-)
1235            }
1236        }
1237
1238        if (empty($params)) {
1239            throw new coding_exception('moodle_database::insert_record_raw() no fields found.');
1240        }
1241
1242        $fields = implode(',', array_keys($params));
1243        $values = array();
1244        foreach ($params as $pname => $value) {
1245            $values[] = ":$pname";
1246        }
1247        $values = implode(',', $values);
1248
1249        $sql = "INSERT INTO {" . $table . "} ($fields) VALUES ($values)";
1250        list($sql, $params, $type) = $this->fix_sql_params($sql, $params);
1251        $sql .= $returning;
1252
1253        $id = 0;
1254
1255        // note we don't need tweak_param_names() here. Placeholders are safe column names. MDL-28080
1256        // list($sql, $params) = $this->tweak_param_names($sql, $params);
1257        $this->query_start($sql, $params, SQL_QUERY_INSERT);
1258        $stmt = $this->parse_query($sql);
1259        if ($returning) {
1260            oci_bind_by_name($stmt, ":oracle_id", $id, 10, SQLT_INT);
1261        }
1262        $descriptors = array();
1263        $this->bind_params($stmt, $params, $table, $descriptors);
1264        $result = oci_execute($stmt, $this->commit_status);
1265        $this->free_descriptors($descriptors);
1266        $this->query_end($result, $stmt);
1267        oci_free_statement($stmt);
1268
1269        if (!$returnid) {
1270            return true;
1271        }
1272
1273        if (!$returning) {
1274            die('TODO - implement oracle 9.2 insert support'); //TODO
1275        }
1276
1277        return (int)$id;
1278    }
1279
1280    /**
1281     * Insert a record into a table and return the "id" field if required.
1282     *
1283     * Some conversions and safety checks are carried out. Lobs are supported.
1284     * If the return ID isn't required, then this just reports success as true/false.
1285     * $data is an object containing needed data
1286     * @param string $table The database table to be inserted into
1287     * @param object|array $dataobject A data object with values for one or more fields in the record
1288     * @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.
1289     * @return bool|int true or new id
1290     * @throws dml_exception A DML specific exception is thrown for any errors.
1291     */
1292    public function insert_record($table, $dataobject, $returnid=true, $bulk=false) {
1293        $dataobject = (array)$dataobject;
1294
1295        $columns = $this->get_columns($table);
1296        if (empty($columns)) {
1297            throw new dml_exception('ddltablenotexist', $table);
1298        }
1299
1300        $cleaned = array();
1301
1302        foreach ($dataobject as $field=>$value) {
1303            if ($field === 'id') {
1304                continue;
1305            }
1306            if (!isset($columns[$field])) { // Non-existing table field, skip it
1307                continue;
1308            }
1309            $column = $columns[$field];
1310            $cleaned[$field] = $this->normalise_value($column, $value);
1311        }
1312
1313        return $this->insert_record_raw($table, $cleaned, $returnid, $bulk);
1314    }
1315
1316    /**
1317     * Import a record into a table, id field is required.
1318     * Safety checks are NOT carried out. Lobs are supported.
1319     *
1320     * @param string $table name of database table to be inserted into
1321     * @param object $dataobject A data object with values for one or more fields in the record
1322     * @return bool true
1323     * @throws dml_exception A DML specific exception is thrown for any errors.
1324     */
1325    public function import_record($table, $dataobject) {
1326        $dataobject = (array)$dataobject;
1327
1328        $columns = $this->get_columns($table);
1329        $cleaned = array();
1330
1331        foreach ($dataobject as $field=>$value) {
1332            if (!isset($columns[$field])) {
1333                continue;
1334            }
1335            $column = $columns[$field];
1336            $cleaned[$field] = $this->normalise_value($column, $value);
1337        }
1338
1339        return $this->insert_record_raw($table, $cleaned, false, true, true);
1340    }
1341
1342    /**
1343     * Update record in database, as fast as possible, no safety checks, lobs not supported.
1344     * @param string $table name
1345     * @param mixed $params data record as object or array
1346     * @param bool true means repeated updates expected
1347     * @return bool true
1348     * @throws dml_exception A DML specific exception is thrown for any errors.
1349     */
1350    public function update_record_raw($table, $params, $bulk=false) {
1351        $params = (array)$params;
1352
1353        if (!isset($params['id'])) {
1354            throw new coding_exception('moodle_database::update_record_raw() id field must be specified.');
1355        }
1356
1357        if (empty($params)) {
1358            throw new coding_exception('moodle_database::update_record_raw() no fields found.');
1359        }
1360
1361        $sets = array();
1362        foreach ($params as $field=>$value) {
1363            if ($field == 'id') {
1364                continue;
1365            }
1366            $sets[] = "$field = :$field";
1367        }
1368
1369        $sets = implode(',', $sets);
1370        $sql = "UPDATE {" . $table . "} SET $sets WHERE id=:id";
1371        list($sql, $params, $type) = $this->fix_sql_params($sql, $params);
1372
1373        // note we don't need tweak_param_names() here. Placeholders are safe column names. MDL-28080
1374        // list($sql, $params) = $this->tweak_param_names($sql, $params);
1375        $this->query_start($sql, $params, SQL_QUERY_UPDATE);
1376        $stmt = $this->parse_query($sql);
1377        $descriptors = array();
1378        $this->bind_params($stmt, $params, $table, $descriptors);
1379        $result = oci_execute($stmt, $this->commit_status);
1380        $this->free_descriptors($descriptors);
1381        $this->query_end($result, $stmt);
1382        oci_free_statement($stmt);
1383
1384        return true;
1385    }
1386
1387    /**
1388     * Update a record in a table
1389     *
1390     * $dataobject is an object containing needed data
1391     * Relies on $dataobject having a variable "id" to
1392     * specify the record to update
1393     *
1394     * @param string $table The database table to be checked against.
1395     * @param object $dataobject An object with contents equal to fieldname=>fieldvalue. Must have an entry for 'id' to map to the table specified.
1396     * @param bool true means repeated updates expected
1397     * @return bool true
1398     * @throws dml_exception A DML specific exception is thrown for any errors.
1399     */
1400    public function update_record($table, $dataobject, $bulk=false) {
1401        $dataobject = (array)$dataobject;
1402
1403        $columns = $this->get_columns($table);
1404        $cleaned = array();
1405
1406        foreach ($dataobject as $field=>$value) {
1407            if (!isset($columns[$field])) {
1408                continue;
1409            }
1410            $column = $columns[$field];
1411            $cleaned[$field] = $this->normalise_value($column, $value);
1412        }
1413
1414        $this->update_record_raw($table, $cleaned, $bulk);
1415
1416        return true;
1417    }
1418
1419    /**
1420     * Set a single field in every table record which match a particular WHERE clause.
1421     *
1422     * @param string $table The database table to be checked against.
1423     * @param string $newfield the field to set.
1424     * @param string $newvalue the value to set the field to.
1425     * @param string $select A fragment of SQL to be used in a where clause in the SQL call.
1426     * @param array $params array of sql parameters
1427     * @return bool true
1428     * @throws dml_exception A DML specific exception is thrown for any errors.
1429     */
1430    public function set_field_select($table, $newfield, $newvalue, $select, array $params=null) {
1431
1432        if ($select) {
1433            $select = "WHERE $select";
1434        }
1435        if (is_null($params)) {
1436            $params = array();
1437        }
1438
1439        // Get column metadata
1440        $columns = $this->get_columns($table);
1441        $column = $columns[$newfield];
1442
1443        $newvalue = $this->normalise_value($column, $newvalue);
1444
1445        list($select, $params, $type) = $this->fix_sql_params($select, $params);
1446
1447        if (is_bool($newvalue)) {
1448            $newvalue = (int)$newvalue; // prevent "false" problems
1449        }
1450        if (is_null($newvalue)) {
1451            $newsql = "$newfield = NULL";
1452        } else {
1453            // Set the param to array ($newfield => $newvalue) and key to 'newfieldtoset'
1454            // name in the build sql. Later, bind_params() will detect the value array and
1455            // perform the needed modifications to allow the query to work. Note that
1456            // 'newfieldtoset' is one arbitrary name that hopefully won't be used ever
1457            // in order to avoid problems where the same field is used both in the set clause and in
1458            // the conditions. This was breaking badly in drivers using NAMED params like oci.
1459            $params['newfieldtoset'] = array($newfield => $newvalue);
1460            $newsql = "$newfield = :newfieldtoset";
1461        }
1462        $sql = "UPDATE {" . $table . "} SET $newsql $select";
1463        list($sql, $params, $type) = $this->fix_sql_params($sql, $params);
1464
1465        list($sql, $params) = $this->tweak_param_names($sql, $params);
1466        $this->query_start($sql, $params, SQL_QUERY_UPDATE);
1467        $stmt = $this->parse_query($sql);
1468        $descriptors = array();
1469        $this->bind_params($stmt, $params, $table, $descriptors);
1470        $result = oci_execute($stmt, $this->commit_status);
1471        $this->free_descriptors($descriptors);
1472        $this->query_end($result, $stmt);
1473        oci_free_statement($stmt);
1474
1475        return true;
1476    }
1477
1478    /**
1479     * Delete one or more records from a table which match a particular WHERE clause.
1480     *
1481     * @param string $table The database table to be checked against.
1482     * @param string $select A fragment of SQL to be used in a where clause in the SQL call (used to define the selection criteria).
1483     * @param array $params array of sql parameters
1484     * @return bool true
1485     * @throws dml_exception A DML specific exception is thrown for any errors.
1486     */
1487    public function delete_records_select($table, $select, array $params=null) {
1488
1489        if ($select) {
1490            $select = "WHERE $select";
1491        }
1492
1493        $sql = "DELETE FROM {" . $table . "} $select";
1494
1495        list($sql, $params, $type) = $this->fix_sql_params($sql, $params);
1496
1497        list($sql, $params) = $this->tweak_param_names($sql, $params);
1498        $this->query_start($sql, $params, SQL_QUERY_UPDATE);
1499        $stmt = $this->parse_query($sql);
1500        $descriptors = array();
1501        $this->bind_params($stmt, $params, null, $descriptors);
1502        $result = oci_execute($stmt, $this->commit_status);
1503        $this->free_descriptors($descriptors);
1504        $this->query_end($result, $stmt);
1505        oci_free_statement($stmt);
1506
1507        return true;
1508    }
1509
1510    function sql_null_from_clause() {
1511        return ' FROM dual';
1512    }
1513
1514    public function sql_bitand($int1, $int2) {
1515        return 'bitand((' . $int1 . '), (' . $int2 . '))';
1516    }
1517
1518    public function sql_bitnot($int1) {
1519        return '((0 - (' . $int1 . ')) - 1)';
1520    }
1521
1522    public function sql_bitor($int1, $int2) {
1523        return 'MOODLELIB.BITOR(' . $int1 . ', ' . $int2 . ')';
1524    }
1525
1526    public function sql_bitxor($int1, $int2) {
1527        return 'MOODLELIB.BITXOR(' . $int1 . ', ' . $int2 . ')';
1528    }
1529
1530    /**
1531     * Returns the SQL text to be used in order to perform module '%'
1532     * operation - remainder after division
1533     *
1534     * @param integer int1 first integer in the operation
1535     * @param integer int2 second integer in the operation
1536     * @return string the piece of SQL code to be used in your statement.
1537     */
1538    public function sql_modulo($int1, $int2) {
1539        return 'MOD(' . $int1 . ', ' . $int2 . ')';
1540    }
1541
1542    public function sql_cast_char2int($fieldname, $text=false) {
1543        if (!$text) {
1544            return ' CAST(' . $fieldname . ' AS INT) ';
1545        } else {
1546            return ' CAST(' . $this->sql_compare_text($fieldname) . ' AS INT) ';
1547        }
1548    }
1549
1550    public function sql_cast_char2real($fieldname, $text=false) {
1551        if (!$text) {
1552            return ' CAST(' . $fieldname . ' AS FLOAT) ';
1553        } else {
1554            return ' CAST(' . $this->sql_compare_text($fieldname) . ' AS FLOAT) ';
1555        }
1556    }
1557
1558    /**
1559     * Returns 'LIKE' part of a query.
1560     *
1561     * @param string $fieldname usually name of the table column
1562     * @param string $param usually bound query parameter (?, :named)
1563     * @param bool $casesensitive use case sensitive search
1564     * @param bool $accensensitive use accent sensitive search (not all databases support accent insensitive)
1565     * @param bool $notlike true means "NOT LIKE"
1566     * @param string $escapechar escape char for '%' and '_'
1567     * @return string SQL code fragment
1568     */
1569    public function sql_like($fieldname, $param, $casesensitive = true, $accentsensitive = true, $notlike = false, $escapechar = '\\') {
1570        if (strpos($param, '%') !== false) {
1571            debugging('Potential SQL injection detected, sql_like() expects bound parameters (? or :named)');
1572        }
1573
1574        $LIKE = $notlike ? 'NOT LIKE' : 'LIKE';
1575
1576        // no accent sensitiveness here for now, sorry
1577
1578        if ($casesensitive) {
1579            return "$fieldname $LIKE $param ESCAPE '$escapechar'";
1580        } else {
1581            return "LOWER($fieldname) $LIKE LOWER($param) ESCAPE '$escapechar'";
1582        }
1583    }
1584
1585    public function sql_concat() {
1586        $arr = func_get_args();
1587        if (empty($arr)) {
1588            return " ' ' ";
1589        }
1590        foreach ($arr as $k => $v) {
1591            if ($v === "' '") {
1592                $arr[$k] = "'*OCISP*'"; // New mega hack.
1593            }
1594        }
1595        $s = $this->recursive_concat($arr);
1596        return " MOODLELIB.UNDO_MEGA_HACK($s) ";
1597    }
1598
1599    public function sql_concat_join($separator="' '", $elements = array()) {
1600        if ($separator === "' '") {
1601            $separator = "'*OCISP*'"; // New mega hack.
1602        }
1603        foreach ($elements as $k => $v) {
1604            if ($v === "' '") {
1605                $elements[$k] = "'*OCISP*'"; // New mega hack.
1606            }
1607        }
1608        for ($n = count($elements)-1; $n > 0 ; $n--) {
1609            array_splice($elements, $n, 0, $separator);
1610        }
1611        if (empty($elements)) {
1612            return " ' ' ";
1613        }
1614        $s = $this->recursive_concat($elements);
1615        return " MOODLELIB.UNDO_MEGA_HACK($s) ";
1616    }
1617
1618    /**
1619     * Return SQL for performing group concatenation on given field/expression
1620     *
1621     * @param string $field
1622     * @param string $separator
1623     * @param string $sort
1624     * @return string
1625     */
1626    public function sql_group_concat(string $field, string $separator = ', ', string $sort = ''): string {
1627        $fieldsort = $sort ?: '1';
1628        return "LISTAGG({$field}, '{$separator}') WITHIN GROUP (ORDER BY {$fieldsort})";
1629    }
1630
1631    /**
1632     * Constructs 'IN()' or '=' sql fragment
1633     *
1634     * Method overriding {@link moodle_database::get_in_or_equal} to be able to get
1635     * more than 1000 elements working, to avoid ORA-01795. We use a pivoting technique
1636     * to be able to transform the params into virtual rows, so the original IN()
1637     * expression gets transformed into a subquery. Once more, be noted that we shouldn't
1638     * be using ever get_in_or_equal() with such number of parameters (proper subquery and/or
1639     * chunking should be used instead).
1640     *
1641     * @param mixed $items A single value or array of values for the expression.
1642     * @param int $type Parameter bounding type : SQL_PARAMS_QM or SQL_PARAMS_NAMED.
1643     * @param string $prefix Named parameter placeholder prefix (a unique counter value is appended to each parameter name).
1644     * @param bool $equal True means we want to equate to the constructed expression, false means we don't want to equate to it.
1645     * @param mixed $onemptyitems This defines the behavior when the array of items provided is empty. Defaults to false,
1646     *              meaning throw exceptions. Other values will become part of the returned SQL fragment.
1647     * @throws coding_exception | dml_exception
1648     * @return array A list containing the constructed sql fragment and an array of parameters.
1649     */
1650    public function get_in_or_equal($items, $type=SQL_PARAMS_QM, $prefix='param', $equal=true, $onemptyitems=false) {
1651        list($sql, $params) = parent::get_in_or_equal($items, $type, $prefix,  $equal, $onemptyitems);
1652
1653        // Less than 1000 elements, nothing to do.
1654        if (count($params) < 1000) {
1655            return array($sql, $params); // Return unmodified.
1656        }
1657
1658        // Extract the interesting parts of the sql to rewrite.
1659        if (preg_match('!(^.*IN \()([^\)]*)(.*)$!', $sql, $matches) === false) {
1660            return array($sql, $params); // Return unmodified.
1661        }
1662
1663        $instart = $matches[1];
1664        $insql = $matches[2];
1665        $inend = $matches[3];
1666        $newsql = '';
1667
1668        // Some basic verification about the matching going ok.
1669        $insqlarr = explode(',', $insql);
1670        if (count($insqlarr) !== count($params)) {
1671            return array($sql, $params); // Return unmodified.
1672        }
1673
1674        // Arrived here, we need to chunk and pivot the params, building a new sql (params remain the same).
1675        $addunionclause = false;
1676        while ($chunk = array_splice($insqlarr, 0, 125)) { // Each chunk will handle up to 125 (+125 +1) elements (DECODE max is 255).
1677            $chunksize = count($chunk);
1678            if ($addunionclause) {
1679                $newsql .= "\n    UNION ALL";
1680            }
1681            $newsql .= "\n        SELECT DECODE(pivot";
1682            $counter = 1;
1683            foreach ($chunk as $element) {
1684                $newsql .= ",\n            {$counter}, " . trim($element);
1685                $counter++;
1686            }
1687            $newsql .= ")";
1688            $newsql .= "\n        FROM dual";
1689            $newsql .= "\n        CROSS JOIN (SELECT LEVEL AS pivot FROM dual CONNECT BY LEVEL <= {$chunksize})";
1690            $addunionclause = true;
1691        }
1692
1693        // Rebuild the complete IN() clause and return it.
1694        return array($instart . $newsql . $inend, $params);
1695    }
1696
1697    /**
1698     * Mega hacky magic to work around crazy Oracle NULL concats.
1699     * @param array $args
1700     * @return string
1701     */
1702    protected function recursive_concat(array $args) {
1703        $count = count($args);
1704        if ($count == 1) {
1705            $arg = reset($args);
1706            return $arg;
1707        }
1708        if ($count == 2) {
1709            $args[] = "' '";
1710            // No return here intentionally.
1711        }
1712        $first = array_shift($args);
1713        $second = array_shift($args);
1714        $third = $this->recursive_concat($args);
1715        return "MOODLELIB.TRICONCAT($first, $second, $third)";
1716    }
1717
1718    /**
1719     * Returns the SQL for returning searching one string for the location of another.
1720     */
1721    public function sql_position($needle, $haystack) {
1722        return "INSTR(($haystack), ($needle))";
1723    }
1724
1725    /**
1726     * Returns the SQL to know if one field is empty.
1727     *
1728     * @param string $tablename Name of the table (without prefix). Not used for now but can be
1729     *                          necessary in the future if we want to use some introspection using
1730     *                          meta information against the DB.
1731     * @param string $fieldname Name of the field we are going to check
1732     * @param bool $nullablefield For specifying if the field is nullable (true) or no (false) in the DB.
1733     * @param bool $textfield For specifying if it is a text (also called clob) field (true) or a varchar one (false)
1734     * @return string the sql code to be added to check for empty values
1735     */
1736    public function sql_isempty($tablename, $fieldname, $nullablefield, $textfield) {
1737        if ($textfield) {
1738            return " (".$this->sql_compare_text($fieldname)." = ' ') ";
1739        } else {
1740            return " ($fieldname = ' ') ";
1741        }
1742    }
1743
1744    public function sql_order_by_text($fieldname, $numchars=32) {
1745        return 'dbms_lob.substr(' . $fieldname . ', ' . $numchars . ',1)';
1746    }
1747
1748    /**
1749     * Is the required OCI server package installed?
1750     * @return bool
1751     */
1752    protected function oci_package_installed() {
1753        $sql = "SELECT 1
1754                FROM user_objects
1755                WHERE object_type = 'PACKAGE BODY'
1756                  AND object_name = 'MOODLELIB'
1757                  AND status = 'VALID'";
1758        $this->query_start($sql, null, SQL_QUERY_AUX);
1759        $stmt = $this->parse_query($sql);
1760        $result = oci_execute($stmt, $this->commit_status);
1761        $this->query_end($result, $stmt);
1762        $records = null;
1763        oci_fetch_all($stmt, $records, 0, -1, OCI_FETCHSTATEMENT_BY_ROW);
1764        oci_free_statement($stmt);
1765        return isset($records[0]) && reset($records[0]) ? true : false;
1766    }
1767
1768    /**
1769     * Try to add required moodle package into oracle server.
1770     */
1771    protected function attempt_oci_package_install() {
1772        $sqls = file_get_contents(__DIR__.'/oci_native_moodle_package.sql');
1773        $sqls = preg_split('/^\/$/sm', $sqls);
1774        foreach ($sqls as $sql) {
1775            $sql = trim($sql);
1776            if ($sql === '' or $sql === 'SHOW ERRORS') {
1777                continue;
1778            }
1779            $this->change_database_structure($sql);
1780        }
1781    }
1782
1783    /**
1784     * Does this driver support tool_replace?
1785     *
1786     * @since Moodle 2.8
1787     * @return bool
1788     */
1789    public function replace_all_text_supported() {
1790        return true;
1791    }
1792
1793    public function session_lock_supported() {
1794        return true;
1795    }
1796
1797    /**
1798     * Obtain session lock
1799     * @param int $rowid id of the row with session record
1800     * @param int $timeout max allowed time to wait for the lock in seconds
1801     * @return void
1802     */
1803    public function get_session_lock($rowid, $timeout) {
1804        parent::get_session_lock($rowid, $timeout);
1805
1806        $fullname = $this->dbname.'-'.$this->prefix.'-session-'.$rowid;
1807        $sql = 'SELECT MOODLELIB.GET_LOCK(:lockname, :locktimeout) FROM DUAL';
1808        $params = array('lockname' => $fullname , 'locktimeout' => $timeout);
1809        $this->query_start($sql, $params, SQL_QUERY_AUX);
1810        $stmt = $this->parse_query($sql);
1811        $this->bind_params($stmt, $params);
1812        $result = oci_execute($stmt, $this->commit_status);
1813        if ($result === false) { // Any failure in get_lock() raises error, causing return of bool false
1814            throw new dml_sessionwait_exception();
1815        }
1816        $this->query_end($result, $stmt);
1817        oci_free_statement($stmt);
1818    }
1819
1820    public function release_session_lock($rowid) {
1821        if (!$this->used_for_db_sessions) {
1822            return;
1823        }
1824
1825        parent::release_session_lock($rowid);
1826
1827        $fullname = $this->dbname.'-'.$this->prefix.'-session-'.$rowid;
1828        $params = array('lockname' => $fullname);
1829        $sql = 'SELECT MOODLELIB.RELEASE_LOCK(:lockname) FROM DUAL';
1830        $this->query_start($sql, $params, SQL_QUERY_AUX);
1831        $stmt = $this->parse_query($sql);
1832        $this->bind_params($stmt, $params);
1833        $result = oci_execute($stmt, $this->commit_status);
1834        $this->query_end($result, $stmt);
1835        oci_free_statement($stmt);
1836    }
1837
1838    /**
1839     * Driver specific start of real database transaction,
1840     * this can not be used directly in code.
1841     * @return void
1842     */
1843    protected function begin_transaction() {
1844        $this->commit_status = OCI_DEFAULT; //Done! ;-)
1845    }
1846
1847    /**
1848     * Driver specific commit of real database transaction,
1849     * this can not be used directly in code.
1850     * @return void
1851     */
1852    protected function commit_transaction() {
1853        $this->query_start('--oracle_commit', NULL, SQL_QUERY_AUX);
1854        $result = oci_commit($this->oci);
1855        $this->commit_status = OCI_COMMIT_ON_SUCCESS;
1856        $this->query_end($result);
1857    }
1858
1859    /**
1860     * Driver specific abort of real database transaction,
1861     * this can not be used directly in code.
1862     * @return void
1863     */
1864    protected function rollback_transaction() {
1865        $this->query_start('--oracle_rollback', NULL, SQL_QUERY_AUX);
1866        $result = oci_rollback($this->oci);
1867        $this->commit_status = OCI_COMMIT_ON_SUCCESS;
1868        $this->query_end($result);
1869    }
1870}
1871