MDL-45536 atto_html: Update the textarea size when switching to HTML view
[moodle.git] / lib / dml / sqlsrv_native_moodle_database.php
bloba2232ab36e83cdf68a195a3099e5276d55fd0919
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 2 of the License, or
7 // (at your option) any later version.
8 //
9 // Moodle is distributed in the hope that it will be useful,
10 // but WITHOUT ANY WARRANTY; without even the implied warranty of
11 // MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the
12 // GNU General Public License for more details.
14 // You should have received a copy of the GNU General Public License
15 // along with Moodle. If not, see <http://www.gnu.org/licenses/>.
17 /**
18 * Native sqlsrv class representing moodle database interface.
20 * @package core_dml
21 * @copyright 2009 onwards Eloy Lafuente (stronk7) {@link http://stronk7.com}
22 * @license http://www.gnu.org/copyleft/gpl.html GNU GPL v2 or later
25 defined('MOODLE_INTERNAL') || die();
27 require_once(__DIR__.'/moodle_database.php');
28 require_once(__DIR__.'/sqlsrv_native_moodle_recordset.php');
29 require_once(__DIR__.'/sqlsrv_native_moodle_temptables.php');
31 /**
32 * Native sqlsrv class representing moodle database interface.
34 * @package core_dml
35 * @copyright 2009 onwards Eloy Lafuente (stronk7) {@link http://stronk7.com}
36 * @license http://www.gnu.org/copyleft/gpl.html GNU GPL v2 or later
38 class sqlsrv_native_moodle_database extends moodle_database {
40 protected $sqlsrv = null;
41 protected $last_error_reporting; // To handle SQL*Server-Native driver default verbosity
42 protected $temptables; // Control existing temptables (sqlsrv_moodle_temptables object)
43 protected $collation; // current DB collation cache
44 /** @var array list of open recordsets */
45 protected $recordsets = array();
47 /**
48 * Constructor - instantiates the database, specifying if it's external (connect to other systems) or no (Moodle DB)
49 * note this has effect to decide if prefix checks must be performed or no
50 * @param bool true means external database used
52 public function __construct($external=false) {
53 parent::__construct($external);
56 /**
57 * Detects if all needed PHP stuff installed.
58 * Note: can be used before connect()
59 * @return mixed true if ok, string if something
61 public function driver_installed() {
62 // use 'function_exists()' rather than 'extension_loaded()' because
63 // the name used by 'extension_loaded()' is case specific! The extension
64 // therefore *could be* mixed case and hence not found.
65 if (!function_exists('sqlsrv_num_rows')) {
66 if (stripos(PHP_OS, 'win') === 0) {
67 return get_string('nativesqlsrvnodriver', 'install');
68 } else {
69 return get_string('nativesqlsrvnonwindows', 'install');
72 return true;
75 /**
76 * Returns database family type - describes SQL dialect
77 * Note: can be used before connect()
78 * @return string db family name (mysql, postgres, mssql, sqlsrv, oracle, etc.)
80 public function get_dbfamily() {
81 return 'mssql';
84 /**
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() {
90 return 'sqlsrv';
93 /**
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() {
99 return 'native';
103 * Returns localised database type name
104 * Note: can be used before connect()
105 * @return string
107 public function get_name() {
108 return get_string('nativesqlsrv', 'install');
112 * Returns localised database configuration help.
113 * Note: can be used before connect()
114 * @return string
116 public function get_configuration_help() {
117 return get_string('nativesqlsrvhelp', 'install');
121 * Connect to db
122 * Must be called before most other methods. (you can call methods that return connection configuration parameters)
123 * @param string $dbhost The database host.
124 * @param string $dbuser The database username.
125 * @param string $dbpass The database username's password.
126 * @param string $dbname The name of the database being connected to.
127 * @param mixed $prefix string|bool The moodle db table name's prefix. false is used for external databases where prefix not used
128 * @param array $dboptions driver specific options
129 * @return bool true
130 * @throws dml_connection_exception if error
132 public function connect($dbhost, $dbuser, $dbpass, $dbname, $prefix, array $dboptions=null) {
133 if ($prefix == '' and !$this->external) {
134 // Enforce prefixes for everybody but mysql.
135 throw new dml_exception('prefixcannotbeempty', $this->get_dbfamily());
138 $driverstatus = $this->driver_installed();
140 if ($driverstatus !== true) {
141 throw new dml_exception('dbdriverproblem', $driverstatus);
145 * Log all Errors.
147 sqlsrv_configure("WarningsReturnAsErrors", FALSE);
148 sqlsrv_configure("LogSubsystems", SQLSRV_LOG_SYSTEM_OFF);
149 sqlsrv_configure("LogSeverity", SQLSRV_LOG_SEVERITY_ERROR);
151 $this->store_settings($dbhost, $dbuser, $dbpass, $dbname, $prefix, $dboptions);
152 $this->sqlsrv = sqlsrv_connect($this->dbhost, array
154 'UID' => $this->dbuser,
155 'PWD' => $this->dbpass,
156 'Database' => $this->dbname,
157 'CharacterSet' => 'UTF-8',
158 'MultipleActiveResultSets' => true,
159 'ConnectionPooling' => !empty($this->dboptions['dbpersist']),
160 'ReturnDatesAsStrings' => true,
163 if ($this->sqlsrv === false) {
164 $this->sqlsrv = null;
165 $dberr = $this->get_last_error();
167 throw new dml_connection_exception($dberr);
170 // Allow quoted identifiers
171 $sql = "SET QUOTED_IDENTIFIER ON";
172 $this->query_start($sql, null, SQL_QUERY_AUX);
173 $result = sqlsrv_query($this->sqlsrv, $sql);
174 $this->query_end($result);
176 $this->free_result($result);
178 // Force ANSI nulls so the NULL check was done by IS NULL and NOT IS NULL
179 // instead of equal(=) and distinct(<>) symbols
180 $sql = "SET ANSI_NULLS ON";
181 $this->query_start($sql, null, SQL_QUERY_AUX);
182 $result = sqlsrv_query($this->sqlsrv, $sql);
183 $this->query_end($result);
185 $this->free_result($result);
187 // Force ANSI warnings so arithmetic/string overflows will be
188 // returning error instead of transparently truncating data
189 $sql = "SET ANSI_WARNINGS ON";
190 $this->query_start($sql, null, SQL_QUERY_AUX);
191 $result = sqlsrv_query($this->sqlsrv, $sql);
192 $this->query_end($result);
194 // Concatenating null with anything MUST return NULL
195 $sql = "SET CONCAT_NULL_YIELDS_NULL ON";
196 $this->query_start($sql, null, SQL_QUERY_AUX);
197 $result = sqlsrv_query($this->sqlsrv, $sql);
198 $this->query_end($result);
200 $this->free_result($result);
202 // Set transactions isolation level to READ_COMMITTED
203 // prevents dirty reads when using transactions +
204 // is the default isolation level of sqlsrv
205 $sql = "SET TRANSACTION ISOLATION LEVEL READ COMMITTED";
206 $this->query_start($sql, NULL, SQL_QUERY_AUX);
207 $result = sqlsrv_query($this->sqlsrv, $sql);
208 $this->query_end($result);
210 $this->free_result($result);
212 // Connection established and configured, going to instantiate the temptables controller
213 $this->temptables = new sqlsrv_native_moodle_temptables($this);
215 return true;
219 * Close database connection and release all resources
220 * and memory (especially circular memory references).
221 * Do NOT use connect() again, create a new instance if needed.
223 public function dispose() {
224 parent::dispose(); // Call parent dispose to write/close session and other common stuff before closing connection
226 if ($this->sqlsrv) {
227 sqlsrv_close($this->sqlsrv);
228 $this->sqlsrv = null;
233 * Called before each db query.
234 * @param string $sql
235 * @param array $params array of parameters
236 * @param int $type type of query
237 * @param mixed $extrainfo driver specific extra information
238 * @return void
240 protected function query_start($sql, array $params = null, $type, $extrainfo = null) {
241 parent::query_start($sql, $params, $type, $extrainfo);
245 * Called immediately after each db query.
246 * @param mixed db specific result
247 * @return void
249 protected function query_end($result) {
250 parent::query_end($result);
254 * Returns database server info array
255 * @return array Array containing 'description', 'version' and 'database' (current db) info
257 public function get_server_info() {
258 static $info;
260 if (!$info) {
261 $server_info = sqlsrv_server_info($this->sqlsrv);
263 if ($server_info) {
264 $info['description'] = $server_info['SQLServerName'];
265 $info['version'] = $server_info['SQLServerVersion'];
266 $info['database'] = $server_info['CurrentDatabase'];
269 return $info;
273 * Override: Converts short table name {tablename} to real table name
274 * supporting temp tables (#) if detected
276 * @param string sql
277 * @return string sql
279 protected function fix_table_names($sql) {
280 if (preg_match_all('/\{([a-z][a-z0-9_]*)\}/i', $sql, $matches)) {
281 foreach ($matches[0] as $key => $match) {
282 $name = $matches[1][$key];
284 if ($this->temptables->is_temptable($name)) {
285 $sql = str_replace($match, $this->temptables->get_correct_name($name), $sql);
286 } else {
287 $sql = str_replace($match, $this->prefix.$name, $sql);
291 return $sql;
295 * Returns supported query parameter types
296 * @return int bitmask
298 protected function allowed_param_types() {
299 return SQL_PARAMS_QM; // sqlsrv 1.1 can bind
303 * Returns last error reported by database engine.
304 * @return string error message
306 public function get_last_error() {
307 $retErrors = sqlsrv_errors(SQLSRV_ERR_ALL);
308 $errorMessage = 'No errors found';
310 if ($retErrors != null) {
311 $errorMessage = '';
313 foreach ($retErrors as $arrError) {
314 $errorMessage .= "SQLState: ".$arrError['SQLSTATE']."<br>\n";
315 $errorMessage .= "Error Code: ".$arrError['code']."<br>\n";
316 $errorMessage .= "Message: ".$arrError['message']."<br>\n";
320 return $errorMessage;
324 * Prepare the query binding and do the actual query.
326 * @param string $sql The sql statement
327 * @param array $params array of params for binding. If NULL, they are ignored.
328 * @param int $sql_query_type - Type of operation
329 * @param bool $free_result - Default true, transaction query will be freed.
330 * @param bool $scrollable - Default false, to use for quickly seeking to target records
331 * @return resource|bool result
333 private function do_query($sql, $params, $sql_query_type, $free_result = true, $scrollable = false) {
334 list($sql, $params, $type) = $this->fix_sql_params($sql, $params);
337 * Bound variables *are* supported. Until I can get it to work, emulate the bindings
338 * The challenge/problem/bug is that although they work, doing a SELECT SCOPE_IDENTITY()
339 * doesn't return a value (no result set)
341 * -- somebody from MS
344 $sql = $this->emulate_bound_params($sql, $params);
345 $this->query_start($sql, $params, $sql_query_type);
346 if (!$scrollable) { // Only supporting next row
347 $result = sqlsrv_query($this->sqlsrv, $sql);
348 } else { // Supporting absolute/relative rows
349 $result = sqlsrv_query($this->sqlsrv, $sql, array(), array('Scrollable' => SQLSRV_CURSOR_STATIC));
352 if ($result === false) {
353 // TODO do something with error or just use if DEV or DEBUG?
354 $dberr = $this->get_last_error();
357 $this->query_end($result);
359 if ($free_result) {
360 $this->free_result($result);
361 return true;
363 return $result;
367 * Return tables in database WITHOUT current prefix.
368 * @param bool $usecache if true, returns list of cached tables.
369 * @return array of table names in lowercase and without prefix
371 public function get_tables($usecache = true) {
372 if ($usecache and count($this->tables) > 0) {
373 return $this->tables;
375 $this->tables = array ();
376 $prefix = str_replace('_', '\\_', $this->prefix);
377 $sql = "SELECT table_name
378 FROM INFORMATION_SCHEMA.TABLES
379 WHERE table_name LIKE '$prefix%' ESCAPE '\\' AND table_type = 'BASE TABLE'";
381 $this->query_start($sql, null, SQL_QUERY_AUX);
382 $result = sqlsrv_query($this->sqlsrv, $sql);
383 $this->query_end($result);
385 if ($result) {
386 while ($row = sqlsrv_fetch_array($result)) {
387 $tablename = reset($row);
388 if ($this->prefix !== false && $this->prefix !== '') {
389 if (strpos($tablename, $this->prefix) !== 0) {
390 continue;
392 $tablename = substr($tablename, strlen($this->prefix));
394 $this->tables[$tablename] = $tablename;
396 $this->free_result($result);
399 // Add the currently available temptables
400 $this->tables = array_merge($this->tables, $this->temptables->get_temptables());
401 return $this->tables;
405 * Return table indexes - everything lowercased.
406 * @param string $table The table we want to get indexes from.
407 * @return array of arrays
409 public function get_indexes($table) {
410 $indexes = array ();
411 $tablename = $this->prefix.$table;
413 // Indexes aren't covered by information_schema metatables, so we need to
414 // go to sys ones. Skipping primary key indexes on purpose.
415 $sql = "SELECT i.name AS index_name, i.is_unique, ic.index_column_id, c.name AS column_name
416 FROM sys.indexes i
417 JOIN sys.index_columns ic ON i.object_id = ic.object_id AND i.index_id = ic.index_id
418 JOIN sys.columns c ON ic.object_id = c.object_id AND ic.column_id = c.column_id
419 JOIN sys.tables t ON i.object_id = t.object_id
420 WHERE t.name = '$tablename' AND i.is_primary_key = 0
421 ORDER BY i.name, i.index_id, ic.index_column_id";
423 $this->query_start($sql, null, SQL_QUERY_AUX);
424 $result = sqlsrv_query($this->sqlsrv, $sql);
425 $this->query_end($result);
427 if ($result) {
428 $lastindex = '';
429 $unique = false;
430 $columns = array ();
432 while ($row = sqlsrv_fetch_array($result, SQLSRV_FETCH_ASSOC)) {
433 if ($lastindex and $lastindex != $row['index_name'])
434 { // Save lastindex to $indexes and reset info
435 $indexes[$lastindex] = array
437 'unique' => $unique,
438 'columns' => $columns
441 $unique = false;
442 $columns = array ();
444 $lastindex = $row['index_name'];
445 $unique = empty($row['is_unique']) ? false : true;
446 $columns[] = $row['column_name'];
449 if ($lastindex) { // Add the last one if exists
450 $indexes[$lastindex] = array
452 'unique' => $unique,
453 'columns' => $columns
457 $this->free_result($result);
459 return $indexes;
463 * Returns detailed information about columns in table. This information is cached internally.
464 * @param string $table name
465 * @param bool $usecache
466 * @return array array of database_column_info objects indexed with column names
468 public function get_columns($table, $usecache = true) {
469 if ($usecache) {
470 $properties = array('dbfamily' => $this->get_dbfamily(), 'settings' => $this->get_settings_hash());
471 $cache = cache::make('core', 'databasemeta', $properties);
472 if ($data = $cache->get($table)) {
473 return $data;
477 $structure = array();
479 if (!$this->temptables->is_temptable($table)) { // normal table, get metadata from own schema
480 $sql = "SELECT column_name AS name,
481 data_type AS type,
482 numeric_precision AS max_length,
483 character_maximum_length AS char_max_length,
484 numeric_scale AS scale,
485 is_nullable AS is_nullable,
486 columnproperty(object_id(quotename(table_schema) + '.' + quotename(table_name)), column_name, 'IsIdentity') AS auto_increment,
487 column_default AS default_value
488 FROM INFORMATION_SCHEMA.COLUMNS
489 WHERE table_name = '{".$table."}'
490 ORDER BY ordinal_position";
491 } else { // temp table, get metadata from tempdb schema
492 $sql = "SELECT column_name AS name,
493 data_type AS type,
494 numeric_precision AS max_length,
495 character_maximum_length AS char_max_length,
496 numeric_scale AS scale,
497 is_nullable AS is_nullable,
498 columnproperty(object_id(quotename(table_schema) + '.' + quotename(table_name)), column_name, 'IsIdentity') AS auto_increment,
499 column_default AS default_value
500 FROM tempdb.INFORMATION_SCHEMA.COLUMNS ".
501 // check this statement
502 // JOIN tempdb..sysobjects ON name = table_name
503 // WHERE id = object_id('tempdb..{".$table."}')
504 "WHERE table_name LIKE '{".$table."}__________%'
505 ORDER BY ordinal_position";
508 list($sql, $params, $type) = $this->fix_sql_params($sql, null);
510 $this->query_start($sql, null, SQL_QUERY_AUX);
511 $result = sqlsrv_query($this->sqlsrv, $sql);
512 $this->query_end($result);
514 if (!$result) {
515 return array ();
518 while ($rawcolumn = sqlsrv_fetch_array($result, SQLSRV_FETCH_ASSOC)) {
520 $rawcolumn = (object)$rawcolumn;
522 $info = new stdClass();
523 $info->name = $rawcolumn->name;
524 $info->type = $rawcolumn->type;
525 $info->meta_type = $this->sqlsrvtype2moodletype($info->type);
527 // Prepare auto_increment info
528 $info->auto_increment = $rawcolumn->auto_increment ? true : false;
530 // Define type for auto_increment columns
531 $info->meta_type = ($info->auto_increment && $info->meta_type == 'I') ? 'R' : $info->meta_type;
533 // id columns being auto_incremnt are PK by definition
534 $info->primary_key = ($info->name == 'id' && $info->meta_type == 'R' && $info->auto_increment);
536 if ($info->meta_type === 'C' and $rawcolumn->char_max_length == -1) {
537 // This is NVARCHAR(MAX), not a normal NVARCHAR.
538 $info->max_length = -1;
539 $info->meta_type = 'X';
540 } else {
541 // Put correct length for character and LOB types
542 $info->max_length = $info->meta_type == 'C' ? $rawcolumn->char_max_length : $rawcolumn->max_length;
543 $info->max_length = ($info->meta_type == 'X' || $info->meta_type == 'B') ? -1 : $info->max_length;
546 // Scale
547 $info->scale = $rawcolumn->scale;
549 // Prepare not_null info
550 $info->not_null = $rawcolumn->is_nullable == 'NO' ? true : false;
552 // Process defaults
553 $info->has_default = !empty($rawcolumn->default_value);
554 if ($rawcolumn->default_value === NULL) {
555 $info->default_value = NULL;
556 } else {
557 $info->default_value = preg_replace("/^[\(N]+[']?(.*?)[']?[\)]+$/", '\\1', $rawcolumn->default_value);
560 // Process binary
561 $info->binary = $info->meta_type == 'B' ? true : false;
563 $structure[$info->name] = new database_column_info($info);
565 $this->free_result($result);
567 if ($usecache) {
568 $cache->set($table, $structure);
571 return $structure;
575 * Normalise values based in RDBMS dependencies (booleans, LOBs...)
577 * @param database_column_info $column column metadata corresponding with the value we are going to normalise
578 * @param mixed $value value we are going to normalise
579 * @return mixed the normalised value
581 protected function normalise_value($column, $value) {
582 $this->detect_objects($value);
584 if (is_bool($value)) { // Always, convert boolean to int
585 $value = (int)$value;
586 } // And continue processing because text columns with numeric info need special handling below
588 if ($column->meta_type == 'B')
589 { // BLOBs need to be properly "packed", but can be inserted directly if so.
590 if (!is_null($value)) { // If value not null, unpack it to unquoted hexadecimal byte-string format
591 $value = unpack('H*hex', $value); // we leave it as array, so emulate_bound_params() can detect it
592 } // easily and "bind" the param ok.
594 } else if ($column->meta_type == 'X') { // sqlsrv doesn't cast from int to text, so if text column
595 if (is_numeric($value)) { // and is numeric value then cast to string
596 $value = array('numstr' => (string)$value); // and put into array, so emulate_bound_params() will know how
597 } // to "bind" the param ok, avoiding reverse conversion to number
598 } else if ($value === '') {
600 if ($column->meta_type == 'I' or $column->meta_type == 'F' or $column->meta_type == 'N') {
601 $value = 0; // prevent '' problems in numeric fields
604 return $value;
608 * Selectively call sqlsrv_free_stmt(), avoiding some warnings without using the horrible @
610 * @param sqlsrv_resource $resource resource to be freed if possible
611 * @return bool
613 private function free_result($resource) {
614 if (!is_bool($resource)) { // true/false resources cannot be freed
615 return sqlsrv_free_stmt($resource);
620 * Provides mapping between sqlsrv native data types and moodle_database - database_column_info - ones)
622 * @param string $sqlsrv_type native sqlsrv data type
623 * @return string 1-char database_column_info data type
625 private function sqlsrvtype2moodletype($sqlsrv_type) {
626 $type = null;
628 switch (strtoupper($sqlsrv_type)) {
629 case 'BIT':
630 $type = 'L';
631 break;
633 case 'INT':
634 case 'SMALLINT':
635 case 'INTEGER':
636 case 'BIGINT':
637 $type = 'I';
638 break;
640 case 'DECIMAL':
641 case 'REAL':
642 case 'FLOAT':
643 $type = 'N';
644 break;
646 case 'VARCHAR':
647 case 'NVARCHAR':
648 $type = 'C';
649 break;
651 case 'TEXT':
652 case 'NTEXT':
653 case 'VARCHAR(MAX)':
654 case 'NVARCHAR(MAX)':
655 $type = 'X';
656 break;
658 case 'IMAGE':
659 case 'VARBINARY':
660 case 'VARBINARY(MAX)':
661 $type = 'B';
662 break;
664 case 'DATETIME':
665 $type = 'D';
666 break;
669 if (!$type) {
670 throw new dml_exception('invalidsqlsrvnativetype', $sqlsrv_type);
672 return $type;
676 * Do NOT use in code, to be used by database_manager only!
677 * @param string|array $sql query
678 * @return bool true
679 * @throws ddl_change_structure_exception A DDL specific exception is thrown for any errors.
681 public function change_database_structure($sql) {
682 $this->get_manager(); // Includes DDL exceptions classes ;-)
683 $sqls = (array)$sql;
685 try {
686 foreach ($sqls as $sql) {
687 $this->query_start($sql, null, SQL_QUERY_STRUCTURE);
688 $result = sqlsrv_query($this->sqlsrv, $sql);
689 $this->query_end($result);
691 } catch (ddl_change_structure_exception $e) {
692 $this->reset_caches();
693 throw $e;
696 $this->reset_caches();
697 return true;
701 * Prepare the array of params for native binding
703 protected function build_native_bound_params(array $params = null) {
705 return null;
709 * Workaround for SQL*Server Native driver similar to MSSQL driver for
710 * consistent behavior.
712 protected function emulate_bound_params($sql, array $params = null) {
714 if (empty($params)) {
715 return $sql;
717 // ok, we have verified sql statement with ? and correct number of params
718 $parts = array_reverse(explode('?', $sql));
719 $return = array_pop($parts);
720 foreach ($params as $param) {
721 if (is_bool($param)) {
722 $return .= (int)$param;
723 } else if (is_array($param) && isset($param['hex'])) { // detect hex binary, bind it specially
724 $return .= '0x'.$param['hex'];
725 } else if (is_array($param) && isset($param['numstr'])) { // detect numerical strings that *must not*
726 $return .= "N'{$param['numstr']}'"; // be converted back to number params, but bound as strings
727 } else if (is_null($param)) {
728 $return .= 'NULL';
730 } else if (is_number($param)) { // we can not use is_numeric() because it eats leading zeros from strings like 0045646
731 $return .= "'$param'"; // this is a hack for MDL-23997, we intentionally use string because it is compatible with both nvarchar and int types
732 } else if (is_float($param)) {
733 $return .= $param;
734 } else {
735 $param = str_replace("'", "''", $param);
736 $param = str_replace("\0", "", $param);
737 $return .= "N'$param'";
740 $return .= array_pop($parts);
742 return $return;
746 * Execute general sql query. Should be used only when no other method suitable.
747 * Do NOT use this to make changes in db structure, use database_manager methods instead!
748 * @param string $sql query
749 * @param array $params query parameters
750 * @return bool true
751 * @throws dml_exception A DML specific exception is thrown for any errors.
753 public function execute($sql, array $params = null) {
754 if (strpos($sql, ';') !== false) {
755 throw new coding_exception('moodle_database::execute() Multiple sql statements found or bound parameters not used properly in query!');
757 $this->do_query($sql, $params, SQL_QUERY_UPDATE);
758 return true;
762 * Get a number of records as a moodle_recordset using a SQL statement.
764 * Since this method is a little less readable, use of it should be restricted to
765 * code where it's possible there might be large datasets being returned. For known
766 * small datasets use get_records_sql - it leads to simpler code.
768 * The return type is like:
769 * @see function get_recordset.
771 * @param string $sql the SQL select query to execute.
772 * @param array $params array of sql parameters
773 * @param int $limitfrom return a subset of records, starting at this point (optional, required if $limitnum is set).
774 * @param int $limitnum return a subset comprising this many records (optional, required if $limitfrom is set).
775 * @return moodle_recordset instance
776 * @throws dml_exception A DML specific exception is thrown for any errors.
778 public function get_recordset_sql($sql, array $params = null, $limitfrom = 0, $limitnum = 0) {
780 list($limitfrom, $limitnum) = $this->normalise_limit_from_num($limitfrom, $limitnum);
782 if ($limitfrom or $limitnum) {
783 if ($limitnum >= 1) { // Only apply TOP clause if we have any limitnum (limitfrom offset is handled later)
784 $fetch = $limitfrom + $limitnum;
785 if (PHP_INT_MAX - $limitnum < $limitfrom) { // Check PHP_INT_MAX overflow
786 $fetch = PHP_INT_MAX;
788 $sql = preg_replace('/^([\s(])*SELECT([\s]+(DISTINCT|ALL))?(?!\s*TOP\s*\()/i',
789 "\\1SELECT\\2 TOP $fetch", $sql);
792 $result = $this->do_query($sql, $params, SQL_QUERY_SELECT, false, (bool)$limitfrom);
794 if ($limitfrom) { // Skip $limitfrom records
795 sqlsrv_fetch($result, SQLSRV_SCROLL_ABSOLUTE, $limitfrom - 1);
797 return $this->create_recordset($result);
801 * Create a record set and initialize with first row
803 * @param mixed $result
804 * @return sqlsrv_native_moodle_recordset
806 protected function create_recordset($result) {
807 $rs = new sqlsrv_native_moodle_recordset($result, $this);
808 $this->recordsets[] = $rs;
809 return $rs;
813 * Do not use outside of recordset class.
814 * @internal
815 * @param sqlsrv_native_moodle_recordset $rs
817 public function recordset_closed(sqlsrv_native_moodle_recordset $rs) {
818 if ($key = array_search($rs, $this->recordsets, true)) {
819 unset($this->recordsets[$key]);
824 * Get a number of records as an array of objects using a SQL statement.
826 * Return value is like:
827 * @see function get_records.
829 * @param string $sql the SQL select query to execute. The first column of this SELECT statement
830 * must be a unique value (usually the 'id' field), as it will be used as the key of the
831 * returned array.
832 * @param array $params array of sql parameters
833 * @param int $limitfrom return a subset of records, starting at this point (optional, required if $limitnum is set).
834 * @param int $limitnum return a subset comprising this many records (optional, required if $limitfrom is set).
835 * @return array of objects, or empty array if no records were found
836 * @throws dml_exception A DML specific exception is thrown for any errors.
838 public function get_records_sql($sql, array $params = null, $limitfrom = 0, $limitnum = 0) {
840 $rs = $this->get_recordset_sql($sql, $params, $limitfrom, $limitnum);
842 $results = array();
844 foreach ($rs as $row) {
845 $id = reset($row);
847 if (isset($results[$id])) {
848 $colname = key($row);
849 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);
851 $results[$id] = (object)$row;
853 $rs->close();
855 return $results;
859 * Selects records and return values (first field) as an array using a SQL statement.
861 * @param string $sql The SQL query
862 * @param array $params array of sql parameters
863 * @return array of values
864 * @throws dml_exception A DML specific exception is thrown for any errors.
866 public function get_fieldset_sql($sql, array $params = null) {
868 $rs = $this->get_recordset_sql($sql, $params);
870 $results = array ();
872 foreach ($rs as $row) {
873 $results[] = reset($row);
875 $rs->close();
877 return $results;
881 * Insert new record into database, as fast as possible, no safety checks, lobs not supported.
882 * @param string $table name
883 * @param mixed $params data record as object or array
884 * @param bool $returnit return it of inserted record
885 * @param bool $bulk true means repeated inserts expected
886 * @param bool $customsequence true if 'id' included in $params, disables $returnid
887 * @return bool|int true or new id
888 * @throws dml_exception A DML specific exception is thrown for any errors.
890 public function insert_record_raw($table, $params, $returnid=true, $bulk=false, $customsequence=false) {
891 if (!is_array($params)) {
892 $params = (array)$params;
895 $isidentity = false;
897 if ($customsequence) {
898 if (!isset($params['id'])) {
899 throw new coding_exception('moodle_database::insert_record_raw() id field must be specified if custom sequences used.');
902 $returnid = false;
903 $columns = $this->get_columns($table);
904 if (isset($columns['id']) and $columns['id']->auto_increment) {
905 $isidentity = true;
908 // Disable IDENTITY column before inserting record with id, only if the
909 // column is identity, from meta information.
910 if ($isidentity) {
911 $sql = 'SET IDENTITY_INSERT {'.$table.'} ON'; // Yes, it' ON!!
912 $this->do_query($sql, null, SQL_QUERY_AUX);
915 } else {
916 unset($params['id']);
919 if (empty($params)) {
920 throw new coding_exception('moodle_database::insert_record_raw() no fields found.');
922 $fields = implode(',', array_keys($params));
923 $qms = array_fill(0, count($params), '?');
924 $qms = implode(',', $qms);
925 $sql = "INSERT INTO {" . $table . "} ($fields) VALUES($qms)";
926 $query_id = $this->do_query($sql, $params, SQL_QUERY_INSERT);
928 if ($customsequence) {
929 // Enable IDENTITY column after inserting record with id, only if the
930 // column is identity, from meta information.
931 if ($isidentity) {
932 $sql = 'SET IDENTITY_INSERT {'.$table.'} OFF'; // Yes, it' OFF!!
933 $this->do_query($sql, null, SQL_QUERY_AUX);
937 if ($returnid) {
938 $id = $this->sqlsrv_fetch_id();
939 return $id;
940 } else {
941 return true;
946 * Get the ID of the current action
948 * @return mixed ID
950 private function sqlsrv_fetch_id() {
951 $query_id = sqlsrv_query($this->sqlsrv, 'SELECT SCOPE_IDENTITY()');
952 if ($query_id === false) {
953 $dberr = $this->get_last_error();
954 return false;
956 $row = $this->sqlsrv_fetchrow($query_id);
957 return (int)$row[0];
961 * Fetch a single row into an numbered array
963 * @param mixed $query_id
965 private function sqlsrv_fetchrow($query_id) {
966 $row = sqlsrv_fetch_array($query_id, SQLSRV_FETCH_NUMERIC);
967 if ($row === false) {
968 $dberr = $this->get_last_error();
969 return false;
972 foreach ($row as $key => $value) {
973 $row[$key] = ($value === ' ' || $value === NULL) ? '' : $value;
975 return $row;
979 * Insert a record into a table and return the "id" field if required.
981 * Some conversions and safety checks are carried out. Lobs are supported.
982 * If the return ID isn't required, then this just reports success as true/false.
983 * $data is an object containing needed data
984 * @param string $table The database table to be inserted into
985 * @param object $data A data object with values for one or more fields in the record
986 * @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.
987 * @return bool|int true or new id
988 * @throws dml_exception A DML specific exception is thrown for any errors.
990 public function insert_record($table, $dataobject, $returnid = true, $bulk = false) {
991 $dataobject = (array)$dataobject;
993 $columns = $this->get_columns($table);
994 if (empty($columns)) {
995 throw new dml_exception('ddltablenotexist', $table);
998 $cleaned = array ();
1000 foreach ($dataobject as $field => $value) {
1001 if ($field === 'id') {
1002 continue;
1004 if (!isset($columns[$field])) {
1005 continue;
1007 $column = $columns[$field];
1008 $cleaned[$field] = $this->normalise_value($column, $value);
1011 return $this->insert_record_raw($table, $cleaned, $returnid, $bulk);
1015 * Import a record into a table, id field is required.
1016 * Safety checks are NOT carried out. Lobs are supported.
1018 * @param string $table name of database table to be inserted into
1019 * @param object $dataobject A data object with values for one or more fields in the record
1020 * @return bool true
1021 * @throws dml_exception A DML specific exception is thrown for any errors.
1023 public function import_record($table, $dataobject) {
1024 if (!is_object($dataobject)) {
1025 $dataobject = (object)$dataobject;
1028 $columns = $this->get_columns($table);
1029 $cleaned = array ();
1031 foreach ($dataobject as $field => $value) {
1032 if (!isset($columns[$field])) {
1033 continue;
1035 $column = $columns[$field];
1036 $cleaned[$field] = $this->normalise_value($column, $value);
1039 $this->insert_record_raw($table, $cleaned, false, false, true);
1041 return true;
1045 * Update record in database, as fast as possible, no safety checks, lobs not supported.
1046 * @param string $table name
1047 * @param mixed $params data record as object or array
1048 * @param bool true means repeated updates expected
1049 * @return bool true
1050 * @throws dml_exception A DML specific exception is thrown for any errors.
1052 public function update_record_raw($table, $params, $bulk = false) {
1053 $params = (array)$params;
1055 if (!isset($params['id'])) {
1056 throw new coding_exception('moodle_database::update_record_raw() id field must be specified.');
1058 $id = $params['id'];
1059 unset($params['id']);
1061 if (empty($params)) {
1062 throw new coding_exception('moodle_database::update_record_raw() no fields found.');
1065 $sets = array ();
1067 foreach ($params as $field => $value) {
1068 $sets[] = "$field = ?";
1071 $params[] = $id; // last ? in WHERE condition
1073 $sets = implode(',', $sets);
1074 $sql = "UPDATE {".$table."} SET $sets WHERE id = ?";
1076 $this->do_query($sql, $params, SQL_QUERY_UPDATE);
1078 return true;
1082 * Update a record in a table
1084 * $dataobject is an object containing needed data
1085 * Relies on $dataobject having a variable "id" to
1086 * specify the record to update
1088 * @param string $table The database table to be checked against.
1089 * @param object $dataobject An object with contents equal to fieldname=>fieldvalue. Must have an entry for 'id' to map to the table specified.
1090 * @param bool true means repeated updates expected
1091 * @return bool true
1092 * @throws dml_exception A DML specific exception is thrown for any errors.
1094 public function update_record($table, $dataobject, $bulk = false) {
1095 $dataobject = (array)$dataobject;
1097 $columns = $this->get_columns($table);
1098 $cleaned = array ();
1100 foreach ($dataobject as $field => $value) {
1101 if (!isset($columns[$field])) {
1102 continue;
1104 $column = $columns[$field];
1105 $cleaned[$field] = $this->normalise_value($column, $value);
1108 return $this->update_record_raw($table, $cleaned, $bulk);
1112 * Set a single field in every table record which match a particular WHERE clause.
1114 * @param string $table The database table to be checked against.
1115 * @param string $newfield the field to set.
1116 * @param string $newvalue the value to set the field to.
1117 * @param string $select A fragment of SQL to be used in a where clause in the SQL call.
1118 * @param array $params array of sql parameters
1119 * @return bool true
1120 * @throws dml_exception A DML specific exception is thrown for any errors.
1122 public function set_field_select($table, $newfield, $newvalue, $select, array $params = null) {
1123 if ($select) {
1124 $select = "WHERE $select";
1127 if (is_null($params)) {
1128 $params = array ();
1131 // convert params to ? types
1132 list($select, $params, $type) = $this->fix_sql_params($select, $params);
1134 // Get column metadata
1135 $columns = $this->get_columns($table);
1136 $column = $columns[$newfield];
1138 $newvalue = $this->normalise_value($column, $newvalue);
1140 if (is_null($newvalue)) {
1141 $newfield = "$newfield = NULL";
1142 } else {
1143 $newfield = "$newfield = ?";
1144 array_unshift($params, $newvalue);
1146 $sql = "UPDATE {".$table."} SET $newfield $select";
1148 $this->do_query($sql, $params, SQL_QUERY_UPDATE);
1150 return true;
1154 * Delete one or more records from a table which match a particular WHERE clause.
1156 * @param string $table The database table to be checked against.
1157 * @param string $select A fragment of SQL to be used in a where clause in the SQL call (used to define the selection criteria).
1158 * @param array $params array of sql parameters
1159 * @return bool true
1160 * @throws dml_exception A DML specific exception is thrown for any errors.
1162 public function delete_records_select($table, $select, array $params = null) {
1163 if ($select) {
1164 $select = "WHERE $select";
1167 $sql = "DELETE FROM {".$table."} $select";
1169 // we use SQL_QUERY_UPDATE because we do not know what is in general SQL, delete constant would not be accurate
1170 $this->do_query($sql, $params, SQL_QUERY_UPDATE);
1172 return true;
1176 public function sql_cast_char2int($fieldname, $text = false) {
1177 if (!$text) {
1178 return ' CAST(' . $fieldname . ' AS INT) ';
1179 } else {
1180 return ' CAST(' . $this->sql_compare_text($fieldname) . ' AS INT) ';
1184 public function sql_cast_char2real($fieldname, $text=false) {
1185 if (!$text) {
1186 return ' CAST(' . $fieldname . ' AS REAL) ';
1187 } else {
1188 return ' CAST(' . $this->sql_compare_text($fieldname) . ' AS REAL) ';
1192 public function sql_ceil($fieldname) {
1193 return ' CEILING('.$fieldname.')';
1196 protected function get_collation() {
1197 if (isset($this->collation)) {
1198 return $this->collation;
1200 if (!empty($this->dboptions['dbcollation'])) {
1201 // perf speedup
1202 $this->collation = $this->dboptions['dbcollation'];
1203 return $this->collation;
1206 // make some default
1207 $this->collation = 'Latin1_General_CI_AI';
1209 $sql = "SELECT CAST(DATABASEPROPERTYEX('$this->dbname', 'Collation') AS varchar(255)) AS SQLCollation";
1210 $this->query_start($sql, null, SQL_QUERY_AUX);
1211 $result = sqlsrv_query($this->sqlsrv, $sql);
1212 $this->query_end($result);
1214 if ($result) {
1215 if ($rawcolumn = sqlsrv_fetch_array($result, SQLSRV_FETCH_ASSOC)) {
1216 $this->collation = reset($rawcolumn);
1218 $this->free_result($result);
1221 return $this->collation;
1225 * Returns 'LIKE' part of a query.
1227 * @param string $fieldname usually name of the table column
1228 * @param string $param usually bound query parameter (?, :named)
1229 * @param bool $casesensitive use case sensitive search
1230 * @param bool $accensensitive use accent sensitive search (not all databases support accent insensitive)
1231 * @param bool $notlike true means "NOT LIKE"
1232 * @param string $escapechar escape char for '%' and '_'
1233 * @return string SQL code fragment
1235 public function sql_like($fieldname, $param, $casesensitive = true, $accentsensitive = true, $notlike = false, $escapechar = '\\') {
1236 if (strpos($param, '%') !== false) {
1237 debugging('Potential SQL injection detected, sql_like() expects bound parameters (? or :named)');
1240 $collation = $this->get_collation();
1241 $LIKE = $notlike ? 'NOT LIKE' : 'LIKE';
1243 if ($casesensitive) {
1244 $collation = str_replace('_CI', '_CS', $collation);
1245 } else {
1246 $collation = str_replace('_CS', '_CI', $collation);
1248 if ($accentsensitive) {
1249 $collation = str_replace('_AI', '_AS', $collation);
1250 } else {
1251 $collation = str_replace('_AS', '_AI', $collation);
1254 return "$fieldname COLLATE $collation $LIKE $param ESCAPE '$escapechar'";
1257 public function sql_concat() {
1258 $arr = func_get_args();
1260 foreach ($arr as $key => $ele) {
1261 $arr[$key] = ' CAST('.$ele.' AS NVARCHAR(255)) ';
1263 $s = implode(' + ', $arr);
1265 if ($s === '') {
1266 return " '' ";
1268 return " $s ";
1271 public function sql_concat_join($separator = "' '", $elements = array ()) {
1272 for ($n = count($elements) - 1; $n > 0; $n--) {
1273 array_splice($elements, $n, 0, $separator);
1275 $s = implode(' + ', $elements);
1277 if ($s === '') {
1278 return " '' ";
1280 return " $s ";
1283 public function sql_isempty($tablename, $fieldname, $nullablefield, $textfield) {
1284 if ($textfield) {
1285 return ' ('.$this->sql_compare_text($fieldname)." = '') ";
1286 } else {
1287 return " ($fieldname = '') ";
1292 * Returns the SQL text to be used to calculate the length in characters of one expression.
1293 * @param string fieldname or expression to calculate its length in characters.
1294 * @return string the piece of SQL code to be used in the statement.
1296 public function sql_length($fieldname) {
1297 return ' LEN('.$fieldname.')';
1300 public function sql_order_by_text($fieldname, $numchars = 32) {
1301 return " CONVERT(varchar({$numchars}), {$fieldname})";
1305 * Returns the SQL for returning searching one string for the location of another.
1307 public function sql_position($needle, $haystack) {
1308 return "CHARINDEX(($needle), ($haystack))";
1312 * Returns the proper substr() SQL text used to extract substrings from DB
1313 * NOTE: this was originally returning only function name
1315 * @param string $expr some string field, no aggregates
1316 * @param mixed $start integer or expression evaluating to int
1317 * @param mixed $length optional integer or expression evaluating to int
1318 * @return string sql fragment
1320 public function sql_substr($expr, $start, $length = false) {
1321 if (count(func_get_args()) < 2) {
1322 throw new coding_exception('moodle_database::sql_substr() requires at least two parameters',
1323 'Originally this function was only returning name of SQL substring function, it now requires all parameters.');
1326 if ($length === false) {
1327 return "SUBSTRING($expr, $start, (LEN($expr) - $start + 1))";
1328 } else {
1329 return "SUBSTRING($expr, $start, $length)";
1334 * Does this driver support tool_replace?
1336 * @since Moodle 2.6.1
1337 * @return bool
1339 public function replace_all_text_supported() {
1340 return true;
1343 public function session_lock_supported() {
1344 return true;
1348 * Obtain session lock
1349 * @param int $rowid id of the row with session record
1350 * @param int $timeout max allowed time to wait for the lock in seconds
1351 * @return void
1353 public function get_session_lock($rowid, $timeout) {
1354 if (!$this->session_lock_supported()) {
1355 return;
1357 parent::get_session_lock($rowid, $timeout);
1359 $timeoutmilli = $timeout * 1000;
1361 $fullname = $this->dbname.'-'.$this->prefix.'-session-'.$rowid;
1362 // While this may work using proper {call sp_...} calls + binding +
1363 // executing + consuming recordsets, the solution used for the mssql
1364 // driver is working perfectly, so 100% mimic-ing that code.
1365 // $sql = "sp_getapplock '$fullname', 'Exclusive', 'Session', $timeoutmilli";
1366 $sql = "BEGIN
1367 DECLARE @result INT
1368 EXECUTE @result = sp_getapplock @Resource='$fullname',
1369 @LockMode='Exclusive',
1370 @LockOwner='Session',
1371 @LockTimeout='$timeoutmilli'
1372 SELECT @result
1373 END";
1374 $this->query_start($sql, null, SQL_QUERY_AUX);
1375 $result = sqlsrv_query($this->sqlsrv, $sql);
1376 $this->query_end($result);
1378 if ($result) {
1379 $row = sqlsrv_fetch_array($result);
1380 if ($row[0] < 0) {
1381 throw new dml_sessionwait_exception();
1385 $this->free_result($result);
1388 public function release_session_lock($rowid) {
1389 if (!$this->session_lock_supported()) {
1390 return;
1392 if (!$this->used_for_db_sessions) {
1393 return;
1396 parent::release_session_lock($rowid);
1398 $fullname = $this->dbname.'-'.$this->prefix.'-session-'.$rowid;
1399 $sql = "sp_releaseapplock '$fullname', 'Session'";
1400 $this->query_start($sql, null, SQL_QUERY_AUX);
1401 $result = sqlsrv_query($this->sqlsrv, $sql);
1402 $this->query_end($result);
1403 $this->free_result($result);
1407 * Driver specific start of real database transaction,
1408 * this can not be used directly in code.
1409 * @return void
1411 protected function begin_transaction() {
1412 // Recordsets do not work well with transactions in SQL Server,
1413 // let's prefetch the recordsets to memory to work around these problems.
1414 foreach ($this->recordsets as $rs) {
1415 $rs->transaction_starts();
1418 $this->query_start('native sqlsrv_begin_transaction', NULL, SQL_QUERY_AUX);
1419 $result = sqlsrv_begin_transaction($this->sqlsrv);
1420 $this->query_end($result);
1424 * Driver specific commit of real database transaction,
1425 * this can not be used directly in code.
1426 * @return void
1428 protected function commit_transaction() {
1429 $this->query_start('native sqlsrv_commit', NULL, SQL_QUERY_AUX);
1430 $result = sqlsrv_commit($this->sqlsrv);
1431 $this->query_end($result);
1435 * Driver specific abort of real database transaction,
1436 * this can not be used directly in code.
1437 * @return void
1439 protected function rollback_transaction() {
1440 $this->query_start('native sqlsrv_rollback', NULL, SQL_QUERY_AUX);
1441 $result = sqlsrv_rollback($this->sqlsrv);
1442 $this->query_end($result);