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 require_once($CFG->libdir.'/dml/moodle_database.php');
29 require_once($CFG->libdir.'/dml/mssql_native_moodle_recordset.php');
30 require_once($CFG->libdir.'/dml/mssql_native_moodle_temptables.php');
33 * Native mssql class representing moodle database interface.
35 class mssql_native_moodle_database extends moodle_database {
37 protected $mssql = null;
39 protected $last_error_reporting; // To handle mssql driver default verbosity
42 * Detects if all needed PHP stuff installed.
43 * Note: can be used before connect()
44 * @return mixed true if ok, string if something
46 public function driver_installed() {
47 if (!function_exists('mssql_connect')) {
48 return get_string('mssqlextensionisnotpresentinphp', 'install');
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.)
58 public function get_dbfamily() {
63 * Returns more specific database driver type
64 * Note: can be used before connect()
65 * @return string db type mysql, pgsql, postgres7
67 protected function get_dbtype() {
72 * Returns general database library name
73 * Note: can be used before connect()
74 * @return string db type pdo, native
76 protected function get_dblibrary() {
81 * Returns localised database type name
82 * Note: can be used before connect()
85 public function get_name() {
86 return get_string('nativemssql', 'install');
90 * Returns localised database configuration help.
91 * Note: can be used before connect()
94 public function get_configuration_help() {
95 return get_string('nativemssqlhelp', 'install');
99 * Returns localised database description
100 * Note: can be used before connect()
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')\"";
108 $str .= '<img src="pix/docs.gif' . '" alt="Docs" class="iconhelp" />';
109 $str .= get_string('moodledocslink', 'install') . '</a></p>';
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
123 * @throws dml_connection_exception if error
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());
131 $driverstatus = $this->driver_installed();
133 if ($driverstatus !== true) {
134 throw new dml_exception('dbdriverproblem', $driverstatus);
137 $this->store_settings($dbhost, $dbuser, $dbpass, $dbname, $prefix, $dboptions);
140 if (!empty($this->dboptions['dbpersist'])) { // persistent connection
141 $this->mssql = mssql_pconnect($this->dbhost, $this->dbuser, $this->dbpass, true);
143 $this->mssql = mssql_connect($this->dbhost, $this->dbuser, $this->dbpass, true);
145 $dberr = ob_get_contents();
148 if ($this->mssql === false) {
150 throw new dml_connection_exception($dberr);
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);
158 // No need to set charset. It's UTF8, with transparent conversions
159 // back and forth performed both by FreeTDS or ODBTP
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);
167 $this->free_result($result);
169 // Force ANSI nulls so the NULL check was done by IS NULL and NOT IS NULL
170 // instead of equal(=) and distinct(<>) symbols
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);
176 $this->free_result($result);
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);
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);
191 $this->free_result($result);
193 // Set transactions isolation level to READ_COMMITTED
194 // prevents dirty reads when using transactions +
195 // is the default isolation level of MSSQL
196 $sql = "SET TRANSACTION ISOLATION LEVEL READ COMMITTED";
197 $this->query_start($sql, NULL, SQL_QUERY_AUX);
198 $result = mssql_query($sql, $this->mssql);
199 $this->query_end($result);
201 $this->free_result($result);
203 // Connection stabilised and configured, going to instantiate the temptables controller
204 $this->temptables = new mssql_native_moodle_temptables($this);
210 * Close database connection and release all resources
211 * and memory (especially circular memory references).
212 * Do NOT use connect() again, create a new instance if needed.
214 public function dispose() {
215 parent::dispose(); // Call parent dispose to write/close session and other common stuff before closing connection
217 mssql_close($this->mssql);
223 * Called before each db query.
225 * @param array array of parameters
226 * @param int $type type of query
227 * @param mixed $extrainfo driver specific extra information
230 protected function query_start($sql, array $params=null, $type, $extrainfo=null) {
231 parent::query_start($sql, $params, $type, $extrainfo);
232 // mssql driver tends to send debug to output, we do not need that ;-)
233 $this->last_error_reporting = error_reporting(0);
237 * Called immediately after each db query.
238 * @param mixed db specific result
241 protected function query_end($result) {
242 // reset original debug level
243 error_reporting($this->last_error_reporting);
244 parent::query_end($result);
248 * Returns database server info array
251 public function get_server_info() {
255 $sql = 'sp_server_info 2';
256 $this->query_start($sql, null, SQL_QUERY_AUX);
257 $result = mssql_query($sql, $this->mssql);
258 $this->query_end($result);
259 $row = mssql_fetch_row($result);
260 $info['server'] = $row[2];
261 $this->free_result($result);
263 $sql = 'sp_server_info 500';
264 $this->query_start($sql, null, SQL_QUERY_AUX);
265 $result = mssql_query($sql, $this->mssql);
266 $this->query_end($result);
267 $row = mssql_fetch_row($result);
268 $info['version'] = $row[2];
269 $this->free_result($result);
274 protected function is_min_version($version) {
275 $server = $this->get_server_info();
276 $server = $server['version'];
277 return version_compare($server, $version, '>=');
281 * Converts short table name {tablename} to real table name
282 * supporting temp tables (#) if detected
287 protected function fix_table_names($sql) {
288 if (preg_match_all('/\{([a-z][a-z0-9_]*)\}/', $sql, $matches)) {
289 foreach($matches[0] as $key=>$match) {
290 $name = $matches[1][$key];
291 if ($this->temptables->is_temptable($name)) {
292 $sql = str_replace($match, $this->temptables->get_correct_name($name), $sql);
294 $sql = str_replace($match, $this->prefix.$name, $sql);
302 * Returns supported query parameter types
305 protected function allowed_param_types() {
306 return SQL_PARAMS_QM; // Not really, but emulated, see emulate_bound_params()
310 * Returns last error reported by database engine.
312 public function get_last_error() {
313 return mssql_get_last_message();
317 * Return tables in database WITHOUT current prefix
318 * @return array of table names in lowercase and without prefix
320 public function get_tables($usecache=true) {
321 if ($usecache and $this->tables !== null) {
322 return $this->tables;
324 $this->tables = array();
325 $sql = "SELECT table_name
326 FROM information_schema.tables
327 WHERE table_name LIKE '$this->prefix%'
328 AND table_type = 'BASE TABLE'";
329 $this->query_start($sql, null, SQL_QUERY_AUX);
330 $result = mssql_query($sql, $this->mssql);
331 $this->query_end($result);
334 while ($row = mssql_fetch_row($result)) {
335 $tablename = reset($row);
336 if (strpos($tablename, $this->prefix) !== 0) {
339 $tablename = substr($tablename, strlen($this->prefix));
340 $this->tables[$tablename] = $tablename;
342 $this->free_result($result);
345 // Add the currently available temptables
346 $this->tables = array_merge($this->tables, $this->temptables->get_temptables());
347 return $this->tables;
351 * Return table indexes - everything lowercased
352 * @return array of arrays
354 public function get_indexes($table) {
356 $tablename = $this->prefix.$table;
358 // Indexes aren't covered by information_schema metatables, so we need to
359 // go to sys ones. Skipping primary key indexes on purpose.
360 $sql = "SELECT i.name AS index_name, i.is_unique, ic.index_column_id, c.name AS column_name
362 JOIN sys.index_columns ic ON i.object_id = ic.object_id AND i.index_id = ic.index_id
363 JOIN sys.columns c ON ic.object_id = c.object_id AND ic.column_id = c.column_id
364 JOIN sys.tables t ON i.object_id = t.object_id
365 WHERE t.name = '$tablename'
366 AND i.is_primary_key = 0
367 ORDER BY i.name, i.index_id, ic.index_column_id";
369 $this->query_start($sql, null, SQL_QUERY_AUX);
370 $result = mssql_query($sql, $this->mssql);
371 $this->query_end($result);
377 while ($row = mssql_fetch_assoc($result)) {
378 if ($lastindex and $lastindex != $row['index_name']) { // Save lastindex to $indexes and reset info
379 $indexes[$lastindex] = array('unique' => $unique, 'columns' => $columns);
383 $lastindex = $row['index_name'];
384 $unique = empty($row['is_unique']) ? false : true;
385 $columns[] = $row['column_name'];
387 if ($lastindex ) { // Add the last one if exists
388 $indexes[$lastindex] = array('unique' => $unique, 'columns' => $columns);
390 $this->free_result($result);
396 * Returns datailed information about columns in table. This information is cached internally.
397 * @param string $table name
398 * @param bool $usecache
399 * @return array array of database_column_info objects indexed with column names
401 public function get_columns($table, $usecache=true) {
402 if ($usecache and isset($this->columns[$table])) {
403 return $this->columns[$table];
406 $this->columns[$table] = array();
408 if (!$this->temptables->is_temptable($table)) { // normal table, get metadata from own schema
409 $sql = "SELECT column_name AS name,
411 numeric_precision AS max_length,
412 character_maximum_length AS char_max_length,
413 numeric_scale AS scale,
414 is_nullable AS is_nullable,
415 columnproperty(object_id(quotename(table_schema) + '.' +
416 quotename(table_name)), column_name, 'IsIdentity') AS auto_increment,
417 column_default AS default_value
418 FROM information_schema.columns
419 WHERE table_name = '{" . $table . "}'
420 ORDER BY ordinal_position";
421 } else { // temp table, get metadata from tempdb schema
422 $sql = "SELECT column_name AS name,
424 numeric_precision AS max_length,
425 character_maximum_length AS char_max_length,
426 numeric_scale AS scale,
427 is_nullable AS is_nullable,
428 columnproperty(object_id(quotename(table_schema) + '.' +
429 quotename(table_name)), column_name, 'IsIdentity') AS auto_increment,
430 column_default AS default_value
431 FROM tempdb.information_schema.columns
432 JOIN tempdb..sysobjects ON name = table_name
433 WHERE id = object_id('tempdb..{" . $table . "}')
434 ORDER BY ordinal_position";
437 list($sql, $params, $type) = $this->fix_sql_params($sql, null);
439 $this->query_start($sql, null, SQL_QUERY_AUX);
440 $result = mssql_query($sql, $this->mssql);
441 $this->query_end($result);
447 while ($rawcolumn = mssql_fetch_assoc($result)) {
449 $rawcolumn = (object)$rawcolumn;
451 $info = new object();
452 $info->name = $rawcolumn->name;
453 $info->type = $rawcolumn->type;
454 $info->meta_type = $this->mssqltype2moodletype($info->type);
456 // Prepare auto_increment info
457 $info->auto_increment = $rawcolumn->auto_increment ? true : false;
459 // Define type for auto_increment columns
460 $info->meta_type = ($info->auto_increment && $info->meta_type == 'I') ? 'R' : $info->meta_type;
462 // id columns being auto_incremnt are PK by definition
463 $info->primary_key = ($info->name == 'id' && $info->meta_type == 'R' && $info->auto_increment);
465 // Put correct length for character and LOB types
466 $info->max_length = $info->meta_type == 'C' ? $rawcolumn->char_max_length : $rawcolumn->max_length;
467 $info->max_length = ($info->meta_type == 'X' || $info->meta_type == 'B') ? -1 : $info->max_length;
470 $info->scale = $rawcolumn->scale ? $rawcolumn->scale : false;
472 // Prepare not_null info
473 $info->not_null = $rawcolumn->is_nullable == 'NO' ? true : false;
476 $info->has_default = !empty($rawcolumn->default_value);
477 $info->default_value = preg_replace("/^[\(N]+[']?(.*?)[']?[\)]+$/", '\\1', $rawcolumn->default_value);
480 $info->binary = $info->meta_type == 'B' ? true : false;
482 $this->columns[$table][$info->name] = new database_column_info($info);
484 $this->free_result($result);
486 return $this->columns[$table];
490 * Normalise values based in RDBMS dependencies (booleans, LOBs...)
492 * @param database_column_info $column column metadata corresponding with the value we are going to normalise
493 * @param mixed $value value we are going to normalise
494 * @return mixed the normalised value
496 protected function normalise_value($column, $value) {
497 if (is_bool($value)) { /// Always, convert boolean to int
498 $value = (int)$value;
499 } // And continue processing because text columns with numeric info need special handling below
501 if ($column->meta_type == 'B') { // BLOBs need to be properly "packed", but can be inserted directly if so.
502 if (!is_null($value)) { // If value not null, unpack it to unquoted hexadecimal byte-string format
503 $value = unpack('H*hex', $value); // we leave it as array, so emulate_bound_params() can detect it
504 } // easily and "bind" the param ok.
506 } else if ($column->meta_type == 'X') { // MSSQL doesn't cast from int to text, so if text column
507 if (is_numeric($value)) { // and is numeric value then cast to string
508 $value = array('numstr' => (string)$value); // and put into array, so emulate_bound_params() will know how
509 } // to "bind" the param ok, avoiding reverse conversion to number
511 } else if ($value === '') {
512 if ($column->meta_type == 'I' or $column->meta_type == 'F' or $column->meta_type == 'N') {
513 $value = 0; // prevent '' problems in numeric fields
520 * Selectively call mssql_free_result(), avoiding some warnings without using the horrible @
522 * @param mssql_resource $resource resource to be freed if possible
524 private function free_result($resource) {
525 if (!is_bool($resource)) { // true/false resources cannot be freed
526 mssql_free_result($resource);
531 * Provides mapping between mssql native data types and moodle_database - database_column_info - ones)
533 * @param string $mssql_type native mssql data type
534 * @return string 1-char database_column_info data type
536 private function mssqltype2moodletype($mssql_type) {
538 switch (strtoupper($mssql_type)) {
560 case 'NVARCHAR(MAX)':
564 case 'VARBINARY(MAX)':
572 throw new dml_exception('invalidmssqlnativetype', $mssql_type);
578 * Do NOT use in code, to be used by database_manager only!
579 * @param string $sql query
581 * @throws dml_exception if error
583 public function change_database_structure($sql) {
584 $this->reset_caches();
586 $this->query_start($sql, null, SQL_QUERY_STRUCTURE);
587 $result = mssql_query($sql, $this->mssql);
588 $this->query_end($result);
594 * Very ugly hack which emulates bound parameters in queries
595 * because the mssql driver doesn't support placeholders natively at all
597 protected function emulate_bound_params($sql, array $params=null) {
598 if (empty($params)) {
601 /// ok, we have verified sql statement with ? and correct number of params
602 $return = strtok($sql, '?');
603 foreach ($params as $param) {
604 if (is_bool($param)) {
605 $return .= (int)$param;
607 } else if (is_array($param) && isset($param['hex'])) { // detect hex binary, bind it specially
608 $return .= '0x' . $param['hex'];
610 } else if (is_array($param) && isset($param['numstr'])) { // detect numerical strings that *must not*
611 $return .= "N'{$param['numstr']}'"; // be converted back to number params, but bound as strings
613 } else if (is_null($param)) {
616 } else if (is_number($param)) { // we can not use is_numeric() because it eats leading zeros from strings like 0045646
619 } else if (is_float($param)) {
623 $param = str_replace("'", "''", $param);
624 $return .= "N'$param'";
627 $return .= strtok('?');
633 * Execute general sql query. Should be used only when no other method suitable.
634 * Do NOT use this to make changes in db structure, use database_manager::execute_sql() instead!
635 * @param string $sql query
636 * @param array $params query parameters
638 * @throws dml_exception if error
640 public function execute($sql, array $params=null) {
642 list($sql, $params, $type) = $this->fix_sql_params($sql, $params);
643 $rawsql = $this->emulate_bound_params($sql, $params);
645 if (strpos($sql, ';') !== false) {
646 throw new coding_exception('moodle_database::execute() Multiple sql statements found or bound parameters not used properly in query!');
649 $this->query_start($sql, $params, SQL_QUERY_UPDATE);
650 $result = mssql_query($rawsql, $this->mssql);
651 $this->query_end($result);
652 $this->free_result($result);
658 * Get a number of records as a moodle_recordset using a SQL statement.
660 * Since this method is a little less readable, use of it should be restricted to
661 * code where it's possible there might be large datasets being returned. For known
662 * small datasets use get_records_sql - it leads to simpler code.
664 * The return type is as for @see function get_recordset.
666 * @param string $sql the SQL select query to execute.
667 * @param array $params array of sql parameters
668 * @param int $limitfrom return a subset of records, starting at this point (optional, required if $limitnum is set).
669 * @param int $limitnum return a subset comprising this many records (optional, required if $limitfrom is set).
670 * @return mixed an moodle_recordset object
671 * @throws dml_exception if error
673 public function get_recordset_sql($sql, array $params=null, $limitfrom=0, $limitnum=0) {
674 $limitfrom = (int)$limitfrom;
675 $limitnum = (int)$limitnum;
676 $limitfrom = ($limitfrom < 0) ? 0 : $limitfrom;
677 $limitnum = ($limitnum < 0) ? 0 : $limitnum;
678 if ($limitfrom or $limitnum) {
679 if ($limitnum >= 1) { // Only apply TOP clause if we have any limitnum (limitfrom offset is handled later)
680 $fetch = $limitfrom + $limitnum;
681 $sql = preg_replace('/^([\s(])*SELECT( DISTINCT)?(?!\s*TOP\s*\()/i',
682 "\\1SELECT\\2 TOP $fetch", $sql);
686 list($sql, $params, $type) = $this->fix_sql_params($sql, $params);
687 $rawsql = $this->emulate_bound_params($sql, $params);
689 $this->query_start($sql, $params, SQL_QUERY_SELECT);
690 $result = mssql_query($rawsql, $this->mssql);
691 $this->query_end($result);
693 if ($limitfrom) { // Skip $limitfrom records
694 mssql_data_seek($result, $limitfrom);
697 return $this->create_recordset($result);
700 protected function create_recordset($result) {
701 return new mssql_native_moodle_recordset($result);
705 * Get a number of records as an array of objects using a SQL statement.
707 * Return value as for @see function get_records.
709 * @param string $sql the SQL select query to execute. The first column of this SELECT statement
710 * must be a unique value (usually the 'id' field), as it will be used as the key of the
712 * @param array $params array of sql parameters
713 * @param int $limitfrom return a subset of records, starting at this point (optional, required if $limitnum is set).
714 * @param int $limitnum return a subset comprising this many records (optional, required if $limitfrom is set).
715 * @return mixed an array of objects, or empty array if no records were found
716 * @throws dml_exception if error
718 public function get_records_sql($sql, array $params=null, $limitfrom=0, $limitnum=0) {
720 $rs = $this->get_recordset_sql($sql, $params, $limitfrom, $limitnum);
724 foreach ($rs as $row) {
726 if (isset($results[$id])) {
727 $colname = key($row);
728 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 $results[$id] = $row;
738 * Selects records and return values (first field) as an array using a SQL statement.
740 * @param string $sql The SQL query
741 * @param array $params array of sql parameters
742 * @return mixed array of values
743 * @throws dml_exception if error
745 public function get_fieldset_sql($sql, array $params=null) {
747 $rs = $this->get_recordset_sql($sql, $params);
751 foreach ($rs as $row) {
752 $results[] = reset($row);
760 * Insert new record into database, as fast as possible, no safety checks, lobs not supported.
761 * @param string $table name
762 * @param mixed $params data record as object or array
763 * @param bool $returnit return it of inserted record
764 * @param bool $bulk true means repeated inserts expected
765 * @param bool $customsequence true if 'id' included in $params, disables $returnid
766 * @return true or new id
767 * @throws dml_exception if error
769 public function insert_record_raw($table, $params, $returnid=true, $bulk=false, $customsequence=false) {
770 if (!is_array($params)) {
771 $params = (array)$params;
776 if ($customsequence) {
777 if (!isset($params['id'])) {
778 throw new coding_exception('moodle_database::insert_record_raw() id field must be specified if custom sequences used.');
782 unset($params['id']);
784 $returning = "; SELECT SCOPE_IDENTITY()";
788 if (empty($params)) {
789 throw new coding_exception('moodle_database::insert_record_raw() no fields found.');
792 $fields = implode(',', array_keys($params));
793 $qms = array_fill(0, count($params), '?');
794 $qms = implode(',', $qms);
796 $sql = "INSERT INTO {" . $table . "} ($fields) VALUES($qms) $returning";
798 list($sql, $params, $type) = $this->fix_sql_params($sql, $params);
799 $rawsql = $this->emulate_bound_params($sql, $params);
801 $this->query_start($sql, $params, SQL_QUERY_INSERT);
802 $result = mssql_query($rawsql, $this->mssql);
803 $this->query_end($result);
805 if ($returning !== "") {
806 $row = mssql_fetch_assoc($result);
807 $params['id'] = reset($row);
809 $this->free_result($result);
815 return (int)$params['id'];
819 * Insert a record into a table and return the "id" field if required.
821 * Some conversions and safety checks are carried out. Lobs are supported.
822 * If the return ID isn't required, then this just reports success as true/false.
823 * $data is an object containing needed data
824 * @param string $table The database table to be inserted into
825 * @param object $data A data object with values for one or more fields in the record
826 * @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.
827 * @return true or new id
828 * @throws dml_exception if error
830 public function insert_record($table, $dataobject, $returnid=true, $bulk=false) {
831 if (!is_object($dataobject)) {
832 $dataobject = (object)$dataobject;
835 unset($dataobject->id);
837 $columns = $this->get_columns($table);
840 foreach ($dataobject as $field => $value) {
841 if (!isset($columns[$field])) {
844 $column = $columns[$field];
845 $cleaned[$field] = $this->normalise_value($column, $value);
848 return $this->insert_record_raw($table, $cleaned, $returnid, $bulk);
852 * Import a record into a table, id field is required.
853 * Safety checks are NOT carried out. Lobs are supported.
855 * @param string $table name of database table to be inserted into
856 * @param object $dataobject A data object with values for one or more fields in the record
858 * @throws dml_exception if error
860 public function import_record($table, $dataobject) {
861 if (!is_object($dataobject)) {
862 $dataobject = (object)$dataobject;
865 $columns = $this->get_columns($table);
868 foreach ($dataobject as $field => $value) {
869 if (!isset($columns[$field])) {
872 $column = $columns[$field];
873 $cleaned[$field] = $this->normalise_value($column, $value);
876 // Disable IDENTITY column before inserting record with id
877 $sql = 'SET IDENTITY_INSERT {' . $table . '} ON'; // Yes, it' ON!!
879 list($sql, $params, $type) = $this->fix_sql_params($sql, null);
881 $this->query_start($sql, null, SQL_QUERY_AUX);
882 $result = mssql_query($sql, $this->mssql);
883 $this->query_end($result);
885 $this->free_result($result);
887 $insertresult = $this->insert_record_raw($table, $cleaned, false, false, true);
889 // Enable IDENTITY column after inserting record with id
890 $sql = 'SET IDENTITY_INSERT {' . $table . '} OFF'; // Yes, it' OFF!!
892 list($sql, $params, $type) = $this->fix_sql_params($sql, null);
894 $this->query_start($sql, null, SQL_QUERY_AUX);
895 $result = mssql_query($sql, $this->mssql);
896 $this->query_end($result);
898 $this->free_result($result);
900 return $insertresult;
904 * Update record in database, as fast as possible, no safety checks, lobs not supported.
905 * @param string $table name
906 * @param mixed $params data record as object or array
907 * @param bool true means repeated updates expected
909 * @throws dml_exception if error
911 public function update_record_raw($table, $params, $bulk=false) {
912 if (!is_array($params)) {
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 if (!is_object($dataobject)) {
961 $dataobject = (object)$dataobject;
964 $columns = $this->get_columns($table);
967 foreach ($dataobject as $field => $value) {
968 if (!isset($columns[$field])) {
971 $column = $columns[$field];
972 $cleaned[$field] = $this->normalise_value($column, $value);
975 return $this->update_record_raw($table, $cleaned, $bulk);
979 * Set a single field in every table record which match a particular WHERE clause.
981 * @param string $table The database table to be checked against.
982 * @param string $newfield the field to set.
983 * @param string $newvalue the value to set the field to.
984 * @param string $select A fragment of SQL to be used in a where clause in the SQL call.
985 * @param array $params array of sql parameters
987 * @throws dml_exception if error
989 public function set_field_select($table, $newfield, $newvalue, $select, array $params=null) {
992 $select = "WHERE $select";
994 if (is_null($params)) {
998 /// Get column metadata
999 $columns = $this->get_columns($table);
1000 $column = $columns[$newfield];
1002 $newvalue = $this->normalise_value($column, $newvalue);
1004 if (is_null($newvalue)) {
1005 $newfield = "$newfield = NULL";
1007 $newfield = "$newfield = ?";
1008 array_unshift($params, $newvalue);
1010 $sql = "UPDATE {" . $table . "} SET $newfield $select";
1012 list($sql, $params, $type) = $this->fix_sql_params($sql, $params);
1013 $rawsql = $this->emulate_bound_params($sql, $params);
1015 $this->query_start($sql, $params, SQL_QUERY_UPDATE);
1016 $result = mssql_query($rawsql, $this->mssql);
1017 $this->query_end($result);
1019 $this->free_result($result);
1025 * Delete one or more records from a table which match a particular WHERE clause.
1027 * @param string $table The database table to be checked against.
1028 * @param string $select A fragment of SQL to be used in a where clause in the SQL call (used to define the selection criteria).
1029 * @param array $params array of sql parameters
1031 * @throws dml_exception if error
1033 public function delete_records_select($table, $select, array $params=null) {
1036 $select = "WHERE $select";
1039 $sql = "DELETE FROM {" . $table . "} $select";
1041 list($sql, $params, $type) = $this->fix_sql_params($sql, $params);
1042 $rawsql = $this->emulate_bound_params($sql, $params);
1044 $this->query_start($sql, $params, SQL_QUERY_UPDATE);
1045 $result = mssql_query($rawsql, $this->mssql);
1046 $this->query_end($result);
1048 $this->free_result($result);
1053 /// SQL helper functions
1055 public function sql_bitxor($int1, $int2) {
1056 return '(' . $this->sql_bitor($int1, $int2) . ' - ' . $this->sql_bitand($int1, $int2) . ')';
1059 public function sql_cast_char2int($fieldname, $text=false) {
1060 return ' CAST(' . $fieldname . ' AS INT) ';
1063 public function sql_ceil($fieldname) {
1064 return ' CEILING(' . $fieldname . ')';
1067 public function sql_concat() {
1068 $arr = func_get_args();
1069 foreach ($arr as $key => $ele) {
1070 $arr[$key] = ' CAST(' . $ele . ' AS VARCHAR(255)) ';
1072 $s = implode(' + ', $arr);
1079 public function sql_concat_join($separator="' '", $elements=array()) {
1080 for ($n=count($elements)-1; $n > 0 ; $n--) {
1081 array_splice($elements, $n, 0, $separator);
1083 $s = implode(' + ', $elements);
1090 public function sql_isempty($tablename, $fieldname, $nullablefield, $textfield) {
1092 return ' (' . $this->sql_compare_text($fieldname) . " = '') ";
1094 return " ($fieldname = '') ";
1099 * Returns the SQL text to be used to calculate the length in characters of one expression.
1100 * @param string fieldname or expression to calculate its length in characters.
1101 * @return string the piece of SQL code to be used in the statement.
1103 public function sql_length($fieldname) {
1104 return ' LEN(' . $fieldname . ')';
1107 public function sql_order_by_text($fieldname, $numchars=32) {
1108 return ' CONVERT(varchar, ' . $fieldname . ', ' . $numchars . ')';
1112 * Returns the SQL for returning searching one string for the location of another.
1114 public function sql_position($needle, $haystack) {
1115 return "CHARINDEX(($needle), ($haystack))";
1119 * Returns the proper substr() SQL text used to extract substrings from DB
1120 * NOTE: this was originally returning only function name
1122 * @param string $expr some string field, no aggregates
1123 * @param mixed $start integer or expression evaluating to int
1124 * @param mixed $length optional integer or expression evaluating to int
1125 * @return string sql fragment
1127 public function sql_substr($expr, $start, $length=false) {
1128 if (count(func_get_args()) < 2) {
1129 throw new coding_exception('moodle_database::sql_substr() requires at least two parameters', 'Originaly this function wa
1130 s only returning name of SQL substring function, it now requires all parameters.');
1132 if ($length === false) {
1133 return "SUBSTRING($expr, $start, (LEN($expr) - $start + 1))";
1135 return "SUBSTRING($expr, $start, $length)";
1141 public function session_lock_supported() {
1145 public function get_session_lock($rowid) {
1146 if (!$this->session_lock_supported()) {
1149 parent::get_session_lock($rowid);
1151 $fullname = $this->dbname.'-'.$this->prefix.'-session-'.$rowid;
1152 $sql = "sp_getapplock '$fullname', 'Exclusive', 'Session', 120000";
1153 $this->query_start($sql, null, SQL_QUERY_AUX);
1154 $result = mssql_query($sql, $this->mssql);
1155 $this->query_end($result);
1157 $this->free_result($result);
1160 public function release_session_lock($rowid) {
1161 if (!$this->session_lock_supported()) {
1164 parent::release_session_lock($rowid);
1166 $fullname = $this->dbname.'-'.$this->prefix.'-session-'.$rowid;
1167 $sql = "sp_releaseapplock '$fullname', 'Session'";
1168 $this->query_start($sql, null, SQL_QUERY_AUX);
1169 $result = mssql_query($sql, $this->mssql);
1170 $this->query_end($result);
1172 $this->free_result($result);
1178 * Driver specific start of real database transaction,
1179 * this can not be used directly in code.
1182 protected function begin_transaction() {
1183 $sql = "BEGIN TRANSACTION"; // Will be using READ COMMITTED isolation
1184 $this->query_start($sql, NULL, SQL_QUERY_AUX);
1185 $result = mssql_query($sql, $this->mssql);
1186 $this->query_end($result);
1188 $this->free_result($result);
1192 * Driver specific commit of real database transaction,
1193 * this can not be used directly in code.
1196 protected function commit_transaction() {
1197 $sql = "COMMIT TRANSACTION";
1198 $this->query_start($sql, NULL, SQL_QUERY_AUX);
1199 $result = mssql_query($sql, $this->mssql);
1200 $this->query_end($result);
1202 $this->free_result($result);
1206 * Driver specific abort of real database transaction,
1207 * this can not be used directly in code.
1210 protected function rollback_transaction() {
1211 $sql = "ROLLBACK TRANSACTION";
1212 $this->query_start($sql, NULL, SQL_QUERY_AUX);
1213 $result = mssql_query($sql, $this->mssql);
1214 $this->query_end($result);
1216 $this->free_result($result);