Merge branch 'MDL-75105_401_STABLE' of https://github.com/marxjohnson/moodle into...
[moodle.git] / lib / dml / sqlsrv_native_moodle_database.php
blob37a1d9fe4ba9fc3bdbc9206a5188ed5cc1026696
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 /**
45 * Does the used db version support ANSI way of limiting (2012 and higher)
46 * @var bool
48 protected $supportsoffsetfetch;
50 /** @var array list of open recordsets */
51 protected $recordsets = array();
53 /** @var array list of reserve words in MSSQL / Transact from http://msdn2.microsoft.com/en-us/library/ms189822.aspx */
54 protected $reservewords = [
55 "add", "all", "alter", "and", "any", "as", "asc", "authorization", "avg", "backup", "begin", "between", "break",
56 "browse", "bulk", "by", "cascade", "case", "check", "checkpoint", "close", "clustered", "coalesce", "collate", "column",
57 "commit", "committed", "compute", "confirm", "constraint", "contains", "containstable", "continue", "controlrow",
58 "convert", "count", "create", "cross", "current", "current_date", "current_time", "current_timestamp", "current_user",
59 "cursor", "database", "dbcc", "deallocate", "declare", "default", "delete", "deny", "desc", "disk", "distinct",
60 "distributed", "double", "drop", "dummy", "dump", "else", "end", "errlvl", "errorexit", "escape", "except", "exec",
61 "execute", "exists", "exit", "external", "fetch", "file", "fillfactor", "floppy", "for", "foreign", "freetext",
62 "freetexttable", "from", "full", "function", "goto", "grant", "group", "having", "holdlock", "identity",
63 "identity_insert", "identitycol", "if", "in", "index", "inner", "insert", "intersect", "into", "is", "isolation",
64 "join", "key", "kill", "left", "level", "like", "lineno", "load", "max", "merge", "min", "mirrorexit", "national",
65 "nocheck", "nonclustered", "not", "null", "nullif", "of", "off", "offsets", "on", "once", "only", "open",
66 "opendatasource", "openquery", "openrowset", "openxml", "option", "or", "order", "outer", "over", "percent", "perm",
67 "permanent", "pipe", "pivot", "plan", "precision", "prepare", "primary", "print", "privileges", "proc", "procedure",
68 "processexit", "public", "raiserror", "read", "readtext", "reconfigure", "references", "repeatable", "replication",
69 "restore", "restrict", "return", "revert", "revoke", "right", "rollback", "rowcount", "rowguidcol", "rule", "save",
70 "schema", "securityaudit", "select", "semantickeyphrasetable", "semanticsimilaritydetailstable",
71 "semanticsimilaritytable", "serializable", "session_user", "set", "setuser", "shutdown", "some", "statistics", "sum",
72 "system_user", "table", "tablesample", "tape", "temp", "temporary", "textsize", "then", "to", "top", "tran",
73 "transaction", "trigger", "truncate", "try_convert", "tsequal", "uncommitted", "union", "unique", "unpivot", "update",
74 "updatetext", "use", "user", "values", "varying", "view", "waitfor", "when", "where", "while", "with", "within group",
75 "work", "writetext"
78 /**
79 * Constructor - instantiates the database, specifying if it's external (connect to other systems) or no (Moodle DB)
80 * note this has effect to decide if prefix checks must be performed or no
81 * @param bool true means external database used
83 public function __construct($external=false) {
84 parent::__construct($external);
87 /**
88 * Detects if all needed PHP stuff installed.
89 * Note: can be used before connect()
90 * @return mixed true if ok, string if something
92 public function driver_installed() {
93 // use 'function_exists()' rather than 'extension_loaded()' because
94 // the name used by 'extension_loaded()' is case specific! The extension
95 // therefore *could be* mixed case and hence not found.
96 if (!function_exists('sqlsrv_num_rows')) {
97 return get_string('nativesqlsrvnodriver', 'install');
99 return true;
103 * Returns database family type - describes SQL dialect
104 * Note: can be used before connect()
105 * @return string db family name (mysql, postgres, mssql, sqlsrv, oracle, etc.)
107 public function get_dbfamily() {
108 return 'mssql';
112 * Returns more specific database driver type
113 * Note: can be used before connect()
114 * @return string db type mysqli, pgsql, oci, mssql, sqlsrv
116 protected function get_dbtype() {
117 return 'sqlsrv';
121 * Returns general database library name
122 * Note: can be used before connect()
123 * @return string db type pdo, native
125 protected function get_dblibrary() {
126 return 'native';
130 * Returns localised database type name
131 * Note: can be used before connect()
132 * @return string
134 public function get_name() {
135 return get_string('nativesqlsrv', 'install');
139 * Returns localised database configuration help.
140 * Note: can be used before connect()
141 * @return string
143 public function get_configuration_help() {
144 return get_string('nativesqlsrvhelp', 'install');
148 * Diagnose database and tables, this function is used
149 * to verify database and driver settings, db engine types, etc.
151 * @return string null means everything ok, string means problem found.
153 public function diagnose() {
154 // Verify the database is running with READ_COMMITTED_SNAPSHOT enabled.
155 // (that's required to get snapshots/row versioning on READ_COMMITED mode).
156 $correctrcsmode = false;
157 $sql = "SELECT is_read_committed_snapshot_on
158 FROM sys.databases
159 WHERE name = '{$this->dbname}'";
160 $this->query_start($sql, null, SQL_QUERY_AUX);
161 $result = sqlsrv_query($this->sqlsrv, $sql);
162 $this->query_end($result);
163 if ($result) {
164 if ($row = sqlsrv_fetch_array($result)) {
165 $correctrcsmode = (bool)reset($row);
168 $this->free_result($result);
170 if (!$correctrcsmode) {
171 return get_string('mssqlrcsmodemissing', 'error');
174 // Arrived here, all right.
175 return null;
179 * Connect to db
180 * Must be called before most other methods. (you can call methods that return connection configuration parameters)
181 * @param string $dbhost The database host.
182 * @param string $dbuser The database username.
183 * @param string $dbpass The database username's password.
184 * @param string $dbname The name of the database being connected to.
185 * @param mixed $prefix string|bool The moodle db table name's prefix. false is used for external databases where prefix not used
186 * @param array $dboptions driver specific options
187 * @return bool true
188 * @throws dml_connection_exception if error
190 public function connect($dbhost, $dbuser, $dbpass, $dbname, $prefix, array $dboptions=null) {
191 if ($prefix == '' and !$this->external) {
192 // Enforce prefixes for everybody but mysql.
193 throw new dml_exception('prefixcannotbeempty', $this->get_dbfamily());
196 $driverstatus = $this->driver_installed();
198 if ($driverstatus !== true) {
199 throw new dml_exception('dbdriverproblem', $driverstatus);
203 * Log all Errors.
205 sqlsrv_configure("WarningsReturnAsErrors", FALSE);
206 sqlsrv_configure("LogSubsystems", SQLSRV_LOG_SYSTEM_OFF);
207 sqlsrv_configure("LogSeverity", SQLSRV_LOG_SEVERITY_ERROR);
209 $this->store_settings($dbhost, $dbuser, $dbpass, $dbname, $prefix, $dboptions);
211 $dbhost = $this->dbhost;
212 if (!empty($dboptions['dbport'])) {
213 $dbhost .= ',' . $dboptions['dbport'];
216 $this->sqlsrv = sqlsrv_connect($dbhost, array
218 'UID' => $this->dbuser,
219 'PWD' => $this->dbpass,
220 'Database' => $this->dbname,
221 'CharacterSet' => 'UTF-8',
222 'MultipleActiveResultSets' => true,
223 'ConnectionPooling' => !empty($this->dboptions['dbpersist']),
224 'ReturnDatesAsStrings' => true,
227 if ($this->sqlsrv === false) {
228 $this->sqlsrv = null;
229 $dberr = $this->get_last_error();
231 throw new dml_connection_exception($dberr);
234 // Disable logging until we are fully setup.
235 $this->query_log_prevent();
237 // Allow quoted identifiers
238 $sql = "SET QUOTED_IDENTIFIER ON";
239 $this->query_start($sql, null, SQL_QUERY_AUX);
240 $result = sqlsrv_query($this->sqlsrv, $sql);
241 $this->query_end($result);
243 $this->free_result($result);
245 // Force ANSI nulls so the NULL check was done by IS NULL and NOT IS NULL
246 // instead of equal(=) and distinct(<>) symbols
247 $sql = "SET ANSI_NULLS ON";
248 $this->query_start($sql, null, SQL_QUERY_AUX);
249 $result = sqlsrv_query($this->sqlsrv, $sql);
250 $this->query_end($result);
252 $this->free_result($result);
254 // Force ANSI warnings so arithmetic/string overflows will be
255 // returning error instead of transparently truncating data
256 $sql = "SET ANSI_WARNINGS ON";
257 $this->query_start($sql, null, SQL_QUERY_AUX);
258 $result = sqlsrv_query($this->sqlsrv, $sql);
259 $this->query_end($result);
261 // Concatenating null with anything MUST return NULL
262 $sql = "SET CONCAT_NULL_YIELDS_NULL ON";
263 $this->query_start($sql, null, SQL_QUERY_AUX);
264 $result = sqlsrv_query($this->sqlsrv, $sql);
265 $this->query_end($result);
267 $this->free_result($result);
269 // Set transactions isolation level to READ_COMMITTED
270 // prevents dirty reads when using transactions +
271 // is the default isolation level of sqlsrv
272 $sql = "SET TRANSACTION ISOLATION LEVEL READ COMMITTED";
273 $this->query_start($sql, NULL, SQL_QUERY_AUX);
274 $result = sqlsrv_query($this->sqlsrv, $sql);
275 $this->query_end($result);
277 $this->free_result($result);
279 $serverinfo = $this->get_server_info();
280 // Fetch/offset is supported staring from SQL Server 2012.
281 $this->supportsoffsetfetch = $serverinfo['version'] > '11';
283 // We can enable logging now.
284 $this->query_log_allow();
286 // Connection established and configured, going to instantiate the temptables controller
287 $this->temptables = new sqlsrv_native_moodle_temptables($this);
289 return true;
293 * Close database connection and release all resources
294 * and memory (especially circular memory references).
295 * Do NOT use connect() again, create a new instance if needed.
297 public function dispose() {
298 parent::dispose(); // Call parent dispose to write/close session and other common stuff before closing connection
300 if ($this->sqlsrv) {
301 sqlsrv_close($this->sqlsrv);
302 $this->sqlsrv = null;
307 * Called before each db query.
308 * @param string $sql
309 * @param array|null $params An array of parameters.
310 * @param int $type type of query
311 * @param mixed $extrainfo driver specific extra information
312 * @return void
314 protected function query_start($sql, ?array $params, $type, $extrainfo = null) {
315 parent::query_start($sql, $params, $type, $extrainfo);
319 * Called immediately after each db query.
320 * @param mixed db specific result
321 * @return void
323 protected function query_end($result) {
324 parent::query_end($result);
328 * Returns database server info array
329 * @return array Array containing 'description', 'version' and 'database' (current db) info
331 public function get_server_info() {
332 static $info;
334 if (!$info) {
335 $server_info = sqlsrv_server_info($this->sqlsrv);
337 if ($server_info) {
338 $info['description'] = $server_info['SQLServerName'];
339 $info['version'] = $server_info['SQLServerVersion'];
340 $info['database'] = $server_info['CurrentDatabase'];
343 return $info;
347 * Override: Converts short table name {tablename} to real table name
348 * supporting temp tables (#) if detected
350 * @param string sql
351 * @return string sql
353 protected function fix_table_names($sql) {
354 if (preg_match_all('/\{([a-z][a-z0-9_]*)\}/i', $sql, $matches)) {
355 foreach ($matches[0] as $key => $match) {
356 $name = $matches[1][$key];
358 if ($this->temptables->is_temptable($name)) {
359 $sql = str_replace($match, $this->temptables->get_correct_name($name), $sql);
360 } else {
361 $sql = str_replace($match, $this->prefix.$name, $sql);
365 return $sql;
369 * Returns supported query parameter types
370 * @return int bitmask
372 protected function allowed_param_types() {
373 return SQL_PARAMS_QM; // sqlsrv 1.1 can bind
377 * Returns last error reported by database engine.
378 * @return string error message
380 public function get_last_error() {
381 $retErrors = sqlsrv_errors(SQLSRV_ERR_ALL);
382 $errorMessage = 'No errors found';
384 if ($retErrors != null) {
385 $errorMessage = '';
387 foreach ($retErrors as $arrError) {
388 $errorMessage .= "SQLState: ".$arrError['SQLSTATE']."<br>\n";
389 $errorMessage .= "Error Code: ".$arrError['code']."<br>\n";
390 $errorMessage .= "Message: ".$arrError['message']."<br>\n";
394 return $errorMessage;
398 * Prepare the query binding and do the actual query.
400 * @param string $sql The sql statement
401 * @param array $params array of params for binding. If NULL, they are ignored.
402 * @param int $sql_query_type - Type of operation
403 * @param bool $free_result - Default true, transaction query will be freed.
404 * @param bool $scrollable - Default false, to use for quickly seeking to target records
405 * @return resource|bool result
407 private function do_query($sql, $params, $sql_query_type, $free_result = true, $scrollable = false) {
408 list($sql, $params, $type) = $this->fix_sql_params($sql, $params);
411 * Bound variables *are* supported. Until I can get it to work, emulate the bindings
412 * The challenge/problem/bug is that although they work, doing a SELECT SCOPE_IDENTITY()
413 * doesn't return a value (no result set)
415 * -- somebody from MS
418 $sql = $this->emulate_bound_params($sql, $params);
419 $this->query_start($sql, $params, $sql_query_type);
420 if (!$scrollable) { // Only supporting next row
421 $result = sqlsrv_query($this->sqlsrv, $sql);
422 } else { // Supporting absolute/relative rows
423 $result = sqlsrv_query($this->sqlsrv, $sql, array(), array('Scrollable' => SQLSRV_CURSOR_STATIC));
426 if ($result === false) {
427 // TODO do something with error or just use if DEV or DEBUG?
428 $dberr = $this->get_last_error();
431 $this->query_end($result);
433 if ($free_result) {
434 $this->free_result($result);
435 return true;
437 return $result;
441 * Return tables in database WITHOUT current prefix.
442 * @param bool $usecache if true, returns list of cached tables.
443 * @return array of table names in lowercase and without prefix
445 public function get_tables($usecache = true) {
446 if ($usecache and $this->tables !== null) {
447 return $this->tables;
449 $this->tables = array ();
450 $prefix = str_replace('_', '\\_', $this->prefix);
451 $sql = "SELECT table_name
452 FROM INFORMATION_SCHEMA.TABLES
453 WHERE table_name LIKE '$prefix%' ESCAPE '\\' AND table_type = 'BASE TABLE'";
455 $this->query_start($sql, null, SQL_QUERY_AUX);
456 $result = sqlsrv_query($this->sqlsrv, $sql);
457 $this->query_end($result);
459 if ($result) {
460 while ($row = sqlsrv_fetch_array($result)) {
461 $tablename = reset($row);
462 if ($this->prefix !== false && $this->prefix !== '') {
463 if (strpos($tablename, $this->prefix) !== 0) {
464 continue;
466 $tablename = substr($tablename, strlen($this->prefix));
468 $this->tables[$tablename] = $tablename;
470 $this->free_result($result);
473 // Add the currently available temptables
474 $this->tables = array_merge($this->tables, $this->temptables->get_temptables());
475 return $this->tables;
479 * Return table indexes - everything lowercased.
480 * @param string $table The table we want to get indexes from.
481 * @return array of arrays
483 public function get_indexes($table) {
484 $indexes = array ();
485 $tablename = $this->prefix.$table;
487 // Indexes aren't covered by information_schema metatables, so we need to
488 // go to sys ones. Skipping primary key indexes on purpose.
489 $sql = "SELECT i.name AS index_name, i.is_unique, ic.index_column_id, c.name AS column_name
490 FROM sys.indexes i
491 JOIN sys.index_columns ic ON i.object_id = ic.object_id AND i.index_id = ic.index_id
492 JOIN sys.columns c ON ic.object_id = c.object_id AND ic.column_id = c.column_id
493 JOIN sys.tables t ON i.object_id = t.object_id
494 WHERE t.name = '$tablename' AND i.is_primary_key = 0
495 ORDER BY i.name, i.index_id, ic.index_column_id";
497 $this->query_start($sql, null, SQL_QUERY_AUX);
498 $result = sqlsrv_query($this->sqlsrv, $sql);
499 $this->query_end($result);
501 if ($result) {
502 $lastindex = '';
503 $unique = false;
504 $columns = array ();
506 while ($row = sqlsrv_fetch_array($result, SQLSRV_FETCH_ASSOC)) {
507 if ($lastindex and $lastindex != $row['index_name'])
508 { // Save lastindex to $indexes and reset info
509 $indexes[$lastindex] = array
511 'unique' => $unique,
512 'columns' => $columns
515 $unique = false;
516 $columns = array ();
518 $lastindex = $row['index_name'];
519 $unique = empty($row['is_unique']) ? false : true;
520 $columns[] = $row['column_name'];
523 if ($lastindex) { // Add the last one if exists
524 $indexes[$lastindex] = array
526 'unique' => $unique,
527 'columns' => $columns
531 $this->free_result($result);
533 return $indexes;
537 * Returns detailed information about columns in table.
539 * @param string $table name
540 * @return array array of database_column_info objects indexed with column names
542 protected function fetch_columns(string $table): array {
543 $structure = array();
545 if (!$this->temptables->is_temptable($table)) { // normal table, get metadata from own schema
546 $sql = "SELECT column_name AS name,
547 data_type AS type,
548 numeric_precision AS max_length,
549 character_maximum_length AS char_max_length,
550 numeric_scale AS scale,
551 is_nullable AS is_nullable,
552 columnproperty(object_id(quotename(table_schema) + '.' + quotename(table_name)), column_name, 'IsIdentity') AS auto_increment,
553 column_default AS default_value
554 FROM INFORMATION_SCHEMA.COLUMNS
555 WHERE table_name = '{".$table."}'
556 ORDER BY ordinal_position";
557 } else { // temp table, get metadata from tempdb schema
558 $sql = "SELECT column_name AS name,
559 data_type AS type,
560 numeric_precision AS max_length,
561 character_maximum_length AS char_max_length,
562 numeric_scale AS scale,
563 is_nullable AS is_nullable,
564 columnproperty(object_id(quotename(table_schema) + '.' + quotename(table_name)), column_name, 'IsIdentity') AS auto_increment,
565 column_default AS default_value
566 FROM tempdb.INFORMATION_SCHEMA.COLUMNS ".
567 // check this statement
568 // JOIN tempdb..sysobjects ON name = table_name
569 // WHERE id = object_id('tempdb..{".$table."}')
570 "WHERE table_name LIKE '{".$table."}__________%'
571 ORDER BY ordinal_position";
574 list($sql, $params, $type) = $this->fix_sql_params($sql, null);
576 $this->query_start($sql, null, SQL_QUERY_AUX);
577 $result = sqlsrv_query($this->sqlsrv, $sql);
578 $this->query_end($result);
580 if (!$result) {
581 return array ();
584 while ($rawcolumn = sqlsrv_fetch_array($result, SQLSRV_FETCH_ASSOC)) {
586 $rawcolumn = (object)$rawcolumn;
588 $info = new stdClass();
589 $info->name = $rawcolumn->name;
590 $info->type = $rawcolumn->type;
591 $info->meta_type = $this->sqlsrvtype2moodletype($info->type);
593 // Prepare auto_increment info
594 $info->auto_increment = $rawcolumn->auto_increment ? true : false;
596 // Define type for auto_increment columns
597 $info->meta_type = ($info->auto_increment && $info->meta_type == 'I') ? 'R' : $info->meta_type;
599 // id columns being auto_incremnt are PK by definition
600 $info->primary_key = ($info->name == 'id' && $info->meta_type == 'R' && $info->auto_increment);
602 if ($info->meta_type === 'C' and $rawcolumn->char_max_length == -1) {
603 // This is NVARCHAR(MAX), not a normal NVARCHAR.
604 $info->max_length = -1;
605 $info->meta_type = 'X';
606 } else {
607 // Put correct length for character and LOB types
608 $info->max_length = $info->meta_type == 'C' ? $rawcolumn->char_max_length : $rawcolumn->max_length;
609 $info->max_length = ($info->meta_type == 'X' || $info->meta_type == 'B') ? -1 : $info->max_length;
612 // Scale
613 $info->scale = $rawcolumn->scale;
615 // Prepare not_null info
616 $info->not_null = $rawcolumn->is_nullable == 'NO' ? true : false;
618 // Process defaults
619 $info->has_default = !empty($rawcolumn->default_value);
620 if ($rawcolumn->default_value === NULL) {
621 $info->default_value = NULL;
622 } else {
623 $info->default_value = preg_replace("/^[\(N]+[']?(.*?)[']?[\)]+$/", '\\1', $rawcolumn->default_value);
626 // Process binary
627 $info->binary = $info->meta_type == 'B' ? true : false;
629 $structure[$info->name] = new database_column_info($info);
631 $this->free_result($result);
633 return $structure;
637 * Normalise values based in RDBMS dependencies (booleans, LOBs...)
639 * @param database_column_info $column column metadata corresponding with the value we are going to normalise
640 * @param mixed $value value we are going to normalise
641 * @return mixed the normalised value
643 protected function normalise_value($column, $value) {
644 $this->detect_objects($value);
646 if (is_bool($value)) { // Always, convert boolean to int
647 $value = (int)$value;
648 } // And continue processing because text columns with numeric info need special handling below
650 if ($column->meta_type == 'B')
651 { // BLOBs need to be properly "packed", but can be inserted directly if so.
652 if (!is_null($value)) { // If value not null, unpack it to unquoted hexadecimal byte-string format
653 $value = unpack('H*hex', $value); // we leave it as array, so emulate_bound_params() can detect it
654 } // easily and "bind" the param ok.
656 } else if ($column->meta_type == 'X') { // sqlsrv doesn't cast from int to text, so if text column
657 if (is_numeric($value)) { // and is numeric value then cast to string
658 $value = array('numstr' => (string)$value); // and put into array, so emulate_bound_params() will know how
659 } // to "bind" the param ok, avoiding reverse conversion to number
660 } else if ($value === '') {
662 if ($column->meta_type == 'I' or $column->meta_type == 'F' or $column->meta_type == 'N') {
663 $value = 0; // prevent '' problems in numeric fields
666 return $value;
670 * Selectively call sqlsrv_free_stmt(), avoiding some warnings without using the horrible @
672 * @param sqlsrv_resource $resource resource to be freed if possible
673 * @return bool
675 private function free_result($resource) {
676 if (!is_bool($resource)) { // true/false resources cannot be freed
677 return sqlsrv_free_stmt($resource);
682 * Provides mapping between sqlsrv native data types and moodle_database - database_column_info - ones)
684 * @param string $sqlsrv_type native sqlsrv data type
685 * @return string 1-char database_column_info data type
687 private function sqlsrvtype2moodletype($sqlsrv_type) {
688 $type = null;
690 switch (strtoupper($sqlsrv_type)) {
691 case 'BIT':
692 $type = 'L';
693 break;
695 case 'INT':
696 case 'SMALLINT':
697 case 'INTEGER':
698 case 'BIGINT':
699 $type = 'I';
700 break;
702 case 'DECIMAL':
703 case 'REAL':
704 case 'FLOAT':
705 $type = 'N';
706 break;
708 case 'VARCHAR':
709 case 'NVARCHAR':
710 $type = 'C';
711 break;
713 case 'TEXT':
714 case 'NTEXT':
715 case 'VARCHAR(MAX)':
716 case 'NVARCHAR(MAX)':
717 $type = 'X';
718 break;
720 case 'IMAGE':
721 case 'VARBINARY':
722 case 'VARBINARY(MAX)':
723 $type = 'B';
724 break;
726 case 'DATETIME':
727 $type = 'D';
728 break;
731 if (!$type) {
732 throw new dml_exception('invalidsqlsrvnativetype', $sqlsrv_type);
734 return $type;
738 * Do NOT use in code, to be used by database_manager only!
739 * @param string|array $sql query
740 * @param array|null $tablenames an array of xmldb table names affected by this request.
741 * @return bool true
742 * @throws ddl_change_structure_exception A DDL specific exception is thrown for any errors.
744 public function change_database_structure($sql, $tablenames = null) {
745 $this->get_manager(); // Includes DDL exceptions classes ;-)
746 $sqls = (array)$sql;
748 try {
749 foreach ($sqls as $sql) {
750 $this->query_start($sql, null, SQL_QUERY_STRUCTURE);
751 $result = sqlsrv_query($this->sqlsrv, $sql);
752 $this->query_end($result);
754 } catch (ddl_change_structure_exception $e) {
755 $this->reset_caches($tablenames);
756 throw $e;
759 $this->reset_caches($tablenames);
760 return true;
764 * Prepare the array of params for native binding
766 protected function build_native_bound_params(array $params = null) {
768 return null;
772 * Workaround for SQL*Server Native driver similar to MSSQL driver for
773 * consistent behavior.
775 protected function emulate_bound_params($sql, array $params = null) {
777 if (empty($params)) {
778 return $sql;
780 // ok, we have verified sql statement with ? and correct number of params
781 $parts = array_reverse(explode('?', $sql));
782 $return = array_pop($parts);
783 foreach ($params as $param) {
784 if (is_bool($param)) {
785 $return .= (int)$param;
786 } else if (is_array($param) && isset($param['hex'])) { // detect hex binary, bind it specially
787 $return .= '0x'.$param['hex'];
788 } else if (is_array($param) && isset($param['numstr'])) { // detect numerical strings that *must not*
789 $return .= "N'{$param['numstr']}'"; // be converted back to number params, but bound as strings
790 } else if (is_null($param)) {
791 $return .= 'NULL';
793 } else if (is_number($param)) { // we can not use is_numeric() because it eats leading zeros from strings like 0045646
794 $return .= "'$param'"; // this is a hack for MDL-23997, we intentionally use string because it is compatible with both nvarchar and int types
795 } else if (is_float($param)) {
796 $return .= $param;
797 } else {
798 $param = str_replace("'", "''", $param);
799 $param = str_replace("\0", "", $param);
800 $return .= "N'$param'";
803 $return .= array_pop($parts);
805 return $return;
809 * Execute general sql query. Should be used only when no other method suitable.
810 * Do NOT use this to make changes in db structure, use database_manager methods instead!
811 * @param string $sql query
812 * @param array $params query parameters
813 * @return bool true
814 * @throws dml_exception A DML specific exception is thrown for any errors.
816 public function execute($sql, array $params = null) {
817 if (strpos($sql, ';') !== false) {
818 throw new coding_exception('moodle_database::execute() Multiple sql statements found or bound parameters not used properly in query!');
820 $this->do_query($sql, $params, SQL_QUERY_UPDATE);
821 return true;
825 * Whether the given SQL statement has the ORDER BY clause in the main query.
827 * @param string $sql the SQL statement
828 * @return bool true if the main query has the ORDER BY clause; otherwise, false.
830 protected static function has_query_order_by(string $sql) {
831 $sqltoupper = strtoupper($sql);
832 // Fail fast if there is no ORDER BY clause in the original query.
833 if (strpos($sqltoupper, 'ORDER BY') === false) {
834 return false;
837 // Search for an ORDER BY clause in the main query, not in any subquery (not always allowed in MSSQL)
838 // or in clauses like OVER with a window function e.g. ROW_NUMBER() OVER (ORDER BY ...) or RANK() OVER (ORDER BY ...):
839 // use PHP PCRE recursive patterns to remove everything found within round brackets.
840 $mainquery = preg_replace('/\(((?>[^()]+)|(?R))*\)/', '()', $sqltoupper);
841 if (strpos($mainquery, 'ORDER BY') !== false) {
842 return true;
845 return false;
849 * Get a number of records as a moodle_recordset using a SQL statement.
851 * Since this method is a little less readable, use of it should be restricted to
852 * code where it's possible there might be large datasets being returned. For known
853 * small datasets use get_records_sql - it leads to simpler code.
855 * The return type is like:
856 * @see function get_recordset.
858 * @param string $sql the SQL select query to execute.
859 * @param array $params array of sql parameters
860 * @param int $limitfrom return a subset of records, starting at this point (optional, required if $limitnum is set).
861 * @param int $limitnum return a subset comprising this many records (optional, required if $limitfrom is set).
862 * @return moodle_recordset instance
863 * @throws dml_exception A DML specific exception is thrown for any errors.
865 public function get_recordset_sql($sql, array $params = null, $limitfrom = 0, $limitnum = 0) {
867 list($limitfrom, $limitnum) = $this->normalise_limit_from_num($limitfrom, $limitnum);
868 $needscrollable = (bool)$limitfrom; // To determine if we'll need to perform scroll to $limitfrom.
870 if ($limitfrom or $limitnum) {
871 if (!$this->supportsoffsetfetch) {
872 if ($limitnum >= 1) { // Only apply TOP clause if we have any limitnum (limitfrom offset is handled later).
873 $fetch = $limitfrom + $limitnum;
874 if (PHP_INT_MAX - $limitnum < $limitfrom) { // Check PHP_INT_MAX overflow.
875 $fetch = PHP_INT_MAX;
877 $sql = preg_replace('/^([\s(])*SELECT([\s]+(DISTINCT|ALL))?(?!\s*TOP\s*\()/i',
878 "\\1SELECT\\2 TOP $fetch", $sql);
880 } else {
881 $needscrollable = false; // Using supported fetch/offset, no need to scroll anymore.
882 $sql = (substr($sql, -1) === ';') ? substr($sql, 0, -1) : $sql;
883 // We need ORDER BY to use FETCH/OFFSET.
884 // Ordering by first column shouldn't break anything if there was no order in the first place.
885 if (!self::has_query_order_by($sql)) {
886 $sql .= " ORDER BY 1";
889 $sql .= " OFFSET ".$limitfrom." ROWS ";
891 if ($limitnum > 0) {
892 $sql .= " FETCH NEXT ".$limitnum." ROWS ONLY";
897 // Add WITH (NOLOCK) to any temp tables.
898 $sql = $this->add_no_lock_to_temp_tables($sql);
900 $result = $this->do_query($sql, $params, SQL_QUERY_SELECT, false, $needscrollable);
902 if ($needscrollable) { // Skip $limitfrom records.
903 sqlsrv_fetch($result, SQLSRV_SCROLL_ABSOLUTE, $limitfrom - 1);
905 return $this->create_recordset($result);
909 * Use NOLOCK on any temp tables. Since it's a temp table and uncommitted reads are low risk anyway.
911 * @param string $sql the SQL select query to execute.
912 * @return string The SQL, with WITH (NOLOCK) added to all temp tables
914 protected function add_no_lock_to_temp_tables($sql) {
915 return preg_replace_callback('/(\{([a-z][a-z0-9_]*)\})(\s+(\w+))?/', function($matches) {
916 $table = $matches[1]; // With the braces, so we can put it back in the query.
917 $name = $matches[2]; // Without the braces, so we can check if it's a temptable.
918 $tail = isset($matches[3]) ? $matches[3] : ''; // Catch the next word afterwards so that we can check if it's an alias.
919 $replacement = $matches[0]; // The table and the word following it, so we can replace it back if no changes are needed.
921 if ($this->temptables && $this->temptables->is_temptable($name)) {
922 if (!empty($tail)) {
923 if (in_array(strtolower(trim($tail)), $this->reservewords)) {
924 // If the table is followed by a reserve word, it's not an alias so put the WITH (NOLOCK) in between.
925 return $table . ' WITH (NOLOCK)' . $tail;
928 // If the table is not followed by a reserve word, put the WITH (NOLOCK) after the whole match.
929 return $replacement . ' WITH (NOLOCK)';
930 } else {
931 return $replacement;
933 }, $sql);
937 * Create a record set and initialize with first row
939 * @param mixed $result
940 * @return sqlsrv_native_moodle_recordset
942 protected function create_recordset($result) {
943 $rs = new sqlsrv_native_moodle_recordset($result, $this);
944 $this->recordsets[] = $rs;
945 return $rs;
949 * Do not use outside of recordset class.
950 * @internal
951 * @param sqlsrv_native_moodle_recordset $rs
953 public function recordset_closed(sqlsrv_native_moodle_recordset $rs) {
954 if ($key = array_search($rs, $this->recordsets, true)) {
955 unset($this->recordsets[$key]);
960 * Get a number of records as an array of objects using a SQL statement.
962 * Return value is like:
963 * @see function get_records.
965 * @param string $sql the SQL select query to execute. The first column of this SELECT statement
966 * must be a unique value (usually the 'id' field), as it will be used as the key of the
967 * returned array.
968 * @param array $params array of sql parameters
969 * @param int $limitfrom return a subset of records, starting at this point (optional, required if $limitnum is set).
970 * @param int $limitnum return a subset comprising this many records (optional, required if $limitfrom is set).
971 * @return array of objects, or empty array if no records were found
972 * @throws dml_exception A DML specific exception is thrown for any errors.
974 public function get_records_sql($sql, array $params = null, $limitfrom = 0, $limitnum = 0) {
976 $rs = $this->get_recordset_sql($sql, $params, $limitfrom, $limitnum);
978 $results = array();
980 foreach ($rs as $row) {
981 $rowarray = (array)$row;
982 $id = reset($rowarray);
984 if (isset($results[$id])) {
985 $colname = key($rowarray);
986 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);
988 $results[$id] = (object)$row;
990 $rs->close();
992 return $results;
996 * Selects records and return values (first field) as an array using a SQL statement.
998 * @param string $sql The SQL query
999 * @param array $params array of sql parameters
1000 * @return array of values
1001 * @throws dml_exception A DML specific exception is thrown for any errors.
1003 public function get_fieldset_sql($sql, array $params = null) {
1005 $rs = $this->get_recordset_sql($sql, $params);
1007 $results = array ();
1009 foreach ($rs as $row) {
1010 $rowarray = (array)$row;
1011 $results[] = reset($rowarray);
1013 $rs->close();
1015 return $results;
1019 * Insert new record into database, as fast as possible, no safety checks, lobs not supported.
1020 * @param string $table name
1021 * @param mixed $params data record as object or array
1022 * @param bool $returnit return it of inserted record
1023 * @param bool $bulk true means repeated inserts expected
1024 * @param bool $customsequence true if 'id' included in $params, disables $returnid
1025 * @return bool|int true or new id
1026 * @throws dml_exception A DML specific exception is thrown for any errors.
1028 public function insert_record_raw($table, $params, $returnid=true, $bulk=false, $customsequence=false) {
1029 if (!is_array($params)) {
1030 $params = (array)$params;
1033 $isidentity = false;
1035 if ($customsequence) {
1036 if (!isset($params['id'])) {
1037 throw new coding_exception('moodle_database::insert_record_raw() id field must be specified if custom sequences used.');
1040 $returnid = false;
1041 $columns = $this->get_columns($table);
1042 if (isset($columns['id']) and $columns['id']->auto_increment) {
1043 $isidentity = true;
1046 // Disable IDENTITY column before inserting record with id, only if the
1047 // column is identity, from meta information.
1048 if ($isidentity) {
1049 $sql = 'SET IDENTITY_INSERT {'.$table.'} ON'; // Yes, it' ON!!
1050 $this->do_query($sql, null, SQL_QUERY_AUX);
1053 } else {
1054 unset($params['id']);
1057 if (empty($params)) {
1058 throw new coding_exception('moodle_database::insert_record_raw() no fields found.');
1060 $fields = implode(',', array_keys($params));
1061 $qms = array_fill(0, count($params), '?');
1062 $qms = implode(',', $qms);
1063 $sql = "INSERT INTO {" . $table . "} ($fields) VALUES($qms)";
1064 $query_id = $this->do_query($sql, $params, SQL_QUERY_INSERT);
1066 if ($customsequence) {
1067 // Enable IDENTITY column after inserting record with id, only if the
1068 // column is identity, from meta information.
1069 if ($isidentity) {
1070 $sql = 'SET IDENTITY_INSERT {'.$table.'} OFF'; // Yes, it' OFF!!
1071 $this->do_query($sql, null, SQL_QUERY_AUX);
1075 if ($returnid) {
1076 $id = $this->sqlsrv_fetch_id();
1077 return $id;
1078 } else {
1079 return true;
1084 * Get the ID of the current action
1086 * @return mixed ID
1088 private function sqlsrv_fetch_id() {
1089 $query_id = sqlsrv_query($this->sqlsrv, 'SELECT SCOPE_IDENTITY()');
1090 if ($query_id === false) {
1091 $dberr = $this->get_last_error();
1092 return false;
1094 $row = $this->sqlsrv_fetchrow($query_id);
1095 return (int)$row[0];
1099 * Fetch a single row into an numbered array
1101 * @param mixed $query_id
1103 private function sqlsrv_fetchrow($query_id) {
1104 $row = sqlsrv_fetch_array($query_id, SQLSRV_FETCH_NUMERIC);
1105 if ($row === false) {
1106 $dberr = $this->get_last_error();
1107 return false;
1110 foreach ($row as $key => $value) {
1111 $row[$key] = ($value === ' ' || $value === NULL) ? '' : $value;
1113 return $row;
1117 * Insert a record into a table and return the "id" field if required.
1119 * Some conversions and safety checks are carried out. Lobs are supported.
1120 * If the return ID isn't required, then this just reports success as true/false.
1121 * $data is an object containing needed data
1122 * @param string $table The database table to be inserted into
1123 * @param object|array $dataobject A data object with values for one or more fields in the record
1124 * @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.
1125 * @return bool|int true or new id
1126 * @throws dml_exception A DML specific exception is thrown for any errors.
1128 public function insert_record($table, $dataobject, $returnid = true, $bulk = false) {
1129 $dataobject = (array)$dataobject;
1131 $columns = $this->get_columns($table);
1132 if (empty($columns)) {
1133 throw new dml_exception('ddltablenotexist', $table);
1136 $cleaned = array ();
1138 foreach ($dataobject as $field => $value) {
1139 if ($field === 'id') {
1140 continue;
1142 if (!isset($columns[$field])) {
1143 continue;
1145 $column = $columns[$field];
1146 $cleaned[$field] = $this->normalise_value($column, $value);
1149 return $this->insert_record_raw($table, $cleaned, $returnid, $bulk);
1153 * Import a record into a table, id field is required.
1154 * Safety checks are NOT carried out. Lobs are supported.
1156 * @param string $table name of database table to be inserted into
1157 * @param object $dataobject A data object with values for one or more fields in the record
1158 * @return bool true
1159 * @throws dml_exception A DML specific exception is thrown for any errors.
1161 public function import_record($table, $dataobject) {
1162 if (!is_object($dataobject)) {
1163 $dataobject = (object)$dataobject;
1166 $columns = $this->get_columns($table);
1167 $cleaned = array ();
1169 foreach ($dataobject as $field => $value) {
1170 if (!isset($columns[$field])) {
1171 continue;
1173 $column = $columns[$field];
1174 $cleaned[$field] = $this->normalise_value($column, $value);
1177 $this->insert_record_raw($table, $cleaned, false, false, true);
1179 return true;
1183 * Update record in database, as fast as possible, no safety checks, lobs not supported.
1184 * @param string $table name
1185 * @param mixed $params data record as object or array
1186 * @param bool true means repeated updates expected
1187 * @return bool true
1188 * @throws dml_exception A DML specific exception is thrown for any errors.
1190 public function update_record_raw($table, $params, $bulk = false) {
1191 $params = (array)$params;
1193 if (!isset($params['id'])) {
1194 throw new coding_exception('moodle_database::update_record_raw() id field must be specified.');
1196 $id = $params['id'];
1197 unset($params['id']);
1199 if (empty($params)) {
1200 throw new coding_exception('moodle_database::update_record_raw() no fields found.');
1203 $sets = array ();
1205 foreach ($params as $field => $value) {
1206 $sets[] = "$field = ?";
1209 $params[] = $id; // last ? in WHERE condition
1211 $sets = implode(',', $sets);
1212 $sql = "UPDATE {".$table."} SET $sets WHERE id = ?";
1214 $this->do_query($sql, $params, SQL_QUERY_UPDATE);
1216 return true;
1220 * Update a record in a table
1222 * $dataobject is an object containing needed data
1223 * Relies on $dataobject having a variable "id" to
1224 * specify the record to update
1226 * @param string $table The database table to be checked against.
1227 * @param object $dataobject An object with contents equal to fieldname=>fieldvalue. Must have an entry for 'id' to map to the table specified.
1228 * @param bool true means repeated updates expected
1229 * @return bool true
1230 * @throws dml_exception A DML specific exception is thrown for any errors.
1232 public function update_record($table, $dataobject, $bulk = false) {
1233 $dataobject = (array)$dataobject;
1235 $columns = $this->get_columns($table);
1236 $cleaned = array ();
1238 foreach ($dataobject as $field => $value) {
1239 if (!isset($columns[$field])) {
1240 continue;
1242 $column = $columns[$field];
1243 $cleaned[$field] = $this->normalise_value($column, $value);
1246 return $this->update_record_raw($table, $cleaned, $bulk);
1250 * Set a single field in every table record which match a particular WHERE clause.
1252 * @param string $table The database table to be checked against.
1253 * @param string $newfield the field to set.
1254 * @param string $newvalue the value to set the field to.
1255 * @param string $select A fragment of SQL to be used in a where clause in the SQL call.
1256 * @param array $params array of sql parameters
1257 * @return bool true
1258 * @throws dml_exception A DML specific exception is thrown for any errors.
1260 public function set_field_select($table, $newfield, $newvalue, $select, array $params = null) {
1261 if ($select) {
1262 $select = "WHERE $select";
1265 if (is_null($params)) {
1266 $params = array ();
1269 // convert params to ? types
1270 list($select, $params, $type) = $this->fix_sql_params($select, $params);
1272 // Get column metadata
1273 $columns = $this->get_columns($table);
1274 $column = $columns[$newfield];
1276 $newvalue = $this->normalise_value($column, $newvalue);
1278 if (is_null($newvalue)) {
1279 $newfield = "$newfield = NULL";
1280 } else {
1281 $newfield = "$newfield = ?";
1282 array_unshift($params, $newvalue);
1284 $sql = "UPDATE {".$table."} SET $newfield $select";
1286 $this->do_query($sql, $params, SQL_QUERY_UPDATE);
1288 return true;
1292 * Delete one or more records from a table which match a particular WHERE clause.
1294 * @param string $table The database table to be checked against.
1295 * @param string $select A fragment of SQL to be used in a where clause in the SQL call (used to define the selection criteria).
1296 * @param array $params array of sql parameters
1297 * @return bool true
1298 * @throws dml_exception A DML specific exception is thrown for any errors.
1300 public function delete_records_select($table, $select, array $params = null) {
1301 if ($select) {
1302 $select = "WHERE $select";
1305 $sql = "DELETE FROM {".$table."} $select";
1307 // we use SQL_QUERY_UPDATE because we do not know what is in general SQL, delete constant would not be accurate
1308 $this->do_query($sql, $params, SQL_QUERY_UPDATE);
1310 return true;
1314 public function sql_cast_char2int($fieldname, $text = false) {
1315 if (!$text) {
1316 return ' CAST(' . $fieldname . ' AS INT) ';
1317 } else {
1318 return ' CAST(' . $this->sql_compare_text($fieldname) . ' AS INT) ';
1322 public function sql_cast_char2real($fieldname, $text=false) {
1323 if (!$text) {
1324 return ' CAST(' . $fieldname . ' AS REAL) ';
1325 } else {
1326 return ' CAST(' . $this->sql_compare_text($fieldname) . ' AS REAL) ';
1330 public function sql_ceil($fieldname) {
1331 return ' CEILING('.$fieldname.')';
1334 protected function get_collation() {
1335 if (isset($this->collation)) {
1336 return $this->collation;
1338 if (!empty($this->dboptions['dbcollation'])) {
1339 // perf speedup
1340 $this->collation = $this->dboptions['dbcollation'];
1341 return $this->collation;
1344 // make some default
1345 $this->collation = 'Latin1_General_CI_AI';
1347 $sql = "SELECT CAST(DATABASEPROPERTYEX('$this->dbname', 'Collation') AS varchar(255)) AS SQLCollation";
1348 $this->query_start($sql, null, SQL_QUERY_AUX);
1349 $result = sqlsrv_query($this->sqlsrv, $sql);
1350 $this->query_end($result);
1352 if ($result) {
1353 if ($rawcolumn = sqlsrv_fetch_array($result, SQLSRV_FETCH_ASSOC)) {
1354 $this->collation = reset($rawcolumn);
1356 $this->free_result($result);
1359 return $this->collation;
1362 public function sql_equal($fieldname, $param, $casesensitive = true, $accentsensitive = true, $notequal = false) {
1363 $equalop = $notequal ? '<>' : '=';
1364 $collation = $this->get_collation();
1366 if ($casesensitive) {
1367 $collation = str_replace('_CI', '_CS', $collation);
1368 } else {
1369 $collation = str_replace('_CS', '_CI', $collation);
1371 if ($accentsensitive) {
1372 $collation = str_replace('_AI', '_AS', $collation);
1373 } else {
1374 $collation = str_replace('_AS', '_AI', $collation);
1377 return "$fieldname COLLATE $collation $equalop $param";
1381 * Returns 'LIKE' part of a query.
1383 * @param string $fieldname usually name of the table column
1384 * @param string $param usually bound query parameter (?, :named)
1385 * @param bool $casesensitive use case sensitive search
1386 * @param bool $accensensitive use accent sensitive search (not all databases support accent insensitive)
1387 * @param bool $notlike true means "NOT LIKE"
1388 * @param string $escapechar escape char for '%' and '_'
1389 * @return string SQL code fragment
1391 public function sql_like($fieldname, $param, $casesensitive = true, $accentsensitive = true, $notlike = false, $escapechar = '\\') {
1392 if (strpos($param, '%') !== false) {
1393 debugging('Potential SQL injection detected, sql_like() expects bound parameters (? or :named)');
1396 $collation = $this->get_collation();
1397 $LIKE = $notlike ? 'NOT LIKE' : 'LIKE';
1399 if ($casesensitive) {
1400 $collation = str_replace('_CI', '_CS', $collation);
1401 } else {
1402 $collation = str_replace('_CS', '_CI', $collation);
1404 if ($accentsensitive) {
1405 $collation = str_replace('_AI', '_AS', $collation);
1406 } else {
1407 $collation = str_replace('_AS', '_AI', $collation);
1410 return "$fieldname COLLATE $collation $LIKE $param ESCAPE '$escapechar'";
1414 * Escape common SQL LIKE special characters like '_' or '%', plus '[' & ']' which are also supported in SQL Server
1416 * Note that '^' and '-' also have meaning within a LIKE, but only when enclosed within square brackets. As this syntax
1417 * is not supported on all databases and the brackets are always escaped, we don't need special handling of them
1419 * @param string $text
1420 * @param string $escapechar
1421 * @return string
1423 public function sql_like_escape($text, $escapechar = '\\') {
1424 $text = parent::sql_like_escape($text, $escapechar);
1426 $text = str_replace('[', $escapechar . '[', $text);
1427 $text = str_replace(']', $escapechar . ']', $text);
1429 return $text;
1432 public function sql_concat() {
1433 $arr = func_get_args();
1435 foreach ($arr as $key => $ele) {
1436 $arr[$key] = ' CAST('.$ele.' AS NVARCHAR(255)) ';
1438 $s = implode(' + ', $arr);
1440 if ($s === '') {
1441 return " '' ";
1443 return " $s ";
1446 public function sql_concat_join($separator = "' '", $elements = array ()) {
1447 for ($n = count($elements) - 1; $n > 0; $n--) {
1448 array_splice($elements, $n, 0, $separator);
1450 return call_user_func_array(array($this, 'sql_concat'), array_values($elements));
1454 * Return SQL for performing group concatenation on given field/expression
1456 * @param string $field
1457 * @param string $separator
1458 * @param string $sort
1459 * @return string
1461 public function sql_group_concat(string $field, string $separator = ', ', string $sort = ''): string {
1462 $fieldsort = $sort ? "WITHIN GROUP (ORDER BY {$sort})" : '';
1463 return "STRING_AGG({$field}, '{$separator}') {$fieldsort}";
1466 public function sql_isempty($tablename, $fieldname, $nullablefield, $textfield) {
1467 if ($textfield) {
1468 return ' ('.$this->sql_compare_text($fieldname)." = '') ";
1469 } else {
1470 return " ($fieldname = '') ";
1475 * Returns the SQL text to be used to calculate the length in characters of one expression.
1476 * @param string fieldname or expression to calculate its length in characters.
1477 * @return string the piece of SQL code to be used in the statement.
1479 public function sql_length($fieldname) {
1480 return ' LEN('.$fieldname.')';
1483 public function sql_order_by_text($fieldname, $numchars = 32) {
1484 return " CONVERT(varchar({$numchars}), {$fieldname})";
1488 * Returns the SQL for returning searching one string for the location of another.
1490 public function sql_position($needle, $haystack) {
1491 return "CHARINDEX(($needle), ($haystack))";
1495 * Returns the proper substr() SQL text used to extract substrings from DB
1496 * NOTE: this was originally returning only function name
1498 * @param string $expr some string field, no aggregates
1499 * @param mixed $start integer or expression evaluating to int
1500 * @param mixed $length optional integer or expression evaluating to int
1501 * @return string sql fragment
1503 public function sql_substr($expr, $start, $length = false) {
1504 if (count(func_get_args()) < 2) {
1505 throw new coding_exception('moodle_database::sql_substr() requires at least two parameters',
1506 'Originally this function was only returning name of SQL substring function, it now requires all parameters.');
1509 if ($length === false) {
1510 return "SUBSTRING($expr, " . $this->sql_cast_char2int($start) . ", 2^31-1)";
1511 } else {
1512 return "SUBSTRING($expr, " . $this->sql_cast_char2int($start) . ", " . $this->sql_cast_char2int($length) . ")";
1517 * Does this driver support tool_replace?
1519 * @since Moodle 2.6.1
1520 * @return bool
1522 public function replace_all_text_supported() {
1523 return true;
1526 public function session_lock_supported() {
1527 return true;
1531 * Obtain session lock
1532 * @param int $rowid id of the row with session record
1533 * @param int $timeout max allowed time to wait for the lock in seconds
1534 * @return void
1536 public function get_session_lock($rowid, $timeout) {
1537 if (!$this->session_lock_supported()) {
1538 return;
1540 parent::get_session_lock($rowid, $timeout);
1542 $timeoutmilli = $timeout * 1000;
1544 $fullname = $this->dbname.'-'.$this->prefix.'-session-'.$rowid;
1545 // While this may work using proper {call sp_...} calls + binding +
1546 // executing + consuming recordsets, the solution used for the mssql
1547 // driver is working perfectly, so 100% mimic-ing that code.
1548 // $sql = "sp_getapplock '$fullname', 'Exclusive', 'Session', $timeoutmilli";
1549 $sql = "BEGIN
1550 DECLARE @result INT
1551 EXECUTE @result = sp_getapplock @Resource='$fullname',
1552 @LockMode='Exclusive',
1553 @LockOwner='Session',
1554 @LockTimeout='$timeoutmilli'
1555 SELECT @result
1556 END";
1557 $this->query_start($sql, null, SQL_QUERY_AUX);
1558 $result = sqlsrv_query($this->sqlsrv, $sql);
1559 $this->query_end($result);
1561 if ($result) {
1562 $row = sqlsrv_fetch_array($result);
1563 if ($row[0] < 0) {
1564 throw new dml_sessionwait_exception();
1568 $this->free_result($result);
1571 public function release_session_lock($rowid) {
1572 if (!$this->session_lock_supported()) {
1573 return;
1575 if (!$this->used_for_db_sessions) {
1576 return;
1579 parent::release_session_lock($rowid);
1581 $fullname = $this->dbname.'-'.$this->prefix.'-session-'.$rowid;
1582 $sql = "sp_releaseapplock '$fullname', 'Session'";
1583 $this->query_start($sql, null, SQL_QUERY_AUX);
1584 $result = sqlsrv_query($this->sqlsrv, $sql);
1585 $this->query_end($result);
1586 $this->free_result($result);
1590 * Driver specific start of real database transaction,
1591 * this can not be used directly in code.
1592 * @return void
1594 protected function begin_transaction() {
1595 // Recordsets do not work well with transactions in SQL Server,
1596 // let's prefetch the recordsets to memory to work around these problems.
1597 foreach ($this->recordsets as $rs) {
1598 $rs->transaction_starts();
1601 $this->query_start('native sqlsrv_begin_transaction', NULL, SQL_QUERY_AUX);
1602 $result = sqlsrv_begin_transaction($this->sqlsrv);
1603 $this->query_end($result);
1607 * Driver specific commit of real database transaction,
1608 * this can not be used directly in code.
1609 * @return void
1611 protected function commit_transaction() {
1612 $this->query_start('native sqlsrv_commit', NULL, SQL_QUERY_AUX);
1613 $result = sqlsrv_commit($this->sqlsrv);
1614 $this->query_end($result);
1618 * Driver specific abort of real database transaction,
1619 * this can not be used directly in code.
1620 * @return void
1622 protected function rollback_transaction() {
1623 $this->query_start('native sqlsrv_rollback', NULL, SQL_QUERY_AUX);
1624 $result = sqlsrv_rollback($this->sqlsrv);
1625 $this->query_end($result);
1629 * Is fulltext search enabled?.
1631 * @return bool
1633 public function is_fulltext_search_supported() {
1634 global $CFG;
1636 $sql = "SELECT FULLTEXTSERVICEPROPERTY('IsFullTextInstalled')";
1637 $this->query_start($sql, null, SQL_QUERY_AUX);
1638 $result = sqlsrv_query($this->sqlsrv, $sql);
1639 $this->query_end($result);
1640 if ($result) {
1641 if ($row = sqlsrv_fetch_array($result)) {
1642 $property = (bool)reset($row);
1645 $this->free_result($result);
1647 return !empty($property);