From 6f11db517524e6fd1cd98edc9dea5dc13845e158 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] MariaDb1043Platform. New MariaDbPlatform 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 modified methods are MariaDBPlatform->getListTableColumnsSQL() and MySQLSchemaManager->selectTableColumns() The changes have been implemented in the MariaDBPlatform (guarded by a check for JSON as column type so they do not affect MariaDB1027Platform) and MySQLSchemaManager (guarded by a platform test). It ought to be possible to push most of the platform changes into the MySQLPlatform given the SQL query changes are guarded by MariaDB specific executable comments and so should be a no op for MySQL. Doing so would allow getDatabaseNameSQL() to be kept private. However, because the changes are entirely MariaDb specific they have been made in the MariaDBPlatform (this is also consistent with the plan to separate MariaDb and MySQL platforms). 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->getInverseJsonToLongtextAliasSQL() generates SQL snippets to inverse the JSON to LONGTEXT aliasing for JSON-specified columns. It is marked public because it is used in MySQLSchemaManager. Overridden methods: MariaDb1043Platform->getJsonTypeDeclarationSQL(). To return JSON. MariaDBPlatform->getListTableColumnsSQL(). To reverse the JSON to LONGTEXT aliasing carried out by MariaDb. MariaDBPlatform->MariaDBColumnToArray(). To unset collation and charset in column array (so parent needed to be marked protected). 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 --- src/Platforms/AbstractMySQLPlatform.php | 2 +- src/Platforms/AbstractPlatform.php | 2 +- src/Platforms/MariaDBPlatform.php | 106 ++++++++++++++++++ src/Platforms/MariaDb1043Platform.php | 24 ++++ src/Schema/MySQLSchemaManager.php | 13 ++- .../Schema/MySQLSchemaManagerTest.php | 21 ++++ tests/Functional/Types/JsonTest.php | 80 +++++++++++++ tests/Platforms/MariaDb1043PlatformTest.php | 42 +++++++ 8 files changed, 286 insertions(+), 4 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..582d57c6a39 100644 --- a/src/Platforms/AbstractMySQLPlatform.php +++ b/src/Platforms/AbstractMySQLPlatform.php @@ -1390,7 +1390,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/AbstractPlatform.php b/src/Platforms/AbstractPlatform.php index 28e0782e8a9..9b24d4a47e4 100644 --- a/src/Platforms/AbstractPlatform.php +++ b/src/Platforms/AbstractPlatform.php @@ -4583,7 +4583,7 @@ final public function escapeStringForLike(string $inputString, string $escapeCha * @return array An associative array with the name of the properties * of the column being declared as array indexes. */ - private function columnToArray(Column $column): array + protected function columnToArray(Column $column): array { $name = $column->getQuotedName($this); diff --git a/src/Platforms/MariaDBPlatform.php b/src/Platforms/MariaDBPlatform.php index 9e3d3ddb9a1..02f2a9a8202 100644 --- a/src/Platforms/MariaDBPlatform.php +++ b/src/Platforms/MariaDBPlatform.php @@ -2,9 +2,13 @@ namespace Doctrine\DBAL\Platforms; +use Doctrine\DBAL\Schema\Column; +use Doctrine\DBAL\Types\JsonType; use Doctrine\DBAL\Types\Types; use Doctrine\Deprecations\Deprecation; +use function sprintf; + /** * Provides the behavior, features and SQL dialect of the MariaDB database platform of the oldest supported version. */ @@ -33,6 +37,62 @@ public function getJsonTypeDeclarationSQL(array $column): string return 'LONGTEXT'; } + /** + * {@inheritdoc} + * + * From version 10.4.3, MariaDb aliases JSON to LONGTEXT and adds a constraint CHECK (json_valid). Reverse + * this process when introspecting tables in relevant versions. + * + * @see https://mariadb.com/kb/en/information-schema-check_constraints-table/ + * @see https://mariadb.com/kb/en/json-data-type/ + * @see https://jira.mariadb.org/browse/MDEV-13916 + * + * Valid for MariaDb versions before and after 10.4.3 and MySQL. + */ + public function getListTableColumnsSQL($table, $database = null): string + { + [$columnTypeSQL, $joinCheckConstraintSQL] = $this->getInverseJsonToLongtextAliasSQL(); + + return sprintf( + <<getDatabaseNameSQL($database), + $this->quoteStringLiteral($table), + ); + } + + /** + * {@inheritDoc} + */ + protected function columnToArray(Column $column): array + { + $columnArray = parent::columnToArray($column); + + // MariaDb forces column collation to utf8mb4_bin where the column was declared as JSON so ignore + // collation and character set for json columns. + if ($this->getJsonTypeDeclarationSQL([]) === 'JSON' && $columnArray['type'] instanceof JsonType) { + unset($columnArray['collation']); + unset($columnArray['charset']); + } + + return $columnArray; + } + /** @deprecated Implement {@see createReservedKeywordsList()} instead. */ protected function getReservedKeywordsClass(): string { @@ -52,4 +112,50 @@ protected function initializeDoctrineTypeMappings(): void $this->doctrineTypeMapping['json'] = Types::JSON; } + + /** + * Generate SQL snippets to inverse the aliasing of JSON to LONGTEXT for applicable MariaDb versions and platforms. + * + * 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 inverse 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. + * + * Applies only for MariaDBPlatforms that set json columns as JSON. + * + * Uses executable comments to ensure the inversing happens on versions of MariaDb which set the column check, + * namely 10.4.3 onwards. + * + * @return array{string, string} + */ + public function getInverseJsonToLongtextAliasSQL(string $tableAlias = 'c'): array + { + if ($this->getJsonTypeDeclarationSQL([]) !== 'JSON') { + return [$tableAlias . '.COLUMN_TYPE', '']; + } + + $columnTypeSQL = <<_platform instanceof MariaDb1027Platform) { + [$columnTypeSQL, $joinCheckConstraintSQL] = $this->_platform->getInverseJsonToLongtextAliasSQL(); + } else { + $columnTypeSQL = 'c.COLUMN_TYPE'; + $joinCheckConstraintSQL = ''; + } + $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..82df5c1a016 --- /dev/null +++ b/tests/Functional/Types/JsonTest.php @@ -0,0 +1,80 @@ +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); + + self::assertSame($value1, $this->select($id1)); + self::assertSame($value2, $this->select($id2)); + } + + /** @param array{int|string, scalar|array{int|string, scalar}}[] $value */ + private function insert(int $id, array $value): void + { + $result = $this->connection->insert('json_table', [ + 'id' => $id, + 'val' => $value, + ], [ + ParameterType::INTEGER, + Type::getType('json'), + ]); + + self::assertSame(1, $result); + } + + /** @return array{int|string, scalar|array{int|string, scalar}}[] $value */ + private function select(int $id): array + { + $value = $this->connection->fetchOne( + 'SELECT val FROM json_table WHERE id = ?', + [$id], + [ParameterType::INTEGER], + ); + + 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'); + } +}