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