MDL-31532 restore: avoid null course->hiddensections problems. Credit goes to Petri...
[moodle.git] / lib / dml / sqlsrv_native_moodle_database.php
blob61567597fc13431e57d9e368c56ff3aa0b253bdc
1 <?php
3 // This file is part of Moodle - http://moodle.org/
4 //
5 // Moodle is free software: you can redistribute it and/or modify
6 // it under the terms of the GNU General Public License as published by
7 // the Free Software Foundation, either version 2 of the License, or
8 // (at your option) any later version.
9 //
10 // Moodle is distributed in the hope that it will be useful,
11 // but WITHOUT ANY WARRANTY; without even the implied warranty of
12 // MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the
13 // GNU General Public License for more details.
15 // You should have received a copy of the GNU General Public License
16 // along with Moodle. If not, see <http://www.gnu.org/licenses/>.
18 /**
19 * Native sqlsrv class representing moodle database interface.
21 * @package core
22 * @subpackage dml
23 * @copyright 2009 onwards Eloy Lafuente (stronk7) {@link http://stronk7.com}
24 * @license http://www.gnu.org/copyleft/gpl.html GNU GPL v2 or later
27 defined('MOODLE_INTERNAL') || die();
29 require_once($CFG->libdir.'/dml/moodle_database.php');
30 require_once($CFG->libdir.'/dml/sqlsrv_native_moodle_recordset.php');
31 require_once($CFG->libdir.'/dml/sqlsrv_native_moodle_temptables.php');
33 /**
34 * Native sqlsrv class representing moodle database interface.
36 class sqlsrv_native_moodle_database extends moodle_database {
38 protected $sqlsrv = null;
39 protected $last_error_reporting; // To handle SQL*Server-Native driver default verbosity
40 protected $temptables; // Control existing temptables (sqlsrv_moodle_temptables object)
41 protected $collation; // current DB collation cache
43 /**
44 * Constructor - instantiates the database, specifying if it's external (connect to other systems) or no (Moodle DB)
45 * note this has effect to decide if prefix checks must be performed or no
46 * @param bool true means external database used
48 public function __construct($external=false) {
49 parent::__construct($external);
52 /**
53 * Detects if all needed PHP stuff installed.
54 * Note: can be used before connect()
55 * @return mixed true if ok, string if something
57 public function driver_installed() {
58 // use 'function_exists()' rather than 'extension_loaded()' because
59 // the name used by 'extension_loaded()' is case specific! The extension
60 // therefore *could be* mixed case and hence not found.
61 if (!function_exists('sqlsrv_num_rows')) {
62 return get_string('sqlsrvextensionisnotpresentinphp', 'install');
64 return true;
67 /**
68 * Returns database family type - describes SQL dialect
69 * Note: can be used before connect()
70 * @return string db family name (mysql, postgres, mssql, sqlsrv, oracle, etc.)
72 public function get_dbfamily() {
73 return 'mssql';
76 /**
77 * Returns more specific database driver type
78 * Note: can be used before connect()
79 * @return string db type mysqli, pgsql, oci, mssql, sqlsrv
81 protected function get_dbtype() {
82 return 'sqlsrv';
85 /**
86 * Returns general database library name
87 * Note: can be used before connect()
88 * @return string db type pdo, native
90 protected function get_dblibrary() {
91 return 'native';
94 /**
95 * Returns localised database type name
96 * Note: can be used before connect()
97 * @return string
99 public function get_name() {
100 return get_string('nativesqlsrv', 'install');
104 * Returns localised database configuration help.
105 * Note: can be used before connect()
106 * @return string
108 public function get_configuration_help() {
109 return get_string('nativesqlsrvhelp', 'install');
113 * Returns localised database description
114 * Note: can be used before connect()
115 * @return string
117 public function get_configuration_hints() {
118 $str = get_string('databasesettingssub_sqlsrv', 'install');
119 $str .= "<p style='text-align:right'><a href=\"javascript:void(0)\" ";
120 $str .= "onclick=\"return window.open('http://docs.moodle.org/en/Using_the_Microsoft_SQL_Server_Driver_for_PHP')\"";
121 $str .= ">";
122 $str .= '<img src="pix/docs.gif'.'" alt="Docs" class="iconhelp" />';
123 $str .= get_string('moodledocslink', 'install').'</a></p>';
124 return $str;
128 * Connect to db
129 * Must be called before other methods.
130 * @param string $dbhost
131 * @param string $dbuser
132 * @param string $dbpass
133 * @param string $dbname
134 * @param mixed $prefix string means moodle db prefix, false used for external databases where prefix not used
135 * @param array $dboptions driver specific options
136 * @return bool true
137 * @throws dml_connection_exception if error
139 public function connect($dbhost, $dbuser, $dbpass, $dbname, $prefix, array $dboptions=null) {
140 $driverstatus = $this->driver_installed();
142 if ($driverstatus !== true) {
143 throw new dml_exception('dbdriverproblem', $driverstatus);
147 * Log all Errors.
149 sqlsrv_configure("WarningsReturnAsErrors", FALSE);
150 sqlsrv_configure("LogSubsystems", SQLSRV_LOG_SYSTEM_ALL);
151 sqlsrv_configure("LogSeverity", SQLSRV_LOG_SEVERITY_ERROR);
153 $this->store_settings($dbhost, $dbuser, $dbpass, $dbname, $prefix, $dboptions);
154 $this->sqlsrv = sqlsrv_connect($this->dbhost, array
156 'UID' => $this->dbuser,
157 'PWD' => $this->dbpass,
158 'Database' => $this->dbname,
159 'CharacterSet' => 'UTF-8',
160 'MultipleActiveResultSets' => true,
161 'ConnectionPooling' => !empty($this->dboptions['dbpersist']),
162 'ReturnDatesAsStrings' => true,
165 if ($this->sqlsrv === false) {
166 $this->sqlsrv = null;
167 $dberr = $this->get_last_error();
169 throw new dml_connection_exception($dberr);
172 // Allow quoted identifiers
173 $sql = "SET QUOTED_IDENTIFIER ON";
174 $this->query_start($sql, null, SQL_QUERY_AUX);
175 $result = sqlsrv_query($this->sqlsrv, $sql);
176 $this->query_end($result);
178 $this->free_result($result);
180 // Force ANSI nulls so the NULL check was done by IS NULL and NOT IS NULL
181 // instead of equal(=) and distinct(<>) symbols
182 $sql = "SET ANSI_NULLS ON";
183 $this->query_start($sql, null, SQL_QUERY_AUX);
184 $result = sqlsrv_query($this->sqlsrv, $sql);
185 $this->query_end($result);
187 $this->free_result($result);
189 // Force ANSI warnings so arithmetic/string overflows will be
190 // returning error instead of transparently truncating data
191 $sql = "SET ANSI_WARNINGS ON";
192 $this->query_start($sql, null, SQL_QUERY_AUX);
193 $result = sqlsrv_query($this->sqlsrv, $sql);
194 $this->query_end($result);
196 // Concatenating null with anything MUST return NULL
197 $sql = "SET CONCAT_NULL_YIELDS_NULL ON";
198 $this->query_start($sql, null, SQL_QUERY_AUX);
199 $result = sqlsrv_query($this->sqlsrv, $sql);
200 $this->query_end($result);
202 $this->free_result($result);
204 // Set transactions isolation level to READ_COMMITTED
205 // prevents dirty reads when using transactions +
206 // is the default isolation level of sqlsrv
207 $sql = "SET TRANSACTION ISOLATION LEVEL READ COMMITTED";
208 $this->query_start($sql, NULL, SQL_QUERY_AUX);
209 $result = sqlsrv_query($this->sqlsrv, $sql);
210 $this->query_end($result);
212 $this->free_result($result);
214 // Connection established and configured, going to instantiate the temptables controller
215 $this->temptables = new sqlsrv_native_moodle_temptables($this);
217 return true;
221 * Close database connection and release all resources
222 * and memory (especially circular memory references).
223 * Do NOT use connect() again, create a new instance if needed.
225 public function dispose() {
226 parent::dispose(); // Call parent dispose to write/close session and other common stuff before closing connection
228 if ($this->sqlsrv) {
229 sqlsrv_close($this->sqlsrv);
230 $this->sqlsrv = null;
235 * Called before each db query.
236 * @param string $sql
237 * @param array array of parameters
238 * @param int $type type of query
239 * @param mixed $extrainfo driver specific extra information
240 * @return void
242 protected function query_start($sql, array $params = null, $type, $extrainfo = null) {
243 parent::query_start($sql, $params, $type, $extrainfo);
247 * Called immediately after each db query.
248 * @param mixed db specific result
249 * @return void
251 protected function query_end($result) {
252 parent::query_end($result);
256 * Returns database server info array
257 * @return array
259 public function get_server_info() {
260 static $info;
262 if (!$info) {
263 $server_info = sqlsrv_server_info($this->sqlsrv);
265 if ($server_info) {
266 $info['description'] = $server_info['SQLServerName'];
267 $info['version'] = $server_info['SQLServerVersion'];
268 $info['database'] = $server_info['CurrentDatabase'];
271 return $info;
275 * Get the minimum SQL allowed
277 * @param mixed $version
278 * @return mixed
280 protected function is_min_version($version) {
281 $server = $this->get_server_info();
282 $server = $server['version'];
283 return version_compare($server, $version, '>=');
287 * Override: Converts short table name {tablename} to real table name
288 * supporting temp tables (#) if detected
290 * @param string sql
291 * @return string sql
293 protected function fix_table_names($sql) {
294 if (preg_match_all('/\{([a-z][a-z0-9_]*)\}/i', $sql, $matches)) {
295 foreach ($matches[0] as $key => $match) {
296 $name = $matches[1][$key];
298 if ($this->temptables->is_temptable($name)) {
299 $sql = str_replace($match, $this->temptables->get_correct_name($name), $sql);
300 } else {
301 $sql = str_replace($match, $this->prefix.$name, $sql);
305 return $sql;
309 * Returns supported query parameter types
310 * @return int bitmask
312 protected function allowed_param_types() {
313 return SQL_PARAMS_QM; // sqlsrv 1.1 can bind
317 * Returns last error reported by database engine.
318 * @return string error message
320 public function get_last_error() {
321 $retErrors = sqlsrv_errors(SQLSRV_ERR_ALL);
322 $errorMessage = 'No errors found';
324 if ($retErrors != null) {
325 $errorMessage = '';
327 foreach ($retErrors as $arrError) {
328 $errorMessage .= "SQLState: ".$arrError['SQLSTATE']."<br>\n";
329 $errorMessage .= "Error Code: ".$arrError['code']."<br>\n";
330 $errorMessage .= "Message: ".$arrError['message']."<br>\n";
334 return $errorMessage;
337 /***
338 * Bound variables *are* supported. Until I can get it to work, emulate the bindings
339 * The challenge/problem/bug is that although they work, doing a SELECT SCOPE_IDENTITY()
340 * doesn't return a value (no result set)
344 * Prepare the query binding and do the actual query.
346 * @param string $sql The sql statement
347 * @param mixed $params array of params for binding. If NULL, they are ignored.
348 * @param mixed $sql_query_type - Type of operation
349 * @param mixed $free_result - Default true, transaction query will be freed.
350 * @param mixed $scrollable - Default false, to use for quickly seeking to target records
352 private function do_query($sql, $params, $sql_query_type, $free_result = true, $scrollable = false) {
353 list($sql, $params, $type) = $this->fix_sql_params($sql, $params);
355 $sql = $this->emulate_bound_params($sql, $params);
356 $this->query_start($sql, $params, $sql_query_type);
357 if (!$scrollable) { // Only supporting next row
358 $result = sqlsrv_query($this->sqlsrv, $sql);
359 } else { // Suporting absolute/relative rows
360 $result = sqlsrv_query($this->sqlsrv, $sql, array(), array('Scrollable' => SQLSRV_CURSOR_STATIC));
363 if ($result === false) {
364 // TODO do something with error or just use if DEV or DEBUG?
365 $dberr = $this->get_last_error();
368 $this->query_end($result);
370 if ($free_result) {
371 $this->free_result($result);
372 return true;
374 return $result;
378 * Return tables in database WITHOUT current prefix
379 * @return array of table names in lowercase and without prefix
381 public function get_tables($usecache = true) {
382 if ($usecache and count($this->tables) > 0) {
383 return $this->tables;
385 $this->tables = array ();
386 $prefix = str_replace('_', '\\_', $this->prefix);
387 $sql = "SELECT table_name
388 FROM information_schema.tables
389 WHERE table_name LIKE '$prefix%' ESCAPE '\\' AND table_type = 'BASE TABLE'";
391 $this->query_start($sql, null, SQL_QUERY_AUX);
392 $result = sqlsrv_query($this->sqlsrv, $sql);
393 $this->query_end($result);
395 if ($result) {
396 while ($row = sqlsrv_fetch_array($result)) {
397 $tablename = reset($row);
398 if (strpos($tablename, $this->prefix) !== 0) {
399 continue;
401 $tablename = substr($tablename, strlen($this->prefix));
402 $this->tables[$tablename] = $tablename;
404 $this->free_result($result);
407 // Add the currently available temptables
408 $this->tables = array_merge($this->tables, $this->temptables->get_temptables());
409 return $this->tables;
413 * Return table indexes - everything lowercased
414 * @return array of arrays
416 public function get_indexes($table) {
417 $indexes = array ();
418 $tablename = $this->prefix.$table;
420 // Indexes aren't covered by information_schema metatables, so we need to
421 // go to sys ones. Skipping primary key indexes on purpose.
422 $sql = "SELECT i.name AS index_name, i.is_unique, ic.index_column_id, c.name AS column_name
423 FROM sys.indexes i
424 JOIN sys.index_columns ic ON i.object_id = ic.object_id AND i.index_id = ic.index_id
425 JOIN sys.columns c ON ic.object_id = c.object_id AND ic.column_id = c.column_id
426 JOIN sys.tables t ON i.object_id = t.object_id
427 WHERE t.name = '$tablename' AND i.is_primary_key = 0
428 ORDER BY i.name, i.index_id, ic.index_column_id";
430 $this->query_start($sql, null, SQL_QUERY_AUX);
431 $result = sqlsrv_query($this->sqlsrv, $sql);
432 $this->query_end($result);
434 if ($result) {
435 $lastindex = '';
436 $unique = false;
437 $columns = array ();
439 while ($row = sqlsrv_fetch_array($result, SQLSRV_FETCH_ASSOC)) {
440 if ($lastindex and $lastindex != $row['index_name'])
441 { // Save lastindex to $indexes and reset info
442 $indexes[$lastindex] = array
444 'unique' => $unique,
445 'columns' => $columns
448 $unique = false;
449 $columns = array ();
451 $lastindex = $row['index_name'];
452 $unique = empty($row['is_unique']) ? false : true;
453 $columns[] = $row['column_name'];
456 if ($lastindex) { // Add the last one if exists
457 $indexes[$lastindex] = array
459 'unique' => $unique,
460 'columns' => $columns
464 $this->free_result($result);
466 return $indexes;
470 * Returns detailed information about columns in table. This information is cached internally.
471 * @param string $table name
472 * @param bool $usecache
473 * @return array array of database_column_info objects indexed with column names
475 public function get_columns($table, $usecache = true) {
476 if ($usecache and isset($this->columns[$table])) {
477 return $this->columns[$table];
480 $this->columns[$table] = array ();
482 if (!$this->temptables->is_temptable($table)) { // normal table, get metadata from own schema
483 $sql = "SELECT column_name AS name,
484 data_type AS type,
485 numeric_precision AS max_length,
486 character_maximum_length AS char_max_length,
487 numeric_scale AS scale,
488 is_nullable AS is_nullable,
489 columnproperty(object_id(quotename(table_schema) + '.' + quotename(table_name)), column_name, 'IsIdentity') AS auto_increment,
490 column_default AS default_value
491 FROM information_schema.columns
492 WHERE table_name = '{".$table."}'
493 ORDER BY ordinal_position";
494 } else { // temp table, get metadata from tempdb schema
495 $sql = "SELECT column_name AS name,
496 data_type AS type,
497 numeric_precision AS max_length,
498 character_maximum_length AS char_max_length,
499 numeric_scale AS scale,
500 is_nullable AS is_nullable,
501 columnproperty(object_id(quotename(table_schema) + '.' + quotename(table_name)), column_name, 'IsIdentity') AS auto_increment,
502 column_default AS default_value
503 FROM tempdb.information_schema.columns ".
504 // check this statement
505 // JOIN tempdb..sysobjects ON name = table_name
506 // WHERE id = object_id('tempdb..{".$table."}')
507 "WHERE table_name LIKE '{".$table."}__________%'
508 ORDER BY ordinal_position";
511 list($sql, $params, $type) = $this->fix_sql_params($sql, null);
513 $this->query_start($sql, null, SQL_QUERY_AUX);
514 $result = sqlsrv_query($this->sqlsrv, $sql);
515 $this->query_end($result);
517 if (!$result) {
518 return array ();
521 while ($rawcolumn = sqlsrv_fetch_array($result, SQLSRV_FETCH_ASSOC)) {
523 $rawcolumn = (object)$rawcolumn;
525 $info = new stdClass();
526 $info->name = $rawcolumn->name;
527 $info->type = $rawcolumn->type;
528 $info->meta_type = $this->sqlsrvtype2moodletype($info->type);
530 // Prepare auto_increment info
531 $info->auto_increment = $rawcolumn->auto_increment ? true : false;
533 // Define type for auto_increment columns
534 $info->meta_type = ($info->auto_increment && $info->meta_type == 'I') ? 'R' : $info->meta_type;
536 // id columns being auto_incremnt are PK by definition
537 $info->primary_key = ($info->name == 'id' && $info->meta_type == 'R' && $info->auto_increment);
539 // Put correct length for character and LOB types
540 $info->max_length = $info->meta_type == 'C' ? $rawcolumn->char_max_length : $rawcolumn->max_length;
541 $info->max_length = ($info->meta_type == 'X' || $info->meta_type == 'B') ? -1 : $info->max_length;
543 // Scale
544 $info->scale = $rawcolumn->scale ? $rawcolumn->scale : false;
546 // Prepare not_null info
547 $info->not_null = $rawcolumn->is_nullable == 'NO' ? true : false;
549 // Process defaults
550 $info->has_default = !empty($rawcolumn->default_value);
551 if ($rawcolumn->default_value === NULL) {
552 $info->default_value = NULL;
553 } else {
554 $info->default_value = preg_replace("/^[\(N]+[']?(.*?)[']?[\)]+$/", '\\1', $rawcolumn->default_value);
557 // Process binary
558 $info->binary = $info->meta_type == 'B' ? true : false;
560 $this->columns[$table][$info->name] = new database_column_info($info);
562 $this->free_result($result);
564 return $this->columns[$table];
568 * Normalise values based in RDBMS dependencies (booleans, LOBs...)
570 * @param database_column_info $column column metadata corresponding with the value we are going to normalise
571 * @param mixed $value value we are going to normalise
572 * @return mixed the normalised value
574 protected function normalise_value($column, $value) {
575 if (is_bool($value)) { /// Always, convert boolean to int
576 $value = (int)$value;
577 } // And continue processing because text columns with numeric info need special handling below
579 if ($column->meta_type == 'B')
580 { // BLOBs need to be properly "packed", but can be inserted directly if so.
581 if (!is_null($value)) { // If value not null, unpack it to unquoted hexadecimal byte-string format
582 $value = unpack('H*hex', $value); // we leave it as array, so emulate_bound_params() can detect it
583 } // easily and "bind" the param ok.
585 } else if ($column->meta_type == 'X') { // sqlsrv doesn't cast from int to text, so if text column
586 if (is_numeric($value)) { // and is numeric value then cast to string
587 $value = array('numstr' => (string)$value); // and put into array, so emulate_bound_params() will know how
588 } // to "bind" the param ok, avoiding reverse conversion to number
589 } else if ($value === '') {
591 if ($column->meta_type == 'I' or $column->meta_type == 'F' or $column->meta_type == 'N') {
592 $value = 0; // prevent '' problems in numeric fields
595 return $value;
599 * Selectively call sqlsrv_free_stmt(), avoiding some warnings without using the horrible @
601 * @param sqlsrv_resource $resource resource to be freed if possible
603 private function free_result($resource) {
604 if (!is_bool($resource)) { // true/false resources cannot be freed
605 return sqlsrv_free_stmt($resource);
610 * Provides mapping between sqlsrv native data types and moodle_database - database_column_info - ones)
612 * @param string $sqlsrv_type native sqlsrv data type
613 * @return string 1-char database_column_info data type
615 private function sqlsrvtype2moodletype($sqlsrv_type) {
616 $type = null;
618 switch (strtoupper($sqlsrv_type)) {
619 case 'BIT':
620 $type = 'L';
621 break;
623 case 'INT':
624 case 'SMALLINT':
625 case 'INTEGER':
626 case 'BIGINT':
627 $type = 'I';
628 break;
630 case 'DECIMAL':
631 case 'REAL':
632 case 'FLOAT':
633 $type = 'N';
634 break;
636 case 'VARCHAR':
637 case 'NVARCHAR':
638 $type = 'C';
639 break;
641 case 'TEXT':
642 case 'NTEXT':
643 case 'VARCHAR(MAX)':
644 case 'NVARCHAR(MAX)':
645 $type = 'X';
646 break;
648 case 'IMAGE':
649 case 'VARBINARY(MAX)':
650 $type = 'B';
651 break;
653 case 'DATETIME':
654 $type = 'D';
655 break;
658 if (!$type) {
659 throw new dml_exception('invalidsqlsrvnativetype', $sqlsrv_type);
661 return $type;
665 * Do NOT use in code, to be used by database_manager only!
666 * @param string $sql query
667 * @return bool true
668 * @throws dml_exception if error
670 public function change_database_structure($sql) {
671 $this->reset_caches();
673 $this->query_start($sql, null, SQL_QUERY_STRUCTURE);
674 $result = sqlsrv_query($this->sqlsrv, $sql);
675 $this->query_end($result);
677 return true;
681 * Prepare the array of params for native binding
683 protected function build_native_bound_params(array $params = null) {
685 return null;
690 * Workaround for SQL*Server Native driver similar to MSSQL driver for
691 * consistent behavior.
693 protected function emulate_bound_params($sql, array $params = null) {
695 if (empty($params)) {
696 return $sql;
698 /// ok, we have verified sql statement with ? and correct number of params
699 $parts = explode('?', $sql);
700 $return = array_shift($parts);
701 foreach ($params as $param) {
702 if (is_bool($param)) {
703 $return .= (int)$param;
704 } else if (is_array($param) && isset($param['hex'])) { // detect hex binary, bind it specially
705 $return .= '0x'.$param['hex'];
706 } else if (is_array($param) && isset($param['numstr'])) { // detect numerical strings that *must not*
707 $return .= "N'{$param['numstr']}'"; // be converted back to number params, but bound as strings
708 } else if (is_null($param)) {
709 $return .= 'NULL';
711 } else if (is_number($param)) { // we can not use is_numeric() because it eats leading zeros from strings like 0045646
712 $return .= "'$param'"; // this is a hack for MDL-23997, we intentionally use string because it is compatible with both nvarchar and int types
713 } else if (is_float($param)) {
714 $return .= $param;
715 } else {
716 $param = str_replace("'", "''", $param);
717 $return .= "N'$param'";
720 $return .= array_shift($parts);
722 return $return;
726 * Execute general sql query. Should be used only when no other method suitable.
727 * Do NOT use this to make changes in db structure, use database_manager::execute_sql() instead!
728 * @param string $sql query
729 * @param array $params query parameters
730 * @return bool true
731 * @throws dml_exception if error
733 public function execute($sql, array $params = null) {
734 if (strpos($sql, ';') !== false) {
735 throw new coding_exception('moodle_database::execute() Multiple sql statements found or bound parameters not used properly in query!');
737 $this->do_query($sql, $params, SQL_QUERY_UPDATE);
738 return true;
742 * Get a number of records as a moodle_recordset using a SQL statement.
744 * Since this method is a little less readable, use of it should be restricted to
745 * code where it's possible there might be large datasets being returned. For known
746 * small datasets use get_records_sql - it leads to simpler code.
748 * The return type is as for @see function get_recordset.
750 * @param string $sql the SQL select query to execute.
751 * @param array $params array of sql parameters
752 * @param int $limitfrom return a subset of records, starting at this point (optional, required if $limitnum is set).
753 * @param int $limitnum return a subset comprising this many records (optional, required if $limitfrom is set).
754 * @return moodle_recordset instance
755 * @throws dml_exception if error
757 public function get_recordset_sql($sql, array $params = null, $limitfrom = 0, $limitnum = 0) {
758 $limitfrom = (int)$limitfrom;
759 $limitnum = (int)$limitnum;
760 $limitfrom = max(0, $limitfrom);
761 $limitnum = max(0, $limitnum);
763 if ($limitfrom or $limitnum) {
764 if ($limitnum >= 1) { // Only apply TOP clause if we have any limitnum (limitfrom offset is handled later)
765 $fetch = $limitfrom + $limitnum;
766 if (PHP_INT_MAX - $limitnum < $limitfrom) { // Check PHP_INT_MAX overflow
767 $fetch = PHP_INT_MAX;
769 $sql = preg_replace('/^([\s(])*SELECT([\s]+(DISTINCT|ALL))?(?!\s*TOP\s*\()/i',
770 "\\1SELECT\\2 TOP $fetch", $sql);
773 $result = $this->do_query($sql, $params, SQL_QUERY_SELECT, false, (bool)$limitfrom);
775 if ($limitfrom) { // Skip $limitfrom records
776 sqlsrv_fetch($result, SQLSRV_SCROLL_ABSOLUTE, $limitfrom - 1);
778 return $this->create_recordset($result);
782 * Create a record set and initialize with first row
784 * @param mixed $result
785 * @return sqlsrv_native_moodle_recordset
787 protected function create_recordset($result) {
788 return new sqlsrv_native_moodle_recordset($result);
792 * Get a number of records as an array of objects using a SQL statement.
794 * Return value as for @see function get_records.
796 * @param string $sql the SQL select query to execute. The first column of this SELECT statement
797 * must be a unique value (usually the 'id' field), as it will be used as the key of the
798 * returned array.
799 * @param array $params array of sql parameters
800 * @param int $limitfrom return a subset of records, starting at this point (optional, required if $limitnum is set).
801 * @param int $limitnum return a subset comprising this many records (optional, required if $limitfrom is set).
802 * @return array of objects, or empty array if no records were found
803 * @throws dml_exception if error
805 public function get_records_sql($sql, array $params = null, $limitfrom = 0, $limitnum = 0) {
807 $rs = $this->get_recordset_sql($sql, $params, $limitfrom, $limitnum);
809 $results = array();
811 foreach ($rs as $row) {
812 $id = reset($row);
814 if (isset($results[$id])) {
815 $colname = key($row);
816 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);
818 $results[$id] = (object)$row;
820 $rs->close();
822 return $results;
826 * Selects records and return values (first field) as an array using a SQL statement.
828 * @param string $sql The SQL query
829 * @param array $params array of sql parameters
830 * @return array of values
831 * @throws dml_exception if error
833 public function get_fieldset_sql($sql, array $params = null) {
835 $rs = $this->get_recordset_sql($sql, $params);
837 $results = array ();
839 foreach ($rs as $row) {
840 $results[] = reset($row);
842 $rs->close();
844 return $results;
848 * Insert new record into database, as fast as possible, no safety checks, lobs not supported.
849 * @param string $table name
850 * @param mixed $params data record as object or array
851 * @param bool $returnit return it of inserted record
852 * @param bool $bulk true means repeated inserts expected
853 * @param bool $customsequence true if 'id' included in $params, disables $returnid
854 * @return bool|int true or new id
855 * @throws dml_exception if error
857 public function insert_record_raw($table, $params, $returnid=true, $bulk=false, $customsequence=false) {
858 if (!is_array($params)) {
859 $params = (array)$params;
861 if ($customsequence) {
862 if (!isset($params['id'])) {
863 throw new coding_exception('moodle_database::insert_record_raw() id field must be specified if custom sequences used.');
865 $returnid = false;
866 // Disable IDENTITY column before inserting record with id
867 $sql = 'SET IDENTITY_INSERT {'.$table.'} ON'; // Yes, it' ON!!
868 $this->do_query($sql, null, SQL_QUERY_AUX);
870 } else {
871 unset($params['id']);
874 if (empty($params)) {
875 throw new coding_exception('moodle_database::insert_record_raw() no fields found.');
877 $fields = implode(',', array_keys($params));
878 $qms = array_fill(0, count($params), '?');
879 $qms = implode(',', $qms);
880 $sql = "INSERT INTO {" . $table . "} ($fields) VALUES($qms)";
881 $query_id = $this->do_query($sql, $params, SQL_QUERY_INSERT);
883 if ($customsequence) {
884 // Enable IDENTITY column after inserting record with id
885 $sql = 'SET IDENTITY_INSERT {'.$table.'} OFF'; // Yes, it' OFF!!
886 $this->do_query($sql, null, SQL_QUERY_AUX);
889 if ($returnid) {
890 $id = $this->sqlsrv_fetch_id();
891 return $id;
892 } else {
893 return true;
898 * Get the ID of the current action
900 * @return mixed ID
902 private function sqlsrv_fetch_id() {
903 $query_id = sqlsrv_query($this->sqlsrv, 'SELECT SCOPE_IDENTITY()');
904 if ($query_id === false) {
905 $dberr = $this->get_last_error();
906 return false;
908 $row = $this->sqlsrv_fetchrow($query_id);
909 return (int)$row[0];
913 * Fetch a single row into an numbered array
915 * @param mixed $query_id
917 private function sqlsrv_fetchrow($query_id) {
918 $row = sqlsrv_fetch_array($query_id, SQLSRV_FETCH_NUMERIC);
919 if ($row === false) {
920 $dberr = $this->get_last_error();
921 return false;
924 foreach ($row as $key => $value) {
925 $row[$key] = ($value === ' ' || $value === NULL) ? '' : $value;
927 return $row;
931 * Insert a record into a table and return the "id" field if required.
933 * Some conversions and safety checks are carried out. Lobs are supported.
934 * If the return ID isn't required, then this just reports success as true/false.
935 * $data is an object containing needed data
936 * @param string $table The database table to be inserted into
937 * @param object $data A data object with values for one or more fields in the record
938 * @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.
939 * @return bool|int true or new id
940 * @throws dml_exception if error
942 public function insert_record($table, $dataobject, $returnid = true, $bulk = false) {
943 $dataobject = (array)$dataobject;
945 $columns = $this->get_columns($table);
946 $cleaned = array ();
948 foreach ($dataobject as $field => $value) {
949 if ($field === 'id') {
950 continue;
952 if (!isset($columns[$field])) {
953 continue;
955 $column = $columns[$field];
956 $cleaned[$field] = $this->normalise_value($column, $value);
959 return $this->insert_record_raw($table, $cleaned, $returnid, $bulk);
963 * Import a record into a table, id field is required.
964 * Safety checks are NOT carried out. Lobs are supported.
966 * @param string $table name of database table to be inserted into
967 * @param object $dataobject A data object with values for one or more fields in the record
968 * @return bool true
969 * @throws dml_exception if error
971 public function import_record($table, $dataobject) {
972 if (!is_object($dataobject)) {
973 $dataobject = (object)$dataobject;
976 $columns = $this->get_columns($table);
977 $cleaned = array ();
979 foreach ($dataobject as $field => $value) {
980 if (!isset($columns[$field])) {
981 continue;
983 $column = $columns[$field];
984 $cleaned[$field] = $this->normalise_value($column, $value);
987 $this->insert_record_raw($table, $cleaned, false, false, true);
989 return true;
993 * Update record in database, as fast as possible, no safety checks, lobs not supported.
994 * @param string $table name
995 * @param mixed $params data record as object or array
996 * @param bool true means repeated updates expected
997 * @return bool true
998 * @throws dml_exception if error
1000 public function update_record_raw($table, $params, $bulk = false) {
1001 $params = (array)$params;
1003 if (!isset($params['id'])) {
1004 throw new coding_exception('moodle_database::update_record_raw() id field must be specified.');
1006 $id = $params['id'];
1007 unset($params['id']);
1009 if (empty($params)) {
1010 throw new coding_exception('moodle_database::update_record_raw() no fields found.');
1013 $sets = array ();
1015 foreach ($params as $field => $value) {
1016 $sets[] = "$field = ?";
1019 $params[] = $id; // last ? in WHERE condition
1021 $sets = implode(',', $sets);
1022 $sql = "UPDATE {".$table."} SET $sets WHERE id = ?";
1024 $this->do_query($sql, $params, SQL_QUERY_UPDATE);
1026 return true;
1030 * Update a record in a table
1032 * $dataobject is an object containing needed data
1033 * Relies on $dataobject having a variable "id" to
1034 * specify the record to update
1036 * @param string $table The database table to be checked against.
1037 * @param object $dataobject An object with contents equal to fieldname=>fieldvalue. Must have an entry for 'id' to map to the table specified.
1038 * @param bool true means repeated updates expected
1039 * @return bool true
1040 * @throws dml_exception if error
1042 public function update_record($table, $dataobject, $bulk = false) {
1043 $dataobject = (array)$dataobject;
1045 $columns = $this->get_columns($table);
1046 $cleaned = array ();
1048 foreach ($dataobject as $field => $value) {
1049 if (!isset($columns[$field])) {
1050 continue;
1052 $column = $columns[$field];
1053 $cleaned[$field] = $this->normalise_value($column, $value);
1056 return $this->update_record_raw($table, $cleaned, $bulk);
1060 * Set a single field in every table record which match a particular WHERE clause.
1062 * @param string $table The database table to be checked against.
1063 * @param string $newfield the field to set.
1064 * @param string $newvalue the value to set the field to.
1065 * @param string $select A fragment of SQL to be used in a where clause in the SQL call.
1066 * @param array $params array of sql parameters
1067 * @return bool true
1068 * @throws dml_exception if error
1070 public function set_field_select($table, $newfield, $newvalue, $select, array $params = null) {
1071 if ($select) {
1072 $select = "WHERE $select";
1075 if (is_null($params)) {
1076 $params = array ();
1079 // convert params to ? types
1080 list($select, $params, $type) = $this->fix_sql_params($select, $params);
1082 /// Get column metadata
1083 $columns = $this->get_columns($table);
1084 $column = $columns[$newfield];
1086 $newvalue = $this->normalise_value($column, $newvalue);
1088 if (is_null($newvalue)) {
1089 $newfield = "$newfield = NULL";
1090 } else {
1091 $newfield = "$newfield = ?";
1092 array_unshift($params, $newvalue);
1094 $sql = "UPDATE {".$table."} SET $newfield $select";
1096 $this->do_query($sql, $params, SQL_QUERY_UPDATE);
1098 return true;
1102 * Delete one or more records from a table which match a particular WHERE clause.
1104 * @param string $table The database table to be checked against.
1105 * @param string $select A fragment of SQL to be used in a where clause in the SQL call (used to define the selection criteria).
1106 * @param array $params array of sql parameters
1107 * @return bool true
1108 * @throws dml_exception if error
1110 public function delete_records_select($table, $select, array $params = null) {
1111 if ($select) {
1112 $select = "WHERE $select";
1115 $sql = "DELETE FROM {".$table."} $select";
1117 // we use SQL_QUERY_UPDATE because we do not know what is in general SQL, delete constant would not be accurate
1118 $this->do_query($sql, $params, SQL_QUERY_UPDATE);
1120 return true;
1124 /// SQL helper functions
1126 public function sql_cast_char2int($fieldname, $text = false) {
1127 if (!$text) {
1128 return ' CAST(' . $fieldname . ' AS INT) ';
1129 } else {
1130 return ' CAST(' . $this->sql_compare_text($fieldname) . ' AS INT) ';
1134 public function sql_cast_char2real($fieldname, $text=false) {
1135 if (!$text) {
1136 return ' CAST(' . $fieldname . ' AS REAL) ';
1137 } else {
1138 return ' CAST(' . $this->sql_compare_text($fieldname) . ' AS REAL) ';
1142 public function sql_ceil($fieldname) {
1143 return ' CEILING('.$fieldname.')';
1146 protected function get_collation() {
1147 if (isset($this->collation)) {
1148 return $this->collation;
1150 if (!empty($this->dboptions['dbcollation'])) {
1151 // perf speedup
1152 $this->collation = $this->dboptions['dbcollation'];
1153 return $this->collation;
1156 // make some default
1157 $this->collation = 'Latin1_General_CI_AI';
1159 $sql = "SELECT CAST(DATABASEPROPERTYEX('$this->dbname', 'Collation') AS varchar(255)) AS SQLCollation";
1160 $this->query_start($sql, null, SQL_QUERY_AUX);
1161 $result = sqlsrv_query($this->sqlsrv, $sql);
1162 $this->query_end($result);
1164 if ($result) {
1165 if ($rawcolumn = sqlsrv_fetch_array($result, SQLSRV_FETCH_ASSOC)) {
1166 $this->collation = reset($rawcolumn);
1168 $this->free_result($result);
1171 return $this->collation;
1175 * Returns 'LIKE' part of a query.
1177 * @param string $fieldname usually name of the table column
1178 * @param string $param usually bound query parameter (?, :named)
1179 * @param bool $casesensitive use case sensitive search
1180 * @param bool $accensensitive use accent sensitive search (not all databases support accent insensitive)
1181 * @param bool $notlike true means "NOT LIKE"
1182 * @param string $escapechar escape char for '%' and '_'
1183 * @return string SQL code fragment
1185 public function sql_like($fieldname, $param, $casesensitive = true, $accentsensitive = true, $notlike = false, $escapechar = '\\') {
1186 if (strpos($param, '%') !== false) {
1187 debugging('Potential SQL injection detected, sql_ilike() expects bound parameters (? or :named)');
1190 $collation = $this->get_collation();
1191 $LIKE = $notlike ? 'NOT LIKE' : 'LIKE';
1193 if ($casesensitive) {
1194 $collation = str_replace('_CI', '_CS', $collation);
1195 } else {
1196 $collation = str_replace('_CS', '_CI', $collation);
1198 if ($accentsensitive) {
1199 $collation = str_replace('_AI', '_AS', $collation);
1200 } else {
1201 $collation = str_replace('_AS', '_AI', $collation);
1204 return "$fieldname COLLATE $collation $LIKE $param ESCAPE '$escapechar'";
1207 public function sql_concat() {
1208 $arr = func_get_args();
1210 foreach ($arr as $key => $ele) {
1211 $arr[$key] = ' CAST('.$ele.' AS VARCHAR(255)) ';
1213 $s = implode(' + ', $arr);
1215 if ($s === '') {
1216 return " '' ";
1218 return " $s ";
1221 public function sql_concat_join($separator = "' '", $elements = array ()) {
1222 for ($n = count($elements) - 1; $n > 0; $n--) {
1223 array_splice($elements, $n, 0, $separator);
1225 $s = implode(' + ', $elements);
1227 if ($s === '') {
1228 return " '' ";
1230 return " $s ";
1233 public function sql_isempty($tablename, $fieldname, $nullablefield, $textfield) {
1234 if ($textfield) {
1235 return ' ('.$this->sql_compare_text($fieldname)." = '') ";
1236 } else {
1237 return " ($fieldname = '') ";
1242 * Returns the SQL text to be used to calculate the length in characters of one expression.
1243 * @param string fieldname or expression to calculate its length in characters.
1244 * @return string the piece of SQL code to be used in the statement.
1246 public function sql_length($fieldname) {
1247 return ' LEN('.$fieldname.')';
1250 public function sql_order_by_text($fieldname, $numchars = 32) {
1251 return ' CONVERT(varchar, '.$fieldname.', '.$numchars.')';
1255 * Returns the SQL for returning searching one string for the location of another.
1257 public function sql_position($needle, $haystack) {
1258 return "CHARINDEX(($needle), ($haystack))";
1262 * Returns the proper substr() SQL text used to extract substrings from DB
1263 * NOTE: this was originally returning only function name
1265 * @param string $expr some string field, no aggregates
1266 * @param mixed $start integer or expression evaluating to int
1267 * @param mixed $length optional integer or expression evaluating to int
1268 * @return string sql fragment
1270 public function sql_substr($expr, $start, $length = false) {
1271 if (count(func_get_args()) < 2) {
1272 throw new coding_exception('moodle_database::sql_substr() requires at least two parameters',
1273 'Originally this function was only returning name of SQL substring function, it now requires all parameters.');
1276 if ($length === false) {
1277 return "SUBSTRING($expr, $start, (LEN($expr) - $start + 1))";
1278 } else {
1279 return "SUBSTRING($expr, $start, $length)";
1283 /// session locking
1285 public function session_lock_supported() {
1286 return true;
1290 * Obtain session lock
1291 * @param int $rowid id of the row with session record
1292 * @param int $timeout max allowed time to wait for the lock in seconds
1293 * @return bool success
1295 public function get_session_lock($rowid, $timeout) {
1296 if (!$this->session_lock_supported()) {
1297 return;
1299 parent::get_session_lock($rowid, $timeout);
1301 $timeoutmilli = $timeout * 1000;
1303 $fullname = $this->dbname.'-'.$this->prefix.'-session-'.$rowid;
1304 // While this may work using proper {call sp_...} calls + binding +
1305 // executing + consuming recordsets, the solution used for the mssql
1306 // driver is working perfectly, so 100% mimic-ing that code.
1307 // $sql = "sp_getapplock '$fullname', 'Exclusive', 'Session', $timeoutmilli";
1308 $sql = "BEGIN
1309 DECLARE @result INT
1310 EXECUTE @result = sp_getapplock @Resource='$fullname',
1311 @LockMode='Exclusive',
1312 @LockOwner='Session',
1313 @LockTimeout='$timeoutmilli'
1314 SELECT @result
1315 END";
1316 $this->query_start($sql, null, SQL_QUERY_AUX);
1317 $result = sqlsrv_query($this->sqlsrv, $sql);
1318 $this->query_end($result);
1320 if ($result) {
1321 $row = sqlsrv_fetch_array($result);
1322 if ($row[0] < 0) {
1323 throw new dml_sessionwait_exception();
1327 $this->free_result($result);
1330 public function release_session_lock($rowid) {
1331 if (!$this->session_lock_supported()) {
1332 return;
1334 parent::release_session_lock($rowid);
1336 $fullname = $this->dbname.'-'.$this->prefix.'-session-'.$rowid;
1337 $sql = "sp_releaseapplock '$fullname', 'Session'";
1338 $this->query_start($sql, null, SQL_QUERY_AUX);
1339 $result = sqlsrv_query($this->sqlsrv, $sql);
1340 $this->query_end($result);
1341 $this->free_result($result);
1345 /// transactions
1347 // NOTE:
1348 // TODO -- should these be wrapped in query start/end? They arn't a query
1349 // but information and error capture is nice. msk
1353 * Driver specific start of real database transaction,
1354 * this can not be used directly in code.
1355 * @return void
1357 protected function begin_transaction() {
1358 $this->query_start('native sqlsrv_begin_transaction', NULL, SQL_QUERY_AUX);
1359 $result = sqlsrv_begin_transaction($this->sqlsrv);
1360 $this->query_end($result);
1364 * Driver specific commit of real database transaction,
1365 * this can not be used directly in code.
1366 * @return void
1368 protected function commit_transaction() {
1369 $this->query_start('native sqlsrv_commit', NULL, SQL_QUERY_AUX);
1370 $result = sqlsrv_commit($this->sqlsrv);
1371 $this->query_end($result);
1375 * Driver specific abort of real database transaction,
1376 * this can not be used directly in code.
1377 * @return void
1379 protected function rollback_transaction() {
1380 $this->query_start('native sqlsrv_rollback', NULL, SQL_QUERY_AUX);
1381 $result = sqlsrv_rollback($this->sqlsrv);
1382 $this->query_end($result);