Merge branch 'wip-mdl-30121-m22' of git://github.com/rajeshtaneja/moodle into MOODLE_...
[moodle.git] / lib / dml / sqlsrv_native_moodle_database.php
blob9b10eeb6b2abd3add9f822b9f34f55ae29c68758
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 if (stripos(PHP_OS, 'win') === 0) {
63 return get_string('nativesqlsrvnodriver', 'install');
64 } else {
65 return get_string('nativesqlsrvnonwindows', 'install');
68 return true;
71 /**
72 * Returns database family type - describes SQL dialect
73 * Note: can be used before connect()
74 * @return string db family name (mysql, postgres, mssql, sqlsrv, oracle, etc.)
76 public function get_dbfamily() {
77 return 'mssql';
80 /**
81 * Returns more specific database driver type
82 * Note: can be used before connect()
83 * @return string db type mysqli, pgsql, oci, mssql, sqlsrv
85 protected function get_dbtype() {
86 return 'sqlsrv';
89 /**
90 * Returns general database library name
91 * Note: can be used before connect()
92 * @return string db type pdo, native
94 protected function get_dblibrary() {
95 return 'native';
98 /**
99 * Returns localised database type name
100 * Note: can be used before connect()
101 * @return string
103 public function get_name() {
104 return get_string('nativesqlsrv', 'install');
108 * Returns localised database configuration help.
109 * Note: can be used before connect()
110 * @return string
112 public function get_configuration_help() {
113 return get_string('nativesqlsrvhelp', 'install');
117 * Returns localised database description
118 * Note: can be used before connect()
119 * @return string
121 public function get_configuration_hints() {
122 $str = get_string('databasesettingssub_sqlsrv', 'install');
123 $str .= "<p style='text-align:right'><a href=\"javascript:void(0)\" ";
124 $str .= "onclick=\"return window.open('http://docs.moodle.org/en/Using_the_Microsoft_SQL_Server_Driver_for_PHP')\"";
125 $str .= ">";
126 $str .= '<img src="pix/docs.gif'.'" alt="Docs" class="iconhelp" />';
127 $str .= get_string('moodledocslink', 'install').'</a></p>';
128 return $str;
132 * Connect to db
133 * Must be called before other methods.
134 * @param string $dbhost
135 * @param string $dbuser
136 * @param string $dbpass
137 * @param string $dbname
138 * @param mixed $prefix string means moodle db prefix, false used for external databases where prefix not used
139 * @param array $dboptions driver specific options
140 * @return bool true
141 * @throws dml_connection_exception if error
143 public function connect($dbhost, $dbuser, $dbpass, $dbname, $prefix, array $dboptions=null) {
144 $driverstatus = $this->driver_installed();
146 if ($driverstatus !== true) {
147 throw new dml_exception('dbdriverproblem', $driverstatus);
151 * Log all Errors.
153 sqlsrv_configure("WarningsReturnAsErrors", FALSE);
154 sqlsrv_configure("LogSubsystems", SQLSRV_LOG_SYSTEM_ALL);
155 sqlsrv_configure("LogSeverity", SQLSRV_LOG_SEVERITY_ERROR);
157 $this->store_settings($dbhost, $dbuser, $dbpass, $dbname, $prefix, $dboptions);
158 $this->sqlsrv = sqlsrv_connect($this->dbhost, array
160 'UID' => $this->dbuser,
161 'PWD' => $this->dbpass,
162 'Database' => $this->dbname,
163 'CharacterSet' => 'UTF-8',
164 'MultipleActiveResultSets' => true,
165 'ConnectionPooling' => !empty($this->dboptions['dbpersist']),
166 'ReturnDatesAsStrings' => true,
169 if ($this->sqlsrv === false) {
170 $this->sqlsrv = null;
171 $dberr = $this->get_last_error();
173 throw new dml_connection_exception($dberr);
176 // Allow quoted identifiers
177 $sql = "SET QUOTED_IDENTIFIER ON";
178 $this->query_start($sql, null, SQL_QUERY_AUX);
179 $result = sqlsrv_query($this->sqlsrv, $sql);
180 $this->query_end($result);
182 $this->free_result($result);
184 // Force ANSI nulls so the NULL check was done by IS NULL and NOT IS NULL
185 // instead of equal(=) and distinct(<>) symbols
186 $sql = "SET ANSI_NULLS ON";
187 $this->query_start($sql, null, SQL_QUERY_AUX);
188 $result = sqlsrv_query($this->sqlsrv, $sql);
189 $this->query_end($result);
191 $this->free_result($result);
193 // Force ANSI warnings so arithmetic/string overflows will be
194 // returning error instead of transparently truncating data
195 $sql = "SET ANSI_WARNINGS ON";
196 $this->query_start($sql, null, SQL_QUERY_AUX);
197 $result = sqlsrv_query($this->sqlsrv, $sql);
198 $this->query_end($result);
200 // Concatenating null with anything MUST return NULL
201 $sql = "SET CONCAT_NULL_YIELDS_NULL ON";
202 $this->query_start($sql, null, SQL_QUERY_AUX);
203 $result = sqlsrv_query($this->sqlsrv, $sql);
204 $this->query_end($result);
206 $this->free_result($result);
208 // Set transactions isolation level to READ_COMMITTED
209 // prevents dirty reads when using transactions +
210 // is the default isolation level of sqlsrv
211 $sql = "SET TRANSACTION ISOLATION LEVEL READ COMMITTED";
212 $this->query_start($sql, NULL, SQL_QUERY_AUX);
213 $result = sqlsrv_query($this->sqlsrv, $sql);
214 $this->query_end($result);
216 $this->free_result($result);
218 // Connection established and configured, going to instantiate the temptables controller
219 $this->temptables = new sqlsrv_native_moodle_temptables($this);
221 return true;
225 * Close database connection and release all resources
226 * and memory (especially circular memory references).
227 * Do NOT use connect() again, create a new instance if needed.
229 public function dispose() {
230 parent::dispose(); // Call parent dispose to write/close session and other common stuff before closing connection
232 if ($this->sqlsrv) {
233 sqlsrv_close($this->sqlsrv);
234 $this->sqlsrv = null;
239 * Called before each db query.
240 * @param string $sql
241 * @param array array of parameters
242 * @param int $type type of query
243 * @param mixed $extrainfo driver specific extra information
244 * @return void
246 protected function query_start($sql, array $params = null, $type, $extrainfo = null) {
247 parent::query_start($sql, $params, $type, $extrainfo);
251 * Called immediately after each db query.
252 * @param mixed db specific result
253 * @return void
255 protected function query_end($result) {
256 parent::query_end($result);
260 * Returns database server info array
261 * @return array
263 public function get_server_info() {
264 static $info;
266 if (!$info) {
267 $server_info = sqlsrv_server_info($this->sqlsrv);
269 if ($server_info) {
270 $info['description'] = $server_info['SQLServerName'];
271 $info['version'] = $server_info['SQLServerVersion'];
272 $info['database'] = $server_info['CurrentDatabase'];
275 return $info;
279 * Get the minimum SQL allowed
281 * @param mixed $version
282 * @return mixed
284 protected function is_min_version($version) {
285 $server = $this->get_server_info();
286 $server = $server['version'];
287 return version_compare($server, $version, '>=');
291 * Override: Converts short table name {tablename} to real table name
292 * supporting temp tables (#) if detected
294 * @param string sql
295 * @return string sql
297 protected function fix_table_names($sql) {
298 if (preg_match_all('/\{([a-z][a-z0-9_]*)\}/i', $sql, $matches)) {
299 foreach ($matches[0] as $key => $match) {
300 $name = $matches[1][$key];
302 if ($this->temptables->is_temptable($name)) {
303 $sql = str_replace($match, $this->temptables->get_correct_name($name), $sql);
304 } else {
305 $sql = str_replace($match, $this->prefix.$name, $sql);
309 return $sql;
313 * Returns supported query parameter types
314 * @return int bitmask
316 protected function allowed_param_types() {
317 return SQL_PARAMS_QM; // sqlsrv 1.1 can bind
321 * Returns last error reported by database engine.
322 * @return string error message
324 public function get_last_error() {
325 $retErrors = sqlsrv_errors(SQLSRV_ERR_ALL);
326 $errorMessage = 'No errors found';
328 if ($retErrors != null) {
329 $errorMessage = '';
331 foreach ($retErrors as $arrError) {
332 $errorMessage .= "SQLState: ".$arrError['SQLSTATE']."<br>\n";
333 $errorMessage .= "Error Code: ".$arrError['code']."<br>\n";
334 $errorMessage .= "Message: ".$arrError['message']."<br>\n";
338 return $errorMessage;
341 /***
342 * Bound variables *are* supported. Until I can get it to work, emulate the bindings
343 * The challenge/problem/bug is that although they work, doing a SELECT SCOPE_IDENTITY()
344 * doesn't return a value (no result set)
348 * Prepare the query binding and do the actual query.
350 * @param string $sql The sql statement
351 * @param mixed $params array of params for binding. If NULL, they are ignored.
352 * @param mixed $sql_query_type - Type of operation
353 * @param mixed $free_result - Default true, transaction query will be freed.
354 * @param mixed $scrollable - Default false, to use for quickly seeking to target records
356 private function do_query($sql, $params, $sql_query_type, $free_result = true, $scrollable = false) {
357 list($sql, $params, $type) = $this->fix_sql_params($sql, $params);
359 $sql = $this->emulate_bound_params($sql, $params);
360 $this->query_start($sql, $params, $sql_query_type);
361 if (!$scrollable) { // Only supporting next row
362 $result = sqlsrv_query($this->sqlsrv, $sql);
363 } else { // Suporting absolute/relative rows
364 $result = sqlsrv_query($this->sqlsrv, $sql, array(), array('Scrollable' => SQLSRV_CURSOR_STATIC));
367 if ($result === false) {
368 // TODO do something with error or just use if DEV or DEBUG?
369 $dberr = $this->get_last_error();
372 $this->query_end($result);
374 if ($free_result) {
375 $this->free_result($result);
376 return true;
378 return $result;
382 * Return tables in database WITHOUT current prefix
383 * @return array of table names in lowercase and without prefix
385 public function get_tables($usecache = true) {
386 if ($usecache and count($this->tables) > 0) {
387 return $this->tables;
389 $this->tables = array ();
390 $prefix = str_replace('_', '\\_', $this->prefix);
391 $sql = "SELECT table_name
392 FROM information_schema.tables
393 WHERE table_name LIKE '$prefix%' ESCAPE '\\' AND table_type = 'BASE TABLE'";
395 $this->query_start($sql, null, SQL_QUERY_AUX);
396 $result = sqlsrv_query($this->sqlsrv, $sql);
397 $this->query_end($result);
399 if ($result) {
400 while ($row = sqlsrv_fetch_array($result)) {
401 $tablename = reset($row);
402 if (strpos($tablename, $this->prefix) !== 0) {
403 continue;
405 $tablename = substr($tablename, strlen($this->prefix));
406 $this->tables[$tablename] = $tablename;
408 $this->free_result($result);
411 // Add the currently available temptables
412 $this->tables = array_merge($this->tables, $this->temptables->get_temptables());
413 return $this->tables;
417 * Return table indexes - everything lowercased
418 * @return array of arrays
420 public function get_indexes($table) {
421 $indexes = array ();
422 $tablename = $this->prefix.$table;
424 // Indexes aren't covered by information_schema metatables, so we need to
425 // go to sys ones. Skipping primary key indexes on purpose.
426 $sql = "SELECT i.name AS index_name, i.is_unique, ic.index_column_id, c.name AS column_name
427 FROM sys.indexes i
428 JOIN sys.index_columns ic ON i.object_id = ic.object_id AND i.index_id = ic.index_id
429 JOIN sys.columns c ON ic.object_id = c.object_id AND ic.column_id = c.column_id
430 JOIN sys.tables t ON i.object_id = t.object_id
431 WHERE t.name = '$tablename' AND i.is_primary_key = 0
432 ORDER BY i.name, i.index_id, ic.index_column_id";
434 $this->query_start($sql, null, SQL_QUERY_AUX);
435 $result = sqlsrv_query($this->sqlsrv, $sql);
436 $this->query_end($result);
438 if ($result) {
439 $lastindex = '';
440 $unique = false;
441 $columns = array ();
443 while ($row = sqlsrv_fetch_array($result, SQLSRV_FETCH_ASSOC)) {
444 if ($lastindex and $lastindex != $row['index_name'])
445 { // Save lastindex to $indexes and reset info
446 $indexes[$lastindex] = array
448 'unique' => $unique,
449 'columns' => $columns
452 $unique = false;
453 $columns = array ();
455 $lastindex = $row['index_name'];
456 $unique = empty($row['is_unique']) ? false : true;
457 $columns[] = $row['column_name'];
460 if ($lastindex) { // Add the last one if exists
461 $indexes[$lastindex] = array
463 'unique' => $unique,
464 'columns' => $columns
468 $this->free_result($result);
470 return $indexes;
474 * Returns detailed information about columns in table. This information is cached internally.
475 * @param string $table name
476 * @param bool $usecache
477 * @return array array of database_column_info objects indexed with column names
479 public function get_columns($table, $usecache = true) {
480 if ($usecache and isset($this->columns[$table])) {
481 return $this->columns[$table];
484 $this->columns[$table] = array ();
486 if (!$this->temptables->is_temptable($table)) { // normal table, get metadata from own schema
487 $sql = "SELECT column_name AS name,
488 data_type AS type,
489 numeric_precision AS max_length,
490 character_maximum_length AS char_max_length,
491 numeric_scale AS scale,
492 is_nullable AS is_nullable,
493 columnproperty(object_id(quotename(table_schema) + '.' + quotename(table_name)), column_name, 'IsIdentity') AS auto_increment,
494 column_default AS default_value
495 FROM information_schema.columns
496 WHERE table_name = '{".$table."}'
497 ORDER BY ordinal_position";
498 } else { // temp table, get metadata from tempdb schema
499 $sql = "SELECT column_name AS name,
500 data_type AS type,
501 numeric_precision AS max_length,
502 character_maximum_length AS char_max_length,
503 numeric_scale AS scale,
504 is_nullable AS is_nullable,
505 columnproperty(object_id(quotename(table_schema) + '.' + quotename(table_name)), column_name, 'IsIdentity') AS auto_increment,
506 column_default AS default_value
507 FROM tempdb.information_schema.columns ".
508 // check this statement
509 // JOIN tempdb..sysobjects ON name = table_name
510 // WHERE id = object_id('tempdb..{".$table."}')
511 "WHERE table_name LIKE '{".$table."}__________%'
512 ORDER BY ordinal_position";
515 list($sql, $params, $type) = $this->fix_sql_params($sql, null);
517 $this->query_start($sql, null, SQL_QUERY_AUX);
518 $result = sqlsrv_query($this->sqlsrv, $sql);
519 $this->query_end($result);
521 if (!$result) {
522 return array ();
525 while ($rawcolumn = sqlsrv_fetch_array($result, SQLSRV_FETCH_ASSOC)) {
527 $rawcolumn = (object)$rawcolumn;
529 $info = new stdClass();
530 $info->name = $rawcolumn->name;
531 $info->type = $rawcolumn->type;
532 $info->meta_type = $this->sqlsrvtype2moodletype($info->type);
534 // Prepare auto_increment info
535 $info->auto_increment = $rawcolumn->auto_increment ? true : false;
537 // Define type for auto_increment columns
538 $info->meta_type = ($info->auto_increment && $info->meta_type == 'I') ? 'R' : $info->meta_type;
540 // id columns being auto_incremnt are PK by definition
541 $info->primary_key = ($info->name == 'id' && $info->meta_type == 'R' && $info->auto_increment);
543 // Put correct length for character and LOB types
544 $info->max_length = $info->meta_type == 'C' ? $rawcolumn->char_max_length : $rawcolumn->max_length;
545 $info->max_length = ($info->meta_type == 'X' || $info->meta_type == 'B') ? -1 : $info->max_length;
547 // Scale
548 $info->scale = $rawcolumn->scale ? $rawcolumn->scale : false;
550 // Prepare not_null info
551 $info->not_null = $rawcolumn->is_nullable == 'NO' ? true : false;
553 // Process defaults
554 $info->has_default = !empty($rawcolumn->default_value);
555 if ($rawcolumn->default_value === NULL) {
556 $info->default_value = NULL;
557 } else {
558 $info->default_value = preg_replace("/^[\(N]+[']?(.*?)[']?[\)]+$/", '\\1', $rawcolumn->default_value);
561 // Process binary
562 $info->binary = $info->meta_type == 'B' ? true : false;
564 $this->columns[$table][$info->name] = new database_column_info($info);
566 $this->free_result($result);
568 return $this->columns[$table];
572 * Normalise values based in RDBMS dependencies (booleans, LOBs...)
574 * @param database_column_info $column column metadata corresponding with the value we are going to normalise
575 * @param mixed $value value we are going to normalise
576 * @return mixed the normalised value
578 protected function normalise_value($column, $value) {
579 if (is_bool($value)) { /// Always, convert boolean to int
580 $value = (int)$value;
581 } // And continue processing because text columns with numeric info need special handling below
583 if ($column->meta_type == 'B')
584 { // BLOBs need to be properly "packed", but can be inserted directly if so.
585 if (!is_null($value)) { // If value not null, unpack it to unquoted hexadecimal byte-string format
586 $value = unpack('H*hex', $value); // we leave it as array, so emulate_bound_params() can detect it
587 } // easily and "bind" the param ok.
589 } else if ($column->meta_type == 'X') { // sqlsrv doesn't cast from int to text, so if text column
590 if (is_numeric($value)) { // and is numeric value then cast to string
591 $value = array('numstr' => (string)$value); // and put into array, so emulate_bound_params() will know how
592 } // to "bind" the param ok, avoiding reverse conversion to number
593 } else if ($value === '') {
595 if ($column->meta_type == 'I' or $column->meta_type == 'F' or $column->meta_type == 'N') {
596 $value = 0; // prevent '' problems in numeric fields
599 return $value;
603 * Selectively call sqlsrv_free_stmt(), avoiding some warnings without using the horrible @
605 * @param sqlsrv_resource $resource resource to be freed if possible
607 private function free_result($resource) {
608 if (!is_bool($resource)) { // true/false resources cannot be freed
609 return sqlsrv_free_stmt($resource);
614 * Provides mapping between sqlsrv native data types and moodle_database - database_column_info - ones)
616 * @param string $sqlsrv_type native sqlsrv data type
617 * @return string 1-char database_column_info data type
619 private function sqlsrvtype2moodletype($sqlsrv_type) {
620 $type = null;
622 switch (strtoupper($sqlsrv_type)) {
623 case 'BIT':
624 $type = 'L';
625 break;
627 case 'INT':
628 case 'SMALLINT':
629 case 'INTEGER':
630 case 'BIGINT':
631 $type = 'I';
632 break;
634 case 'DECIMAL':
635 case 'REAL':
636 case 'FLOAT':
637 $type = 'N';
638 break;
640 case 'VARCHAR':
641 case 'NVARCHAR':
642 $type = 'C';
643 break;
645 case 'TEXT':
646 case 'NTEXT':
647 case 'VARCHAR(MAX)':
648 case 'NVARCHAR(MAX)':
649 $type = 'X';
650 break;
652 case 'IMAGE':
653 case 'VARBINARY(MAX)':
654 $type = 'B';
655 break;
657 case 'DATETIME':
658 $type = 'D';
659 break;
662 if (!$type) {
663 throw new dml_exception('invalidsqlsrvnativetype', $sqlsrv_type);
665 return $type;
669 * Do NOT use in code, to be used by database_manager only!
670 * @param string $sql query
671 * @return bool true
672 * @throws dml_exception if error
674 public function change_database_structure($sql) {
675 $this->reset_caches();
677 $this->query_start($sql, null, SQL_QUERY_STRUCTURE);
678 $result = sqlsrv_query($this->sqlsrv, $sql);
679 $this->query_end($result);
681 return true;
685 * Prepare the array of params for native binding
687 protected function build_native_bound_params(array $params = null) {
689 return null;
694 * Workaround for SQL*Server Native driver similar to MSSQL driver for
695 * consistent behavior.
697 protected function emulate_bound_params($sql, array $params = null) {
699 if (empty($params)) {
700 return $sql;
702 /// ok, we have verified sql statement with ? and correct number of params
703 $parts = explode('?', $sql);
704 $return = array_shift($parts);
705 foreach ($params as $param) {
706 if (is_bool($param)) {
707 $return .= (int)$param;
708 } else if (is_array($param) && isset($param['hex'])) { // detect hex binary, bind it specially
709 $return .= '0x'.$param['hex'];
710 } else if (is_array($param) && isset($param['numstr'])) { // detect numerical strings that *must not*
711 $return .= "N'{$param['numstr']}'"; // be converted back to number params, but bound as strings
712 } else if (is_null($param)) {
713 $return .= 'NULL';
715 } else if (is_number($param)) { // we can not use is_numeric() because it eats leading zeros from strings like 0045646
716 $return .= "'$param'"; // this is a hack for MDL-23997, we intentionally use string because it is compatible with both nvarchar and int types
717 } else if (is_float($param)) {
718 $return .= $param;
719 } else {
720 $param = str_replace("'", "''", $param);
721 $return .= "N'$param'";
724 $return .= array_shift($parts);
726 return $return;
730 * Execute general sql query. Should be used only when no other method suitable.
731 * Do NOT use this to make changes in db structure, use database_manager methods instead!
732 * @param string $sql query
733 * @param array $params query parameters
734 * @return bool true
735 * @throws dml_exception if error
737 public function execute($sql, array $params = null) {
738 if (strpos($sql, ';') !== false) {
739 throw new coding_exception('moodle_database::execute() Multiple sql statements found or bound parameters not used properly in query!');
741 $this->do_query($sql, $params, SQL_QUERY_UPDATE);
742 return true;
746 * Get a number of records as a moodle_recordset using a SQL statement.
748 * Since this method is a little less readable, use of it should be restricted to
749 * code where it's possible there might be large datasets being returned. For known
750 * small datasets use get_records_sql - it leads to simpler code.
752 * The return type is as for @see function get_recordset.
754 * @param string $sql the SQL select query to execute.
755 * @param array $params array of sql parameters
756 * @param int $limitfrom return a subset of records, starting at this point (optional, required if $limitnum is set).
757 * @param int $limitnum return a subset comprising this many records (optional, required if $limitfrom is set).
758 * @return moodle_recordset instance
759 * @throws dml_exception if error
761 public function get_recordset_sql($sql, array $params = null, $limitfrom = 0, $limitnum = 0) {
762 $limitfrom = (int)$limitfrom;
763 $limitnum = (int)$limitnum;
764 $limitfrom = max(0, $limitfrom);
765 $limitnum = max(0, $limitnum);
767 if ($limitfrom or $limitnum) {
768 if ($limitnum >= 1) { // Only apply TOP clause if we have any limitnum (limitfrom offset is handled later)
769 $fetch = $limitfrom + $limitnum;
770 if (PHP_INT_MAX - $limitnum < $limitfrom) { // Check PHP_INT_MAX overflow
771 $fetch = PHP_INT_MAX;
773 $sql = preg_replace('/^([\s(])*SELECT([\s]+(DISTINCT|ALL))?(?!\s*TOP\s*\()/i',
774 "\\1SELECT\\2 TOP $fetch", $sql);
777 $result = $this->do_query($sql, $params, SQL_QUERY_SELECT, false, (bool)$limitfrom);
779 if ($limitfrom) { // Skip $limitfrom records
780 sqlsrv_fetch($result, SQLSRV_SCROLL_ABSOLUTE, $limitfrom - 1);
782 return $this->create_recordset($result);
786 * Create a record set and initialize with first row
788 * @param mixed $result
789 * @return sqlsrv_native_moodle_recordset
791 protected function create_recordset($result) {
792 return new sqlsrv_native_moodle_recordset($result);
796 * Get a number of records as an array of objects using a SQL statement.
798 * Return value as for @see function get_records.
800 * @param string $sql the SQL select query to execute. The first column of this SELECT statement
801 * must be a unique value (usually the 'id' field), as it will be used as the key of the
802 * returned array.
803 * @param array $params array of sql parameters
804 * @param int $limitfrom return a subset of records, starting at this point (optional, required if $limitnum is set).
805 * @param int $limitnum return a subset comprising this many records (optional, required if $limitfrom is set).
806 * @return array of objects, or empty array if no records were found
807 * @throws dml_exception if error
809 public function get_records_sql($sql, array $params = null, $limitfrom = 0, $limitnum = 0) {
811 $rs = $this->get_recordset_sql($sql, $params, $limitfrom, $limitnum);
813 $results = array();
815 foreach ($rs as $row) {
816 $id = reset($row);
818 if (isset($results[$id])) {
819 $colname = key($row);
820 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);
822 $results[$id] = (object)$row;
824 $rs->close();
826 return $results;
830 * Selects records and return values (first field) as an array using a SQL statement.
832 * @param string $sql The SQL query
833 * @param array $params array of sql parameters
834 * @return array of values
835 * @throws dml_exception if error
837 public function get_fieldset_sql($sql, array $params = null) {
839 $rs = $this->get_recordset_sql($sql, $params);
841 $results = array ();
843 foreach ($rs as $row) {
844 $results[] = reset($row);
846 $rs->close();
848 return $results;
852 * Insert new record into database, as fast as possible, no safety checks, lobs not supported.
853 * @param string $table name
854 * @param mixed $params data record as object or array
855 * @param bool $returnit return it of inserted record
856 * @param bool $bulk true means repeated inserts expected
857 * @param bool $customsequence true if 'id' included in $params, disables $returnid
858 * @return bool|int true or new id
859 * @throws dml_exception if error
861 public function insert_record_raw($table, $params, $returnid=true, $bulk=false, $customsequence=false) {
862 if (!is_array($params)) {
863 $params = (array)$params;
865 if ($customsequence) {
866 if (!isset($params['id'])) {
867 throw new coding_exception('moodle_database::insert_record_raw() id field must be specified if custom sequences used.');
869 $returnid = false;
870 // Disable IDENTITY column before inserting record with id
871 $sql = 'SET IDENTITY_INSERT {'.$table.'} ON'; // Yes, it' ON!!
872 $this->do_query($sql, null, SQL_QUERY_AUX);
874 } else {
875 unset($params['id']);
878 if (empty($params)) {
879 throw new coding_exception('moodle_database::insert_record_raw() no fields found.');
881 $fields = implode(',', array_keys($params));
882 $qms = array_fill(0, count($params), '?');
883 $qms = implode(',', $qms);
884 $sql = "INSERT INTO {" . $table . "} ($fields) VALUES($qms)";
885 $query_id = $this->do_query($sql, $params, SQL_QUERY_INSERT);
887 if ($customsequence) {
888 // Enable IDENTITY column after inserting record with id
889 $sql = 'SET IDENTITY_INSERT {'.$table.'} OFF'; // Yes, it' OFF!!
890 $this->do_query($sql, null, SQL_QUERY_AUX);
893 if ($returnid) {
894 $id = $this->sqlsrv_fetch_id();
895 return $id;
896 } else {
897 return true;
902 * Get the ID of the current action
904 * @return mixed ID
906 private function sqlsrv_fetch_id() {
907 $query_id = sqlsrv_query($this->sqlsrv, 'SELECT SCOPE_IDENTITY()');
908 if ($query_id === false) {
909 $dberr = $this->get_last_error();
910 return false;
912 $row = $this->sqlsrv_fetchrow($query_id);
913 return (int)$row[0];
917 * Fetch a single row into an numbered array
919 * @param mixed $query_id
921 private function sqlsrv_fetchrow($query_id) {
922 $row = sqlsrv_fetch_array($query_id, SQLSRV_FETCH_NUMERIC);
923 if ($row === false) {
924 $dberr = $this->get_last_error();
925 return false;
928 foreach ($row as $key => $value) {
929 $row[$key] = ($value === ' ' || $value === NULL) ? '' : $value;
931 return $row;
935 * Insert a record into a table and return the "id" field if required.
937 * Some conversions and safety checks are carried out. Lobs are supported.
938 * If the return ID isn't required, then this just reports success as true/false.
939 * $data is an object containing needed data
940 * @param string $table The database table to be inserted into
941 * @param object $data A data object with values for one or more fields in the record
942 * @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.
943 * @return bool|int true or new id
944 * @throws dml_exception if error
946 public function insert_record($table, $dataobject, $returnid = true, $bulk = false) {
947 $dataobject = (array)$dataobject;
949 $columns = $this->get_columns($table);
950 $cleaned = array ();
952 foreach ($dataobject as $field => $value) {
953 if ($field === 'id') {
954 continue;
956 if (!isset($columns[$field])) {
957 continue;
959 $column = $columns[$field];
960 $cleaned[$field] = $this->normalise_value($column, $value);
963 return $this->insert_record_raw($table, $cleaned, $returnid, $bulk);
967 * Import a record into a table, id field is required.
968 * Safety checks are NOT carried out. Lobs are supported.
970 * @param string $table name of database table to be inserted into
971 * @param object $dataobject A data object with values for one or more fields in the record
972 * @return bool true
973 * @throws dml_exception if error
975 public function import_record($table, $dataobject) {
976 if (!is_object($dataobject)) {
977 $dataobject = (object)$dataobject;
980 $columns = $this->get_columns($table);
981 $cleaned = array ();
983 foreach ($dataobject as $field => $value) {
984 if (!isset($columns[$field])) {
985 continue;
987 $column = $columns[$field];
988 $cleaned[$field] = $this->normalise_value($column, $value);
991 $this->insert_record_raw($table, $cleaned, false, false, true);
993 return true;
997 * Update record in database, as fast as possible, no safety checks, lobs not supported.
998 * @param string $table name
999 * @param mixed $params data record as object or array
1000 * @param bool true means repeated updates expected
1001 * @return bool true
1002 * @throws dml_exception if error
1004 public function update_record_raw($table, $params, $bulk = false) {
1005 $params = (array)$params;
1007 if (!isset($params['id'])) {
1008 throw new coding_exception('moodle_database::update_record_raw() id field must be specified.');
1010 $id = $params['id'];
1011 unset($params['id']);
1013 if (empty($params)) {
1014 throw new coding_exception('moodle_database::update_record_raw() no fields found.');
1017 $sets = array ();
1019 foreach ($params as $field => $value) {
1020 $sets[] = "$field = ?";
1023 $params[] = $id; // last ? in WHERE condition
1025 $sets = implode(',', $sets);
1026 $sql = "UPDATE {".$table."} SET $sets WHERE id = ?";
1028 $this->do_query($sql, $params, SQL_QUERY_UPDATE);
1030 return true;
1034 * Update a record in a table
1036 * $dataobject is an object containing needed data
1037 * Relies on $dataobject having a variable "id" to
1038 * specify the record to update
1040 * @param string $table The database table to be checked against.
1041 * @param object $dataobject An object with contents equal to fieldname=>fieldvalue. Must have an entry for 'id' to map to the table specified.
1042 * @param bool true means repeated updates expected
1043 * @return bool true
1044 * @throws dml_exception if error
1046 public function update_record($table, $dataobject, $bulk = false) {
1047 $dataobject = (array)$dataobject;
1049 $columns = $this->get_columns($table);
1050 $cleaned = array ();
1052 foreach ($dataobject as $field => $value) {
1053 if (!isset($columns[$field])) {
1054 continue;
1056 $column = $columns[$field];
1057 $cleaned[$field] = $this->normalise_value($column, $value);
1060 return $this->update_record_raw($table, $cleaned, $bulk);
1064 * Set a single field in every table record which match a particular WHERE clause.
1066 * @param string $table The database table to be checked against.
1067 * @param string $newfield the field to set.
1068 * @param string $newvalue the value to set the field to.
1069 * @param string $select A fragment of SQL to be used in a where clause in the SQL call.
1070 * @param array $params array of sql parameters
1071 * @return bool true
1072 * @throws dml_exception if error
1074 public function set_field_select($table, $newfield, $newvalue, $select, array $params = null) {
1075 if ($select) {
1076 $select = "WHERE $select";
1079 if (is_null($params)) {
1080 $params = array ();
1083 // convert params to ? types
1084 list($select, $params, $type) = $this->fix_sql_params($select, $params);
1086 /// Get column metadata
1087 $columns = $this->get_columns($table);
1088 $column = $columns[$newfield];
1090 $newvalue = $this->normalise_value($column, $newvalue);
1092 if (is_null($newvalue)) {
1093 $newfield = "$newfield = NULL";
1094 } else {
1095 $newfield = "$newfield = ?";
1096 array_unshift($params, $newvalue);
1098 $sql = "UPDATE {".$table."} SET $newfield $select";
1100 $this->do_query($sql, $params, SQL_QUERY_UPDATE);
1102 return true;
1106 * Delete one or more records from a table which match a particular WHERE clause.
1108 * @param string $table The database table to be checked against.
1109 * @param string $select A fragment of SQL to be used in a where clause in the SQL call (used to define the selection criteria).
1110 * @param array $params array of sql parameters
1111 * @return bool true
1112 * @throws dml_exception if error
1114 public function delete_records_select($table, $select, array $params = null) {
1115 if ($select) {
1116 $select = "WHERE $select";
1119 $sql = "DELETE FROM {".$table."} $select";
1121 // we use SQL_QUERY_UPDATE because we do not know what is in general SQL, delete constant would not be accurate
1122 $this->do_query($sql, $params, SQL_QUERY_UPDATE);
1124 return true;
1128 /// SQL helper functions
1130 public function sql_cast_char2int($fieldname, $text = false) {
1131 if (!$text) {
1132 return ' CAST(' . $fieldname . ' AS INT) ';
1133 } else {
1134 return ' CAST(' . $this->sql_compare_text($fieldname) . ' AS INT) ';
1138 public function sql_cast_char2real($fieldname, $text=false) {
1139 if (!$text) {
1140 return ' CAST(' . $fieldname . ' AS REAL) ';
1141 } else {
1142 return ' CAST(' . $this->sql_compare_text($fieldname) . ' AS REAL) ';
1146 public function sql_ceil($fieldname) {
1147 return ' CEILING('.$fieldname.')';
1150 protected function get_collation() {
1151 if (isset($this->collation)) {
1152 return $this->collation;
1154 if (!empty($this->dboptions['dbcollation'])) {
1155 // perf speedup
1156 $this->collation = $this->dboptions['dbcollation'];
1157 return $this->collation;
1160 // make some default
1161 $this->collation = 'Latin1_General_CI_AI';
1163 $sql = "SELECT CAST(DATABASEPROPERTYEX('$this->dbname', 'Collation') AS varchar(255)) AS SQLCollation";
1164 $this->query_start($sql, null, SQL_QUERY_AUX);
1165 $result = sqlsrv_query($this->sqlsrv, $sql);
1166 $this->query_end($result);
1168 if ($result) {
1169 if ($rawcolumn = sqlsrv_fetch_array($result, SQLSRV_FETCH_ASSOC)) {
1170 $this->collation = reset($rawcolumn);
1172 $this->free_result($result);
1175 return $this->collation;
1179 * Returns 'LIKE' part of a query.
1181 * @param string $fieldname usually name of the table column
1182 * @param string $param usually bound query parameter (?, :named)
1183 * @param bool $casesensitive use case sensitive search
1184 * @param bool $accensensitive use accent sensitive search (not all databases support accent insensitive)
1185 * @param bool $notlike true means "NOT LIKE"
1186 * @param string $escapechar escape char for '%' and '_'
1187 * @return string SQL code fragment
1189 public function sql_like($fieldname, $param, $casesensitive = true, $accentsensitive = true, $notlike = false, $escapechar = '\\') {
1190 if (strpos($param, '%') !== false) {
1191 debugging('Potential SQL injection detected, sql_ilike() expects bound parameters (? or :named)');
1194 $collation = $this->get_collation();
1195 $LIKE = $notlike ? 'NOT LIKE' : 'LIKE';
1197 if ($casesensitive) {
1198 $collation = str_replace('_CI', '_CS', $collation);
1199 } else {
1200 $collation = str_replace('_CS', '_CI', $collation);
1202 if ($accentsensitive) {
1203 $collation = str_replace('_AI', '_AS', $collation);
1204 } else {
1205 $collation = str_replace('_AS', '_AI', $collation);
1208 return "$fieldname COLLATE $collation $LIKE $param ESCAPE '$escapechar'";
1211 public function sql_concat() {
1212 $arr = func_get_args();
1214 foreach ($arr as $key => $ele) {
1215 $arr[$key] = ' CAST('.$ele.' AS VARCHAR(255)) ';
1217 $s = implode(' + ', $arr);
1219 if ($s === '') {
1220 return " '' ";
1222 return " $s ";
1225 public function sql_concat_join($separator = "' '", $elements = array ()) {
1226 for ($n = count($elements) - 1; $n > 0; $n--) {
1227 array_splice($elements, $n, 0, $separator);
1229 $s = implode(' + ', $elements);
1231 if ($s === '') {
1232 return " '' ";
1234 return " $s ";
1237 public function sql_isempty($tablename, $fieldname, $nullablefield, $textfield) {
1238 if ($textfield) {
1239 return ' ('.$this->sql_compare_text($fieldname)." = '') ";
1240 } else {
1241 return " ($fieldname = '') ";
1246 * Returns the SQL text to be used to calculate the length in characters of one expression.
1247 * @param string fieldname or expression to calculate its length in characters.
1248 * @return string the piece of SQL code to be used in the statement.
1250 public function sql_length($fieldname) {
1251 return ' LEN('.$fieldname.')';
1254 public function sql_order_by_text($fieldname, $numchars = 32) {
1255 return ' CONVERT(varchar, '.$fieldname.', '.$numchars.')';
1259 * Returns the SQL for returning searching one string for the location of another.
1261 public function sql_position($needle, $haystack) {
1262 return "CHARINDEX(($needle), ($haystack))";
1266 * Returns the proper substr() SQL text used to extract substrings from DB
1267 * NOTE: this was originally returning only function name
1269 * @param string $expr some string field, no aggregates
1270 * @param mixed $start integer or expression evaluating to int
1271 * @param mixed $length optional integer or expression evaluating to int
1272 * @return string sql fragment
1274 public function sql_substr($expr, $start, $length = false) {
1275 if (count(func_get_args()) < 2) {
1276 throw new coding_exception('moodle_database::sql_substr() requires at least two parameters',
1277 'Originally this function was only returning name of SQL substring function, it now requires all parameters.');
1280 if ($length === false) {
1281 return "SUBSTRING($expr, $start, (LEN($expr) - $start + 1))";
1282 } else {
1283 return "SUBSTRING($expr, $start, $length)";
1287 /// session locking
1289 public function session_lock_supported() {
1290 return true;
1294 * Obtain session lock
1295 * @param int $rowid id of the row with session record
1296 * @param int $timeout max allowed time to wait for the lock in seconds
1297 * @return bool success
1299 public function get_session_lock($rowid, $timeout) {
1300 if (!$this->session_lock_supported()) {
1301 return;
1303 parent::get_session_lock($rowid, $timeout);
1305 $timeoutmilli = $timeout * 1000;
1307 $fullname = $this->dbname.'-'.$this->prefix.'-session-'.$rowid;
1308 // While this may work using proper {call sp_...} calls + binding +
1309 // executing + consuming recordsets, the solution used for the mssql
1310 // driver is working perfectly, so 100% mimic-ing that code.
1311 // $sql = "sp_getapplock '$fullname', 'Exclusive', 'Session', $timeoutmilli";
1312 $sql = "BEGIN
1313 DECLARE @result INT
1314 EXECUTE @result = sp_getapplock @Resource='$fullname',
1315 @LockMode='Exclusive',
1316 @LockOwner='Session',
1317 @LockTimeout='$timeoutmilli'
1318 SELECT @result
1319 END";
1320 $this->query_start($sql, null, SQL_QUERY_AUX);
1321 $result = sqlsrv_query($this->sqlsrv, $sql);
1322 $this->query_end($result);
1324 if ($result) {
1325 $row = sqlsrv_fetch_array($result);
1326 if ($row[0] < 0) {
1327 throw new dml_sessionwait_exception();
1331 $this->free_result($result);
1334 public function release_session_lock($rowid) {
1335 if (!$this->session_lock_supported()) {
1336 return;
1338 parent::release_session_lock($rowid);
1340 $fullname = $this->dbname.'-'.$this->prefix.'-session-'.$rowid;
1341 $sql = "sp_releaseapplock '$fullname', 'Session'";
1342 $this->query_start($sql, null, SQL_QUERY_AUX);
1343 $result = sqlsrv_query($this->sqlsrv, $sql);
1344 $this->query_end($result);
1345 $this->free_result($result);
1349 /// transactions
1351 // NOTE:
1352 // TODO -- should these be wrapped in query start/end? They arn't a query
1353 // but information and error capture is nice. msk
1357 * Driver specific start of real database transaction,
1358 * this can not be used directly in code.
1359 * @return void
1361 protected function begin_transaction() {
1362 $this->query_start('native sqlsrv_begin_transaction', NULL, SQL_QUERY_AUX);
1363 $result = sqlsrv_begin_transaction($this->sqlsrv);
1364 $this->query_end($result);
1368 * Driver specific commit of real database transaction,
1369 * this can not be used directly in code.
1370 * @return void
1372 protected function commit_transaction() {
1373 $this->query_start('native sqlsrv_commit', NULL, SQL_QUERY_AUX);
1374 $result = sqlsrv_commit($this->sqlsrv);
1375 $this->query_end($result);
1379 * Driver specific abort of real database transaction,
1380 * this can not be used directly in code.
1381 * @return void
1383 protected function rollback_transaction() {
1384 $this->query_start('native sqlsrv_rollback', NULL, SQL_QUERY_AUX);
1385 $result = sqlsrv_rollback($this->sqlsrv);
1386 $this->query_end($result);