3 // This file is part of Moodle - http://moodle.org/
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.
10 // Moodle is distributed in the hope that it will be useful,
11 // but WITHOUT ANY WARRANTY; without even the implied warranty of
12 // MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the
13 // GNU General Public License for more details.
15 // You should have received a copy of the GNU General Public License
16 // along with Moodle. If not, see <http://www.gnu.org/licenses/>.
20 * Native mssql class representing moodle database interface.
23 * @subpackage dml_driver
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
28 defined('MOODLE_INTERNAL') || die();
30 require_once($CFG->libdir.'/dml/moodle_database.php');
31 require_once($CFG->libdir.'/dml/mssql_native_moodle_recordset.php');
32 require_once($CFG->libdir.'/dml/mssql_native_moodle_temptables.php');
35 * Native mssql class representing moodle database interface.
38 * @subpackage dml_driver
39 * @copyright 2009 onwards Eloy Lafuente (stronk7) {@link http://stronk7.com}
40 * @license http://www.gnu.org/copyleft/gpl.html GNU GPL v3 or later
42 class mssql_native_moodle_database extends moodle_database {
44 protected $mssql = null;
45 protected $last_error_reporting; // To handle mssql driver default verbosity
46 protected $collation; // current DB collation cache
49 * Detects if all needed PHP stuff installed.
50 * Note: can be used before connect()
51 * @return mixed true if ok, string if something
53 public function driver_installed() {
54 if (!function_exists('mssql_connect')) {
55 return get_string('mssqlextensionisnotpresentinphp', 'install');
61 * Returns database family type - describes SQL dialect
62 * Note: can be used before connect()
63 * @return string db family name (mysql, postgres, mssql, oracle, etc.)
65 public function get_dbfamily() {
70 * Returns more specific database driver type
71 * Note: can be used before connect()
72 * @return string db type mysqli, pgsql, oci, mssql, sqlsrv
74 protected function get_dbtype() {
79 * Returns general database library name
80 * Note: can be used before connect()
81 * @return string db type pdo, native
83 protected function get_dblibrary() {
88 * Returns localised database type name
89 * Note: can be used before connect()
92 public function get_name() {
93 return get_string('nativemssql', 'install');
97 * Returns localised database configuration help.
98 * Note: can be used before connect()
101 public function get_configuration_help() {
102 return get_string('nativemssqlhelp', 'install');
106 * Returns localised database description
107 * Note: can be used before connect()
110 public function get_configuration_hints() {
111 $str = get_string('databasesettingssub_mssql', 'install');
112 $str .= "<p style='text-align:right'><a href=\"javascript:void(0)\" ";
113 $str .= "onclick=\"return window.open('http://docs.moodle.org/en/Installing_MSSQL_for_PHP')\"";
115 $str .= '<img src="pix/docs.gif' . '" alt="Docs" class="iconhelp" />';
116 $str .= get_string('moodledocslink', 'install') . '</a></p>';
122 * Must be called before other methods.
123 * @param string $dbhost The database host.
124 * @param string $dbuser The database username.
125 * @param string $dbpass The database username's password.
126 * @param string $dbname The name of the database being connected to.
127 * @param mixed $prefix string means moodle db prefix, false used for external databases where prefix not used
128 * @param array $dboptions driver specific options
130 * @throws dml_connection_exception if error
132 public function connect($dbhost, $dbuser, $dbpass, $dbname, $prefix, array $dboptions=null) {
133 if ($prefix == '' and !$this->external) {
134 //Enforce prefixes for everybody but mysql
135 throw new dml_exception('prefixcannotbeempty', $this->get_dbfamily());
138 $driverstatus = $this->driver_installed();
140 if ($driverstatus !== true) {
141 throw new dml_exception('dbdriverproblem', $driverstatus);
144 $this->store_settings($dbhost, $dbuser, $dbpass, $dbname, $prefix, $dboptions);
146 $dbhost = $this->dbhost;
147 if (isset($dboptions['dbport'])) {
148 if (stristr(PHP_OS, 'win') && !stristr(PHP_OS, 'darwin')) {
149 $dbhost .= ','.$dboptions['dbport'];
151 $dbhost .= ':'.$dboptions['dbport'];
155 if (!empty($this->dboptions['dbpersist'])) { // persistent connection
156 $this->mssql = mssql_pconnect($dbhost, $this->dbuser, $this->dbpass, true);
158 $this->mssql = mssql_connect($dbhost, $this->dbuser, $this->dbpass, true);
160 $dberr = ob_get_contents();
163 if ($this->mssql === false) {
165 throw new dml_connection_exception($dberr);
168 // already connected, select database and set some env. variables
169 $this->query_start("--mssql_select_db", null, SQL_QUERY_AUX);
170 $result = mssql_select_db($this->dbname, $this->mssql);
171 $this->query_end($result);
173 // No need to set charset. It's UTF8, with transparent conversions
174 // back and forth performed both by FreeTDS or ODBTP
176 // Allow quoted identifiers
177 $sql = "SET QUOTED_IDENTIFIER ON";
178 $this->query_start($sql, null, SQL_QUERY_AUX);
179 $result = mssql_query($sql, $this->mssql);
180 $this->query_end($result);
182 $this->free_result($result);
184 // Force ANSI nulls so the NULL check was done by IS NULL and NOT IS NULL
185 // instead of equal(=) and distinct(<>) symbols
186 $sql = "SET ANSI_NULLS ON";
187 $this->query_start($sql, null, SQL_QUERY_AUX);
188 $result = mssql_query($sql, $this->mssql);
189 $this->query_end($result);
191 $this->free_result($result);
193 // Force ANSI warnings so arithmetic/string overflows will be
194 // returning error instead of transparently truncating data
195 $sql = "SET ANSI_WARNINGS ON";
196 $this->query_start($sql, null, SQL_QUERY_AUX);
197 $result = mssql_query($sql, $this->mssql);
198 $this->query_end($result);
200 // Concatenating null with anything MUST return NULL
201 $sql = "SET CONCAT_NULL_YIELDS_NULL ON";
202 $this->query_start($sql, null, SQL_QUERY_AUX);
203 $result = mssql_query($sql, $this->mssql);
204 $this->query_end($result);
206 $this->free_result($result);
208 // Set transactions isolation level to READ_COMMITTED
209 // prevents dirty reads when using transactions +
210 // is the default isolation level of MSSQL
211 // Requires database to run with READ_COMMITTED_SNAPSHOT ON
212 $sql = "SET TRANSACTION ISOLATION LEVEL READ COMMITTED";
213 $this->query_start($sql, NULL, SQL_QUERY_AUX);
214 $result = mssql_query($sql, $this->mssql);
215 $this->query_end($result);
217 $this->free_result($result);
219 // Connection stabilised and configured, going to instantiate the temptables controller
220 $this->temptables = new mssql_native_moodle_temptables($this);
226 * Close database connection and release all resources
227 * and memory (especially circular memory references).
228 * Do NOT use connect() again, create a new instance if needed.
230 public function dispose() {
231 parent::dispose(); // Call parent dispose to write/close session and other common stuff before closing connection
233 mssql_close($this->mssql);
239 * Called before each db query.
241 * @param array array of parameters
242 * @param int $type type of query
243 * @param mixed $extrainfo driver specific extra information
246 protected function query_start($sql, array $params=null, $type, $extrainfo=null) {
247 parent::query_start($sql, $params, $type, $extrainfo);
248 // mssql driver tends to send debug to output, we do not need that ;-)
249 $this->last_error_reporting = error_reporting(0);
253 * Called immediately after each db query.
254 * @param mixed db specific result
257 protected function query_end($result) {
258 // reset original debug level
259 error_reporting($this->last_error_reporting);
260 parent::query_end($result);
264 * Returns database server info array
265 * @return array Array containing 'description' and 'version' info
267 public function get_server_info() {
271 $sql = 'sp_server_info 2';
272 $this->query_start($sql, null, SQL_QUERY_AUX);
273 $result = mssql_query($sql, $this->mssql);
274 $this->query_end($result);
275 $row = mssql_fetch_row($result);
276 $info['description'] = $row[2];
277 $this->free_result($result);
279 $sql = 'sp_server_info 500';
280 $this->query_start($sql, null, SQL_QUERY_AUX);
281 $result = mssql_query($sql, $this->mssql);
282 $this->query_end($result);
283 $row = mssql_fetch_row($result);
284 $info['version'] = $row[2];
285 $this->free_result($result);
290 protected function is_min_version($version) {
291 $server = $this->get_server_info();
292 $server = $server['version'];
293 return version_compare($server, $version, '>=');
297 * Converts short table name {tablename} to real table name
298 * supporting temp tables (#) if detected
303 protected function fix_table_names($sql) {
304 if (preg_match_all('/\{([a-z][a-z0-9_]*)\}/', $sql, $matches)) {
305 foreach($matches[0] as $key=>$match) {
306 $name = $matches[1][$key];
307 if ($this->temptables->is_temptable($name)) {
308 $sql = str_replace($match, $this->temptables->get_correct_name($name), $sql);
310 $sql = str_replace($match, $this->prefix.$name, $sql);
318 * Returns supported query parameter types
319 * @return int bitmask of accepted SQL_PARAMS_*
321 protected function allowed_param_types() {
322 return SQL_PARAMS_QM; // Not really, but emulated, see emulate_bound_params()
326 * Returns last error reported by database engine.
327 * @return string error message
329 public function get_last_error() {
330 return mssql_get_last_message();
334 * Return tables in database WITHOUT current prefix
335 * @param bool $usecache if true, returns list of cached tables.
336 * @return array of table names in lowercase and without prefix
338 public function get_tables($usecache=true) {
339 if ($usecache and $this->tables !== null) {
340 return $this->tables;
342 $this->tables = array();
343 $sql = "SELECT table_name
344 FROM information_schema.tables
345 WHERE table_name LIKE '$this->prefix%'
346 AND table_type = 'BASE TABLE'";
347 $this->query_start($sql, null, SQL_QUERY_AUX);
348 $result = mssql_query($sql, $this->mssql);
349 $this->query_end($result);
352 while ($row = mssql_fetch_row($result)) {
353 $tablename = reset($row);
354 if (strpos($tablename, $this->prefix) !== 0) {
357 $tablename = substr($tablename, strlen($this->prefix));
358 $this->tables[$tablename] = $tablename;
360 $this->free_result($result);
363 // Add the currently available temptables
364 $this->tables = array_merge($this->tables, $this->temptables->get_temptables());
365 return $this->tables;
369 * Return table indexes - everything lowercased.
370 * @param string $table The table we want to get indexes from.
371 * @return array An associative array of indexes containing 'unique' flag and 'columns' being indexed
373 public function get_indexes($table) {
375 $tablename = $this->prefix.$table;
377 // Indexes aren't covered by information_schema metatables, so we need to
378 // go to sys ones. Skipping primary key indexes on purpose.
379 $sql = "SELECT i.name AS index_name, i.is_unique, ic.index_column_id, c.name AS column_name
381 JOIN sys.index_columns ic ON i.object_id = ic.object_id AND i.index_id = ic.index_id
382 JOIN sys.columns c ON ic.object_id = c.object_id AND ic.column_id = c.column_id
383 JOIN sys.tables t ON i.object_id = t.object_id
384 WHERE t.name = '$tablename'
385 AND i.is_primary_key = 0
386 ORDER BY i.name, i.index_id, ic.index_column_id";
388 $this->query_start($sql, null, SQL_QUERY_AUX);
389 $result = mssql_query($sql, $this->mssql);
390 $this->query_end($result);
396 while ($row = mssql_fetch_assoc($result)) {
397 if ($lastindex and $lastindex != $row['index_name']) { // Save lastindex to $indexes and reset info
398 $indexes[$lastindex] = array('unique' => $unique, 'columns' => $columns);
402 $lastindex = $row['index_name'];
403 $unique = empty($row['is_unique']) ? false : true;
404 $columns[] = $row['column_name'];
406 if ($lastindex ) { // Add the last one if exists
407 $indexes[$lastindex] = array('unique' => $unique, 'columns' => $columns);
409 $this->free_result($result);
415 * Returns datailed information about columns in table. This information is cached internally.
416 * @param string $table name
417 * @param bool $usecache
418 * @return array array of database_column_info objects indexed with column names
420 public function get_columns($table, $usecache=true) {
421 if ($usecache and isset($this->columns[$table])) {
422 return $this->columns[$table];
425 $this->columns[$table] = array();
427 if (!$this->temptables->is_temptable($table)) { // normal table, get metadata from own schema
428 $sql = "SELECT column_name AS name,
430 numeric_precision AS max_length,
431 character_maximum_length AS char_max_length,
432 numeric_scale AS scale,
433 is_nullable AS is_nullable,
434 columnproperty(object_id(quotename(table_schema) + '.' +
435 quotename(table_name)), column_name, 'IsIdentity') AS auto_increment,
436 column_default AS default_value
437 FROM information_schema.columns
438 WHERE table_name = '{" . $table . "}'
439 ORDER BY ordinal_position";
440 } else { // temp table, get metadata from tempdb schema
441 $sql = "SELECT column_name AS name,
443 numeric_precision AS max_length,
444 character_maximum_length AS char_max_length,
445 numeric_scale AS scale,
446 is_nullable AS is_nullable,
447 columnproperty(object_id(quotename(table_schema) + '.' +
448 quotename(table_name)), column_name, 'IsIdentity') AS auto_increment,
449 column_default AS default_value
450 FROM tempdb.information_schema.columns
451 JOIN tempdb..sysobjects ON name = table_name
452 WHERE id = object_id('tempdb..{" . $table . "}')
453 ORDER BY ordinal_position";
456 list($sql, $params, $type) = $this->fix_sql_params($sql, null);
458 $this->query_start($sql, null, SQL_QUERY_AUX);
459 $result = mssql_query($sql, $this->mssql);
460 $this->query_end($result);
466 while ($rawcolumn = mssql_fetch_assoc($result)) {
468 $rawcolumn = (object)$rawcolumn;
470 $info = new stdClass();
471 $info->name = $rawcolumn->name;
472 $info->type = $rawcolumn->type;
473 $info->meta_type = $this->mssqltype2moodletype($info->type);
475 // Prepare auto_increment info
476 $info->auto_increment = $rawcolumn->auto_increment ? true : false;
478 // Define type for auto_increment columns
479 $info->meta_type = ($info->auto_increment && $info->meta_type == 'I') ? 'R' : $info->meta_type;
481 // id columns being auto_incremnt are PK by definition
482 $info->primary_key = ($info->name == 'id' && $info->meta_type == 'R' && $info->auto_increment);
484 // Put correct length for character and LOB types
485 $info->max_length = $info->meta_type == 'C' ? $rawcolumn->char_max_length : $rawcolumn->max_length;
486 $info->max_length = ($info->meta_type == 'X' || $info->meta_type == 'B') ? -1 : $info->max_length;
489 $info->scale = $rawcolumn->scale ? $rawcolumn->scale : false;
491 // Prepare not_null info
492 $info->not_null = $rawcolumn->is_nullable == 'NO' ? true : false;
495 $info->has_default = !empty($rawcolumn->default_value);
496 if ($rawcolumn->default_value === NULL) {
497 $info->default_value = NULL;
499 $info->default_value = preg_replace("/^[\(N]+[']?(.*?)[']?[\)]+$/", '\\1', $rawcolumn->default_value);
503 $info->binary = $info->meta_type == 'B' ? true : false;
505 $this->columns[$table][$info->name] = new database_column_info($info);
507 $this->free_result($result);
509 return $this->columns[$table];
513 * Normalise values based on varying RDBMS's dependencies (booleans, LOBs...)
515 * @param database_column_info $column column metadata corresponding with the value we are going to normalise
516 * @param mixed $value value we are going to normalise
517 * @return mixed the normalised value
519 protected function normalise_value($column, $value) {
520 $this->detect_objects($value);
522 if (is_bool($value)) { /// Always, convert boolean to int
523 $value = (int)$value;
524 } // And continue processing because text columns with numeric info need special handling below
526 if ($column->meta_type == 'B') { // BLOBs need to be properly "packed", but can be inserted directly if so.
527 if (!is_null($value)) { // If value not null, unpack it to unquoted hexadecimal byte-string format
528 $value = unpack('H*hex', $value); // we leave it as array, so emulate_bound_params() can detect it
529 } // easily and "bind" the param ok.
531 } else if ($column->meta_type == 'X') { // MSSQL doesn't cast from int to text, so if text column
532 if (is_numeric($value)) { // and is numeric value then cast to string
533 $value = array('numstr' => (string)$value); // and put into array, so emulate_bound_params() will know how
534 } // to "bind" the param ok, avoiding reverse conversion to number
536 } else if ($value === '') {
537 if ($column->meta_type == 'I' or $column->meta_type == 'F' or $column->meta_type == 'N') {
538 $value = 0; // prevent '' problems in numeric fields
545 * Selectively call mssql_free_result(), avoiding some warnings without using the horrible @
547 * @param mssql_resource $resource resource to be freed if possible
549 private function free_result($resource) {
550 if (!is_bool($resource)) { // true/false resources cannot be freed
551 mssql_free_result($resource);
556 * Provides mapping between mssql native data types and moodle_database - database_column_info - ones)
558 * @param string $mssql_type native mssql data type
559 * @return string 1-char database_column_info data type
561 private function mssqltype2moodletype($mssql_type) {
563 switch (strtoupper($mssql_type)) {
585 case 'NVARCHAR(MAX)':
589 case 'VARBINARY(MAX)':
597 throw new dml_exception('invalidmssqlnativetype', $mssql_type);
603 * Do NOT use in code, to be used by database_manager only!
604 * @param string $sql query
606 * @throws dml_exception A DML specific exception is thrown for any errors.
608 public function change_database_structure($sql) {
609 $this->reset_caches();
611 $this->query_start($sql, null, SQL_QUERY_STRUCTURE);
612 $result = mssql_query($sql, $this->mssql);
613 $this->query_end($result);
619 * Very ugly hack which emulates bound parameters in queries
620 * because the mssql driver doesn't support placeholders natively at all
622 protected function emulate_bound_params($sql, array $params=null) {
623 if (empty($params)) {
626 /// ok, we have verified sql statement with ? and correct number of params
627 $parts = explode('?', $sql);
628 $return = array_shift($parts);
629 foreach ($params as $param) {
630 if (is_bool($param)) {
631 $return .= (int)$param;
633 } else if (is_array($param) && isset($param['hex'])) { // detect hex binary, bind it specially
634 $return .= '0x' . $param['hex'];
636 } else if (is_array($param) && isset($param['numstr'])) { // detect numerical strings that *must not*
637 $return .= "N'{$param['numstr']}'"; // be converted back to number params, but bound as strings
639 } else if (is_null($param)) {
642 } else if (is_number($param)) { // we can not use is_numeric() because it eats leading zeros from strings like 0045646
643 $return .= "'".$param."'"; //fix for MDL-24863 to prevent auto-cast to int.
645 } else if (is_float($param)) {
649 $param = str_replace("'", "''", $param);
650 $return .= "N'$param'";
653 $return .= array_shift($parts);
659 * Execute general sql query. Should be used only when no other method suitable.
660 * Do NOT use this to make changes in db structure, use database_manager methods instead!
661 * @param string $sql query
662 * @param array $params query parameters
664 * @throws dml_exception A DML specific exception is thrown for any errors.
666 public function execute($sql, array $params=null) {
668 list($sql, $params, $type) = $this->fix_sql_params($sql, $params);
669 $rawsql = $this->emulate_bound_params($sql, $params);
671 if (strpos($sql, ';') !== false) {
672 throw new coding_exception('moodle_database::execute() Multiple sql statements found or bound parameters not used properly in query!');
675 $this->query_start($sql, $params, SQL_QUERY_UPDATE);
676 $result = mssql_query($rawsql, $this->mssql);
677 $this->query_end($result);
678 $this->free_result($result);
684 * Get a number of records as a moodle_recordset using a SQL statement.
686 * Since this method is a little less readable, use of it should be restricted to
687 * code where it's possible there might be large datasets being returned. For known
688 * small datasets use get_records_sql - it leads to simpler code.
690 * The return type is like:
691 * @see function get_recordset.
693 * @param string $sql the SQL select query to execute.
694 * @param array $params array of sql parameters
695 * @param int $limitfrom return a subset of records, starting at this point (optional, required if $limitnum is set).
696 * @param int $limitnum return a subset comprising this many records (optional, required if $limitfrom is set).
697 * @return moodle_recordset instance
698 * @throws dml_exception A DML specific exception is thrown for any errors.
700 public function get_recordset_sql($sql, array $params=null, $limitfrom=0, $limitnum=0) {
701 $limitfrom = (int)$limitfrom;
702 $limitnum = (int)$limitnum;
703 $limitfrom = ($limitfrom < 0) ? 0 : $limitfrom;
704 $limitnum = ($limitnum < 0) ? 0 : $limitnum;
705 if ($limitfrom or $limitnum) {
706 if ($limitnum >= 1) { // Only apply TOP clause if we have any limitnum (limitfrom offset is handled later)
707 $fetch = $limitfrom + $limitnum;
708 if (PHP_INT_MAX - $limitnum < $limitfrom) { // Check PHP_INT_MAX overflow
709 $fetch = PHP_INT_MAX;
711 $sql = preg_replace('/^([\s(])*SELECT([\s]+(DISTINCT|ALL))?(?!\s*TOP\s*\()/i',
712 "\\1SELECT\\2 TOP $fetch", $sql);
716 list($sql, $params, $type) = $this->fix_sql_params($sql, $params);
717 $rawsql = $this->emulate_bound_params($sql, $params);
719 $this->query_start($sql, $params, SQL_QUERY_SELECT);
720 $result = mssql_query($rawsql, $this->mssql);
721 $this->query_end($result);
723 if ($limitfrom) { // Skip $limitfrom records
724 mssql_data_seek($result, $limitfrom);
727 return $this->create_recordset($result);
730 protected function create_recordset($result) {
731 return new mssql_native_moodle_recordset($result);
735 * Get a number of records as an array of objects using a SQL statement.
737 * Return value is like:
738 * @see function get_records.
740 * @param string $sql the SQL select query to execute. The first column of this SELECT statement
741 * must be a unique value (usually the 'id' field), as it will be used as the key of the
743 * @param array $params array of sql parameters
744 * @param int $limitfrom return a subset of records, starting at this point (optional, required if $limitnum is set).
745 * @param int $limitnum return a subset comprising this many records (optional, required if $limitfrom is set).
746 * @return array of objects, or empty array if no records were found
747 * @throws dml_exception A DML specific exception is thrown for any errors.
749 public function get_records_sql($sql, array $params=null, $limitfrom=0, $limitnum=0) {
751 $rs = $this->get_recordset_sql($sql, $params, $limitfrom, $limitnum);
755 foreach ($rs as $row) {
757 if (isset($results[$id])) {
758 $colname = key($row);
759 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);
761 $results[$id] = $row;
769 * Selects records and return values (first field) as an array using a SQL statement.
771 * @param string $sql The SQL query
772 * @param array $params array of sql parameters
773 * @return array of values
774 * @throws dml_exception A DML specific exception is thrown for any errors.
776 public function get_fieldset_sql($sql, array $params=null) {
778 $rs = $this->get_recordset_sql($sql, $params);
782 foreach ($rs as $row) {
783 $results[] = reset($row);
791 * Insert new record into database, as fast as possible, no safety checks, lobs not supported.
792 * @param string $table name
793 * @param mixed $params data record as object or array
794 * @param bool $returnit return it of inserted record
795 * @param bool $bulk true means repeated inserts expected
796 * @param bool $customsequence true if 'id' included in $params, disables $returnid
797 * @return bool|int true or new id
798 * @throws dml_exception A DML specific exception is thrown for any errors.
800 public function insert_record_raw($table, $params, $returnid=true, $bulk=false, $customsequence=false) {
801 if (!is_array($params)) {
802 $params = (array)$params;
807 if ($customsequence) {
808 if (!isset($params['id'])) {
809 throw new coding_exception('moodle_database::insert_record_raw() id field must be specified if custom sequences used.');
813 // Disable IDENTITY column before inserting record with id
814 $sql = 'SET IDENTITY_INSERT {' . $table . '} ON'; // Yes, it' ON!!
815 list($sql, $xparams, $xtype) = $this->fix_sql_params($sql, null);
816 $this->query_start($sql, null, SQL_QUERY_AUX);
817 $result = mssql_query($sql, $this->mssql);
818 $this->query_end($result);
819 $this->free_result($result);
822 unset($params['id']);
824 $returning = "; SELECT SCOPE_IDENTITY()";
828 if (empty($params)) {
829 throw new coding_exception('moodle_database::insert_record_raw() no fields found.');
832 $fields = implode(',', array_keys($params));
833 $qms = array_fill(0, count($params), '?');
834 $qms = implode(',', $qms);
836 $sql = "INSERT INTO {" . $table . "} ($fields) VALUES($qms) $returning";
838 list($sql, $params, $type) = $this->fix_sql_params($sql, $params);
839 $rawsql = $this->emulate_bound_params($sql, $params);
841 $this->query_start($sql, $params, SQL_QUERY_INSERT);
842 $result = mssql_query($rawsql, $this->mssql);
843 $this->query_end($result);
845 if ($returning !== "") {
846 $row = mssql_fetch_assoc($result);
847 $params['id'] = reset($row);
849 $this->free_result($result);
851 if ($customsequence) {
852 // Enable IDENTITY column after inserting record with id
853 $sql = 'SET IDENTITY_INSERT {' . $table . '} OFF'; // Yes, it' OFF!!
854 list($sql, $xparams, $xtype) = $this->fix_sql_params($sql, null);
855 $this->query_start($sql, null, SQL_QUERY_AUX);
856 $result = mssql_query($sql, $this->mssql);
857 $this->query_end($result);
858 $this->free_result($result);
865 return (int)$params['id'];
869 * Insert a record into a table and return the "id" field if required.
871 * Some conversions and safety checks are carried out. Lobs are supported.
872 * If the return ID isn't required, then this just reports success as true/false.
873 * $data is an object containing needed data
874 * @param string $table The database table to be inserted into
875 * @param object $data A data object with values for one or more fields in the record
876 * @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.
877 * @return bool|int true or new id
878 * @throws dml_exception A DML specific exception is thrown for any errors.
880 public function insert_record($table, $dataobject, $returnid=true, $bulk=false) {
881 $dataobject = (array)$dataobject;
883 $columns = $this->get_columns($table);
886 foreach ($dataobject as $field => $value) {
887 if ($field === 'id') {
890 if (!isset($columns[$field])) {
893 $column = $columns[$field];
894 $cleaned[$field] = $this->normalise_value($column, $value);
897 return $this->insert_record_raw($table, $cleaned, $returnid, $bulk);
901 * Import a record into a table, id field is required.
902 * Safety checks are NOT carried out. Lobs are supported.
904 * @param string $table name of database table to be inserted into
905 * @param object $dataobject A data object with values for one or more fields in the record
907 * @throws dml_exception A DML specific exception is thrown for any errors.
909 public function import_record($table, $dataobject) {
910 $dataobject = (array)$dataobject;
912 $columns = $this->get_columns($table);
915 foreach ($dataobject as $field => $value) {
916 if (!isset($columns[$field])) {
919 $column = $columns[$field];
920 $cleaned[$field] = $this->normalise_value($column, $value);
923 $this->insert_record_raw($table, $cleaned, false, false, true);
929 * Update record in database, as fast as possible, no safety checks, lobs not supported.
930 * @param string $table name
931 * @param mixed $params data record as object or array
932 * @param bool true means repeated updates expected
934 * @throws dml_exception A DML specific exception is thrown for any errors.
936 public function update_record_raw($table, $params, $bulk=false) {
937 $params = (array)$params;
939 if (!isset($params['id'])) {
940 throw new coding_exception('moodle_database::update_record_raw() id field must be specified.');
943 unset($params['id']);
945 if (empty($params)) {
946 throw new coding_exception('moodle_database::update_record_raw() no fields found.');
950 foreach ($params as $field=>$value) {
951 $sets[] = "$field = ?";
954 $params[] = $id; // last ? in WHERE condition
956 $sets = implode(',', $sets);
957 $sql = "UPDATE {" . $table . "} SET $sets WHERE id = ?";
959 list($sql, $params, $type) = $this->fix_sql_params($sql, $params);
960 $rawsql = $this->emulate_bound_params($sql, $params);
962 $this->query_start($sql, $params, SQL_QUERY_UPDATE);
963 $result = mssql_query($rawsql, $this->mssql);
964 $this->query_end($result);
966 $this->free_result($result);
971 * Update a record in a table
973 * $dataobject is an object containing needed data
974 * Relies on $dataobject having a variable "id" to
975 * specify the record to update
977 * @param string $table The database table to be checked against.
978 * @param object $dataobject An object with contents equal to fieldname=>fieldvalue. Must have an entry for 'id' to map to the table specified.
979 * @param bool true means repeated updates expected
981 * @throws dml_exception A DML specific exception is thrown for any errors.
983 public function update_record($table, $dataobject, $bulk=false) {
984 $dataobject = (array)$dataobject;
986 $columns = $this->get_columns($table);
989 foreach ($dataobject as $field => $value) {
990 if (!isset($columns[$field])) {
993 $column = $columns[$field];
994 $cleaned[$field] = $this->normalise_value($column, $value);
997 return $this->update_record_raw($table, $cleaned, $bulk);
1001 * Set a single field in every table record which match a particular WHERE clause.
1003 * @param string $table The database table to be checked against.
1004 * @param string $newfield the field to set.
1005 * @param string $newvalue the value to set the field to.
1006 * @param string $select A fragment of SQL to be used in a where clause in the SQL call.
1007 * @param array $params array of sql parameters
1009 * @throws dml_exception A DML specific exception is thrown for any errors.
1011 public function set_field_select($table, $newfield, $newvalue, $select, array $params=null) {
1014 $select = "WHERE $select";
1016 if (is_null($params)) {
1020 // convert params to ? types
1021 list($select, $params, $type) = $this->fix_sql_params($select, $params);
1023 /// Get column metadata
1024 $columns = $this->get_columns($table);
1025 $column = $columns[$newfield];
1027 $newvalue = $this->normalise_value($column, $newvalue);
1029 if (is_null($newvalue)) {
1030 $newfield = "$newfield = NULL";
1032 $newfield = "$newfield = ?";
1033 array_unshift($params, $newvalue);
1035 $sql = "UPDATE {" . $table . "} SET $newfield $select";
1037 list($sql, $params, $type) = $this->fix_sql_params($sql, $params);
1038 $rawsql = $this->emulate_bound_params($sql, $params);
1040 $this->query_start($sql, $params, SQL_QUERY_UPDATE);
1041 $result = mssql_query($rawsql, $this->mssql);
1042 $this->query_end($result);
1044 $this->free_result($result);
1050 * Delete one or more records from a table which match a particular WHERE clause.
1052 * @param string $table The database table to be checked against.
1053 * @param string $select A fragment of SQL to be used in a where clause in the SQL call (used to define the selection criteria).
1054 * @param array $params array of sql parameters
1056 * @throws dml_exception A DML specific exception is thrown for any errors.
1058 public function delete_records_select($table, $select, array $params=null) {
1061 $select = "WHERE $select";
1064 $sql = "DELETE FROM {" . $table . "} $select";
1066 list($sql, $params, $type) = $this->fix_sql_params($sql, $params);
1067 $rawsql = $this->emulate_bound_params($sql, $params);
1069 $this->query_start($sql, $params, SQL_QUERY_UPDATE);
1070 $result = mssql_query($rawsql, $this->mssql);
1071 $this->query_end($result);
1073 $this->free_result($result);
1078 /// SQL helper functions
1080 public function sql_cast_char2int($fieldname, $text=false) {
1082 return ' CAST(' . $fieldname . ' AS INT) ';
1084 return ' CAST(' . $this->sql_compare_text($fieldname) . ' AS INT) ';
1088 public function sql_cast_char2real($fieldname, $text=false) {
1090 return ' CAST(' . $fieldname . ' AS REAL) ';
1092 return ' CAST(' . $this->sql_compare_text($fieldname) . ' AS REAL) ';
1096 public function sql_ceil($fieldname) {
1097 return ' CEILING(' . $fieldname . ')';
1101 protected function get_collation() {
1102 if (isset($this->collation)) {
1103 return $this->collation;
1105 if (!empty($this->dboptions['dbcollation'])) {
1107 $this->collation = $this->dboptions['dbcollation'];
1108 return $this->collation;
1111 // make some default
1112 $this->collation = 'Latin1_General_CI_AI';
1114 $sql = "SELECT CAST(DATABASEPROPERTYEX('$this->dbname', 'Collation') AS varchar(255)) AS SQLCollation";
1115 $this->query_start($sql, null, SQL_QUERY_AUX);
1116 $result = mssql_query($sql, $this->mssql);
1117 $this->query_end($result);
1120 if ($rawcolumn = mssql_fetch_assoc($result)) {
1121 $this->collation = reset($rawcolumn);
1123 $this->free_result($result);
1126 return $this->collation;
1130 * Returns 'LIKE' part of a query.
1132 * @param string $fieldname usually name of the table column
1133 * @param string $param usually bound query parameter (?, :named)
1134 * @param bool $casesensitive use case sensitive search
1135 * @param bool $accensensitive use accent sensitive search (not all databases support accent insensitive)
1136 * @param bool $notlike true means "NOT LIKE"
1137 * @param string $escapechar escape char for '%' and '_'
1138 * @return string SQL code fragment
1140 public function sql_like($fieldname, $param, $casesensitive = true, $accentsensitive = true, $notlike = false, $escapechar = '\\') {
1141 if (strpos($param, '%') !== false) {
1142 debugging('Potential SQL injection detected, sql_ilike() expects bound parameters (? or :named)');
1145 $collation = $this->get_collation();
1147 if ($casesensitive) {
1148 $collation = str_replace('_CI', '_CS', $collation);
1150 $collation = str_replace('_CS', '_CI', $collation);
1152 if ($accentsensitive) {
1153 $collation = str_replace('_AI', '_AS', $collation);
1155 $collation = str_replace('_AS', '_AI', $collation);
1158 $LIKE = $notlike ? 'NOT LIKE' : 'LIKE';
1160 return "$fieldname COLLATE $collation $LIKE $param ESCAPE '$escapechar'";
1163 public function sql_concat() {
1164 $arr = func_get_args();
1165 foreach ($arr as $key => $ele) {
1166 $arr[$key] = ' CAST(' . $ele . ' AS VARCHAR(255)) ';
1168 $s = implode(' + ', $arr);
1175 public function sql_concat_join($separator="' '", $elements=array()) {
1176 for ($n=count($elements)-1; $n > 0 ; $n--) {
1177 array_splice($elements, $n, 0, $separator);
1179 $s = implode(' + ', $elements);
1186 public function sql_isempty($tablename, $fieldname, $nullablefield, $textfield) {
1188 return ' (' . $this->sql_compare_text($fieldname) . " = '') ";
1190 return " ($fieldname = '') ";
1195 * Returns the SQL text to be used to calculate the length in characters of one expression.
1196 * @param string fieldname or expression to calculate its length in characters.
1197 * @return string the piece of SQL code to be used in the statement.
1199 public function sql_length($fieldname) {
1200 return ' LEN(' . $fieldname . ')';
1203 public function sql_order_by_text($fieldname, $numchars=32) {
1204 return ' CONVERT(varchar, ' . $fieldname . ', ' . $numchars . ')';
1208 * Returns the SQL for returning searching one string for the location of another.
1210 public function sql_position($needle, $haystack) {
1211 return "CHARINDEX(($needle), ($haystack))";
1215 * Returns the proper substr() SQL text used to extract substrings from DB
1216 * NOTE: this was originally returning only function name
1218 * @param string $expr some string field, no aggregates
1219 * @param mixed $start integer or expression evaluating to int
1220 * @param mixed $length optional integer or expression evaluating to int
1221 * @return string sql fragment
1223 public function sql_substr($expr, $start, $length=false) {
1224 if (count(func_get_args()) < 2) {
1225 throw new coding_exception('moodle_database::sql_substr() requires at least two parameters', 'Originaly this function wa
1226 s only returning name of SQL substring function, it now requires all parameters.');
1228 if ($length === false) {
1229 return "SUBSTRING($expr, $start, (LEN($expr) - $start + 1))";
1231 return "SUBSTRING($expr, $start, $length)";
1237 public function session_lock_supported() {
1242 * Obtain session lock
1243 * @param int $rowid id of the row with session record
1244 * @param int $timeout max allowed time to wait for the lock in seconds
1245 * @return bool success
1247 public function get_session_lock($rowid, $timeout) {
1248 if (!$this->session_lock_supported()) {
1251 parent::get_session_lock($rowid, $timeout);
1253 $timeoutmilli = $timeout * 1000;
1255 $fullname = $this->dbname.'-'.$this->prefix.'-session-'.$rowid;
1256 // There is one bug in PHP/freetds (both reproducible with mssql_query()
1257 // and its mssql_init()/mssql_bind()/mssql_execute() alternative) for
1258 // stored procedures, causing scalar results of the execution
1259 // to be cast to boolean (true/fals). Here there is one
1260 // workaround that forces the return of one recordset resource.
1261 // $sql = "sp_getapplock '$fullname', 'Exclusive', 'Session', $timeoutmilli";
1264 EXECUTE @result = sp_getapplock @Resource='$fullname',
1265 @LockMode='Exclusive',
1266 @LockOwner='Session',
1267 @LockTimeout='$timeoutmilli'
1270 $this->query_start($sql, null, SQL_QUERY_AUX);
1271 $result = mssql_query($sql, $this->mssql);
1272 $this->query_end($result);
1275 $row = mssql_fetch_row($result);
1277 throw new dml_sessionwait_exception();
1281 $this->free_result($result);
1284 public function release_session_lock($rowid) {
1285 if (!$this->session_lock_supported()) {
1288 parent::release_session_lock($rowid);
1290 $fullname = $this->dbname.'-'.$this->prefix.'-session-'.$rowid;
1291 $sql = "sp_releaseapplock '$fullname', 'Session'";
1292 $this->query_start($sql, null, SQL_QUERY_AUX);
1293 $result = mssql_query($sql, $this->mssql);
1294 $this->query_end($result);
1296 $this->free_result($result);
1302 * Driver specific start of real database transaction,
1303 * this can not be used directly in code.
1306 protected function begin_transaction() {
1307 // requires database to run with READ_COMMITTED_SNAPSHOT ON
1308 $sql = "BEGIN TRANSACTION"; // Will be using READ COMMITTED isolation
1309 $this->query_start($sql, NULL, SQL_QUERY_AUX);
1310 $result = mssql_query($sql, $this->mssql);
1311 $this->query_end($result);
1313 $this->free_result($result);
1317 * Driver specific commit of real database transaction,
1318 * this can not be used directly in code.
1321 protected function commit_transaction() {
1322 $sql = "COMMIT TRANSACTION";
1323 $this->query_start($sql, NULL, SQL_QUERY_AUX);
1324 $result = mssql_query($sql, $this->mssql);
1325 $this->query_end($result);
1327 $this->free_result($result);
1331 * Driver specific abort of real database transaction,
1332 * this can not be used directly in code.
1335 protected function rollback_transaction() {
1336 $sql = "ROLLBACK TRANSACTION";
1337 $this->query_start($sql, NULL, SQL_QUERY_AUX);
1338 $result = mssql_query($sql, $this->mssql);
1339 $this->query_end($result);
1341 $this->free_result($result);