From 9fe0073723fac02545eb5f2f3d991bf5cfd26b6f Mon Sep 17 00:00:00 2001 From: Colin Knox <124388865+cgknx@users.noreply.github.com> Date: Thu, 9 Feb 2023 16:07:03 +0000 Subject: [PATCH] Add MariaDb1043Platform using JSON as json column type. MariaDb aliases columns specified as JSON to LONGTEXT. Since version 10.4.3, MariaDb adds a CHECK constraint to JSON columns to ensure they contain valid JSON and sets the column collation to utf8mb4_bin. Simply setting JSON as the column type in the platform results in introspection failures as the database reports LONGTEXT (not JSON) with changed collation. Therefore, inverse the aliasing where the relevant check constraint exists and ignore collation changes for JSON columns in the relevant database versions. The main functional changes are in: - MariaDB1043Platform->getListTableColumnsSQL() and - MySQLSchemaManager->selectTableColumns() MariaDb1043Platform extends MariaDb1027Platform rather than MariaDBPlatform to ensure the platform checks in MySQLSchemaManager (based on MariaDb1027Platform) continue to work as expected. The alternative approach of adding the CHECK constraint to the SQL for the column is not robust as MariaDb syntax seems to require the CHECK constraint to be the final part of the column declaration and it was not obvious how to guarantee this (specifically, appending the CHECK constraint to the output of getJsonTypeDeclarationSQL() did not work). New public methods: MariaDBPlatform->getColumnTypeSQLSnippets() generates SQL snippets to reverse the JSON to LONGTEXT aliasing for JSON-specified columns. It is also used in MySQLSchemaManager. It still checks that json columns are JSON data type so that switching the getJsonTypeDeclarationSQL to LONGTEXT is all that is necessary to revert to old behaviour which is helpful for testing. Overridden methods in MariaDb1043Platform: MariaDb1043Platform->getJsonTypeDeclarationSQL(). To return JSON. MariaDBPlatform->getListTableColumnsSQL(). To reverse the JSON to LONGTEXT aliasing carried out by MariaDb. MariaDBPlatform->getColumnDeclarationSQL(). To unset collation and charset (used by the comparator). New test cases: 1. Types/JsonTest. Test storage and retrieval of json data. 2. Platforms/MariaDb1043PlatformTest. A clone of MariaDb1027Platform test. 3. Schema/MySQLSchemaManagerTest->testColumnIntrospection(). Ensures introspected table matches original table. Tests all doctrine types not just json. Based on failure highlighted in pull request #5100. For previous discussion on this topic, see: https://github.com/doctrine/dbal/pull/5100 https://github.com/doctrine/dbal/issues/3202 Further background at: https://mariadb.com/kb/en/json-data-type/ https://mariadb.com/kb/en/information-schema-check_constraints-table/ https://jira.mariadb.org/browse/MDEV-13916 Notes regarding JsonTest.php: 1. Some platforms return json as a stream so convert streams to strings. 2. 'json_table' is a reserved word in MySQL (and a function name in Oracle SQL). Use json_test_table instead. 3. Some platforms reorder json arrays so the insert order will not necessarily match the select order. Resort the arrays before testing for equality. --- src/Platforms/AbstractMySQLPlatform.php | 14 ++- src/Platforms/MariaDb1043Platform.php | 114 ++++++++++++++++++ src/Platforms/MariaDb1052Platform.php | 2 +- src/Schema/MySQLSchemaManager.php | 7 +- .../Schema/MySQLSchemaManagerTest.php | 21 ++++ tests/Functional/Types/JsonTest.php | 96 +++++++++++++++ tests/Platforms/MariaDb1043PlatformTest.php | 42 +++++++ tests/Platforms/MariaDb1052PlatformTest.php | 2 +- 8 files changed, 293 insertions(+), 5 deletions(-) create mode 100644 src/Platforms/MariaDb1043Platform.php create mode 100644 tests/Functional/Types/JsonTest.php create mode 100644 tests/Platforms/MariaDb1043PlatformTest.php diff --git a/src/Platforms/AbstractMySQLPlatform.php b/src/Platforms/AbstractMySQLPlatform.php index cdbdbec78b9..503881a6c4a 100644 --- a/src/Platforms/AbstractMySQLPlatform.php +++ b/src/Platforms/AbstractMySQLPlatform.php @@ -396,6 +396,18 @@ public function getListTableColumnsSQL($table, $database = null) ' ORDER BY ORDINAL_POSITION ASC'; } + /** + * The SQL snippets required to elucidate a column type + * + * Returns an array of the form [column type SELECT snippet, additional JOIN statement snippet] + * + * @return array{string, string} + */ + public function getColumnTypeSQLSnippets(string $tableAlias = 'c'): array + { + return [$tableAlias . '.COLUMN_TYPE', '']; + } + /** @deprecated The SQL used for schema introspection is an implementation detail and should not be relied upon. */ public function getListTableMetadataSQL(string $table, ?string $database = null): string { @@ -1390,7 +1402,7 @@ public function supportsColumnLengthIndexes(): bool return true; } - private function getDatabaseNameSQL(?string $databaseName): string + protected function getDatabaseNameSQL(?string $databaseName): string { if ($databaseName !== null) { return $this->quoteStringLiteral($databaseName); diff --git a/src/Platforms/MariaDb1043Platform.php b/src/Platforms/MariaDb1043Platform.php new file mode 100644 index 00000000000..a9b7b1de5ba --- /dev/null +++ b/src/Platforms/MariaDb1043Platform.php @@ -0,0 +1,114 @@ +getColumnTypeSQLSnippets(); + + return sprintf( + <<getDatabaseNameSQL($database), + $this->quoteStringLiteral($table), + ); + } + + /** + * Generate SQL snippets to reverse the aliasing of JSON to LONGTEXT. + * + * MariaDb aliases columns specified as JSON to LONGTEXT and sets a CHECK constraint to ensure the column + * is valid json. This function generates the SQL snippets which reverse this aliasing i.e. report a column + * as JSON where it was originally specified as such instead of LONGTEXT. + * + * The CHECK constraints are stored in information_schema.CHECK_CONSTRAINTS so JOIN that table. + * + * @return array{string, string} + */ + public function getColumnTypeSQLSnippets(string $tableAlias = 'c'): array + { + if ($this->getJsonTypeDeclarationSQL([]) !== 'JSON') { + return parent::getColumnTypeSQLSnippets($tableAlias); + } + + $columnTypeSQL = <<getJsonTypeDeclarationSQL([]) === 'JSON' && ($column['type'] ?? null) instanceof JsonType) { + unset($column['collation']); + unset($column['charset']); + } + + return parent::getColumnDeclarationSQL($name, $column); + } +} diff --git a/src/Platforms/MariaDb1052Platform.php b/src/Platforms/MariaDb1052Platform.php index b4a3a20cf73..b25fb1af9e6 100644 --- a/src/Platforms/MariaDb1052Platform.php +++ b/src/Platforms/MariaDb1052Platform.php @@ -10,7 +10,7 @@ * * Note: Should not be used with versions prior to 10.5.2. */ -class MariaDb1052Platform extends MariaDb1027Platform +class MariaDb1052Platform extends MariaDb1043Platform { /** * {@inheritdoc} diff --git a/src/Schema/MySQLSchemaManager.php b/src/Schema/MySQLSchemaManager.php index f2305098ab4..5b43ab07463 100644 --- a/src/Schema/MySQLSchemaManager.php +++ b/src/Schema/MySQLSchemaManager.php @@ -405,15 +405,17 @@ protected function selectTableNames(string $databaseName): Result protected function selectTableColumns(string $databaseName, ?string $tableName = null): Result { + [$columnTypeSQL, $joinCheckConstraintSQL] = $this->_platform->getColumnTypeSQLSnippets(); + $sql = 'SELECT'; if ($tableName === null) { $sql .= ' c.TABLE_NAME,'; } - $sql .= <<<'SQL' + $sql .= <<getOption('comment')); self::assertEquals([], $onlineTable->getOption('create_options')); } + + public function testColumnIntrospection(): void + { + $table = new Table('test_column_introspection'); + + $doctrineTypes = array_keys(Type::getTypesMap()); + + foreach ($doctrineTypes as $type) { + $table->addColumn('col_' . $type, $type); + } + + $this->dropAndCreateTable($table); + + $onlineTable = $this->schemaManager->introspectTable('test_column_introspection'); + + $diff = $this->schemaManager->createComparator()->diffTable($table, $onlineTable); + + self::assertFalse($diff, 'Tables should be identical.'); + } } diff --git a/tests/Functional/Types/JsonTest.php b/tests/Functional/Types/JsonTest.php new file mode 100644 index 00000000000..feb431b7924 --- /dev/null +++ b/tests/Functional/Types/JsonTest.php @@ -0,0 +1,96 @@ +addColumn('id', 'integer'); + + $table->addColumn('val', 'json'); + $table->setPrimaryKey(['id']); + + $this->dropAndCreateTable($table); + } + + public function testInsertAndSelect(): void + { + $id1 = 1; + $id2 = 2; + + $value1 = [ + 'firstKey' => 'firstVal', + 'secondKey' => 'secondVal', + 'nestedKey' => [ + 'nestedKey1' => 'nestedVal1', + 'nestedKey2' => 2, + ], + ]; + $value2 = json_decode('{"key1":"Val1","key2":2,"key3":"Val3"}', true); + + $this->insert($id1, $value1); + $this->insert($id2, $value2); + + $res1 = $this->select($id1); + $res2 = $this->select($id2); + + // The returned arrays are not guaranteed to be in the same order so sort them + ksort($value1); + ksort($value2); + ksort($res1); + ksort($res2); + + self::assertSame($value1, $res1); + self::assertSame($value2, $res2); + } + + /** @param array $value */ + private function insert(int $id, array $value): void + { + $result = $this->connection->insert('json_test_table', [ + 'id' => $id, + 'val' => $value, + ], [ + ParameterType::INTEGER, + Type::getType('json'), + ]); + + self::assertSame(1, $result); + } + + /** @return array */ + private function select(int $id): array + { + $value = $this->connection->fetchOne( + 'SELECT val FROM json_test_table WHERE id = ?', + [$id], + [ParameterType::INTEGER], + ); + + if (is_resource($value)) { + $value = stream_get_contents($value); + } + + self::assertIsString($value); + + $value = json_decode($value, true); + + self::assertIsArray($value); + + return $value; + } +} diff --git a/tests/Platforms/MariaDb1043PlatformTest.php b/tests/Platforms/MariaDb1043PlatformTest.php new file mode 100644 index 00000000000..e3c8a1aed16 --- /dev/null +++ b/tests/Platforms/MariaDb1043PlatformTest.php @@ -0,0 +1,42 @@ +platform->hasNativeJsonType()); + } + + /** + * From MariaDB 10.2.7, JSON type is an alias to LONGTEXT however from 10.4.3 setting a column + * as JSON adds additional functionality so use JSON. + * + * @link https://mariadb.com/kb/en/library/json-data-type/ + */ + public function testReturnsJsonTypeDeclarationSQL(): void + { + self::assertSame('JSON', $this->platform->getJsonTypeDeclarationSQL([])); + } + + public function testInitializesJsonTypeMapping(): void + { + self::assertTrue($this->platform->hasDoctrineTypeMappingFor('json')); + self::assertSame(Types::JSON, $this->platform->getDoctrineTypeMapping('json')); + } + + public function testIgnoresDifferenceInDefaultValuesForUnsupportedColumnTypes(): void + { + self::markTestSkipped('MariaDb1043Platform supports default values for BLOB and TEXT columns'); + } +} diff --git a/tests/Platforms/MariaDb1052PlatformTest.php b/tests/Platforms/MariaDb1052PlatformTest.php index 72847db531e..f740afc7b97 100644 --- a/tests/Platforms/MariaDb1052PlatformTest.php +++ b/tests/Platforms/MariaDb1052PlatformTest.php @@ -5,7 +5,7 @@ use Doctrine\DBAL\Platforms\AbstractPlatform; use Doctrine\DBAL\Platforms\MariaDb1052Platform; -class MariaDb1052PlatformTest extends MariaDb1027PlatformTest +class MariaDb1052PlatformTest extends MariaDb1043PlatformTest { public function createPlatform(): AbstractPlatform {