forked from doctrine/dbal
-
Notifications
You must be signed in to change notification settings - Fork 0
Commit
This commit does not belong to any branch on this repository, and may belong to a fork outside of the repository.
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 doctrine#5100. For previous discussion on this topic, see: doctrine#5100 doctrine#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.
- Loading branch information
Showing
8 changed files
with
293 additions
and
5 deletions.
There are no files selected for viewing
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,114 @@ | ||
<?php | ||
|
||
namespace Doctrine\DBAL\Platforms; | ||
|
||
use Doctrine\DBAL\Types\JsonType; | ||
|
||
use function sprintf; | ||
|
||
/** | ||
* Provides the behavior, features and SQL dialect of the MariaDB 10.4 (10.4.6 GA) database platform. | ||
* | ||
* Extend deprecated MariaDb1027Platform to ensure correct functions used in MySQLSchemaManager which | ||
* tests for MariaDb1027Platform not MariaDBPlatform. | ||
*/ | ||
class MariaDb1043Platform extends MariaDb1027Platform | ||
{ | ||
/** | ||
* Use JSON rather than LONGTEXT for json columns. Since it is not a true native type, do not override | ||
* hasNativeJsonType() so the DC2Type comment will still be set. | ||
* | ||
* {@inheritdoc} | ||
*/ | ||
public function getJsonTypeDeclarationSQL(array $column): string | ||
{ | ||
return 'JSON'; | ||
} | ||
|
||
/** | ||
* {@inheritdoc} | ||
* | ||
* From version 10.4.3, MariaDb aliases JSON to LONGTEXT and adds a constraint CHECK (json_valid). Reverse | ||
* this process when introspecting tables. | ||
* | ||
* @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 | ||
*/ | ||
public function getListTableColumnsSQL($table, $database = null): string | ||
{ | ||
[$columnTypeSQL, $joinCheckConstraintSQL] = $this->getColumnTypeSQLSnippets(); | ||
|
||
return sprintf( | ||
<<<SQL | ||
SELECT c.COLUMN_NAME AS Field, | ||
$columnTypeSQL AS Type, | ||
c.IS_NULLABLE AS `Null`, | ||
c.COLUMN_KEY AS `Key`, | ||
c.COLUMN_DEFAULT AS `Default`, | ||
c.EXTRA AS Extra, | ||
c.COLUMN_COMMENT AS Comment, | ||
c.CHARACTER_SET_NAME AS CharacterSet, | ||
c.COLLATION_NAME AS Collation | ||
FROM information_schema.COLUMNS c | ||
$joinCheckConstraintSQL | ||
WHERE c.TABLE_SCHEMA = %s | ||
AND c.TABLE_NAME = %s | ||
ORDER BY ORDINAL_POSITION ASC; | ||
SQL | ||
, | ||
$this->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 = <<<SQL | ||
IF( | ||
x.CHECK_CLAUSE IS NOT NULL AND $tableAlias.COLUMN_TYPE = 'longtext', | ||
'json', | ||
$tableAlias.COLUMN_TYPE | ||
) | ||
SQL; | ||
|
||
$joinCheckConstraintSQL = <<<SQL | ||
LEFT JOIN information_schema.CHECK_CONSTRAINTS x | ||
ON ( | ||
$tableAlias.TABLE_SCHEMA = x.CONSTRAINT_SCHEMA | ||
AND $tableAlias.TABLE_NAME = x.TABLE_NAME | ||
AND x.CHECK_CLAUSE = CONCAT('json_valid(`', $tableAlias.COLUMN_NAME , '`)') | ||
) | ||
SQL; | ||
|
||
return [$columnTypeSQL, $joinCheckConstraintSQL]; | ||
} | ||
|
||
/** {@inheritDoc} */ | ||
public function getColumnDeclarationSQL($name, array $column) | ||
{ | ||
// MariaDb forces column collation to utf8mb4_bin where the column was declared as JSON so ignore | ||
// collation and character set for json columns as attempting to set them can cause an error. | ||
if ($this->getJsonTypeDeclarationSQL([]) === 'JSON' && ($column['type'] ?? null) instanceof JsonType) { | ||
unset($column['collation']); | ||
unset($column['charset']); | ||
} | ||
|
||
return parent::getColumnDeclarationSQL($name, $column); | ||
} | ||
} |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,96 @@ | ||
<?php | ||
|
||
declare(strict_types=1); | ||
|
||
namespace Doctrine\DBAL\Tests\Functional\Types; | ||
|
||
use Doctrine\DBAL\ParameterType; | ||
use Doctrine\DBAL\Schema\Table; | ||
use Doctrine\DBAL\Tests\FunctionalTestCase; | ||
use Doctrine\DBAL\Types\Type; | ||
|
||
use function is_resource; | ||
use function json_decode; | ||
use function ksort; | ||
use function stream_get_contents; | ||
|
||
class JsonTest extends FunctionalTestCase | ||
{ | ||
protected function setUp(): void | ||
{ | ||
$table = new Table('json_test_table'); | ||
$table->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<scalar|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<scalar|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; | ||
} | ||
} |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,42 @@ | ||
<?php | ||
|
||
namespace Doctrine\DBAL\Tests\Platforms; | ||
|
||
use Doctrine\DBAL\Platforms\AbstractPlatform; | ||
use Doctrine\DBAL\Platforms\MariaDb1043Platform; | ||
use Doctrine\DBAL\Types\Types; | ||
|
||
class MariaDb1043PlatformTest extends AbstractMySQLPlatformTestCase | ||
{ | ||
public function createPlatform(): AbstractPlatform | ||
{ | ||
return new MariaDb1043Platform(); | ||
} | ||
|
||
public function testHasNativeJsonType(): void | ||
{ | ||
self::assertFalse($this->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'); | ||
} | ||
} |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters