mirror of
https://github.com/moodle/moodle.git
synced 2025-01-19 06:18:28 +01:00
MDL-75170 dml: add sql_order_by_null method
Standardises return patterns of null values across database types to keep with sorting nullsto the top when ascending, and to the bottom when descending
This commit is contained in:
parent
8f492a836a
commit
70dfee9e23
@ -2354,6 +2354,19 @@ abstract class moodle_database {
|
||||
return $fieldname;
|
||||
}
|
||||
|
||||
/**
|
||||
* Returns the SQL text to be used to order by columns, standardising the return
|
||||
* pattern of null values across database types to sort nulls first when ascending
|
||||
* and last when descending.
|
||||
*
|
||||
* @param string $fieldname The name of the field we need to sort by.
|
||||
* @param int $sort An order to sort the results in.
|
||||
* @return string The piece of SQL code to be used in your statement.
|
||||
*/
|
||||
public function sql_order_by_null(string $fieldname, int $sort = SORT_ASC): string {
|
||||
return $fieldname . ' ' . ($sort == SORT_ASC ? 'ASC' : 'DESC');
|
||||
}
|
||||
|
||||
/**
|
||||
* Returns the SQL text to be used to calculate the length in characters of one expression.
|
||||
* @param string $fieldname The fieldname/expression to calculate its length in characters.
|
||||
|
@ -1653,6 +1653,19 @@ class oci_native_moodle_database extends moodle_database {
|
||||
return "LISTAGG({$field}, '{$separator}') WITHIN GROUP (ORDER BY {$fieldsort})";
|
||||
}
|
||||
|
||||
/**
|
||||
* Returns the SQL text to be used to order by columns, standardising the return
|
||||
* pattern of null values across database types to sort nulls first when ascending
|
||||
* and last when descending.
|
||||
*
|
||||
* @param string $fieldname The name of the field we need to sort by.
|
||||
* @param int $sort An order to sort the results in.
|
||||
* @return string The piece of SQL code to be used in your statement.
|
||||
*/
|
||||
public function sql_order_by_null(string $fieldname, int $sort = SORT_ASC): string {
|
||||
return parent::sql_order_by_null($fieldname, $sort) . ' NULLS ' . ($sort == SORT_ASC ? 'FIRST' : 'LAST');
|
||||
}
|
||||
|
||||
/**
|
||||
* Constructs 'IN()' or '=' sql fragment
|
||||
*
|
||||
|
@ -1525,6 +1525,19 @@ class pgsql_native_moodle_database extends moodle_database {
|
||||
return "STRING_AGG(" . $this->sql_cast_to_char($field) . ", '{$separator}' {$fieldsort})";
|
||||
}
|
||||
|
||||
/**
|
||||
* Returns the SQL text to be used to order by columns, standardising the return
|
||||
* pattern of null values across database types to sort nulls first when ascending
|
||||
* and last when descending.
|
||||
*
|
||||
* @param string $fieldname The name of the field we need to sort by.
|
||||
* @param int $sort An order to sort the results in.
|
||||
* @return string The piece of SQL code to be used in your statement.
|
||||
*/
|
||||
public function sql_order_by_null(string $fieldname, int $sort = SORT_ASC): string {
|
||||
return parent::sql_order_by_null($fieldname, $sort) . ' NULLS ' . ($sort == SORT_ASC ? 'FIRST' : 'LAST');
|
||||
}
|
||||
|
||||
public function sql_regex_supported() {
|
||||
return true;
|
||||
}
|
||||
|
@ -4596,6 +4596,41 @@ EOD;
|
||||
$this->assertEquals(2, $last->id);
|
||||
}
|
||||
|
||||
/**
|
||||
* Test DML libraries sql_order_by_null method
|
||||
*/
|
||||
public function test_sql_order_by_null(): void {
|
||||
$DB = $this->tdb;
|
||||
$dbman = $DB->get_manager();
|
||||
|
||||
$table = $this->get_test_table();
|
||||
$tablename = $table->getName();
|
||||
|
||||
$table->add_field('id', XMLDB_TYPE_INTEGER, '10', null, XMLDB_NOTNULL, XMLDB_SEQUENCE, null);
|
||||
$table->add_field('name', XMLDB_TYPE_CHAR, '255', null, null, null, null);
|
||||
$table->add_key('primary', XMLDB_KEY_PRIMARY, array('id'));
|
||||
$dbman->create_table($table);
|
||||
|
||||
$DB->insert_record($tablename, array('name' => 'aaaa'));
|
||||
$DB->insert_record($tablename, array('name' => 'bbbb'));
|
||||
$DB->insert_record($tablename, array('name' => ''));
|
||||
$DB->insert_record($tablename, array('name' => null));
|
||||
|
||||
$sql = "SELECT * FROM {{$tablename}} ORDER BY ".$DB->sql_order_by_null('name');
|
||||
$records = $DB->get_records_sql($sql);
|
||||
$this->assertEquals(null, array_shift($records)->name);
|
||||
$this->assertEquals('', array_shift($records)->name);
|
||||
$this->assertEquals('aaaa', array_shift($records)->name);
|
||||
$this->assertEquals('bbbb', array_shift($records)->name);
|
||||
|
||||
$sql = "SELECT * FROM {{$tablename}} ORDER BY ".$DB->sql_order_by_null('name', SORT_DESC);
|
||||
$records = $DB->get_records_sql($sql);
|
||||
$this->assertEquals('bbbb', array_shift($records)->name);
|
||||
$this->assertEquals('aaaa', array_shift($records)->name);
|
||||
$this->assertEquals('', array_shift($records)->name);
|
||||
$this->assertEquals(null, array_shift($records)->name);
|
||||
}
|
||||
|
||||
public function test_sql_substring() {
|
||||
$DB = $this->tdb;
|
||||
$dbman = $DB->get_manager();
|
||||
|
@ -41,6 +41,7 @@ information provided here is intended especially for developers.
|
||||
implemented by adhoc tasks. For backwards compatibility, a default implementation has been added to `\core\task\adhoc_task` to
|
||||
return the class name.
|
||||
* The function get_module_metadata() has been finally deprecated and can not be used anymore.
|
||||
* New DML driver method `$DB->sql_order_by_null` for sorting nulls sort nulls first when ascending and last when descending.
|
||||
|
||||
=== 4.0 ===
|
||||
|
||||
|
Loading…
x
Reference in New Issue
Block a user