MDL-25276 dml - fix/implement sql_cast2int/real() across the 5 drivers. Tests passing.
[moodle.git] / lib / dml / mssql_native_moodle_database.php
CommitLineData
520b730c 1<?php
2
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 3 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.
14//
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/>.
17
18
19/**
20 * Native mssql class representing moodle database interface.
21 *
66c0ee78 22 * @package core
f2ed3f05 23 * @subpackage dml
520b730c 24 * @copyright 2009 onwards Eloy Lafuente (stronk7) {@link http://stronk7.com}
25 * @license http://www.gnu.org/copyleft/gpl.html GNU GPL v3 or later
26 */
27
f2ed3f05
PS
28defined('MOODLE_INTERNAL') || die();
29
520b730c 30require_once($CFG->libdir.'/dml/moodle_database.php');
31require_once($CFG->libdir.'/dml/mssql_native_moodle_recordset.php');
32require_once($CFG->libdir.'/dml/mssql_native_moodle_temptables.php');
33
34/**
35 * Native mssql class representing moodle database interface.
36 */
37class mssql_native_moodle_database extends moodle_database {
38
39 protected $mssql = null;
5c08b24b 40 protected $last_error_reporting; // To handle mssql driver default verbosity
6055f89d 41 protected $collation; // current DB collation cache
5c08b24b 42
520b730c 43 /**
44 * Detects if all needed PHP stuff installed.
45 * Note: can be used before connect()
46 * @return mixed true if ok, string if something
47 */
48 public function driver_installed() {
49 if (!function_exists('mssql_connect')) {
50 return get_string('mssqlextensionisnotpresentinphp', 'install');
51 }
52 return true;
53 }
54
55 /**
56 * Returns database family type - describes SQL dialect
57 * Note: can be used before connect()
58 * @return string db family name (mysql, postgres, mssql, oracle, etc.)
59 */
60 public function get_dbfamily() {
61 return 'mssql';
62 }
63
64 /**
65 * Returns more specific database driver type
66 * Note: can be used before connect()
4a6c2ab8 67 * @return string db type mysqli, pgsql, oci, mssql, sqlsrv
520b730c 68 */
69 protected function get_dbtype() {
70 return 'mssql';
71 }
72
73 /**
74 * Returns general database library name
75 * Note: can be used before connect()
eb123deb 76 * @return string db type pdo, native
520b730c 77 */
78 protected function get_dblibrary() {
79 return 'native';
80 }
81
82 /**
83 * Returns localised database type name
84 * Note: can be used before connect()
85 * @return string
86 */
87 public function get_name() {
88 return get_string('nativemssql', 'install');
89 }
90
520b730c 91 /**
92 * Returns localised database configuration help.
93 * Note: can be used before connect()
94 * @return string
95 */
96 public function get_configuration_help() {
97 return get_string('nativemssqlhelp', 'install');
98 }
99
100 /**
101 * Returns localised database description
102 * Note: can be used before connect()
103 * @return string
104 */
105 public function get_configuration_hints() {
106 $str = get_string('databasesettingssub_mssql', 'install');
107 $str .= "<p style='text-align:right'><a href=\"javascript:void(0)\" ";
108 $str .= "onclick=\"return window.open('http://docs.moodle.org/en/Installing_MSSQL_for_PHP')\"";
109 $str .= ">";
110 $str .= '<img src="pix/docs.gif' . '" alt="Docs" class="iconhelp" />';
111 $str .= get_string('moodledocslink', 'install') . '</a></p>';
112 return $str;
113 }
114
115 /**
116 * Connect to db
117 * Must be called before other methods.
118 * @param string $dbhost
119 * @param string $dbuser
120 * @param string $dbpass
121 * @param string $dbname
122 * @param mixed $prefix string means moodle db prefix, false used for external databases where prefix not used
123 * @param array $dboptions driver specific options
124 * @return bool true
125 * @throws dml_connection_exception if error
126 */
127 public function connect($dbhost, $dbuser, $dbpass, $dbname, $prefix, array $dboptions=null) {
128 if ($prefix == '' and !$this->external) {
129 //Enforce prefixes for everybody but mysql
130 throw new dml_exception('prefixcannotbeempty', $this->get_dbfamily());
131 }
132
133 $driverstatus = $this->driver_installed();
134
135 if ($driverstatus !== true) {
136 throw new dml_exception('dbdriverproblem', $driverstatus);
137 }
138
139 $this->store_settings($dbhost, $dbuser, $dbpass, $dbname, $prefix, $dboptions);
140
141 ob_start();
a0b7200d 142 if (!empty($this->dboptions['dbpersist'])) { // persistent connection
520b730c 143 $this->mssql = mssql_pconnect($this->dbhost, $this->dbuser, $this->dbpass, true);
144 } else {
145 $this->mssql = mssql_connect($this->dbhost, $this->dbuser, $this->dbpass, true);
146 }
147 $dberr = ob_get_contents();
148 ob_end_clean();
149
150 if ($this->mssql === false) {
151 $this->mssql = null;
152 throw new dml_connection_exception($dberr);
153 }
154
155 // already connected, select database and set some env. variables
156 $this->query_start("--mssql_select_db", null, SQL_QUERY_AUX);
157 $result = mssql_select_db($this->dbname, $this->mssql);
158 $this->query_end($result);
159
160 // No need to set charset. It's UTF8, with transparent conversions
161 // back and forth performed both by FreeTDS or ODBTP
162
163 // Allow quoted identifiers
164 $sql = "SET QUOTED_IDENTIFIER ON";
165 $this->query_start($sql, null, SQL_QUERY_AUX);
166 $result = mssql_query($sql, $this->mssql);
167 $this->query_end($result);
168
169 $this->free_result($result);
170
171 // Force ANSI nulls so the NULL check was done by IS NULL and NOT IS NULL
4d276e34 172 // instead of equal(=) and distinct(<>) symbols
520b730c 173 $sql = "SET ANSI_NULLS ON";
174 $this->query_start($sql, null, SQL_QUERY_AUX);
175 $result = mssql_query($sql, $this->mssql);
176 $this->query_end($result);
177
178 $this->free_result($result);
179
180 // Force ANSI warnings so arithmetic/string overflows will be
181 // returning error instead of transparently truncating data
182 $sql = "SET ANSI_WARNINGS ON";
183 $this->query_start($sql, null, SQL_QUERY_AUX);
184 $result = mssql_query($sql, $this->mssql);
185 $this->query_end($result);
186
187 // Concatenating null with anything MUST return NULL
188 $sql = "SET CONCAT_NULL_YIELDS_NULL ON";
189 $this->query_start($sql, null, SQL_QUERY_AUX);
190 $result = mssql_query($sql, $this->mssql);
191 $this->query_end($result);
192
193 $this->free_result($result);
194
195 // Set transactions isolation level to READ_COMMITTED
196 // prevents dirty reads when using transactions +
197 // is the default isolation level of MSSQL
12ffe203 198 // Requires database to run with READ_COMMITTED_SNAPSHOT ON
520b730c 199 $sql = "SET TRANSACTION ISOLATION LEVEL READ COMMITTED";
200 $this->query_start($sql, NULL, SQL_QUERY_AUX);
201 $result = mssql_query($sql, $this->mssql);
202 $this->query_end($result);
203
204 $this->free_result($result);
205
4d276e34 206 // Connection stabilised and configured, going to instantiate the temptables controller
520b730c 207 $this->temptables = new mssql_native_moodle_temptables($this);
208
209 return true;
210 }
211
212 /**
213 * Close database connection and release all resources
214 * and memory (especially circular memory references).
215 * Do NOT use connect() again, create a new instance if needed.
216 */
217 public function dispose() {
4d276e34 218 parent::dispose(); // Call parent dispose to write/close session and other common stuff before closing connection
520b730c 219 if ($this->mssql) {
220 mssql_close($this->mssql);
221 $this->mssql = null;
222 }
223 }
224
225 /**
226 * Called before each db query.
227 * @param string $sql
228 * @param array array of parameters
229 * @param int $type type of query
230 * @param mixed $extrainfo driver specific extra information
231 * @return void
232 */
233 protected function query_start($sql, array $params=null, $type, $extrainfo=null) {
234 parent::query_start($sql, $params, $type, $extrainfo);
5c08b24b 235 // mssql driver tends to send debug to output, we do not need that ;-)
236 $this->last_error_reporting = error_reporting(0);
520b730c 237 }
238
239 /**
240 * Called immediately after each db query.
241 * @param mixed db specific result
242 * @return void
243 */
244 protected function query_end($result) {
5c08b24b 245 // reset original debug level
246 error_reporting($this->last_error_reporting);
520b730c 247 parent::query_end($result);
248 }
249
250 /**
251 * Returns database server info array
252 * @return array
253 */
254 public function get_server_info() {
255 static $info;
256 if (!$info) {
257 $info = array();
258 $sql = 'sp_server_info 2';
259 $this->query_start($sql, null, SQL_QUERY_AUX);
260 $result = mssql_query($sql, $this->mssql);
261 $this->query_end($result);
262 $row = mssql_fetch_row($result);
b809f813 263 $info['description'] = $row[2];
520b730c 264 $this->free_result($result);
265
266 $sql = 'sp_server_info 500';
267 $this->query_start($sql, null, SQL_QUERY_AUX);
268 $result = mssql_query($sql, $this->mssql);
269 $this->query_end($result);
270 $row = mssql_fetch_row($result);
271 $info['version'] = $row[2];
272 $this->free_result($result);
273 }
274 return $info;
275 }
276
277 protected function is_min_version($version) {
278 $server = $this->get_server_info();
279 $server = $server['version'];
280 return version_compare($server, $version, '>=');
281 }
282
283 /**
284 * Converts short table name {tablename} to real table name
285 * supporting temp tables (#) if detected
286 *
287 * @param string sql
288 * @return string sql
289 */
290 protected function fix_table_names($sql) {
291 if (preg_match_all('/\{([a-z][a-z0-9_]*)\}/', $sql, $matches)) {
292 foreach($matches[0] as $key=>$match) {
293 $name = $matches[1][$key];
4b1ee2b3 294 if ($this->temptables->is_temptable($name)) {
295 $sql = str_replace($match, $this->temptables->get_correct_name($name), $sql);
296 } else {
297 $sql = str_replace($match, $this->prefix.$name, $sql);
298 }
520b730c 299 }
300 }
301 return $sql;
302 }
303
304 /**
305 * Returns supported query parameter types
9331d879 306 * @return int bitmask
520b730c 307 */
308 protected function allowed_param_types() {
309 return SQL_PARAMS_QM; // Not really, but emulated, see emulate_bound_params()
310 }
311
312 /**
313 * Returns last error reported by database engine.
9331d879 314 * @return string error message
520b730c 315 */
316 public function get_last_error() {
317 return mssql_get_last_message();
318 }
319
320 /**
321 * Return tables in database WITHOUT current prefix
322 * @return array of table names in lowercase and without prefix
323 */
324 public function get_tables($usecache=true) {
325 if ($usecache and $this->tables !== null) {
326 return $this->tables;
327 }
328 $this->tables = array();
329 $sql = "SELECT table_name
330 FROM information_schema.tables
331 WHERE table_name LIKE '$this->prefix%'
332 AND table_type = 'BASE TABLE'";
333 $this->query_start($sql, null, SQL_QUERY_AUX);
334 $result = mssql_query($sql, $this->mssql);
335 $this->query_end($result);
336
337 if ($result) {
338 while ($row = mssql_fetch_row($result)) {
339 $tablename = reset($row);
340 if (strpos($tablename, $this->prefix) !== 0) {
341 continue;
342 }
343 $tablename = substr($tablename, strlen($this->prefix));
344 $this->tables[$tablename] = $tablename;
345 }
346 $this->free_result($result);
347 }
348
349 // Add the currently available temptables
350 $this->tables = array_merge($this->tables, $this->temptables->get_temptables());
351 return $this->tables;
352 }
353
354 /**
355 * Return table indexes - everything lowercased
356 * @return array of arrays
357 */
358 public function get_indexes($table) {
359 $indexes = array();
360 $tablename = $this->prefix.$table;
361
362 // Indexes aren't covered by information_schema metatables, so we need to
363 // go to sys ones. Skipping primary key indexes on purpose.
364 $sql = "SELECT i.name AS index_name, i.is_unique, ic.index_column_id, c.name AS column_name
365 FROM sys.indexes i
366 JOIN sys.index_columns ic ON i.object_id = ic.object_id AND i.index_id = ic.index_id
367 JOIN sys.columns c ON ic.object_id = c.object_id AND ic.column_id = c.column_id
368 JOIN sys.tables t ON i.object_id = t.object_id
369 WHERE t.name = '$tablename'
370 AND i.is_primary_key = 0
371 ORDER BY i.name, i.index_id, ic.index_column_id";
372
373 $this->query_start($sql, null, SQL_QUERY_AUX);
374 $result = mssql_query($sql, $this->mssql);
375 $this->query_end($result);
376
377 if ($result) {
378 $lastindex = '';
379 $unique = false;
380 $columns = array();
381 while ($row = mssql_fetch_assoc($result)) {
382 if ($lastindex and $lastindex != $row['index_name']) { // Save lastindex to $indexes and reset info
383 $indexes[$lastindex] = array('unique' => $unique, 'columns' => $columns);
384 $unique = false;
385 $columns = array();
386 }
387 $lastindex = $row['index_name'];
388 $unique = empty($row['is_unique']) ? false : true;
389 $columns[] = $row['column_name'];
390 }
391 if ($lastindex ) { // Add the last one if exists
392 $indexes[$lastindex] = array('unique' => $unique, 'columns' => $columns);
393 }
394 $this->free_result($result);
395 }
396 return $indexes;
397 }
398
399 /**
400 * Returns datailed information about columns in table. This information is cached internally.
401 * @param string $table name
402 * @param bool $usecache
403 * @return array array of database_column_info objects indexed with column names
404 */
405 public function get_columns($table, $usecache=true) {
406 if ($usecache and isset($this->columns[$table])) {
407 return $this->columns[$table];
408 }
409
410 $this->columns[$table] = array();
411
520b730c 412 if (!$this->temptables->is_temptable($table)) { // normal table, get metadata from own schema
413 $sql = "SELECT column_name AS name,
414 data_type AS type,
415 numeric_precision AS max_length,
416 character_maximum_length AS char_max_length,
417 numeric_scale AS scale,
418 is_nullable AS is_nullable,
419 columnproperty(object_id(quotename(table_schema) + '.' +
420 quotename(table_name)), column_name, 'IsIdentity') AS auto_increment,
421 column_default AS default_value
422 FROM information_schema.columns
896a2a91 423 WHERE table_name = '{" . $table . "}'
520b730c 424 ORDER BY ordinal_position";
425 } else { // temp table, get metadata from tempdb schema
426 $sql = "SELECT column_name AS name,
427 data_type AS type,
428 numeric_precision AS max_length,
429 character_maximum_length AS char_max_length,
430 numeric_scale AS scale,
431 is_nullable AS is_nullable,
432 columnproperty(object_id(quotename(table_schema) + '.' +
433 quotename(table_name)), column_name, 'IsIdentity') AS auto_increment,
434 column_default AS default_value
435 FROM tempdb.information_schema.columns
3c41bba0 436 JOIN tempdb..sysobjects ON name = table_name
437 WHERE id = object_id('tempdb..{" . $table . "}')
520b730c 438 ORDER BY ordinal_position";
439 }
440
896a2a91 441 list($sql, $params, $type) = $this->fix_sql_params($sql, null);
442
520b730c 443 $this->query_start($sql, null, SQL_QUERY_AUX);
444 $result = mssql_query($sql, $this->mssql);
445 $this->query_end($result);
446
447 if (!$result) {
448 return array();
449 }
450
451 while ($rawcolumn = mssql_fetch_assoc($result)) {
452
453 $rawcolumn = (object)$rawcolumn;
454
ac6f1a82 455 $info = new stdClass();
520b730c 456 $info->name = $rawcolumn->name;
457 $info->type = $rawcolumn->type;
458 $info->meta_type = $this->mssqltype2moodletype($info->type);
459
460 // Prepare auto_increment info
461 $info->auto_increment = $rawcolumn->auto_increment ? true : false;
462
463 // Define type for auto_increment columns
464 $info->meta_type = ($info->auto_increment && $info->meta_type == 'I') ? 'R' : $info->meta_type;
465
466 // id columns being auto_incremnt are PK by definition
467 $info->primary_key = ($info->name == 'id' && $info->meta_type == 'R' && $info->auto_increment);
468
469 // Put correct length for character and LOB types
470 $info->max_length = $info->meta_type == 'C' ? $rawcolumn->char_max_length : $rawcolumn->max_length;
471 $info->max_length = ($info->meta_type == 'X' || $info->meta_type == 'B') ? -1 : $info->max_length;
472
473 // Scale
474 $info->scale = $rawcolumn->scale ? $rawcolumn->scale : false;
475
476 // Prepare not_null info
477 $info->not_null = $rawcolumn->is_nullable == 'NO' ? true : false;
478
479 // Process defaults
480 $info->has_default = !empty($rawcolumn->default_value);
559d79d2
PS
481 if ($rawcolumn->default_value === NULL) {
482 $info->default_value = NULL;
483 } else {
484 $info->default_value = preg_replace("/^[\(N]+[']?(.*?)[']?[\)]+$/", '\\1', $rawcolumn->default_value);
485 }
520b730c 486
487 // Process binary
488 $info->binary = $info->meta_type == 'B' ? true : false;
489
490 $this->columns[$table][$info->name] = new database_column_info($info);
491 }
492 $this->free_result($result);
493
494 return $this->columns[$table];
495 }
496
497 /**
498 * Normalise values based in RDBMS dependencies (booleans, LOBs...)
499 *
500 * @param database_column_info $column column metadata corresponding with the value we are going to normalise
501 * @param mixed $value value we are going to normalise
502 * @return mixed the normalised value
503 */
e3acc8af 504 protected function normalise_value($column, $value) {
520b730c 505 if (is_bool($value)) { /// Always, convert boolean to int
506 $value = (int)$value;
8a89be3c 507 } // And continue processing because text columns with numeric info need special handling below
520b730c 508
8a89be3c 509 if ($column->meta_type == 'B') { // BLOBs need to be properly "packed", but can be inserted directly if so.
520b730c 510 if (!is_null($value)) { // If value not null, unpack it to unquoted hexadecimal byte-string format
511 $value = unpack('H*hex', $value); // we leave it as array, so emulate_bound_params() can detect it
512 } // easily and "bind" the param ok.
513
514 } else if ($column->meta_type == 'X') { // MSSQL doesn't cast from int to text, so if text column
515 if (is_numeric($value)) { // and is numeric value then cast to string
516 $value = array('numstr' => (string)$value); // and put into array, so emulate_bound_params() will know how
517 } // to "bind" the param ok, avoiding reverse conversion to number
518
519 } else if ($value === '') {
520 if ($column->meta_type == 'I' or $column->meta_type == 'F' or $column->meta_type == 'N') {
521 $value = 0; // prevent '' problems in numeric fields
522 }
523 }
524 return $value;
525 }
526
527 /**
528 * Selectively call mssql_free_result(), avoiding some warnings without using the horrible @
529 *
530 * @param mssql_resource $resource resource to be freed if possible
531 */
532 private function free_result($resource) {
533 if (!is_bool($resource)) { // true/false resources cannot be freed
534 mssql_free_result($resource);
535 }
536 }
537
538 /**
539 * Provides mapping between mssql native data types and moodle_database - database_column_info - ones)
540 *
541 * @param string $mssql_type native mssql data type
542 * @return string 1-char database_column_info data type
543 */
544 private function mssqltype2moodletype($mssql_type) {
545 $type = null;
546 switch (strtoupper($mssql_type)) {
547 case 'BIT':
548 $type = 'L';
549 break;
550 case 'INT':
551 case 'SMALLINT':
552 case 'INTEGER':
553 case 'BIGINT':
554 $type = 'I';
555 break;
556 case 'DECIMAL':
557 case 'REAL':
558 case 'FLOAT':
559 $type = 'N';
560 break;
561 case 'VARCHAR':
562 case 'NVARCHAR':
563 $type = 'C';
564 break;
565 case 'TEXT':
566 case 'NTEXT':
567 case 'VARCHAR(MAX)':
568 case 'NVARCHAR(MAX)':
569 $type = 'X';
570 break;
571 case 'IMAGE':
572 case 'VARBINARY(MAX)':
573 $type = 'B';
574 break;
575 case 'DATETIME':
576 $type = 'D';
577 break;
578 }
579 if (!$type) {
580 throw new dml_exception('invalidmssqlnativetype', $mssql_type);
581 }
582 return $type;
583 }
584
585 /**
586 * Do NOT use in code, to be used by database_manager only!
587 * @param string $sql query
588 * @return bool true
589 * @throws dml_exception if error
590 */
591 public function change_database_structure($sql) {
592 $this->reset_caches();
593
594 $this->query_start($sql, null, SQL_QUERY_STRUCTURE);
5c08b24b 595 $result = mssql_query($sql, $this->mssql);
520b730c 596 $this->query_end($result);
597
598 return true;
599 }
600
601 /**
602 * Very ugly hack which emulates bound parameters in queries
603 * because the mssql driver doesn't support placeholders natively at all
604 */
605 protected function emulate_bound_params($sql, array $params=null) {
606 if (empty($params)) {
607 return $sql;
608 }
609 /// ok, we have verified sql statement with ? and correct number of params
610 $return = strtok($sql, '?');
611 foreach ($params as $param) {
612 if (is_bool($param)) {
613 $return .= (int)$param;
614
615 } else if (is_array($param) && isset($param['hex'])) { // detect hex binary, bind it specially
616 $return .= '0x' . $param['hex'];
617
618 } else if (is_array($param) && isset($param['numstr'])) { // detect numerical strings that *must not*
619 $return .= "N'{$param['numstr']}'"; // be converted back to number params, but bound as strings
620
621 } else if (is_null($param)) {
622 $return .= 'NULL';
623
624 } else if (is_number($param)) { // we can not use is_numeric() because it eats leading zeros from strings like 0045646
4f8b9632 625 $return .= "'".$param."'"; //fix for MDL-24863 to prevent auto-cast to int.
520b730c 626
627 } else if (is_float($param)) {
628 $return .= $param;
629
630 } else {
631 $param = str_replace("'", "''", $param);
632 $return .= "N'$param'";
633 }
634
635 $return .= strtok('?');
636 }
637 return $return;
638 }
639
640 /**
641 * Execute general sql query. Should be used only when no other method suitable.
642 * Do NOT use this to make changes in db structure, use database_manager::execute_sql() instead!
643 * @param string $sql query
644 * @param array $params query parameters
645 * @return bool true
646 * @throws dml_exception if error
647 */
648 public function execute($sql, array $params=null) {
649
650 list($sql, $params, $type) = $this->fix_sql_params($sql, $params);
651 $rawsql = $this->emulate_bound_params($sql, $params);
652
653 if (strpos($sql, ';') !== false) {
654 throw new coding_exception('moodle_database::execute() Multiple sql statements found or bound parameters not used properly in query!');
655 }
656
657 $this->query_start($sql, $params, SQL_QUERY_UPDATE);
5c08b24b 658 $result = mssql_query($rawsql, $this->mssql);
520b730c 659 $this->query_end($result);
660 $this->free_result($result);
661
662 return true;
663 }
664
665 /**
666 * Get a number of records as a moodle_recordset using a SQL statement.
667 *
668 * Since this method is a little less readable, use of it should be restricted to
669 * code where it's possible there might be large datasets being returned. For known
670 * small datasets use get_records_sql - it leads to simpler code.
671 *
672 * The return type is as for @see function get_recordset.
673 *
674 * @param string $sql the SQL select query to execute.
675 * @param array $params array of sql parameters
676 * @param int $limitfrom return a subset of records, starting at this point (optional, required if $limitnum is set).
677 * @param int $limitnum return a subset comprising this many records (optional, required if $limitfrom is set).
5212b07f 678 * @return moodle_recordset instance
520b730c 679 * @throws dml_exception if error
680 */
681 public function get_recordset_sql($sql, array $params=null, $limitfrom=0, $limitnum=0) {
682 $limitfrom = (int)$limitfrom;
683 $limitnum = (int)$limitnum;
684 $limitfrom = ($limitfrom < 0) ? 0 : $limitfrom;
685 $limitnum = ($limitnum < 0) ? 0 : $limitnum;
686 if ($limitfrom or $limitnum) {
4d276e34 687 if ($limitnum >= 1) { // Only apply TOP clause if we have any limitnum (limitfrom offset is handled later)
72a3902f 688 $fetch = $limitfrom + $limitnum;
3a55ee2f
EL
689 $sql = preg_replace('/^([\s(])*SELECT([\s]+)(DISTINCT|ALL)?(?!\s*TOP\s*\()/i',
690 "\\1SELECT\\2\\3 TOP $fetch", $sql);
520b730c 691 }
520b730c 692 }
693
694 list($sql, $params, $type) = $this->fix_sql_params($sql, $params);
695 $rawsql = $this->emulate_bound_params($sql, $params);
696
697 $this->query_start($sql, $params, SQL_QUERY_SELECT);
5c08b24b 698 $result = mssql_query($rawsql, $this->mssql);
520b730c 699 $this->query_end($result);
700
72a3902f 701 if ($limitfrom) { // Skip $limitfrom records
5c08b24b 702 mssql_data_seek($result, $limitfrom);
520b730c 703 }
704
705 return $this->create_recordset($result);
706 }
707
708 protected function create_recordset($result) {
709 return new mssql_native_moodle_recordset($result);
710 }
711
712 /**
713 * Get a number of records as an array of objects using a SQL statement.
714 *
715 * Return value as for @see function get_records.
716 *
717 * @param string $sql the SQL select query to execute. The first column of this SELECT statement
718 * must be a unique value (usually the 'id' field), as it will be used as the key of the
719 * returned array.
720 * @param array $params array of sql parameters
721 * @param int $limitfrom return a subset of records, starting at this point (optional, required if $limitnum is set).
722 * @param int $limitnum return a subset comprising this many records (optional, required if $limitfrom is set).
3503dcad 723 * @return array of objects, or empty array if no records were found
520b730c 724 * @throws dml_exception if error
725 */
726 public function get_records_sql($sql, array $params=null, $limitfrom=0, $limitnum=0) {
727
728 $rs = $this->get_recordset_sql($sql, $params, $limitfrom, $limitnum);
729
730 $results = array();
731
732 foreach ($rs as $row) {
df5f9165 733 $id = reset($row);
734 if (isset($results[$id])) {
520b730c 735 $colname = key($row);
736 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);
737 }
df5f9165 738 $results[$id] = $row;
520b730c 739 }
740 $rs->close();
741
742 return $results;
743 }
744
745 /**
746 * Selects records and return values (first field) as an array using a SQL statement.
747 *
748 * @param string $sql The SQL query
749 * @param array $params array of sql parameters
3503dcad 750 * @return array of values
520b730c 751 * @throws dml_exception if error
752 */
753 public function get_fieldset_sql($sql, array $params=null) {
754
755 $rs = $this->get_recordset_sql($sql, $params);
756
757 $results = array();
758
759 foreach ($rs as $row) {
760 $results[] = reset($row);
761 }
762 $rs->close();
763
764 return $results;
765 }
766
767 /**
768 * Insert new record into database, as fast as possible, no safety checks, lobs not supported.
769 * @param string $table name
770 * @param mixed $params data record as object or array
771 * @param bool $returnit return it of inserted record
772 * @param bool $bulk true means repeated inserts expected
773 * @param bool $customsequence true if 'id' included in $params, disables $returnid
3503dcad 774 * @return bool|int true or new id
520b730c 775 * @throws dml_exception if error
776 */
777 public function insert_record_raw($table, $params, $returnid=true, $bulk=false, $customsequence=false) {
778 if (!is_array($params)) {
779 $params = (array)$params;
780 }
781
782 $returning = "";
783
784 if ($customsequence) {
785 if (!isset($params['id'])) {
786 throw new coding_exception('moodle_database::insert_record_raw() id field must be specified if custom sequences used.');
787 }
788 $returnid = false;
97dbac93
PS
789
790 // Disable IDENTITY column before inserting record with id
791 $sql = 'SET IDENTITY_INSERT {' . $table . '} ON'; // Yes, it' ON!!
792 list($sql, $xparams, $xtype) = $this->fix_sql_params($sql, null);
793 $this->query_start($sql, null, SQL_QUERY_AUX);
794 $result = mssql_query($sql, $this->mssql);
795 $this->query_end($result);
796 $this->free_result($result);
797
520b730c 798 } else {
799 unset($params['id']);
800 if ($returnid) {
801 $returning = "; SELECT SCOPE_IDENTITY()";
802 }
803 }
804
805 if (empty($params)) {
806 throw new coding_exception('moodle_database::insert_record_raw() no fields found.');
807 }
808
809 $fields = implode(',', array_keys($params));
810 $qms = array_fill(0, count($params), '?');
811 $qms = implode(',', $qms);
812
813 $sql = "INSERT INTO {" . $table . "} ($fields) VALUES($qms) $returning";
814
815 list($sql, $params, $type) = $this->fix_sql_params($sql, $params);
816 $rawsql = $this->emulate_bound_params($sql, $params);
817
818 $this->query_start($sql, $params, SQL_QUERY_INSERT);
5c08b24b 819 $result = mssql_query($rawsql, $this->mssql);
520b730c 820 $this->query_end($result);
821
822 if ($returning !== "") {
823 $row = mssql_fetch_assoc($result);
824 $params['id'] = reset($row);
825 }
826 $this->free_result($result);
827
97dbac93
PS
828 if ($customsequence) {
829 // Enable IDENTITY column after inserting record with id
830 $sql = 'SET IDENTITY_INSERT {' . $table . '} OFF'; // Yes, it' OFF!!
831 list($sql, $xparams, $xtype) = $this->fix_sql_params($sql, null);
832 $this->query_start($sql, null, SQL_QUERY_AUX);
833 $result = mssql_query($sql, $this->mssql);
834 $this->query_end($result);
835 $this->free_result($result);
836 }
837
520b730c 838 if (!$returnid) {
839 return true;
840 }
841
842 return (int)$params['id'];
843 }
844
845 /**
846 * Insert a record into a table and return the "id" field if required.
847 *
848 * Some conversions and safety checks are carried out. Lobs are supported.
849 * If the return ID isn't required, then this just reports success as true/false.
850 * $data is an object containing needed data
851 * @param string $table The database table to be inserted into
852 * @param object $data A data object with values for one or more fields in the record
853 * @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.
3503dcad 854 * @return bool|int true or new id
520b730c 855 * @throws dml_exception if error
856 */
857 public function insert_record($table, $dataobject, $returnid=true, $bulk=false) {
d8fa8e40 858 $dataobject = (array)$dataobject;
520b730c 859
860 $columns = $this->get_columns($table);
861 $cleaned = array();
862
863 foreach ($dataobject as $field => $value) {
d8fa8e40
PS
864 if ($field === 'id') {
865 continue;
866 }
520b730c 867 if (!isset($columns[$field])) {
868 continue;
869 }
870 $column = $columns[$field];
871 $cleaned[$field] = $this->normalise_value($column, $value);
872 }
873
874 return $this->insert_record_raw($table, $cleaned, $returnid, $bulk);
875 }
876
877 /**
878 * Import a record into a table, id field is required.
879 * Safety checks are NOT carried out. Lobs are supported.
880 *
881 * @param string $table name of database table to be inserted into
882 * @param object $dataobject A data object with values for one or more fields in the record
883 * @return bool true
884 * @throws dml_exception if error
885 */
886 public function import_record($table, $dataobject) {
d8fa8e40 887 $dataobject = (array)$dataobject;
520b730c 888
889 $columns = $this->get_columns($table);
890 $cleaned = array();
891
896a2a91 892 foreach ($dataobject as $field => $value) {
520b730c 893 if (!isset($columns[$field])) {
894 continue;
895 }
896a2a91 896 $column = $columns[$field];
897 $cleaned[$field] = $this->normalise_value($column, $value);
520b730c 898 }
899
97dbac93 900 $this->insert_record_raw($table, $cleaned, false, false, true);
896a2a91 901
97dbac93 902 return true;
520b730c 903 }
904
905 /**
906 * Update record in database, as fast as possible, no safety checks, lobs not supported.
907 * @param string $table name
908 * @param mixed $params data record as object or array
909 * @param bool true means repeated updates expected
910 * @return bool true
911 * @throws dml_exception if error
912 */
913 public function update_record_raw($table, $params, $bulk=false) {
d8fa8e40
PS
914 $params = (array)$params;
915
520b730c 916 if (!isset($params['id'])) {
917 throw new coding_exception('moodle_database::update_record_raw() id field must be specified.');
918 }
919 $id = $params['id'];
920 unset($params['id']);
921
922 if (empty($params)) {
923 throw new coding_exception('moodle_database::update_record_raw() no fields found.');
924 }
925
926 $sets = array();
927 foreach ($params as $field=>$value) {
928 $sets[] = "$field = ?";
929 }
930
931 $params[] = $id; // last ? in WHERE condition
932
933 $sets = implode(',', $sets);
934 $sql = "UPDATE {" . $table . "} SET $sets WHERE id = ?";
935
936 list($sql, $params, $type) = $this->fix_sql_params($sql, $params);
937 $rawsql = $this->emulate_bound_params($sql, $params);
938
939 $this->query_start($sql, $params, SQL_QUERY_UPDATE);
5c08b24b 940 $result = mssql_query($rawsql, $this->mssql);
520b730c 941 $this->query_end($result);
942
943 $this->free_result($result);
944 return true;
945 }
946
947 /**
948 * Update a record in a table
949 *
950 * $dataobject is an object containing needed data
951 * Relies on $dataobject having a variable "id" to
952 * specify the record to update
953 *
954 * @param string $table The database table to be checked against.
955 * @param object $dataobject An object with contents equal to fieldname=>fieldvalue. Must have an entry for 'id' to map to the table specified.
956 * @param bool true means repeated updates expected
957 * @return bool true
958 * @throws dml_exception if error
959 */
960 public function update_record($table, $dataobject, $bulk=false) {
d8fa8e40 961 $dataobject = (array)$dataobject;
520b730c 962
963 $columns = $this->get_columns($table);
964 $cleaned = array();
965
966 foreach ($dataobject as $field => $value) {
967 if (!isset($columns[$field])) {
968 continue;
969 }
970 $column = $columns[$field];
971 $cleaned[$field] = $this->normalise_value($column, $value);
972 }
973
974 return $this->update_record_raw($table, $cleaned, $bulk);
975 }
976
977 /**
978 * Set a single field in every table record which match a particular WHERE clause.
979 *
980 * @param string $table The database table to be checked against.
981 * @param string $newfield the field to set.
982 * @param string $newvalue the value to set the field to.
983 * @param string $select A fragment of SQL to be used in a where clause in the SQL call.
984 * @param array $params array of sql parameters
985 * @return bool true
986 * @throws dml_exception if error
987 */
988 public function set_field_select($table, $newfield, $newvalue, $select, array $params=null) {
989
990 if ($select) {
991 $select = "WHERE $select";
992 }
993 if (is_null($params)) {
994 $params = array();
995 }
996
997 /// Get column metadata
998 $columns = $this->get_columns($table);
999 $column = $columns[$newfield];
1000
1001 $newvalue = $this->normalise_value($column, $newvalue);
1002
1003 if (is_null($newvalue)) {
1004 $newfield = "$newfield = NULL";
1005 } else {
1006 $newfield = "$newfield = ?";
1007 array_unshift($params, $newvalue);
1008 }
1009 $sql = "UPDATE {" . $table . "} SET $newfield $select";
1010
1011 list($sql, $params, $type) = $this->fix_sql_params($sql, $params);
1012 $rawsql = $this->emulate_bound_params($sql, $params);
1013
1014 $this->query_start($sql, $params, SQL_QUERY_UPDATE);
5c08b24b 1015 $result = mssql_query($rawsql, $this->mssql);
520b730c 1016 $this->query_end($result);
1017
1018 $this->free_result($result);
1019
1020 return true;
1021 }
1022
1023 /**
1024 * Delete one or more records from a table which match a particular WHERE clause.
1025 *
1026 * @param string $table The database table to be checked against.
1027 * @param string $select A fragment of SQL to be used in a where clause in the SQL call (used to define the selection criteria).
1028 * @param array $params array of sql parameters
1029 * @return bool true
1030 * @throws dml_exception if error
1031 */
1032 public function delete_records_select($table, $select, array $params=null) {
1033
1034 if ($select) {
1035 $select = "WHERE $select";
1036 }
1037
1038 $sql = "DELETE FROM {" . $table . "} $select";
1039
1040 list($sql, $params, $type) = $this->fix_sql_params($sql, $params);
1041 $rawsql = $this->emulate_bound_params($sql, $params);
1042
1043 $this->query_start($sql, $params, SQL_QUERY_UPDATE);
5c08b24b 1044 $result = mssql_query($rawsql, $this->mssql);
520b730c 1045 $this->query_end($result);
1046
1047 $this->free_result($result);
1048
1049 return true;
1050 }
1051
1052/// SQL helper functions
1053
520b730c 1054 public function sql_cast_char2int($fieldname, $text=false) {
9882b2c8
EL
1055 if (!$text) {
1056 return ' CAST(' . $fieldname . ' AS INT) ';
1057 } else {
1058 return ' CAST(' . $this->sql_compare_text($fieldname) . ' AS INT) ';
1059 }
1060 }
1061
1062 public function sql_cast_char2real($fieldname, $text=false) {
1063 if (!$text) {
1064 return ' CAST(' . $fieldname . ' AS REAL) ';
1065 } else {
1066 return ' CAST(' . $this->sql_compare_text($fieldname) . ' AS REAL) ';
1067 }
520b730c 1068 }
1069
1070 public function sql_ceil($fieldname) {
1071 return ' CEILING(' . $fieldname . ')';
1072 }
1073
6055f89d
PS
1074
1075 protected function get_collation() {
1076 if (isset($this->collation)) {
1077 return $this->collation;
1078 }
1079 if (!empty($this->dboptions['dbcollation'])) {
1080 // perf speedup
1081 $this->collation = $this->dboptions['dbcollation'];
1082 return $this->collation;
1083 }
1084
1085 // make some default
1086 $this->collation = 'Latin1_General_CI_AI';
1087
1088 $sql = "SELECT CAST(DATABASEPROPERTYEX('$this->dbname', 'Collation') AS varchar(255)) AS SQLCollation";
1089 $this->query_start($sql, null, SQL_QUERY_AUX);
e016d126 1090 $result = mssql_query($sql, $this->mssql);
6055f89d
PS
1091 $this->query_end($result);
1092
1093 if ($result) {
e016d126 1094 if ($rawcolumn = mssql_fetch_assoc($result)) {
6055f89d
PS
1095 $this->collation = reset($rawcolumn);
1096 }
1097 $this->free_result($result);
1098 }
1099
1100 return $this->collation;
1101 }
1102
6055f89d
PS
1103 /**
1104 * Returns 'LIKE' part of a query.
1105 *
1106 * @param string $fieldname usually name of the table column
1107 * @param string $param usually bound query parameter (?, :named)
1108 * @param bool $casesensitive use case sensitive search
1109 * @param bool $accensensitive use accent sensitive search (not all databases support accent insensitive)
16114b9d 1110 * @param bool $notlike true means "NOT LIKE"
6055f89d
PS
1111 * @param string $escapechar escape char for '%' and '_'
1112 * @return string SQL code fragment
1113 */
16114b9d 1114 public function sql_like($fieldname, $param, $casesensitive = true, $accentsensitive = true, $notlike = false, $escapechar = '\\') {
6055f89d
PS
1115 if (strpos($param, '%') !== false) {
1116 debugging('Potential SQL injection detected, sql_ilike() expects bound parameters (? or :named)');
1117 }
1118
1119 $collation = $this->get_collation();
1120
1121 if ($casesensitive) {
1122 $collation = str_replace('_CI', '_CS', $collation);
1123 } else {
1124 $collation = str_replace('_CS', '_CI', $collation);
1125 }
1126 if ($accentsensitive) {
1127 $collation = str_replace('_AI', '_AS', $collation);
1128 } else {
1129 $collation = str_replace('_AS', '_AI', $collation);
1130 }
1131
16114b9d
PS
1132 $LIKE = $notlike ? 'NOT LIKE' : 'LIKE';
1133
1134 return "$fieldname COLLATE $collation $LIKE $param ESCAPE '$escapechar'";
6055f89d
PS
1135 }
1136
520b730c 1137 public function sql_concat() {
1138 $arr = func_get_args();
1139 foreach ($arr as $key => $ele) {
1140 $arr[$key] = ' CAST(' . $ele . ' AS VARCHAR(255)) ';
1141 }
1142 $s = implode(' + ', $arr);
1143 if ($s === '') {
1144 return " '' ";
1145 }
1146 return " $s ";
1147 }
1148
1149 public function sql_concat_join($separator="' '", $elements=array()) {
1150 for ($n=count($elements)-1; $n > 0 ; $n--) {
1151 array_splice($elements, $n, 0, $separator);
1152 }
1153 $s = implode(' + ', $elements);
1154 if ($s === '') {
1155 return " '' ";
1156 }
1157 return " $s ";
1158 }
1159
1160 public function sql_isempty($tablename, $fieldname, $nullablefield, $textfield) {
1161 if ($textfield) {
63b3d8ab 1162 return ' (' . $this->sql_compare_text($fieldname) . " = '') ";
520b730c 1163 } else {
63b3d8ab 1164 return " ($fieldname = '') ";
520b730c 1165 }
1166 }
1167
1168 /**
1169 * Returns the SQL text to be used to calculate the length in characters of one expression.
1170 * @param string fieldname or expression to calculate its length in characters.
1171 * @return string the piece of SQL code to be used in the statement.
1172 */
1173 public function sql_length($fieldname) {
1174 return ' LEN(' . $fieldname . ')';
1175 }
1176
1177 public function sql_order_by_text($fieldname, $numchars=32) {
1178 return ' CONVERT(varchar, ' . $fieldname . ', ' . $numchars . ')';
1179 }
1180
1181 /**
1182 * Returns the SQL for returning searching one string for the location of another.
1183 */
1184 public function sql_position($needle, $haystack) {
1185 return "CHARINDEX(($needle), ($haystack))";
1186 }
1187
1188 /**
ab62bd23 1189 * Returns the proper substr() SQL text used to extract substrings from DB
520b730c 1190 * NOTE: this was originally returning only function name
1191 *
1192 * @param string $expr some string field, no aggregates
4d276e34
PS
1193 * @param mixed $start integer or expression evaluating to int
1194 * @param mixed $length optional integer or expression evaluating to int
520b730c 1195 * @return string sql fragment
1196 */
1197 public function sql_substr($expr, $start, $length=false) {
1198 if (count(func_get_args()) < 2) {
1199 throw new coding_exception('moodle_database::sql_substr() requires at least two parameters', 'Originaly this function wa
1200s only returning name of SQL substring function, it now requires all parameters.');
1201 }
1202 if ($length === false) {
1203 return "SUBSTRING($expr, $start, (LEN($expr) - $start + 1))";
1204 } else {
1205 return "SUBSTRING($expr, $start, $length)";
1206 }
1207 }
1208
1209/// session locking
1210
1211 public function session_lock_supported() {
6d682bae 1212 return true;
520b730c 1213 }
1214
1215 public function get_session_lock($rowid) {
520b730c 1216 if (!$this->session_lock_supported()) {
1217 return;
1218 }
520b730c 1219 parent::get_session_lock($rowid);
6d682bae 1220
1221 $fullname = $this->dbname.'-'.$this->prefix.'-session-'.$rowid;
1222 $sql = "sp_getapplock '$fullname', 'Exclusive', 'Session', 120000";
520b730c 1223 $this->query_start($sql, null, SQL_QUERY_AUX);
6d682bae 1224 $result = mssql_query($sql, $this->mssql);
520b730c 1225 $this->query_end($result);
1226
6d682bae 1227 $this->free_result($result);
520b730c 1228 }
1229
1230 public function release_session_lock($rowid) {
1231 if (!$this->session_lock_supported()) {
1232 return;
1233 }
1234 parent::release_session_lock($rowid);
1235
6d682bae 1236 $fullname = $this->dbname.'-'.$this->prefix.'-session-'.$rowid;
982fd65f 1237 $sql = "sp_releaseapplock '$fullname', 'Session'";
520b730c 1238 $this->query_start($sql, null, SQL_QUERY_AUX);
6d682bae 1239 $result = mssql_query($sql, $this->mssql);
520b730c 1240 $this->query_end($result);
1241
6d682bae 1242 $this->free_result($result);
520b730c 1243 }
1244
1245/// transactions
1246
1247 /**
d5a8d9aa
PS
1248 * Driver specific start of real database transaction,
1249 * this can not be used directly in code.
1250 * @return void
520b730c 1251 */
12ffe203
EL
1252 protected function begin_transaction() {
1253 // requires database to run with READ_COMMITTED_SNAPSHOT ON
520b730c 1254 $sql = "BEGIN TRANSACTION"; // Will be using READ COMMITTED isolation
1255 $this->query_start($sql, NULL, SQL_QUERY_AUX);
1256 $result = mssql_query($sql, $this->mssql);
1257 $this->query_end($result);
1258
1259 $this->free_result($result);
520b730c 1260 }
1261
1262 /**
d5a8d9aa
PS
1263 * Driver specific commit of real database transaction,
1264 * this can not be used directly in code.
1265 * @return void
520b730c 1266 */
12ffe203 1267 protected function commit_transaction() {
520b730c 1268 $sql = "COMMIT TRANSACTION";
1269 $this->query_start($sql, NULL, SQL_QUERY_AUX);
1270 $result = mssql_query($sql, $this->mssql);
1271 $this->query_end($result);
1272
1273 $this->free_result($result);
520b730c 1274 }
1275
1276 /**
d5a8d9aa
PS
1277 * Driver specific abort of real database transaction,
1278 * this can not be used directly in code.
1279 * @return void
520b730c 1280 */
12ffe203 1281 protected function rollback_transaction() {
520b730c 1282 $sql = "ROLLBACK TRANSACTION";
1283 $this->query_start($sql, NULL, SQL_QUERY_AUX);
1284 $result = mssql_query($sql, $this->mssql);
1285 $this->query_end($result);
1286
1287 $this->free_result($result);
520b730c 1288 }
1289}