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.
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.
37 class mssql_native_moodle_database extends moodle_database {
39 protected $mssql = null;
40 protected $last_error_reporting; // To handle mssql driver default verbosity
41 protected $collation; // current DB collation cache
44 * Detects if all needed PHP stuff installed.
45 * Note: can be used before connect()
46 * @return mixed true if ok, string if something
48 public function driver_installed() {
49 if (!function_exists('mssql_connect')) {
50 return get_string('mssqlextensionisnotpresentinphp', 'install');
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.)
60 public function get_dbfamily() {
65 * Returns more specific database driver type
66 * Note: can be used before connect()
67 * @return string db type mysqli, pgsql, oci, mssql, sqlsrv
69 protected function get_dbtype() {
74 * Returns general database library name
75 * Note: can be used before connect()
76 * @return string db type pdo, native
78 protected function get_dblibrary() {
83 * Returns localised database type name
84 * Note: can be used before connect()
87 public function get_name() {
88 return get_string('nativemssql', 'install');
92 * Returns localised database configuration help.
93 * Note: can be used before connect()
96 public function get_configuration_help() {
97 return get_string('nativemssqlhelp', 'install');
101 * Returns localised database description
102 * Note: can be used before connect()
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')\"";
110 $str .= '<img src="pix/docs.gif' . '" alt="Docs" class="iconhelp" />';
111 $str .= get_string('moodledocslink', 'install') . '</a></p>';
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
125 * @throws dml_connection_exception if error
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());
133 $driverstatus = $this->driver_installed();
135 if ($driverstatus !== true) {
136 throw new dml_exception('dbdriverproblem', $driverstatus);
139 $this->store_settings($dbhost, $dbuser, $dbpass, $dbname, $prefix, $dboptions);
142 if (!empty($this->dboptions['dbpersist'])) { // persistent connection
143 $this->mssql = mssql_pconnect($this->dbhost, $this->dbuser, $this->dbpass, true);
145 $this->mssql = mssql_connect($this->dbhost, $this->dbuser, $this->dbpass, true);
147 $dberr = ob_get_contents();
150 if ($this->mssql === false) {
152 throw new dml_connection_exception($dberr);
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);
160 // No need to set charset. It's UTF8, with transparent conversions
161 // back and forth performed both by FreeTDS or ODBTP
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);
169 $this->free_result($result);
171 // Force ANSI nulls so the NULL check was done by IS NULL and NOT IS NULL
172 // instead of equal(=) and distinct(<>) symbols
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);
178 $this->free_result($result);
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);
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);
193 $this->free_result($result);
195 // Set transactions isolation level to READ_COMMITTED
196 // prevents dirty reads when using transactions +
197 // is the default isolation level of MSSQL
198 // Requires database to run with READ_COMMITTED_SNAPSHOT ON
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);
204 $this->free_result($result);
206 // Connection stabilised and configured, going to instantiate the temptables controller
207 $this->temptables = new mssql_native_moodle_temptables($this);
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.
217 public function dispose() {
218 parent::dispose(); // Call parent dispose to write/close session and other common stuff before closing connection
220 mssql_close($this->mssql);
226 * Called before each db query.
228 * @param array array of parameters
229 * @param int $type type of query
230 * @param mixed $extrainfo driver specific extra information
233 protected function query_start($sql, array $params=null, $type, $extrainfo=null) {
234 parent::query_start($sql, $params, $type, $extrainfo);
235 // mssql driver tends to send debug to output, we do not need that ;-)
236 $this->last_error_reporting = error_reporting(0);
240 * Called immediately after each db query.
241 * @param mixed db specific result
244 protected function query_end($result) {
245 // reset original debug level
246 error_reporting($this->last_error_reporting);
247 parent::query_end($result);
251 * Returns database server info array
254 public function get_server_info() {
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);
263 $info['server'] = $row[2];
264 $this->free_result($result);
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);
277 protected function is_min_version($version) {
278 $server = $this->get_server_info();
279 $server = $server['version'];
280 return version_compare($server, $version, '>=');
284 * Converts short table name {tablename} to real table name
285 * supporting temp tables (#) if detected
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];
294 if ($this->temptables->is_temptable($name)) {
295 $sql = str_replace($match, $this->temptables->get_correct_name($name), $sql);
297 $sql = str_replace($match, $this->prefix.$name, $sql);
305 * Returns supported query parameter types
306 * @return int bitmask
308 protected function allowed_param_types() {
309 return SQL_PARAMS_QM; // Not really, but emulated, see emulate_bound_params()
313 * Returns last error reported by database engine.
314 * @return string error message
316 public function get_last_error() {
317 return mssql_get_last_message();
321 * Return tables in database WITHOUT current prefix
322 * @return array of table names in lowercase and without prefix
324 public function get_tables($usecache=true) {
325 if ($usecache and $this->tables !== null) {
326 return $this->tables;
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);
338 while ($row = mssql_fetch_row($result)) {
339 $tablename = reset($row);
340 if (strpos($tablename, $this->prefix) !== 0) {
343 $tablename = substr($tablename, strlen($this->prefix));
344 $this->tables[$tablename] = $tablename;
346 $this->free_result($result);
349 // Add the currently available temptables
350 $this->tables = array_merge($this->tables, $this->temptables->get_temptables());
351 return $this->tables;
355 * Return table indexes - everything lowercased
356 * @return array of arrays
358 public function get_indexes($table) {
360 $tablename = $this->prefix.$table;
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
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";
373 $this->query_start($sql, null, SQL_QUERY_AUX);
374 $result = mssql_query($sql, $this->mssql);
375 $this->query_end($result);
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);
387 $lastindex = $row['index_name'];
388 $unique = empty($row['is_unique']) ? false : true;
389 $columns[] = $row['column_name'];
391 if ($lastindex ) { // Add the last one if exists
392 $indexes[$lastindex] = array('unique' => $unique, 'columns' => $columns);
394 $this->free_result($result);
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
405 public function get_columns($table, $usecache=true) {
406 if ($usecache and isset($this->columns[$table])) {
407 return $this->columns[$table];
410 $this->columns[$table] = array();
412 if (!$this->temptables->is_temptable($table)) { // normal table, get metadata from own schema
413 $sql = "SELECT column_name AS name,
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
423 WHERE table_name = '{" . $table . "}'
424 ORDER BY ordinal_position";
425 } else { // temp table, get metadata from tempdb schema
426 $sql = "SELECT column_name AS name,
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
436 JOIN tempdb..sysobjects ON name = table_name
437 WHERE id = object_id('tempdb..{" . $table . "}')
438 ORDER BY ordinal_position";
441 list($sql, $params, $type) = $this->fix_sql_params($sql, null);
443 $this->query_start($sql, null, SQL_QUERY_AUX);
444 $result = mssql_query($sql, $this->mssql);
445 $this->query_end($result);
451 while ($rawcolumn = mssql_fetch_assoc($result)) {
453 $rawcolumn = (object)$rawcolumn;
455 $info = new object();
456 $info->name = $rawcolumn->name;
457 $info->type = $rawcolumn->type;
458 $info->meta_type = $this->mssqltype2moodletype($info->type);
460 // Prepare auto_increment info
461 $info->auto_increment = $rawcolumn->auto_increment ? true : false;
463 // Define type for auto_increment columns
464 $info->meta_type = ($info->auto_increment && $info->meta_type == 'I') ? 'R' : $info->meta_type;
466 // id columns being auto_incremnt are PK by definition
467 $info->primary_key = ($info->name == 'id' && $info->meta_type == 'R' && $info->auto_increment);
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;
474 $info->scale = $rawcolumn->scale ? $rawcolumn->scale : false;
476 // Prepare not_null info
477 $info->not_null = $rawcolumn->is_nullable == 'NO' ? true : false;
480 $info->has_default = !empty($rawcolumn->default_value);
481 $info->default_value = preg_replace("/^[\(N]+[']?(.*?)[']?[\)]+$/", '\\1', $rawcolumn->default_value);
484 $info->binary = $info->meta_type == 'B' ? true : false;
486 $this->columns[$table][$info->name] = new database_column_info($info);
488 $this->free_result($result);
490 return $this->columns[$table];
494 * Normalise values based in RDBMS dependencies (booleans, LOBs...)
496 * @param database_column_info $column column metadata corresponding with the value we are going to normalise
497 * @param mixed $value value we are going to normalise
498 * @return mixed the normalised value
500 protected function normalise_value($column, $value) {
501 if (is_bool($value)) { /// Always, convert boolean to int
502 $value = (int)$value;
503 } // And continue processing because text columns with numeric info need special handling below
505 if ($column->meta_type == 'B') { // BLOBs need to be properly "packed", but can be inserted directly if so.
506 if (!is_null($value)) { // If value not null, unpack it to unquoted hexadecimal byte-string format
507 $value = unpack('H*hex', $value); // we leave it as array, so emulate_bound_params() can detect it
508 } // easily and "bind" the param ok.
510 } else if ($column->meta_type == 'X') { // MSSQL doesn't cast from int to text, so if text column
511 if (is_numeric($value)) { // and is numeric value then cast to string
512 $value = array('numstr' => (string)$value); // and put into array, so emulate_bound_params() will know how
513 } // to "bind" the param ok, avoiding reverse conversion to number
515 } else if ($value === '') {
516 if ($column->meta_type == 'I' or $column->meta_type == 'F' or $column->meta_type == 'N') {
517 $value = 0; // prevent '' problems in numeric fields
524 * Selectively call mssql_free_result(), avoiding some warnings without using the horrible @
526 * @param mssql_resource $resource resource to be freed if possible
528 private function free_result($resource) {
529 if (!is_bool($resource)) { // true/false resources cannot be freed
530 mssql_free_result($resource);
535 * Provides mapping between mssql native data types and moodle_database - database_column_info - ones)
537 * @param string $mssql_type native mssql data type
538 * @return string 1-char database_column_info data type
540 private function mssqltype2moodletype($mssql_type) {
542 switch (strtoupper($mssql_type)) {
564 case 'NVARCHAR(MAX)':
568 case 'VARBINARY(MAX)':
576 throw new dml_exception('invalidmssqlnativetype', $mssql_type);
582 * Do NOT use in code, to be used by database_manager only!
583 * @param string $sql query
585 * @throws dml_exception if error
587 public function change_database_structure($sql) {
588 $this->reset_caches();
590 $this->query_start($sql, null, SQL_QUERY_STRUCTURE);
591 $result = mssql_query($sql, $this->mssql);
592 $this->query_end($result);
598 * Very ugly hack which emulates bound parameters in queries
599 * because the mssql driver doesn't support placeholders natively at all
601 protected function emulate_bound_params($sql, array $params=null) {
602 if (empty($params)) {
605 /// ok, we have verified sql statement with ? and correct number of params
606 $return = strtok($sql, '?');
607 foreach ($params as $param) {
608 if (is_bool($param)) {
609 $return .= (int)$param;
611 } else if (is_array($param) && isset($param['hex'])) { // detect hex binary, bind it specially
612 $return .= '0x' . $param['hex'];
614 } else if (is_array($param) && isset($param['numstr'])) { // detect numerical strings that *must not*
615 $return .= "N'{$param['numstr']}'"; // be converted back to number params, but bound as strings
617 } else if (is_null($param)) {
620 } else if (is_number($param)) { // we can not use is_numeric() because it eats leading zeros from strings like 0045646
623 } else if (is_float($param)) {
627 $param = str_replace("'", "''", $param);
628 $return .= "N'$param'";
631 $return .= strtok('?');
637 * Execute general sql query. Should be used only when no other method suitable.
638 * Do NOT use this to make changes in db structure, use database_manager::execute_sql() instead!
639 * @param string $sql query
640 * @param array $params query parameters
642 * @throws dml_exception if error
644 public function execute($sql, array $params=null) {
646 list($sql, $params, $type) = $this->fix_sql_params($sql, $params);
647 $rawsql = $this->emulate_bound_params($sql, $params);
649 if (strpos($sql, ';') !== false) {
650 throw new coding_exception('moodle_database::execute() Multiple sql statements found or bound parameters not used properly in query!');
653 $this->query_start($sql, $params, SQL_QUERY_UPDATE);
654 $result = mssql_query($rawsql, $this->mssql);
655 $this->query_end($result);
656 $this->free_result($result);
662 * Get a number of records as a moodle_recordset using a SQL statement.
664 * Since this method is a little less readable, use of it should be restricted to
665 * code where it's possible there might be large datasets being returned. For known
666 * small datasets use get_records_sql - it leads to simpler code.
668 * The return type is as for @see function get_recordset.
670 * @param string $sql the SQL select query to execute.
671 * @param array $params array of sql parameters
672 * @param int $limitfrom return a subset of records, starting at this point (optional, required if $limitnum is set).
673 * @param int $limitnum return a subset comprising this many records (optional, required if $limitfrom is set).
674 * @return moodle_recordset instance
675 * @throws dml_exception if error
677 public function get_recordset_sql($sql, array $params=null, $limitfrom=0, $limitnum=0) {
678 $limitfrom = (int)$limitfrom;
679 $limitnum = (int)$limitnum;
680 $limitfrom = ($limitfrom < 0) ? 0 : $limitfrom;
681 $limitnum = ($limitnum < 0) ? 0 : $limitnum;
682 if ($limitfrom or $limitnum) {
683 if ($limitnum >= 1) { // Only apply TOP clause if we have any limitnum (limitfrom offset is handled later)
684 $fetch = $limitfrom + $limitnum;
685 $sql = preg_replace('/^([\s(])*SELECT( DISTINCT)?(?!\s*TOP\s*\()/i',
686 "\\1SELECT\\2 TOP $fetch", $sql);
690 list($sql, $params, $type) = $this->fix_sql_params($sql, $params);
691 $rawsql = $this->emulate_bound_params($sql, $params);
693 $this->query_start($sql, $params, SQL_QUERY_SELECT);
694 $result = mssql_query($rawsql, $this->mssql);
695 $this->query_end($result);
697 if ($limitfrom) { // Skip $limitfrom records
698 mssql_data_seek($result, $limitfrom);
701 return $this->create_recordset($result);
704 protected function create_recordset($result) {
705 return new mssql_native_moodle_recordset($result);
709 * Get a number of records as an array of objects using a SQL statement.
711 * Return value as for @see function get_records.
713 * @param string $sql the SQL select query to execute. The first column of this SELECT statement
714 * must be a unique value (usually the 'id' field), as it will be used as the key of the
716 * @param array $params array of sql parameters
717 * @param int $limitfrom return a subset of records, starting at this point (optional, required if $limitnum is set).
718 * @param int $limitnum return a subset comprising this many records (optional, required if $limitfrom is set).
719 * @return array of objects, or empty array if no records were found
720 * @throws dml_exception if error
722 public function get_records_sql($sql, array $params=null, $limitfrom=0, $limitnum=0) {
724 $rs = $this->get_recordset_sql($sql, $params, $limitfrom, $limitnum);
728 foreach ($rs as $row) {
730 if (isset($results[$id])) {
731 $colname = key($row);
732 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);
734 $results[$id] = $row;
742 * Selects records and return values (first field) as an array using a SQL statement.
744 * @param string $sql The SQL query
745 * @param array $params array of sql parameters
746 * @return array of values
747 * @throws dml_exception if error
749 public function get_fieldset_sql($sql, array $params=null) {
751 $rs = $this->get_recordset_sql($sql, $params);
755 foreach ($rs as $row) {
756 $results[] = reset($row);
764 * Insert new record into database, as fast as possible, no safety checks, lobs not supported.
765 * @param string $table name
766 * @param mixed $params data record as object or array
767 * @param bool $returnit return it of inserted record
768 * @param bool $bulk true means repeated inserts expected
769 * @param bool $customsequence true if 'id' included in $params, disables $returnid
770 * @return bool|int true or new id
771 * @throws dml_exception if error
773 public function insert_record_raw($table, $params, $returnid=true, $bulk=false, $customsequence=false) {
774 if (!is_array($params)) {
775 $params = (array)$params;
780 if ($customsequence) {
781 if (!isset($params['id'])) {
782 throw new coding_exception('moodle_database::insert_record_raw() id field must be specified if custom sequences used.');
786 unset($params['id']);
788 $returning = "; SELECT SCOPE_IDENTITY()";
792 if (empty($params)) {
793 throw new coding_exception('moodle_database::insert_record_raw() no fields found.');
796 $fields = implode(',', array_keys($params));
797 $qms = array_fill(0, count($params), '?');
798 $qms = implode(',', $qms);
800 $sql = "INSERT INTO {" . $table . "} ($fields) VALUES($qms) $returning";
802 list($sql, $params, $type) = $this->fix_sql_params($sql, $params);
803 $rawsql = $this->emulate_bound_params($sql, $params);
805 $this->query_start($sql, $params, SQL_QUERY_INSERT);
806 $result = mssql_query($rawsql, $this->mssql);
807 $this->query_end($result);
809 if ($returning !== "") {
810 $row = mssql_fetch_assoc($result);
811 $params['id'] = reset($row);
813 $this->free_result($result);
819 return (int)$params['id'];
823 * Insert a record into a table and return the "id" field if required.
825 * Some conversions and safety checks are carried out. Lobs are supported.
826 * If the return ID isn't required, then this just reports success as true/false.
827 * $data is an object containing needed data
828 * @param string $table The database table to be inserted into
829 * @param object $data A data object with values for one or more fields in the record
830 * @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.
831 * @return bool|int true or new id
832 * @throws dml_exception if error
834 public function insert_record($table, $dataobject, $returnid=true, $bulk=false) {
835 $dataobject = (array)$dataobject;
837 $columns = $this->get_columns($table);
840 foreach ($dataobject as $field => $value) {
841 if ($field === 'id') {
844 if (!isset($columns[$field])) {
847 $column = $columns[$field];
848 $cleaned[$field] = $this->normalise_value($column, $value);
851 return $this->insert_record_raw($table, $cleaned, $returnid, $bulk);
855 * Import a record into a table, id field is required.
856 * Safety checks are NOT carried out. Lobs are supported.
858 * @param string $table name of database table to be inserted into
859 * @param object $dataobject A data object with values for one or more fields in the record
861 * @throws dml_exception if error
863 public function import_record($table, $dataobject) {
864 $dataobject = (array)$dataobject;
866 $columns = $this->get_columns($table);
869 foreach ($dataobject as $field => $value) {
870 if (!isset($columns[$field])) {
873 $column = $columns[$field];
874 $cleaned[$field] = $this->normalise_value($column, $value);
877 // Disable IDENTITY column before inserting record with id
878 $sql = 'SET IDENTITY_INSERT {' . $table . '} ON'; // Yes, it' ON!!
880 list($sql, $params, $type) = $this->fix_sql_params($sql, null);
882 $this->query_start($sql, null, SQL_QUERY_AUX);
883 $result = mssql_query($sql, $this->mssql);
884 $this->query_end($result);
886 $this->free_result($result);
888 $insertresult = $this->insert_record_raw($table, $cleaned, false, false, true);
890 // Enable IDENTITY column after inserting record with id
891 $sql = 'SET IDENTITY_INSERT {' . $table . '} OFF'; // Yes, it' OFF!!
893 list($sql, $params, $type) = $this->fix_sql_params($sql, null);
895 $this->query_start($sql, null, SQL_QUERY_AUX);
896 $result = mssql_query($sql, $this->mssql);
897 $this->query_end($result);
899 $this->free_result($result);
901 return $insertresult;
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
910 * @throws dml_exception if error
912 public function update_record_raw($table, $params, $bulk=false) {
913 $params = (array)$params;
915 if (!isset($params['id'])) {
916 throw new coding_exception('moodle_database::update_record_raw() id field must be specified.');
919 unset($params['id']);
921 if (empty($params)) {
922 throw new coding_exception('moodle_database::update_record_raw() no fields found.');
926 foreach ($params as $field=>$value) {
927 $sets[] = "$field = ?";
930 $params[] = $id; // last ? in WHERE condition
932 $sets = implode(',', $sets);
933 $sql = "UPDATE {" . $table . "} SET $sets WHERE id = ?";
935 list($sql, $params, $type) = $this->fix_sql_params($sql, $params);
936 $rawsql = $this->emulate_bound_params($sql, $params);
938 $this->query_start($sql, $params, SQL_QUERY_UPDATE);
939 $result = mssql_query($rawsql, $this->mssql);
940 $this->query_end($result);
942 $this->free_result($result);
947 * Update a record in a table
949 * $dataobject is an object containing needed data
950 * Relies on $dataobject having a variable "id" to
951 * specify the record to update
953 * @param string $table The database table to be checked against.
954 * @param object $dataobject An object with contents equal to fieldname=>fieldvalue. Must have an entry for 'id' to map to the table specified.
955 * @param bool true means repeated updates expected
957 * @throws dml_exception if error
959 public function update_record($table, $dataobject, $bulk=false) {
960 $dataobject = (array)$dataobject;
962 $columns = $this->get_columns($table);
965 foreach ($dataobject as $field => $value) {
966 if (!isset($columns[$field])) {
969 $column = $columns[$field];
970 $cleaned[$field] = $this->normalise_value($column, $value);
973 return $this->update_record_raw($table, $cleaned, $bulk);
977 * Set a single field in every table record which match a particular WHERE clause.
979 * @param string $table The database table to be checked against.
980 * @param string $newfield the field to set.
981 * @param string $newvalue the value to set the field to.
982 * @param string $select A fragment of SQL to be used in a where clause in the SQL call.
983 * @param array $params array of sql parameters
985 * @throws dml_exception if error
987 public function set_field_select($table, $newfield, $newvalue, $select, array $params=null) {
990 $select = "WHERE $select";
992 if (is_null($params)) {
996 /// Get column metadata
997 $columns = $this->get_columns($table);
998 $column = $columns[$newfield];
1000 $newvalue = $this->normalise_value($column, $newvalue);
1002 if (is_null($newvalue)) {
1003 $newfield = "$newfield = NULL";
1005 $newfield = "$newfield = ?";
1006 array_unshift($params, $newvalue);
1008 $sql = "UPDATE {" . $table . "} SET $newfield $select";
1010 list($sql, $params, $type) = $this->fix_sql_params($sql, $params);
1011 $rawsql = $this->emulate_bound_params($sql, $params);
1013 $this->query_start($sql, $params, SQL_QUERY_UPDATE);
1014 $result = mssql_query($rawsql, $this->mssql);
1015 $this->query_end($result);
1017 $this->free_result($result);
1023 * Delete one or more records from a table which match a particular WHERE clause.
1025 * @param string $table The database table to be checked against.
1026 * @param string $select A fragment of SQL to be used in a where clause in the SQL call (used to define the selection criteria).
1027 * @param array $params array of sql parameters
1029 * @throws dml_exception if error
1031 public function delete_records_select($table, $select, array $params=null) {
1034 $select = "WHERE $select";
1037 $sql = "DELETE FROM {" . $table . "} $select";
1039 list($sql, $params, $type) = $this->fix_sql_params($sql, $params);
1040 $rawsql = $this->emulate_bound_params($sql, $params);
1042 $this->query_start($sql, $params, SQL_QUERY_UPDATE);
1043 $result = mssql_query($rawsql, $this->mssql);
1044 $this->query_end($result);
1046 $this->free_result($result);
1051 /// SQL helper functions
1053 public function sql_bitxor($int1, $int2) {
1054 return '(' . $this->sql_bitor($int1, $int2) . ' - ' . $this->sql_bitand($int1, $int2) . ')';
1057 public function sql_cast_char2int($fieldname, $text=false) {
1058 return ' CAST(' . $fieldname . ' AS INT) ';
1061 public function sql_ceil($fieldname) {
1062 return ' CEILING(' . $fieldname . ')';
1066 protected function get_collation() {
1067 if (isset($this->collation)) {
1068 return $this->collation;
1070 if (!empty($this->dboptions['dbcollation'])) {
1072 $this->collation = $this->dboptions['dbcollation'];
1073 return $this->collation;
1076 // make some default
1077 $this->collation = 'Latin1_General_CI_AI';
1079 $sql = "SELECT CAST(DATABASEPROPERTYEX('$this->dbname', 'Collation') AS varchar(255)) AS SQLCollation";
1080 $this->query_start($sql, null, SQL_QUERY_AUX);
1081 $result = mssql_query($this->mssql, $sql);
1082 $this->query_end($result);
1085 if ($rawcolumn = mssql_fetch_array($result, SQLSRV_FETCH_ASSOC)) {
1086 $this->collation = reset($rawcolumn);
1088 $this->free_result($result);
1091 return $this->collation;
1095 * Returns 'LIKE' part of a query.
1097 * @param string $fieldname usually name of the table column
1098 * @param string $param usually bound query parameter (?, :named)
1099 * @param bool $casesensitive use case sensitive search
1100 * @param bool $accensensitive use accent sensitive search (not all databases support accent insensitive)
1101 * @param string $escapechar escape char for '%' and '_'
1102 * @return string SQL code fragment
1104 public function sql_like($fieldname, $param, $casesensitive = true, $accentsensitive = true, $escapechar = '\\') {
1105 if (strpos($param, '%') !== false) {
1106 debugging('Potential SQL injection detected, sql_ilike() expects bound parameters (? or :named)');
1109 $collation = $this->get_collation();
1111 if ($casesensitive) {
1112 $collation = str_replace('_CI', '_CS', $collation);
1114 $collation = str_replace('_CS', '_CI', $collation);
1116 if ($accentsensitive) {
1117 $collation = str_replace('_AI', '_AS', $collation);
1119 $collation = str_replace('_AS', '_AI', $collation);
1122 return "$fieldname COLLATE $collation LIKE $param ESCAPE '$escapechar'";
1125 public function sql_concat() {
1126 $arr = func_get_args();
1127 foreach ($arr as $key => $ele) {
1128 $arr[$key] = ' CAST(' . $ele . ' AS VARCHAR(255)) ';
1130 $s = implode(' + ', $arr);
1137 public function sql_concat_join($separator="' '", $elements=array()) {
1138 for ($n=count($elements)-1; $n > 0 ; $n--) {
1139 array_splice($elements, $n, 0, $separator);
1141 $s = implode(' + ', $elements);
1148 public function sql_isempty($tablename, $fieldname, $nullablefield, $textfield) {
1150 return ' (' . $this->sql_compare_text($fieldname) . " = '') ";
1152 return " ($fieldname = '') ";
1157 * Returns the SQL text to be used to calculate the length in characters of one expression.
1158 * @param string fieldname or expression to calculate its length in characters.
1159 * @return string the piece of SQL code to be used in the statement.
1161 public function sql_length($fieldname) {
1162 return ' LEN(' . $fieldname . ')';
1165 public function sql_order_by_text($fieldname, $numchars=32) {
1166 return ' CONVERT(varchar, ' . $fieldname . ', ' . $numchars . ')';
1170 * Returns the SQL for returning searching one string for the location of another.
1172 public function sql_position($needle, $haystack) {
1173 return "CHARINDEX(($needle), ($haystack))";
1177 * Returns the proper substr() SQL text used to extract substrings from DB
1178 * NOTE: this was originally returning only function name
1180 * @param string $expr some string field, no aggregates
1181 * @param mixed $start integer or expression evaluating to int
1182 * @param mixed $length optional integer or expression evaluating to int
1183 * @return string sql fragment
1185 public function sql_substr($expr, $start, $length=false) {
1186 if (count(func_get_args()) < 2) {
1187 throw new coding_exception('moodle_database::sql_substr() requires at least two parameters', 'Originaly this function wa
1188 s only returning name of SQL substring function, it now requires all parameters.');
1190 if ($length === false) {
1191 return "SUBSTRING($expr, $start, (LEN($expr) - $start + 1))";
1193 return "SUBSTRING($expr, $start, $length)";
1199 public function session_lock_supported() {
1203 public function get_session_lock($rowid) {
1204 if (!$this->session_lock_supported()) {
1207 parent::get_session_lock($rowid);
1209 $fullname = $this->dbname.'-'.$this->prefix.'-session-'.$rowid;
1210 $sql = "sp_getapplock '$fullname', 'Exclusive', 'Session', 120000";
1211 $this->query_start($sql, null, SQL_QUERY_AUX);
1212 $result = mssql_query($sql, $this->mssql);
1213 $this->query_end($result);
1215 $this->free_result($result);
1218 public function release_session_lock($rowid) {
1219 if (!$this->session_lock_supported()) {
1222 parent::release_session_lock($rowid);
1224 $fullname = $this->dbname.'-'.$this->prefix.'-session-'.$rowid;
1225 $sql = "sp_releaseapplock '$fullname', 'Session'";
1226 $this->query_start($sql, null, SQL_QUERY_AUX);
1227 $result = mssql_query($sql, $this->mssql);
1228 $this->query_end($result);
1230 $this->free_result($result);
1236 * Driver specific start of real database transaction,
1237 * this can not be used directly in code.
1240 protected function begin_transaction() {
1241 // requires database to run with READ_COMMITTED_SNAPSHOT ON
1242 $sql = "BEGIN TRANSACTION"; // Will be using READ COMMITTED isolation
1243 $this->query_start($sql, NULL, SQL_QUERY_AUX);
1244 $result = mssql_query($sql, $this->mssql);
1245 $this->query_end($result);
1247 $this->free_result($result);
1251 * Driver specific commit of real database transaction,
1252 * this can not be used directly in code.
1255 protected function commit_transaction() {
1256 $sql = "COMMIT TRANSACTION";
1257 $this->query_start($sql, NULL, SQL_QUERY_AUX);
1258 $result = mssql_query($sql, $this->mssql);
1259 $this->query_end($result);
1261 $this->free_result($result);
1265 * Driver specific abort of real database transaction,
1266 * this can not be used directly in code.
1269 protected function rollback_transaction() {
1270 $sql = "ROLLBACK TRANSACTION";
1271 $this->query_start($sql, NULL, SQL_QUERY_AUX);
1272 $result = mssql_query($sql, $this->mssql);
1273 $this->query_end($result);
1275 $this->free_result($result);