From 36af5457dc795a2d869dfacf4a03cbad5df5e1eb Mon Sep 17 00:00:00 2001 From: Paul Holden Date: Tue, 25 Jul 2023 00:20:18 +0100 Subject: [PATCH] MDL-78787 dml: native casting to char in SQL Server driver. Ensure the same is used during concatentation to prevent truncation of data, which was previously set at 255 characters per field. --- lib/dml/sqlsrv_native_moodle_database.php | 12 +++- lib/dml/tests/dml_test.php | 73 +++++++++++++++++------ 2 files changed, 67 insertions(+), 18 deletions(-) diff --git a/lib/dml/sqlsrv_native_moodle_database.php b/lib/dml/sqlsrv_native_moodle_database.php index 8b8ebf8c7ef..9afc56b9e8c 100644 --- a/lib/dml/sqlsrv_native_moodle_database.php +++ b/lib/dml/sqlsrv_native_moodle_database.php @@ -1318,6 +1318,16 @@ class sqlsrv_native_moodle_database extends moodle_database { return true; } + /** + * Return SQL for casting to char of given field/expression + * + * @param string $field Table field or SQL expression to be cast + * @return string + */ + public function sql_cast_to_char(string $field): string { + return "CAST({$field} AS NVARCHAR(MAX))"; + } + public function sql_cast_char2int($fieldname, $text = false) { if (!$text) { @@ -1441,7 +1451,7 @@ class sqlsrv_native_moodle_database extends moodle_database { $arr = func_get_args(); foreach ($arr as $key => $ele) { - $arr[$key] = ' CAST('.$ele.' AS NVARCHAR(255)) '; + $arr[$key] = $this->sql_cast_to_char($ele); } $s = implode(' + ', $arr); diff --git a/lib/dml/tests/dml_test.php b/lib/dml/tests/dml_test.php index 0667f73b517..38a1b906f06 100644 --- a/lib/dml/tests/dml_test.php +++ b/lib/dml/tests/dml_test.php @@ -4366,29 +4366,68 @@ EOD; $tablename = $table->getName(); $table->add_field('id', XMLDB_TYPE_INTEGER, '10', null, XMLDB_NOTNULL, XMLDB_SEQUENCE, null); - $table->add_field('description', XMLDB_TYPE_TEXT, 'big', null, null, null, null); + $table->add_field('charshort', XMLDB_TYPE_CHAR, '255'); + $table->add_field('charlong', XMLDB_TYPE_CHAR, '1333'); + $table->add_field('description', XMLDB_TYPE_TEXT, 'big'); $table->add_key('primary', XMLDB_KEY_PRIMARY, array('id')); $dbman->create_table($table); - $DB->insert_record($tablename, array('description'=>'áéíóú')); - $DB->insert_record($tablename, array('description'=>'dxxx')); - $DB->insert_record($tablename, array('description'=>'bcde')); + // Regarding 1300 length - all drivers except Oracle support larger values (2K+), but this hits a limit on Oracle. + $DB->insert_record($tablename, [ + 'charshort' => 'áéíóú', + 'charlong' => str_repeat('A', 512), + 'description' => str_repeat('X', 1300), + ]); + $DB->insert_record($tablename, [ + 'charshort' => 'dxxx', + 'charlong' => str_repeat('B', 512), + 'description' => str_repeat('Y', 1300), + ]); + $DB->insert_record($tablename, [ + 'charshort' => 'bcde', + 'charlong' => str_repeat('C', 512), + 'description' => str_repeat('Z', 1300), + ]); + + // Char (short) fieldnames and values. + $fieldsql = $DB->sql_concat('charshort', "'harcoded'", '?', '?'); + $this->assertEqualsCanonicalizing([ + 'áéíóúharcoded123.45test', + 'dxxxharcoded123.45test', + 'bcdeharcoded123.45test', + ], $DB->get_fieldset_select($tablename, $fieldsql, '', [123.45, 'test'])); + + // Char (long) fieldnames and values. + $fieldsql = $DB->sql_concat('charlong', "'harcoded'", '?', '?'); + $this->assertEqualsCanonicalizing([ + str_repeat('A', 512) . 'harcoded123.45test', + str_repeat('B', 512) . 'harcoded123.45test', + str_repeat('C', 512) . 'harcoded123.45test', + ], $DB->get_fieldset_select($tablename, $fieldsql, '', [123.45, 'test'])); + + // Text fieldnames and values. + $fieldsql = $DB->sql_concat('description', "'harcoded'", '?', '?'); + $this->assertEqualsCanonicalizing([ + str_repeat('X', 1300) . 'harcoded123.45test', + str_repeat('Y', 1300) . 'harcoded123.45test', + str_repeat('Z', 1300) . 'harcoded123.45test', + ], $DB->get_fieldset_select($tablename, $fieldsql, '', [123.45, 'test'])); - // Fieldnames and values mixed. - $sql = 'SELECT id, ' . $DB->sql_concat('description', "'harcoded'", '?', '?') . ' AS result FROM {' . $tablename . '}'; - $records = $DB->get_records_sql($sql, array(123.45, 'test')); - $this->assertCount(3, $records); - $this->assertSame('áéíóúharcoded123.45test', $records[1]->result); // Integer fieldnames and values. - $sql = 'SELECT id, ' . $DB->sql_concat('id', "'harcoded'", '?', '?') . ' AS result FROM {' . $tablename . '}'; - $records = $DB->get_records_sql($sql, array(123.45, 'test')); - $this->assertCount(3, $records); - $this->assertSame('1harcoded123.45test', $records[1]->result); + $fieldsql = $DB->sql_concat('id', "'harcoded'", '?', '?'); + $this->assertEqualsCanonicalizing([ + '1harcoded123.45test', + '2harcoded123.45test', + '3harcoded123.45test', + ], $DB->get_fieldset_select($tablename, $fieldsql, '', [123.45, 'test'])); + // All integer fieldnames. - $sql = 'SELECT id, ' . $DB->sql_concat('id', 'id', 'id') . ' AS result FROM {' . $tablename . '}'; - $records = $DB->get_records_sql($sql, array()); - $this->assertCount(3, $records); - $this->assertSame('111', $records[1]->result); + $fieldsql = $DB->sql_concat('id', 'id', 'id'); + $this->assertEqualsCanonicalizing([ + '111', + '222', + '333', + ], $DB->get_fieldset_select($tablename, $fieldsql, '')); }