Skip to content

Commit

Permalink
MariaDb1043Platform. New MariaDbPlatform using JSON as json column type.
Browse files Browse the repository at this point in the history
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 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

v2
JsonTest.php:
1. Simplify array shapes of json structures.

2. Deal with json returned as a stream not string.

   It seems Oracle 11 returns json as a stream so convert streams to
   strings.

v3
JsonTest.php:

1. 'json_table' is a reserved word in MySQL (and a function name in
   Oracle SQL). Use json_test_table instead.

2. Some databases e.g. MySQL reorder json arrays so the insert order
   will not necessarily match the select order. Resort the arrays
   before testing for equality.

MySQLSchemaManager.php:

Remove 'instanceof MariaDb1027Platform' test as follows:

a. Add getColumnTypeSQLSnippets() method to AbstractMySQLPlatform which
   returns the default snippets for all databases except MariaDb.

b. Override the method in MariDBPlatform to return the SQL snippets
   which inverse the JSON to LONGTEXT aliasing.

Note that the getColumnTypeSQLSnippets() method in MariaDBPlatform was
previously called getInverseJsonToLongtextAliasSQL() and was renamed to
make more sense for MySQL platforms in general.
  • Loading branch information
cgknx committed Mar 4, 2023
1 parent 762d8bf commit 553df9b
Show file tree
Hide file tree
Showing 8 changed files with 308 additions and 4 deletions.
14 changes: 13 additions & 1 deletion src/Platforms/AbstractMySQLPlatform.php
Original file line number Diff line number Diff line change
Expand Up @@ -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
{
Expand Down Expand Up @@ -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);
Expand Down
2 changes: 1 addition & 1 deletion src/Platforms/AbstractPlatform.php
Original file line number Diff line number Diff line change
Expand Up @@ -4583,7 +4583,7 @@ final public function escapeStringForLike(string $inputString, string $escapeCha
* @return array<string,mixed> 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);

Expand Down
106 changes: 106 additions & 0 deletions src/Platforms/MariaDBPlatform.php
Original file line number Diff line number Diff line change
Expand Up @@ -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.
*/
Expand Down Expand Up @@ -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->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),
);
}

/**
* {@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
{
Expand All @@ -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 getColumnTypeSQLSnippets(string $tableAlias = 'c'): array
{
if ($this->getJsonTypeDeclarationSQL([]) !== 'JSON') {
return parent::getColumnTypeSQLSnippets($tableAlias);
}

$columnTypeSQL = <<<SQL
/*M!100403
IF(
x.CHECK_CLAUSE IS NOT NULL AND $tableAlias.COLUMN_TYPE = 'longtext',
'json', */
$tableAlias.COLUMN_TYPE
/*M!100403
) */
SQL;

$joinCheckConstraintSQL = <<<SQL
/*M!100403
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];
}
}
24 changes: 24 additions & 0 deletions src/Platforms/MariaDb1043Platform.php
Original file line number Diff line number Diff line change
@@ -0,0 +1,24 @@
<?php

namespace Doctrine\DBAL\Platforms;

/**
* 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.
*
* Note: Should not be used with versions prior to 10.4.3 when the 'native' JSON type was added. Since
* it is not a true native type, do not override hasNativeJsonType() so the DC2Type comment will still
* be set.
*/
class MariaDb1043Platform extends MariaDb1027Platform
{
/**
* {@inheritdoc}
*/
public function getJsonTypeDeclarationSQL(array $column): string
{
return 'JSON';
}
}
7 changes: 5 additions & 2 deletions src/Schema/MySQLSchemaManager.php
Original file line number Diff line number Diff line change
Expand Up @@ -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 .= <<<SQL
c.COLUMN_NAME AS field,
c.COLUMN_TYPE AS type,
$columnTypeSQL AS type,
c.IS_NULLABLE AS `null`,
c.COLUMN_KEY AS `key`,
c.COLUMN_DEFAULT AS `default`,
Expand All @@ -424,6 +426,7 @@ protected function selectTableColumns(string $databaseName, ?string $tableName =
FROM information_schema.COLUMNS c
INNER JOIN information_schema.TABLES t
ON t.TABLE_NAME = c.TABLE_NAME
$joinCheckConstraintSQL
SQL;

// The schema name is passed multiple times as a literal in the WHERE clause instead of using a JOIN condition
Expand Down
21 changes: 21 additions & 0 deletions tests/Functional/Schema/MySQLSchemaManagerTest.php
Original file line number Diff line number Diff line change
Expand Up @@ -13,6 +13,8 @@
use Doctrine\DBAL\Types\Type;
use Doctrine\DBAL\Types\Types;

use function array_keys;

class MySQLSchemaManagerTest extends SchemaManagerFunctionalTestCase
{
public static function setUpBeforeClass(): void
Expand Down Expand Up @@ -541,4 +543,23 @@ public function testEnsureTableWithoutOptionsAreReflectedInMetadata(): void
self::assertEquals('', $onlineTable->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.');
}
}
96 changes: 96 additions & 0 deletions tests/Functional/Types/JsonTest.php
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;
}
}
42 changes: 42 additions & 0 deletions tests/Platforms/MariaDb1043PlatformTest.php
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');
}
}

0 comments on commit 553df9b

Please sign in to comment.