MDL-52817 dml: implement driver methods for SQL group concatenation.

This commit is contained in:
Paul Holden 2020-11-11 22:38:34 +00:00
parent a93828a188
commit b2d19cc29f
9 changed files with 226 additions and 0 deletions

View File

@ -2297,6 +2297,16 @@ abstract class moodle_database {
*/
public abstract function sql_concat_join($separator="' '", $elements=array());
/**
* Return SQL for performing group concatenation on given field/expression
*
* @param string $field Table field or SQL expression to be concatenated
* @param string $separator The separator desired between each concatetated field
* @param string $sort Ordering of the concatenated field
* @return string
*/
public abstract function sql_group_concat(string $field, string $separator = ', ', string $sort = ''): string;
/**
* Returns the proper SQL (for the dbms in use) to concatenate $firstname and $lastname
*

View File

@ -1823,6 +1823,19 @@ class mysqli_native_moodle_database extends moodle_database {
return "CONCAT_WS($separator, $s)";
}
/**
* Return SQL for performing group concatenation on given field/expression
*
* @param string $field
* @param string $separator
* @param string $sort
* @return string
*/
public function sql_group_concat(string $field, string $separator = ', ', string $sort = ''): string {
$fieldsort = $sort ? "ORDER BY {$sort}" : '';
return "GROUP_CONCAT({$field} {$fieldsort} SEPARATOR '{$separator}')";
}
/**
* Returns the SQL text to be used to calculate the length in characters of one expression.
* @param string fieldname or expression to calculate its length in characters.

View File

@ -1615,6 +1615,19 @@ class oci_native_moodle_database extends moodle_database {
return " MOODLELIB.UNDO_MEGA_HACK($s) ";
}
/**
* Return SQL for performing group concatenation on given field/expression
*
* @param string $field
* @param string $separator
* @param string $sort
* @return string
*/
public function sql_group_concat(string $field, string $separator = ', ', string $sort = ''): string {
$fieldsort = $sort ?: '1';
return "LISTAGG({$field}, '{$separator}') WITHIN GROUP (ORDER BY {$fieldsort})";
}
/**
* Constructs 'IN()' or '=' sql fragment
*

View File

@ -542,6 +542,18 @@ abstract class pdo_moodle_database extends moodle_database {
print_error('TODO');
}
/**
* Return SQL for performing group concatenation on given field/expression
*
* @param string $field
* @param string $separator
* @param string $sort
* @return string
*/
public function sql_group_concat(string $field, string $separator = ', ', string $sort = ''): string {
return ''; // TODO.
}
protected function begin_transaction() {
$this->query_start('', NULL, SQL_QUERY_AUX);
try {

View File

@ -1452,6 +1452,19 @@ class pgsql_native_moodle_database extends moodle_database {
return " $s ";
}
/**
* Return SQL for performing group concatenation on given field/expression
*
* @param string $field
* @param string $separator
* @param string $sort
* @return string
*/
public function sql_group_concat(string $field, string $separator = ', ', string $sort = ''): string {
$fieldsort = $sort ? "ORDER BY {$sort}" : '';
return "STRING_AGG(CAST({$field} AS VARCHAR), '{$separator}' {$fieldsort})";
}
public function sql_regex_supported() {
return true;
}

View File

@ -1429,6 +1429,19 @@ class sqlsrv_native_moodle_database extends moodle_database {
return call_user_func_array(array($this, 'sql_concat'), $elements);
}
/**
* Return SQL for performing group concatenation on given field/expression
*
* @param string $field
* @param string $separator
* @param string $sort
* @return string
*/
public function sql_group_concat(string $field, string $separator = ', ', string $sort = ''): string {
$fieldsort = $sort ? "WITHIN GROUP (ORDER BY {$sort})" : '';
return "STRING_AGG({$field}, '{$separator}') {$fieldsort}";
}
public function sql_isempty($tablename, $fieldname, $nullablefield, $textfield) {
if ($textfield) {
return ' ('.$this->sql_compare_text($fieldname)." = '') ";

View File

@ -4295,6 +4295,141 @@ EOD;
$this->assertEquals($expected, $result);
}
/**
* Test DML libraries sql_group_contact method
*/
public function test_group_concat(): void {
$DB = $this->tdb;
$dbman = $DB->get_manager();
$table = $this->get_test_table();
$table->add_field('id', XMLDB_TYPE_INTEGER, '10', null, XMLDB_NOTNULL, XMLDB_SEQUENCE, null);
$table->add_field('intfield', XMLDB_TYPE_INTEGER, '10', null, XMLDB_NOTNULL, null, '0');
$table->add_field('charfield', XMLDB_TYPE_CHAR, '255', null, XMLDB_NOTNULL, null, null);
$table->add_key('primary', XMLDB_KEY_PRIMARY, ['id']);
$dbman->create_table($table);
$tablename = $table->getName();
$DB->insert_record($tablename, (object) ['intfield' => 10, 'charfield' => 'uno']);
$DB->insert_record($tablename, (object) ['intfield' => 20, 'charfield' => 'dos']);
$DB->insert_record($tablename, (object) ['intfield' => 20, 'charfield' => 'tres']);
$DB->insert_record($tablename, (object) ['intfield' => 30, 'charfield' => 'tres']);
// Test charfield => concatenated intfield ASC.
$fieldsql = $DB->sql_group_concat('intfield', ', ', 'intfield ASC');
$sql = "SELECT charfield, {$fieldsql} AS falias
FROM {{$tablename}}
GROUP BY charfield";
$this->assertEquals([
'dos' => '20',
'tres' => '20, 30',
'uno' => '10',
], $DB->get_records_sql_menu($sql));
// Test charfield => concatenated intfield DESC.
$fieldsql = $DB->sql_group_concat('intfield', ', ', 'intfield DESC');
$sql = "SELECT charfield, {$fieldsql} AS falias
FROM {{$tablename}}
GROUP BY charfield";
$this->assertEquals([
'dos' => '20',
'tres' => '30, 20',
'uno' => '10',
], $DB->get_records_sql_menu($sql));
// Test intfield => concatenated charfield ASC.
$fieldsql = $DB->sql_group_concat('charfield', ', ', 'charfield ASC');
$sql = "SELECT intfield, {$fieldsql} AS falias
FROM {{$tablename}}
GROUP BY intfield";
$this->assertEquals([
10 => 'uno',
20 => 'dos, tres',
30 => 'tres',
], $DB->get_records_sql_menu($sql));
// Test intfield => concatenated charfield DESC.
$fieldsql = $DB->sql_group_concat('charfield', ', ', 'charfield DESC');
$sql = "SELECT intfield, {$fieldsql} AS falias
FROM {{$tablename}}
GROUP BY intfield";
$this->assertEquals([
10 => 'uno',
20 => 'tres, dos',
30 => 'tres',
], $DB->get_records_sql_menu($sql));
// Assert expressions with parameters can also be used.
$fieldexpr = $DB->sql_concat(':greeting', 'charfield');
$fieldsql = $DB->sql_group_concat($fieldexpr, ', ', 'charfield ASC');
$sql = "SELECT intfield, {$fieldsql} AS falias
FROM {{$tablename}}
GROUP BY intfield";
$this->assertEquals([
10 => 'Hola uno',
20 => 'Hola dos, Hola tres',
30 => 'Hola tres',
], $DB->get_records_sql_menu($sql, ['greeting' => 'Hola ']));
}
/**
* Test DML libraries sql_group_contact method joining tables, aggregating data from each
*/
public function test_group_concat_join_tables(): void {
$DB = $this->tdb;
$dbman = $DB->get_manager();
$tableparent = $this->get_test_table('parent');
$tableparent->add_field('id', XMLDB_TYPE_INTEGER, '10', null, XMLDB_NOTNULL, XMLDB_SEQUENCE, null);
$tableparent->add_field('name', XMLDB_TYPE_CHAR, '255', null, XMLDB_NOTNULL, null, null);
$tableparent->add_key('primary', XMLDB_KEY_PRIMARY, ['id']);
$dbman->create_table($tableparent);
$tablechild = $this->get_test_table('child');
$tablechild->add_field('id', XMLDB_TYPE_INTEGER, '10', null, XMLDB_NOTNULL, XMLDB_SEQUENCE, null);
$tablechild->add_field('parentid', XMLDB_TYPE_INTEGER, '10', null, XMLDB_NOTNULL, null, '0');
$tablechild->add_field('name', XMLDB_TYPE_CHAR, '255', null, XMLDB_NOTNULL, null, null);
$tablechild->add_key('primary', XMLDB_KEY_PRIMARY, ['id']);
$tablechild->add_key('parentid', XMLDB_KEY_FOREIGN, ['parentid'], $tableparent->getName(), ['id']);
$dbman->create_table($tablechild);
$tableparentname = $tableparent->getName();
$tablechildname = $tablechild->getName();
$parentone = $DB->insert_record($tableparentname, (object) ['name' => 'Alice']);
$DB->insert_record($tablechildname, (object) ['parentid' => $parentone, 'name' => 'Eve']);
$DB->insert_record($tablechildname, (object) ['parentid' => $parentone, 'name' => 'Charlie']);
$parenttwo = $DB->insert_record($tableparentname, (object) ['name' => 'Bob']);
$DB->insert_record($tablechildname, (object) ['parentid' => $parenttwo, 'name' => 'Dan']);
$DB->insert_record($tablechildname, (object) ['parentid' => $parenttwo, 'name' => 'Grace']);
$tableparentalias = 'p';
$tablechildalias = 'c';
$fieldsql = $DB->sql_group_concat("{$tablechildalias}.name", ', ', "{$tablechildalias}.name ASC");
$sql = "SELECT {$tableparentalias}.name, {$fieldsql} AS falias
FROM {{$tableparentname}} {$tableparentalias}
JOIN {{$tablechildname}} {$tablechildalias} ON {$tablechildalias}.parentid = {$tableparentalias}.id
GROUP BY {$tableparentalias}.name";
$this->assertEqualsCanonicalizing([
(object) [
'name' => 'Alice',
'falias' => 'Charlie, Eve',
],
(object) [
'name' => 'Bob',
'falias' => 'Dan, Grace',
],
], $DB->get_records_sql($sql));
}
public function test_sql_fullname() {
$DB = $this->tdb;
$sql = "SELECT ".$DB->sql_fullname(':first', ':last')." AS fullname ".$DB->sql_null_from_clause();
@ -5861,6 +5996,9 @@ class moodle_database_for_testing extends moodle_database {
public function delete_records_select($table, $select, array $params=null) {}
public function sql_concat() {}
public function sql_concat_join($separator="' '", $elements=array()) {}
public function sql_group_concat(string $field, string $separator = ', ', string $sort = ''): string {
return '';
}
public function sql_substr($expr, $start, $length=false) {}
public function begin_transaction() {}
public function commit_transaction() {}

View File

@ -340,6 +340,19 @@ abstract class test_moodle_database extends moodle_database {
throw new Exception("sql_concat_join() not implemented");
}
/**
* Default implementation, throws Exception
*
* @param string $field
* @param string $separator
* @param string $sort
* @return string
* @throws Exception
*/
public function sql_group_concat(string $field, string $separator = ', ', string $sort = ''): string {
throw new Exception('sql_group_concat() not implemented');
}
/**
* Default implementation, throws Exception
* @return void

View File

@ -30,6 +30,7 @@ information provided here is intended especially for developers.
* Behat now supports date and time selection from the datetime form element. Examples:
- I set the field "<field_string>" to "##15 March 2021 08:15##"
- I set the field "<field_string>" to "##first day of January last year noon##"
* New DML driver method `$DB->sql_group_concat` for performing group concatenation of a field within a SQL query
* Added new class, AMD modules and WS that allow displaying forms in modal popups or load and submit in AJAX requests.
See https://docs.moodle.org/dev/Modal_and_AJAX_forms for more details.