Data manipulation API: Difference between revisions
mNo edit summary |
Dev Docs Bot (talk | contribs) m (Protected "Data manipulation API": Developer Docs Migration ([Edit=Allow only administrators] (indefinite))) |
||
(18 intermediate revisions by 12 users not shown) | |||
Line 1: | Line 1: | ||
{{Template:Migrated|newDocId=/docs/apis/core/dml}} | |||
{{Moodle_2.0}}This page describes the functions available to access data in the Moodle database. You should '''exclusively''' use these functions in order to retrieve or modify database content because these functions provide a high level of abstraction and guarantee that your database manipulation will work against different RDBMSes. | {{Moodle_2.0}}This page describes the functions available to access data in the Moodle database. You should '''exclusively''' use these functions in order to retrieve or modify database content because these functions provide a high level of abstraction and guarantee that your database manipulation will work against different RDBMSes. | ||
Where possible, tricks and examples will be documented here in order to make developers' lives a bit easier. Of course, feel free to clarify, complete and add more information to | Where possible, tricks and examples will be documented here in order to make developers' lives a bit easier. Of course, feel free to clarify, complete and add more information to this documentation. It will be welcome, absolutely! | ||
== General concepts == | |||
=== DB object === | |||
* The data manipulation API is exposed via public methods of the <tt>$DB</tt> object. | |||
* Moodle core takes care of setting up the connection to the database according to values specified in the main config.php file. | |||
* The $DB global object is an instance of the <tt>moodle_database</tt> class. It is instantiated automatically during the bootstrap setup, i.e. as a part of including the main config.php file. | |||
* The DB object is available in the global scope right after including the config.php file: | |||
<syntaxhighlight lang="php"> | |||
<?php | |||
require(__DIR__.'/../../../config.php'); | |||
// You can access the database via the $DB method calls here. | |||
</syntaxhighlight> | |||
* To make the DB object available in your local scope, such as within a function: | |||
<syntaxhighlight lang="php"> | |||
<?php | |||
defined('MOODLE_INTERNAL') || die(); | |||
function my_function_making_use_of_database() { | |||
global $DB; | |||
// You can access the database via the $DB method calls here. | |||
} | |||
</syntaxhighlight> | |||
=== Table prefix === | |||
* Most Moodle installations use a prefix for all the database tables, such as <tt>mdl_</tt>. This prefix is NOT to be used in the code in the code itself. | |||
* All the $table parameters in the functions are meant to be the table name without prefixes: | |||
<syntaxhighlight lang="php">$user = $DB->get_record('user', ['id' => '1']);</syntaxhighlight> | |||
* In custom SQL queries, table names must be enclosed between curly braces. They will be then automatically converted to the real prefixed table name. There is no need to access <tt>$CFG->prefix</tt> | |||
<syntaxhighlight lang="php">$user = $DB->get_record_sql('SELECT COUNT(*) FROM {user} WHERE deleted = 1 OR suspended = 1;');</syntaxhighlight> | |||
=== Conditions === | |||
* All the $conditions parameters in the functions are arrays of fieldname=>fieldvalue elements. | |||
* They all must be fulfilled - i.e. logical <tt>AND</tt> is used to populate the actual <tt>WHERE</tt> statement. | |||
<syntaxhighlight lang="php">$user = $DB->get_record('user', ['firstname' => 'Martin', 'lastname' => 'Dougiamas']);</syntaxhighlight> | |||
=== Placeholders === | |||
</ | * All the $params parameters in the functions are arrays of values used to fill placeholders in SQL statements. | ||
* Placeholders help to avoid problems with SQL-injection and/or invalid quotes in SQL queries. They facilitate secure and cross-db compatible code. | |||
=== | * Two types of placeholders are supported - question marks (<tt>SQL_PARAMS_QM</tt>) and named placeholders (<tt>SQL_PARAMS_NAMED</tt>). | ||
* Named params '''must be unique''' even if the value passed is the same. If you need to pass the same value multiple times, you need to have multiple distinct named parameters. | |||
<syntaxhighlight lang="php"> | |||
// Example of using question mark placeholders. | |||
$DB->get_record_sql('SELECT * FROM {user} WHERE firstname = ? AND lastname = ?', | |||
['Martin', 'Dougiamas']); | |||
< | |||
< | |||
< | |||
= | |||
$ | |||
</ | |||
</ | |||
= | |||
$ | |||
</ | |||
=== | |||
< | |||
// | |||
$ | |||
</ | |||
=== | |||
< | |||
< | |||
</ | |||
===== | // Example of using named placeholders. | ||
$DB->get_record_sql('SELECT * FROM {user} WHERE firstname = :firstname AND lastname = :lastname', | |||
< | ['firstname' => 'Martin', 'lastname' => 'Dougiamas']); | ||
///Get all | </syntaxhighlight> | ||
$sql = | === Strictness === | ||
$params = array( | Some methods accept the <tt>$strictness</tt> parameter affecting the method behaviour. Supported modes are specified using the constants: | ||
* <tt>MUST_EXIST</tt> - In this mode, the requested record must exist and must be unique. An exception will be thrown if no record is found or multiple matching records are found. | |||
* <tt>IGNORE_MISSING</tt> - In this mode, a missing record is not an error. False boolean is returned if the requested record is not found. If more records are found, a debugging message is displayed. | |||
* <tt>IGNORE_MULTIPLE</tt> - This is not a recommended mode. The function will silently ignore multiple records found and will return just the first one of them. | |||
== Getting a single record == | |||
=== get_record === | |||
Return a single database record as an object where all the given conditions are met. | |||
<syntaxhighlight lang="php">$DB->get_record($table, array $conditions, $fields='*', $strictness=IGNORE_MISSING)</syntaxhighlight> | |||
=== get_record_select === | |||
Return a single database record as an object where the given conditions are used in the WHERE clause. | |||
<syntaxhighlight lang="php">$DB->get_record_select($table, $select, array $params=null, $fields='*', $strictness=IGNORE_MISSING)</syntaxhighlight> | |||
=== get_record_sql === | |||
Return a single database record as an object using a custom SELECT query. | |||
<syntaxhighlight lang="php">$DB->get_record_sql($sql, array $params=null, $strictness=IGNORE_MISSING)</syntaxhighlight> | |||
== Getting a hashed array of records == | |||
Each of the following methods return an array of objects. The array is indexed by the first column of the fields returned by the query. To assure consistency, it is a good practice to ensure that your query include an "id column" as the first field. When designing custom tables, make <tt>id</tt> their first column and primary key. | |||
=== get_records === | |||
Return a list of records as an array of objects where all the given conditions are met. | |||
<syntaxhighlight lang="php">$DB->get_records($table, array $conditions=null, $sort='', $fields='*', $limitfrom=0, $limitnum=0)</syntaxhighlight> | |||
=== get_records_select === | |||
Return a list of records as an array of objects where the given conditions are used in the WHERE clause. | |||
<syntaxhighlight lang="php">$DB->get_records_select($table, $select, array $params=null, $sort='', $fields='*', $limitfrom=0, $limitnum=0)</syntaxhighlight> | |||
$fields is a comma separated list of fields to return (optional, by default all fields are returned). | |||
=== get_records_sql === | |||
Return a list of records as an array of objects using a custom SELECT query. | |||
<syntaxhighlight lang="php">$DB->get_records_sql($sql, array $params=null, $limitfrom=0, $limitnum=0)</syntaxhighlight> | |||
=== get_records_list === | |||
Return a list of records as an array of objects where the given field matches one of the possible values. | |||
<syntaxhighlight lang="php">$DB->get_records_list($table, $field, array $values, $sort='', $fields='*', $limitfrom='', $limitnum='')</syntaxhighlight> | |||
== Getting data as key/value pairs in an associative array == | |||
=== get_records_menu === | |||
Return the first two columns from a list of records as an associative array where all the given conditions are met. | |||
<syntaxhighlight lang="php">$DB->get_records_menu($table, array $conditions=null, $sort='', $fields='*', $limitfrom=0, $limitnum=0)</syntaxhighlight> | |||
=== get_records_select_menu === | |||
Return the first two columns from a list of records as an associative array where the given conditions are used in the WHERE clause. | |||
<syntaxhighlight lang="php">$DB->get_records_select_menu($table, $select, array $params=null, $sort='', $fields='*', $limitfrom=0, $limitnum=0)</syntaxhighlight> | |||
=== get_records_sql_menu === | |||
Return the first two columns from a number of records as an associative array using a custom SELECT query. | |||
<syntaxhighlight lang="php">$DB->get_records_sql_menu($sql, array $params=null, $limitfrom=0, $limitnum=0)</syntaxhighlight> | |||
== Counting records that match the given criteria == | |||
=== count_records === | |||
Count the records in a table where all the given conditions are met. | |||
<syntaxhighlight lang="php">$DB->count_records($table, array $conditions=null) </syntaxhighlight> | |||
=== count_records_select === | |||
Count the records in a table where the given conditions are used in the WHERE clause. | |||
<syntaxhighlight lang="php">$DB->count_records_select($table, $select, array $params=null, $countitem="COUNT('x')")</syntaxhighlight> | |||
=== count_records_sql === | |||
Counting the records using a custom SELECT COUNT(...) query. | |||
<syntaxhighlight lang="php">$DB->count_records_sql($sql, array $params=null)</syntaxhighlight> | |||
== Checking if a given record exists == | |||
=== record_exists === | |||
Test whether a record exists in a table where all the given conditions are met. | |||
<syntaxhighlight lang="php">$DB->record_exists($table, array $conditions=null)</syntaxhighlight> | |||
=== record_exists_select === | |||
Test whether any records exists in a table where the given conditions are used in the WHERE clause. | |||
<syntaxhighlight lang="php">$DB->record_exists_select($table, $select, array $params=null)</syntaxhighlight> | |||
=== record_exists_sql === | |||
Test whether the given SELECT query would return any record. | |||
<syntaxhighlight lang="php">$DB->record_exists_sql($sql, array $params=null)</syntaxhighlight> | |||
== Getting a particular field value from one record == | |||
=== get_field === | |||
Get a single field value from a table record where all the given conditions are met. | |||
<syntaxhighlight lang="php">$DB->get_field($table, $return, array $conditions, $strictness=IGNORE_MISSING)</syntaxhighlight> | |||
=== get_field_select === | |||
Get a single field value from a table record where the given conditions are used in the WHERE clause. | |||
<syntaxhighlight lang="php">$DB->get_field_select($table, $return, $select, array $params=null, $strictness=IGNORE_MISSING)</syntaxhighlight> | |||
=== get_field_sql === | |||
Get a single field value (first field) using a custom SELECT query. | |||
<syntaxhighlight lang="php">$DB->get_field_sql($sql, array $params=null, $strictness=IGNORE_MISSING)</syntaxhighlight> | |||
== Getting field values from multiple records == | |||
=== get_fieldset_select === | |||
Return values of the given field as an array where the given conditions are used in the WHERE clause. | |||
<syntaxhighlight lang="php">$DB->get_fieldset_select($table, $return, $select, array $params=null)</syntaxhighlight> | |||
=== get_fieldset_sql === | |||
Return values of the first column as an array using a custom SELECT field FROM ... query. | |||
<syntaxhighlight lang="php">$DB->get_fieldset_sql($sql, array $params=null)</syntaxhighlight> | |||
== Setting a field value == | |||
=== set_field === | |||
Set a single field in every record where all the given conditions are met. | |||
<syntaxhighlight lang="php">$DB->set_field($table, $newfield, $newvalue, array $conditions=null)</syntaxhighlight> | |||
=== set_field_select === | |||
Set a single field in every table record where the given conditions are used in the WHERE clause. | |||
<syntaxhighlight lang="php">$DB->set_field_select($table, $newfield, $newvalue, $select, array $params=null)</syntaxhighlight> | |||
== Deleting records == | |||
=== delete_records === | |||
Delete records from the table where all the given conditions are met. | |||
<syntaxhighlight lang="php">$DB->delete_records($table, array $conditions=null)</syntaxhighlight> | |||
=== delete_records_select === | |||
Delete records from the table where the given conditions are used in the WHERE clause. | |||
<syntaxhighlight lang="php">$DB->delete_records_select($table, $select, array $params=null)</syntaxhighlight> | |||
== Inserting records == | |||
=== insert_record === | |||
Insert the given data object into the table and return the "id" of the newly created record. | |||
<syntaxhighlight lang="php">$DB->insert_record($table, $dataobject, $returnid=true, $bulk=false)</syntaxhighlight> | |||
=== insert_records === | |||
{{Moodle_2.7}}Insert multiple records into the table as fast as possible. Records are inserted in the given order, but the operation is not atomic. Use transactions if necessary. | |||
<syntaxhighlight lang="php">$DB->insert_records($table, $dataobjects)</syntaxhighlight> | |||
=== insert_record_raw === | |||
For rare cases when you also need to specify the ID of the record to be inserted. | |||
== Updating records == | |||
=== update_record === | |||
Update a record in the table. The data object must have the property "id" set. | |||
<syntaxhighlight lang="php">$DB->update_record($table, $dataobject, $bulk=false)</syntaxhighlight> | |||
== Executing a custom query == | |||
=== execute === | |||
* If you need to perform a complex update using arbitrary SQL, you can use the low level "execute" method. Only use this when no specialised method exists. | |||
* Do NOT use this to make changes in database structure, use database_manager methods instead! | |||
<syntaxhighlight lang="php">$DB->execute($sql, array $params=null)</syntaxhighlight> | |||
== Using recordsets == | |||
If the number of records to be retrieved from DB is high, the 'get_records_xxx() functions above are far from optimal, because they load all the records into the memory via the returned array. Under those circumstances, it is highly recommended to use these get_recordset_xxx() functions instead. They return an iterator to iterate over all the found records and save a lot of memory. | |||
It is '''absolutely important''' to not forget to close the returned recordset iterator after using it. This is to free up a lot of resources in the RDBMS. | |||
A general way to iterate over records using the get_recordset_xxx() functions: | |||
<syntaxhighlight lang="php"> | |||
$rs = $DB->get_recordset(....); | |||
< | |||
$rs = $DB->get_recordset(....) | |||
foreach ($rs as $record) { | foreach ($rs as $record) { | ||
// Do whatever you want with this record | // Do whatever you want with this record | ||
} | } | ||
$rs->close(); | $rs->close(); | ||
</syntaxhighlight> | |||
Unlike get_record functions, you cannot check if <tt>$rs == true</tt> or <tt>!empty($rs)</tt> to determine if any records were found. Instead, if you need to, you can use: | |||
<syntaxhighlight lang="php"> | |||
</ | |||
Unlike get_record functions, you cannot | |||
< | |||
if ($rs->valid()) { | if ($rs->valid()) { | ||
// The recordset contains records. | // The recordset contains some records. | ||
} | } | ||
</ | </syntaxhighlight> | ||
=== get_recordset === | |||
===Delegated transactions== | Return a list of records as a moodle_recordset where all the given conditions are met. | ||
<syntaxhighlight lang="php">$DB->get_recordset($table, array $conditions=null, $sort='', $fields='*', $limitfrom=0, $limitnum=0)</syntaxhighlight> | |||
=== get_recordset_select === | |||
Return a list of records as a moodle_recordset where the given conditions are used in the WHERE clause. | |||
<syntaxhighlight lang="php">$DB->get_recordset_select($table, $select, array $params=null, $sort='', $fields='*', $limitfrom=0, $limitnum=0)</syntaxhighlight> | |||
=== get_recordset_sql === | |||
Return a list of records as a moodle_recordset using a custom SELECT query. | |||
<syntaxhighlight lang="php">$DB->get_recordset_sql($sql, array $params=null, $limitfrom=0, $limitnum=0)</syntaxhighlight> | |||
=== get_recordset_list === | |||
Return a list of records as a moodle_recordset where the given field matches one of the possible values. | |||
<syntaxhighlight lang="php">$DB->get_recordset_list($table, $field, array $values, $sort='', $fields='*', $limitfrom='', $limitnum='')</syntaxhighlight> | |||
== Delegated transactions == | |||
* Please note some databases do not support transactions (such as the MyISAM MySQL database engine), however all server administrators are strongly encouraged to migrate to databases that support transactions (such as the InnoDB MySQL database engine). | * Please note some databases do not support transactions (such as the MyISAM MySQL database engine), however all server administrators are strongly encouraged to migrate to databases that support transactions (such as the InnoDB MySQL database engine). | ||
* Previous versions supported only one level of transaction. Since Moodle 2.0, the DML layer emulates delegated transactions that allow nesting of transactions. | * Previous versions supported only one level of transaction. Since Moodle 2.0, the DML layer emulates delegated transactions that allow nesting of transactions. | ||
* Some subsystems (such as messaging) do not support transactions because it is not possible to rollback in external systems. | |||
* Some subsystems (such as messaging) do not support transactions because | |||
A transaction is started by: | A transaction is started by: | ||
< | <syntaxhighlight lang="php"> | ||
$transaction = $DB->start_delegated_transaction(); | $transaction = $DB->start_delegated_transaction(); | ||
</ | </syntaxhighlight> | ||
and finished by: | and finished by: | ||
< | <syntaxhighlight lang="php"> | ||
$transaction->allow_commit(); | $transaction->allow_commit(); | ||
</ | </syntaxhighlight> | ||
Usually a transaction is rolled back when an exception is thrown: | |||
Usually a transaction is rolled back when an exception is thrown | <syntaxhighlight lang="php">$transaction->rollback($ex);</syntaxhighlight> | ||
which must be used very carefully because it might break compatibility with databases that do not support transactions. Transactions cannot be used as part of expected code flow; they can be used only as an emergency protection of data consistency. | |||
See more details in [[DB layer 2.0 delegated transactions]] or MDL-20625. | See more details in [[DB layer 2.0 delegated transactions]] or MDL-20625. | ||
=== Example === | |||
<syntaxhighlight lang="php"> | |||
< | |||
global $DB; | global $DB; | ||
try { | try { | ||
$transaction = $DB->start_delegated_transaction(); | $transaction = $DB->start_delegated_transaction(); | ||
$DB->insert_record('foo', $object); | $DB->insert_record('foo', $object); | ||
$DB->insert_record('bar', $otherobject); | $DB->insert_record('bar', $otherobject); | ||
Line 388: | Line 219: | ||
// Assuming the both inserts work, we get to the following line. | // Assuming the both inserts work, we get to the following line. | ||
$transaction->allow_commit(); | $transaction->allow_commit(); | ||
} catch(Exception $e) { | } catch(Exception $e) { | ||
$transaction->rollback($e); | $transaction->rollback($e); | ||
} | } | ||
</ | </syntaxhighlight> | ||
== Cross-DB compatibility == | |||
== | Moodle supports several SQL servers (MySQL, PostgreSQL, MS-SQL and Oracle). Each of them have some specific syntax in certain cases. In order to achieve cross-db compatibility of the code, following functions must be used to generate the fragments of the query valid for the actual SQL server. | ||
=== sql_bitand === | |||
In order | Return the SQL text to be used in order to perform a bitwise AND operation between 2 integers. | ||
<syntaxhighlight lang="php">$DB->sql_bitand($int1, $int2)</syntaxhighlight> | |||
=== sql_bitnot === | |||
Return the SQL text to be used in order to perform a bitwise NOT operation on the given integer. | |||
<syntaxhighlight lang="php">$DB->sql_bitnot($int1)</syntaxhighlight> | |||
=== sql_bitor === | |||
Return the SQL text to be used in order to perform a bitwise OR operation between 2 integers. | |||
<syntaxhighlight lang="php">$DB->sql_bitor($int1, $int2)</syntaxhighlight> | |||
=== sql_bitxor === | |||
Return the SQL text to be used in order to perform a bitwise XOR operation between 2 integers. | |||
<syntaxhighlight lang="php">$DB->sql_bitxor($int1, $int2)</syntaxhighlight> | |||
=== sql_null_from_clause === | |||
Return an empty FROM clause required by some DBs in all SELECT statements. | |||
<syntaxhighlight lang="php">$DB->sql_null_from_clause()</syntaxhighlight> | |||
=== sql_ceil === | |||
Return the correct CEIL expression applied to the given fieldname. | |||
<syntaxhighlight lang="php">$DB->sql_ceil($fieldname)</syntaxhighlight> | |||
=== sql_equal === | |||
{{Moodle 3.2}}Return the query fragment to perform cross-db varchar comparisons when case-sensitiveness is important. | |||
<syntaxhighlight lang="php">$DB->sql_equal($fieldname, $param, $casesensitive = true, $accentsensitive = true, $notequal = false)</syntaxhighlight> | |||
=== sql_like === | |||
Return the query fragment to perform the LIKE comparison. | |||
<syntaxhighlight lang="php">$DB->sql_like($fieldname, $param, $casesensitive = true, $accentsensitive = true, $notlike = false, $escapechar = ' \\ ')</syntaxhighlight> | |||
Example: Searching for records partially matching the given hard-coded literal. | |||
<syntaxhighlight lang="php">$DB->get_records_sql('SELECT id,fullname FROM {course} WHERE '.$DB->sql_like('idnumber', ':idnum'), ['idnum' => 'DEMO-%']);</syntaxhighlight> | |||
See below if you need to compare with a value submitted by the user. | |||
=== sql_like_escape === | |||
Escape the value submitted by the user so that it can be used for partial comparison and the special characters like '_' or '%' behave as literal characters, not wildcards. | |||
<syntaxhighlight lang="php">$DB->sql_like_escape($text, $escapechar = '\\')</syntaxhighlight> | |||
Example: If you need to perform a partial comparison with a value that has been submitted by the user. | |||
<syntaxhighlight lang="php"> | |||
$search = required_param('search', PARAM_RAW); | |||
$DB->get_records_sql('SELECT id,fullname FROM {course} WHERE '.$DB->sql_like('fullname', ':fullname'), ['fullname' => '%'.$DB->sql_like_escape($search).'%']); | |||
</syntaxhighlight> | |||
=== sql_length === | |||
Return the query fragment to be used to calculate the length of the expression in characters. | |||
<syntaxhighlight lang="php">$DB->sql_length($fieldname)</syntaxhighlight> | |||
=== sql_modulo === | |||
Return the query fragment to be used to calculate the remainder after division. | |||
<syntaxhighlight lang="php">$DB->sql_modulo($int1, $int2)</syntaxhighlight> | |||
=== sql_position === | |||
Return the query fragment for searching a string for the location of a substring. If both needle and haystack use placeholders, you must use named placeholders. | |||
<syntaxhighlight lang="php">$DB->sql_position($needle, $haystack)</syntaxhighlight> | |||
=== sql_substr === | |||
Return the query fragment for extracting a substring from the given expression. | |||
<syntaxhighlight lang="php">$DB->sql_substr($expr, $start, $length=false)</syntaxhighlight> | |||
=== sql_cast_char2int === | |||
Return the query fragment to cast a CHAR column to INTEGER | |||
<syntaxhighlight lang="php">$DB->sql_cast_char2int($fieldname, $text=false)</syntaxhighlight> | |||
=== sql_cast_char2real === | |||
Return the query fragment to cast a CHAR column to REAL (float) number | |||
<syntaxhighlight lang="php">$DB->sql_cast_char2real($fieldname, $text=false)</syntaxhighlight> | |||
=== sql_compare_text === | |||
Return the query fragment to be used when comparing a TEXT (clob) column with a given string or a VARCHAR field (some RDBMs do not allow for direct comparison). | |||
<syntaxhighlight lang="php">$DB->sql_compare_text($fieldname, $numchars=32)</syntaxhighlight> | |||
Example: | |||
<syntaxhighlight lang="php"> | |||
$todogroups = $DB->get_records_sql('SELECT id FROM {group} WHERE ' . $DB->sql_compare_text('description') . ' = ' . $DB->sql_compare_text(':description'), ['description' => 'TODO']); | |||
</syntaxhighlight> | |||
=== sql_order_by_text === | |||
Return the query fragment to be used to get records ordered by a TEXT (clob) column. Note this affects the performance badly and should be avoided if possible. | |||
<syntaxhighlight lang="php">$DB->sql_order_by_text($fieldname, $numchars=32)</syntaxhighlight> | |||
=== sql_concat === | |||
Return the query fragment to concatenate all given paremeters into one string. | |||
</ | <syntaxhighlight lang="php">$DB->sql_concat(...)</syntaxhighlight> | ||
There is a gotcha if you are trying to concat fields which may be null which result in the entire result being null: | |||
=== | <syntaxhighlight lang="php">$DB->sql_concat('requiredfield', 'optionalfield'); // BAD!</syntaxhighlight> | ||
You must cast or coalesce every nullable argument eg: | |||
<syntaxhighlight lang="php">$DB->sql_concat('requiredfield', "COALESCE(optionalfield, '')"); // Good.</syntaxhighlight> | |||
< | === sql_group_concat === | ||
$DB-> | {{Moodle_3.11}} | ||
</ | Return SQL for performing group concatenation on given field/expression. | ||
<syntaxhighlight lang="php">$DB->sql_group_concat(string $field, string $separator = ', ', string $sort = '')</syntaxhighlight> | |||
=== sql_concat_join === | |||
== | Return the query fragment to concatenate all given elements into one string using the given separator. | ||
<syntaxhighlight lang="php">$DB->sql_concat_join($separator="' '", $elements=array())</syntaxhighlight> | |||
=== | === sql_fullname === | ||
Return the query fragment to concatenate the given $firstname and $lastname | |||
<syntaxhighlight lang="php">$DB->sql_fullname($first='firstname', $last='lastname')</syntaxhighlight> | |||
=== sql_isempty === | |||
Return the query fragment to check if the field is empty | |||
<syntaxhighlight lang="php">$DB->sql_isempty($tablename, $fieldname, $nullablefield, $textfield)</syntaxhighlight> | |||
=== sql_isnotempty === | |||
Return the query fragment to check if the field is not empty | |||
<syntaxhighlight lang="php">$DB->sql_isnotempty($tablename, $fieldname, $nullablefield, $textfield)</syntaxhighlight> | |||
=== get_in_or_equal === | |||
Return the query fragment to check if a value is IN the given list of items (with a fallback to plain equal comparison if there is just one item) | |||
<syntaxhighlight lang="php">$DB->get_in_or_equal($items, $type=SQL_PARAMS_QM, $prefix='param', $equal=true, $onemptyitems=false)</syntaxhighlight> | |||
Example: | |||
<syntaxhighlight lang="php"> | |||
$statuses = ['todo', 'open', 'inprogress', 'intesting']; | |||
list($insql, $inparams) = $DB->get_in_or_equal($statuses); | |||
$sql = "SELECT * FROM {bugtracker_issues} WHERE status $insql"; | |||
$bugs = $DB->get_records_sql($sql, $inparams); | |||
</syntaxhighlight> | |||
An example using named params: | |||
<syntaxhighlight lang="php"> | |||
... | |||
list($insql, $params) = $DB->get_in_or_equal($contexts, SQL_PARAMS_NAMED, 'ctx'); | |||
$contextsql = "AND rc.contextid $insql"; | |||
... | |||
</syntaxhighlight> | |||
=== sql_regex_supported === | |||
Does the current database driver support regex syntax when searching? | |||
<syntaxhighlight lang="php">$DB->sql_regex_supported()</syntaxhighlight> | |||
=== sql_regex === | |||
Return the query fragment to perform a regex search. | |||
<syntaxhighlight lang="php">$DB->sql_regex($positivematch = true, $casesensitive = false)</syntaxhighlight> | |||
Example: Searching for Page module instances containing links. | |||
<syntaxhighlight lang="php"> | |||
if ($DB->sql_regex_supported()) { | |||
$select = 'content ' . $DB->sql_regex() . ' :pattern'; | |||
$params = ['pattern' => "(src|data)\ *=\ *[\\\"\']https?://"] | |||
} else { | |||
$select = $DB->sql_like('content', ':pattern', false); | |||
$params = ['pattern' => '%=%http%://%']; | |||
} | |||
$pages = $DB->get_records_select('page', $select, $params, 'course', 'id, course, name'); | |||
</syntaxhighlight> | |||
=== sql_intersect === | |||
{{Moodle 2.8}}Return the query fragment that allows to find intersection of two or more queries | |||
<syntaxhighlight lang="php">$DB->sql_intersect($selects, $fields)</syntaxhighlight> | |||
== Debugging == | |||
=== set_debug === | |||
You can enable a debugging mode to make $DB output the SQL of every executed query, along with some timing information. This can be useful when debugging your code. Obviously, all such calls should be removed before code is submitted for integration. | |||
<syntaxhighlight lang="php">$DB->set_debug(true)</syntaxhighlight> | |||
== Special cases == | |||
=== get_course === | |||
From Moodle 2.5.1 onwards, you should use the get_course function instead of using get_record('course', ...) if you want to get a course record based on its ID, especially if there is a significant possibility that the course being retrieved is either the current course for the page, or the site course. Those two course records have probably already been loaded, and using this function will save a database query. | From Moodle 2.5.1 onwards, you should use the get_course function instead of using get_record('course', ...) if you want to get a course record based on its ID, especially if there is a significant possibility that the course being retrieved is either the current course for the page, or the site course. Those two course records have probably already been loaded, and using this function will save a database query. | ||
Additionally, the code is shorter and easier to read. | |||
=== get_courses === | |||
===get_courses=== | |||
If you want to get all the current courses in your Moodle, use get_courses() without parameter: | If you want to get all the current courses in your Moodle, use get_courses() without parameter: | ||
$courses = get_courses(); | $courses = get_courses(); | ||
== See also == | |||
==See also== | |||
* [[SQL coding style]] | * [[SQL coding style]] | ||
* [[Core APIs]] | * [[Core APIs]] | ||
Line 503: | Line 372: | ||
* [[DB layer 2.0 migration docs|DB layer 2.0 migration docs]]: Information about how to modify your code to work with the new Moodle 2.0 DB layer. | * [[DB layer 2.0 migration docs|DB layer 2.0 migration docs]]: Information about how to modify your code to work with the new Moodle 2.0 DB layer. | ||
* [[DTL functions|DTL functions]]: Exporting, importing and moving of data stored in SQL databases | * [[DTL functions|DTL functions]]: Exporting, importing and moving of data stored in SQL databases | ||
[[Category:DB]] | [[Category:DB]] | ||
[[Category:XMLDB]] | [[Category:XMLDB]] | ||
[[Category:API]] | [[Category:API]] |
Latest revision as of 14:05, 13 June 2022
Important:
This content of this page has been updated and migrated to the new Moodle Developer Resources. The information contained on the page should no longer be seen up-to-date. Why not view this page on the new site and help us to migrate more content to the new site! |
Moodle 2.0
This page describes the functions available to access data in the Moodle database. You should exclusively use these functions in order to retrieve or modify database content because these functions provide a high level of abstraction and guarantee that your database manipulation will work against different RDBMSes.
Where possible, tricks and examples will be documented here in order to make developers' lives a bit easier. Of course, feel free to clarify, complete and add more information to this documentation. It will be welcome, absolutely!
General concepts
DB object
- The data manipulation API is exposed via public methods of the $DB object.
- Moodle core takes care of setting up the connection to the database according to values specified in the main config.php file.
- The $DB global object is an instance of the moodle_database class. It is instantiated automatically during the bootstrap setup, i.e. as a part of including the main config.php file.
- The DB object is available in the global scope right after including the config.php file:
<?php
require(__DIR__.'/../../../config.php');
// You can access the database via the $DB method calls here.
- To make the DB object available in your local scope, such as within a function:
<?php
defined('MOODLE_INTERNAL') || die();
function my_function_making_use_of_database() {
global $DB;
// You can access the database via the $DB method calls here.
}
Table prefix
- Most Moodle installations use a prefix for all the database tables, such as mdl_. This prefix is NOT to be used in the code in the code itself.
- All the $table parameters in the functions are meant to be the table name without prefixes:
$user = $DB->get_record('user', ['id' => '1']);
- In custom SQL queries, table names must be enclosed between curly braces. They will be then automatically converted to the real prefixed table name. There is no need to access $CFG->prefix
$user = $DB->get_record_sql('SELECT COUNT(*) FROM {user} WHERE deleted = 1 OR suspended = 1;');
Conditions
- All the $conditions parameters in the functions are arrays of fieldname=>fieldvalue elements.
- They all must be fulfilled - i.e. logical AND is used to populate the actual WHERE statement.
$user = $DB->get_record('user', ['firstname' => 'Martin', 'lastname' => 'Dougiamas']);
Placeholders
- All the $params parameters in the functions are arrays of values used to fill placeholders in SQL statements.
- Placeholders help to avoid problems with SQL-injection and/or invalid quotes in SQL queries. They facilitate secure and cross-db compatible code.
- Two types of placeholders are supported - question marks (SQL_PARAMS_QM) and named placeholders (SQL_PARAMS_NAMED).
- Named params must be unique even if the value passed is the same. If you need to pass the same value multiple times, you need to have multiple distinct named parameters.
// Example of using question mark placeholders.
$DB->get_record_sql('SELECT * FROM {user} WHERE firstname = ? AND lastname = ?',
['Martin', 'Dougiamas']);
// Example of using named placeholders.
$DB->get_record_sql('SELECT * FROM {user} WHERE firstname = :firstname AND lastname = :lastname',
['firstname' => 'Martin', 'lastname' => 'Dougiamas']);
Strictness
Some methods accept the $strictness parameter affecting the method behaviour. Supported modes are specified using the constants:
- MUST_EXIST - In this mode, the requested record must exist and must be unique. An exception will be thrown if no record is found or multiple matching records are found.
- IGNORE_MISSING - In this mode, a missing record is not an error. False boolean is returned if the requested record is not found. If more records are found, a debugging message is displayed.
- IGNORE_MULTIPLE - This is not a recommended mode. The function will silently ignore multiple records found and will return just the first one of them.
Getting a single record
get_record
Return a single database record as an object where all the given conditions are met.
$DB->get_record($table, array $conditions, $fields='*', $strictness=IGNORE_MISSING)
get_record_select
Return a single database record as an object where the given conditions are used in the WHERE clause.
$DB->get_record_select($table, $select, array $params=null, $fields='*', $strictness=IGNORE_MISSING)
get_record_sql
Return a single database record as an object using a custom SELECT query.
$DB->get_record_sql($sql, array $params=null, $strictness=IGNORE_MISSING)
Getting a hashed array of records
Each of the following methods return an array of objects. The array is indexed by the first column of the fields returned by the query. To assure consistency, it is a good practice to ensure that your query include an "id column" as the first field. When designing custom tables, make id their first column and primary key.
get_records
Return a list of records as an array of objects where all the given conditions are met.
$DB->get_records($table, array $conditions=null, $sort='', $fields='*', $limitfrom=0, $limitnum=0)
get_records_select
Return a list of records as an array of objects where the given conditions are used in the WHERE clause.
$DB->get_records_select($table, $select, array $params=null, $sort='', $fields='*', $limitfrom=0, $limitnum=0)
$fields is a comma separated list of fields to return (optional, by default all fields are returned).
get_records_sql
Return a list of records as an array of objects using a custom SELECT query.
$DB->get_records_sql($sql, array $params=null, $limitfrom=0, $limitnum=0)
get_records_list
Return a list of records as an array of objects where the given field matches one of the possible values.
$DB->get_records_list($table, $field, array $values, $sort='', $fields='*', $limitfrom='', $limitnum='')
Getting data as key/value pairs in an associative array
Return the first two columns from a list of records as an associative array where all the given conditions are met.
$DB->get_records_menu($table, array $conditions=null, $sort='', $fields='*', $limitfrom=0, $limitnum=0)
Return the first two columns from a list of records as an associative array where the given conditions are used in the WHERE clause.
$DB->get_records_select_menu($table, $select, array $params=null, $sort='', $fields='*', $limitfrom=0, $limitnum=0)
Return the first two columns from a number of records as an associative array using a custom SELECT query.
$DB->get_records_sql_menu($sql, array $params=null, $limitfrom=0, $limitnum=0)
Counting records that match the given criteria
count_records
Count the records in a table where all the given conditions are met.
$DB->count_records($table, array $conditions=null)
count_records_select
Count the records in a table where the given conditions are used in the WHERE clause.
$DB->count_records_select($table, $select, array $params=null, $countitem="COUNT('x')")
count_records_sql
Counting the records using a custom SELECT COUNT(...) query.
$DB->count_records_sql($sql, array $params=null)
Checking if a given record exists
record_exists
Test whether a record exists in a table where all the given conditions are met.
$DB->record_exists($table, array $conditions=null)
record_exists_select
Test whether any records exists in a table where the given conditions are used in the WHERE clause.
$DB->record_exists_select($table, $select, array $params=null)
record_exists_sql
Test whether the given SELECT query would return any record.
$DB->record_exists_sql($sql, array $params=null)
Getting a particular field value from one record
get_field
Get a single field value from a table record where all the given conditions are met.
$DB->get_field($table, $return, array $conditions, $strictness=IGNORE_MISSING)
get_field_select
Get a single field value from a table record where the given conditions are used in the WHERE clause.
$DB->get_field_select($table, $return, $select, array $params=null, $strictness=IGNORE_MISSING)
get_field_sql
Get a single field value (first field) using a custom SELECT query.
$DB->get_field_sql($sql, array $params=null, $strictness=IGNORE_MISSING)
Getting field values from multiple records
get_fieldset_select
Return values of the given field as an array where the given conditions are used in the WHERE clause.
$DB->get_fieldset_select($table, $return, $select, array $params=null)
get_fieldset_sql
Return values of the first column as an array using a custom SELECT field FROM ... query.
$DB->get_fieldset_sql($sql, array $params=null)
Setting a field value
set_field
Set a single field in every record where all the given conditions are met.
$DB->set_field($table, $newfield, $newvalue, array $conditions=null)
set_field_select
Set a single field in every table record where the given conditions are used in the WHERE clause.
$DB->set_field_select($table, $newfield, $newvalue, $select, array $params=null)
Deleting records
delete_records
Delete records from the table where all the given conditions are met.
$DB->delete_records($table, array $conditions=null)
delete_records_select
Delete records from the table where the given conditions are used in the WHERE clause.
$DB->delete_records_select($table, $select, array $params=null)
Inserting records
insert_record
Insert the given data object into the table and return the "id" of the newly created record.
$DB->insert_record($table, $dataobject, $returnid=true, $bulk=false)
insert_records
Moodle 2.7 Insert multiple records into the table as fast as possible. Records are inserted in the given order, but the operation is not atomic. Use transactions if necessary.
$DB->insert_records($table, $dataobjects)
insert_record_raw
For rare cases when you also need to specify the ID of the record to be inserted.
Updating records
update_record
Update a record in the table. The data object must have the property "id" set.
$DB->update_record($table, $dataobject, $bulk=false)
Executing a custom query
execute
- If you need to perform a complex update using arbitrary SQL, you can use the low level "execute" method. Only use this when no specialised method exists.
- Do NOT use this to make changes in database structure, use database_manager methods instead!
$DB->execute($sql, array $params=null)
Using recordsets
If the number of records to be retrieved from DB is high, the 'get_records_xxx() functions above are far from optimal, because they load all the records into the memory via the returned array. Under those circumstances, it is highly recommended to use these get_recordset_xxx() functions instead. They return an iterator to iterate over all the found records and save a lot of memory.
It is absolutely important to not forget to close the returned recordset iterator after using it. This is to free up a lot of resources in the RDBMS.
A general way to iterate over records using the get_recordset_xxx() functions:
$rs = $DB->get_recordset(....);
foreach ($rs as $record) {
// Do whatever you want with this record
}
$rs->close();
Unlike get_record functions, you cannot check if $rs == true or !empty($rs) to determine if any records were found. Instead, if you need to, you can use:
if ($rs->valid()) {
// The recordset contains some records.
}
get_recordset
Return a list of records as a moodle_recordset where all the given conditions are met.
$DB->get_recordset($table, array $conditions=null, $sort='', $fields='*', $limitfrom=0, $limitnum=0)
get_recordset_select
Return a list of records as a moodle_recordset where the given conditions are used in the WHERE clause.
$DB->get_recordset_select($table, $select, array $params=null, $sort='', $fields='*', $limitfrom=0, $limitnum=0)
get_recordset_sql
Return a list of records as a moodle_recordset using a custom SELECT query.
$DB->get_recordset_sql($sql, array $params=null, $limitfrom=0, $limitnum=0)
get_recordset_list
Return a list of records as a moodle_recordset where the given field matches one of the possible values.
$DB->get_recordset_list($table, $field, array $values, $sort='', $fields='*', $limitfrom='', $limitnum='')
Delegated transactions
- Please note some databases do not support transactions (such as the MyISAM MySQL database engine), however all server administrators are strongly encouraged to migrate to databases that support transactions (such as the InnoDB MySQL database engine).
- Previous versions supported only one level of transaction. Since Moodle 2.0, the DML layer emulates delegated transactions that allow nesting of transactions.
- Some subsystems (such as messaging) do not support transactions because it is not possible to rollback in external systems.
A transaction is started by:
$transaction = $DB->start_delegated_transaction();
and finished by:
$transaction->allow_commit();
Usually a transaction is rolled back when an exception is thrown:
$transaction->rollback($ex);
which must be used very carefully because it might break compatibility with databases that do not support transactions. Transactions cannot be used as part of expected code flow; they can be used only as an emergency protection of data consistency.
See more details in DB layer 2.0 delegated transactions or MDL-20625.
Example
global $DB;
try {
$transaction = $DB->start_delegated_transaction();
$DB->insert_record('foo', $object);
$DB->insert_record('bar', $otherobject);
// Assuming the both inserts work, we get to the following line.
$transaction->allow_commit();
} catch(Exception $e) {
$transaction->rollback($e);
}
Cross-DB compatibility
Moodle supports several SQL servers (MySQL, PostgreSQL, MS-SQL and Oracle). Each of them have some specific syntax in certain cases. In order to achieve cross-db compatibility of the code, following functions must be used to generate the fragments of the query valid for the actual SQL server.
sql_bitand
Return the SQL text to be used in order to perform a bitwise AND operation between 2 integers.
$DB->sql_bitand($int1, $int2)
sql_bitnot
Return the SQL text to be used in order to perform a bitwise NOT operation on the given integer.
$DB->sql_bitnot($int1)
sql_bitor
Return the SQL text to be used in order to perform a bitwise OR operation between 2 integers.
$DB->sql_bitor($int1, $int2)
sql_bitxor
Return the SQL text to be used in order to perform a bitwise XOR operation between 2 integers.
$DB->sql_bitxor($int1, $int2)
sql_null_from_clause
Return an empty FROM clause required by some DBs in all SELECT statements.
$DB->sql_null_from_clause()
sql_ceil
Return the correct CEIL expression applied to the given fieldname.
$DB->sql_ceil($fieldname)
sql_equal
Moodle 3.2 Return the query fragment to perform cross-db varchar comparisons when case-sensitiveness is important.
$DB->sql_equal($fieldname, $param, $casesensitive = true, $accentsensitive = true, $notequal = false)
sql_like
Return the query fragment to perform the LIKE comparison.
$DB->sql_like($fieldname, $param, $casesensitive = true, $accentsensitive = true, $notlike = false, $escapechar = ' \\ ')
Example: Searching for records partially matching the given hard-coded literal.
$DB->get_records_sql('SELECT id,fullname FROM {course} WHERE '.$DB->sql_like('idnumber', ':idnum'), ['idnum' => 'DEMO-%']);
See below if you need to compare with a value submitted by the user.
sql_like_escape
Escape the value submitted by the user so that it can be used for partial comparison and the special characters like '_' or '%' behave as literal characters, not wildcards.
$DB->sql_like_escape($text, $escapechar = '\\')
Example: If you need to perform a partial comparison with a value that has been submitted by the user.
$search = required_param('search', PARAM_RAW);
$DB->get_records_sql('SELECT id,fullname FROM {course} WHERE '.$DB->sql_like('fullname', ':fullname'), ['fullname' => '%'.$DB->sql_like_escape($search).'%']);
sql_length
Return the query fragment to be used to calculate the length of the expression in characters.
$DB->sql_length($fieldname)
sql_modulo
Return the query fragment to be used to calculate the remainder after division.
$DB->sql_modulo($int1, $int2)
sql_position
Return the query fragment for searching a string for the location of a substring. If both needle and haystack use placeholders, you must use named placeholders.
$DB->sql_position($needle, $haystack)
sql_substr
Return the query fragment for extracting a substring from the given expression.
$DB->sql_substr($expr, $start, $length=false)
sql_cast_char2int
Return the query fragment to cast a CHAR column to INTEGER
$DB->sql_cast_char2int($fieldname, $text=false)
sql_cast_char2real
Return the query fragment to cast a CHAR column to REAL (float) number
$DB->sql_cast_char2real($fieldname, $text=false)
sql_compare_text
Return the query fragment to be used when comparing a TEXT (clob) column with a given string or a VARCHAR field (some RDBMs do not allow for direct comparison).
$DB->sql_compare_text($fieldname, $numchars=32)
Example:
$todogroups = $DB->get_records_sql('SELECT id FROM {group} WHERE ' . $DB->sql_compare_text('description') . ' = ' . $DB->sql_compare_text(':description'), ['description' => 'TODO']);
sql_order_by_text
Return the query fragment to be used to get records ordered by a TEXT (clob) column. Note this affects the performance badly and should be avoided if possible.
$DB->sql_order_by_text($fieldname, $numchars=32)
sql_concat
Return the query fragment to concatenate all given paremeters into one string.
$DB->sql_concat(...)
There is a gotcha if you are trying to concat fields which may be null which result in the entire result being null:
$DB->sql_concat('requiredfield', 'optionalfield'); // BAD!
You must cast or coalesce every nullable argument eg:
$DB->sql_concat('requiredfield', "COALESCE(optionalfield, '')"); // Good.
sql_group_concat
Return SQL for performing group concatenation on given field/expression.
$DB->sql_group_concat(string $field, string $separator = ', ', string $sort = '')
sql_concat_join
Return the query fragment to concatenate all given elements into one string using the given separator.
$DB->sql_concat_join($separator="' '", $elements=array())
sql_fullname
Return the query fragment to concatenate the given $firstname and $lastname
$DB->sql_fullname($first='firstname', $last='lastname')
sql_isempty
Return the query fragment to check if the field is empty
$DB->sql_isempty($tablename, $fieldname, $nullablefield, $textfield)
sql_isnotempty
Return the query fragment to check if the field is not empty
$DB->sql_isnotempty($tablename, $fieldname, $nullablefield, $textfield)
get_in_or_equal
Return the query fragment to check if a value is IN the given list of items (with a fallback to plain equal comparison if there is just one item)
$DB->get_in_or_equal($items, $type=SQL_PARAMS_QM, $prefix='param', $equal=true, $onemptyitems=false)
Example:
$statuses = ['todo', 'open', 'inprogress', 'intesting'];
list($insql, $inparams) = $DB->get_in_or_equal($statuses);
$sql = "SELECT * FROM {bugtracker_issues} WHERE status $insql";
$bugs = $DB->get_records_sql($sql, $inparams);
An example using named params:
...
list($insql, $params) = $DB->get_in_or_equal($contexts, SQL_PARAMS_NAMED, 'ctx');
$contextsql = "AND rc.contextid $insql";
...
sql_regex_supported
Does the current database driver support regex syntax when searching?
$DB->sql_regex_supported()
sql_regex
Return the query fragment to perform a regex search.
$DB->sql_regex($positivematch = true, $casesensitive = false)
Example: Searching for Page module instances containing links.
if ($DB->sql_regex_supported()) {
$select = 'content ' . $DB->sql_regex() . ' :pattern';
$params = ['pattern' => "(src|data)\ *=\ *[\\\"\']https?://"]
} else {
$select = $DB->sql_like('content', ':pattern', false);
$params = ['pattern' => '%=%http%://%'];
}
$pages = $DB->get_records_select('page', $select, $params, 'course', 'id, course, name');
sql_intersect
Moodle 2.8 Return the query fragment that allows to find intersection of two or more queries
$DB->sql_intersect($selects, $fields)
Debugging
set_debug
You can enable a debugging mode to make $DB output the SQL of every executed query, along with some timing information. This can be useful when debugging your code. Obviously, all such calls should be removed before code is submitted for integration.
$DB->set_debug(true)
Special cases
get_course
From Moodle 2.5.1 onwards, you should use the get_course function instead of using get_record('course', ...) if you want to get a course record based on its ID, especially if there is a significant possibility that the course being retrieved is either the current course for the page, or the site course. Those two course records have probably already been loaded, and using this function will save a database query.
Additionally, the code is shorter and easier to read.
get_courses
If you want to get all the current courses in your Moodle, use get_courses() without parameter:
$courses = get_courses();
See also
- SQL coding style
- Core APIs
- DML exceptions: New DML code is throwing exceptions instead of returning false if anything goes wrong
- DML drivers: Database drivers for new DML layer
- DML functions - pre 2.0: (deprecated!) For information valid before Moodle 2.0.
- DDL functions: Where all the functions used to handle DB objects (DDL) are defined.
- DB layer 2.0 examples: To see some code examples using various DML functions.
- DB layer 2.0 migration docs: Information about how to modify your code to work with the new Moodle 2.0 DB layer.
- DTL functions: Exporting, importing and moving of data stored in SQL databases