From 9744af49db5a760d3aa128d00a271a1b407804e5 Mon Sep 17 00:00:00 2001 From: "Alexander M. Turek" Date: Thu, 10 Oct 2024 14:20:22 +0200 Subject: [PATCH] Implement an EnumType for MySQL/MariaDB (#6536) | Q | A |------------- | ----------- | Type | feature | Fixed issues | doctrine/migrations#1441 (partly) #### Summary This PR adds an `EnumType` that allows us to introspect and diff tables that make use of MySQL's `ENUM` column type. --- docs/en/reference/types.rst | 10 ++ .../ColumnValuesRequired.php | 30 ++++ src/Platforms/AbstractMySQLPlatform.php | 19 +++ src/Platforms/AbstractPlatform.php | 22 +++ src/Schema/Column.php | 44 ++++-- src/Schema/MySQLSchemaManager.php | 21 +++ src/Types/EnumType.php | 18 +++ src/Types/Type.php | 1 + src/Types/Types.php | 1 + .../Schema/MySQLSchemaManagerTest.php | 5 +- tests/Functional/Types/EnumTypeTest.php | 132 ++++++++++++++++++ tests/Schema/ColumnTest.php | 1 + 12 files changed, 292 insertions(+), 12 deletions(-) create mode 100644 src/Exception/InvalidColumnType/ColumnValuesRequired.php create mode 100644 src/Types/EnumType.php create mode 100644 tests/Functional/Types/EnumTypeTest.php diff --git a/docs/en/reference/types.rst b/docs/en/reference/types.rst index 21dd2669911..8ebc7edff1b 100644 --- a/docs/en/reference/types.rst +++ b/docs/en/reference/types.rst @@ -196,6 +196,16 @@ type natively, this type is mapped to the ``string`` type internally. Values retrieved from the database are always converted to PHP's ``string`` type or ``null`` if no data is present. +enum +++++ + +Maps and converts a string which is one of a set of predefined values. This +type is specifically designed for MySQL and MariaDB, where it is mapped to +the native ``ENUM`` type. For other database vendors, this type is mapped to +a string field (``VARCHAR``) with the maximum length being the length of the +longest value in the set. Values retrieved from the database are always +converted to PHP's ``string`` type or ``null`` if no data is present. + Binary string types ^^^^^^^^^^^^^^^^^^^ diff --git a/src/Exception/InvalidColumnType/ColumnValuesRequired.php b/src/Exception/InvalidColumnType/ColumnValuesRequired.php new file mode 100644 index 00000000000..ac6069ed30c --- /dev/null +++ b/src/Exception/InvalidColumnType/ColumnValuesRequired.php @@ -0,0 +1,30 @@ +getUnsignedDeclaration($column); } + /** + * {@inheritDoc} + */ + public function getEnumDeclarationSQL(array $column): string + { + if (! isset($column['values']) || ! is_array($column['values']) || $column['values'] === []) { + throw ColumnValuesRequired::new($this, 'ENUM'); + } + + return sprintf('ENUM(%s)', implode(', ', array_map( + $this->quoteStringLiteral(...), + $column['values'], + ))); + } + /** * Get unsigned declaration for a column. * @@ -718,6 +736,7 @@ protected function initializeDoctrineTypeMappings(): void 'datetime' => Types::DATETIME_MUTABLE, 'decimal' => Types::DECIMAL, 'double' => Types::FLOAT, + 'enum' => Types::ENUM, 'float' => Types::SMALLFLOAT, 'int' => Types::INTEGER, 'integer' => Types::INTEGER, diff --git a/src/Platforms/AbstractPlatform.php b/src/Platforms/AbstractPlatform.php index d7fe9a790f8..53b71a8dcd5 100644 --- a/src/Platforms/AbstractPlatform.php +++ b/src/Platforms/AbstractPlatform.php @@ -12,6 +12,7 @@ use Doctrine\DBAL\Exception\InvalidColumnType\ColumnLengthRequired; use Doctrine\DBAL\Exception\InvalidColumnType\ColumnPrecisionRequired; use Doctrine\DBAL\Exception\InvalidColumnType\ColumnScaleRequired; +use Doctrine\DBAL\Exception\InvalidColumnType\ColumnValuesRequired; use Doctrine\DBAL\LockMode; use Doctrine\DBAL\Platforms\Exception\NoColumnsSpecifiedForTable; use Doctrine\DBAL\Platforms\Exception\NotSupported; @@ -51,6 +52,8 @@ use function is_float; use function is_int; use function is_string; +use function max; +use function mb_strlen; use function preg_quote; use function preg_replace; use function sprintf; @@ -190,6 +193,25 @@ public function getBinaryTypeDeclarationSQL(array $column): string } } + /** + * Returns the SQL snippet to declare an ENUM column. + * + * Enum is a non-standard type that is especially popular in MySQL and MariaDB. By default, this method map to + * a simple VARCHAR field which allows us to deploy it on any platform, e.g. SQLite. + * + * @param array $column + * + * @throws ColumnValuesRequired If the column definition does not contain any values. + */ + public function getEnumDeclarationSQL(array $column): string + { + if (! isset($column['values']) || ! is_array($column['values']) || $column['values'] === []) { + throw ColumnValuesRequired::new($this, 'ENUM'); + } + + return $this->getStringTypeDeclarationSQL(['length' => max(...array_map(mb_strlen(...), $column['values']))]); + } + /** * Returns the SQL snippet to declare a GUID/UUID column. * diff --git a/src/Schema/Column.php b/src/Schema/Column.php index 8963cd7acb2..2d02403b262 100644 --- a/src/Schema/Column.php +++ b/src/Schema/Column.php @@ -33,6 +33,9 @@ class Column extends AbstractAsset protected bool $_autoincrement = false; + /** @var list */ + protected array $_values = []; + /** @var array */ protected array $_platformOptions = []; @@ -231,22 +234,41 @@ public function getComment(): string return $this->_comment; } + /** + * @param list $values + * + * @return $this + */ + public function setValues(array $values): static + { + $this->_values = $values; + + return $this; + } + + /** @return list */ + public function getValues(): array + { + return $this->_values; + } + /** @return array */ public function toArray(): array { return array_merge([ - 'name' => $this->_name, - 'type' => $this->_type, - 'default' => $this->_default, - 'notnull' => $this->_notnull, - 'length' => $this->_length, - 'precision' => $this->_precision, - 'scale' => $this->_scale, - 'fixed' => $this->_fixed, - 'unsigned' => $this->_unsigned, - 'autoincrement' => $this->_autoincrement, + 'name' => $this->_name, + 'type' => $this->_type, + 'default' => $this->_default, + 'notnull' => $this->_notnull, + 'length' => $this->_length, + 'precision' => $this->_precision, + 'scale' => $this->_scale, + 'fixed' => $this->_fixed, + 'unsigned' => $this->_unsigned, + 'autoincrement' => $this->_autoincrement, 'columnDefinition' => $this->_columnDefinition, - 'comment' => $this->_comment, + 'comment' => $this->_comment, + 'values' => $this->_values, ], $this->_platformOptions); } } diff --git a/src/Schema/MySQLSchemaManager.php b/src/Schema/MySQLSchemaManager.php index 1c0915905fa..becb6819e8b 100644 --- a/src/Schema/MySQLSchemaManager.php +++ b/src/Schema/MySQLSchemaManager.php @@ -17,11 +17,13 @@ use Doctrine\DBAL\Types\Type; use function array_change_key_case; +use function array_map; use function assert; use function explode; use function implode; use function is_string; use function preg_match; +use function preg_match_all; use function str_contains; use function strtok; use function strtolower; @@ -134,6 +136,8 @@ protected function _getPortableTableColumnDefinition(array $tableColumn): Column $type = $this->platform->getDoctrineTypeMapping($dbType); + $values = []; + switch ($dbType) { case 'char': case 'binary': @@ -192,6 +196,10 @@ protected function _getPortableTableColumnDefinition(array $tableColumn): Column case 'year': $length = null; break; + + case 'enum': + $values = $this->parseEnumExpression($tableColumn['type']); + break; } if ($this->platform instanceof MariaDBPlatform) { @@ -209,6 +217,7 @@ protected function _getPortableTableColumnDefinition(array $tableColumn): Column 'scale' => $scale, 'precision' => $precision, 'autoincrement' => str_contains($tableColumn['extra'], 'auto_increment'), + 'values' => $values, ]; if (isset($tableColumn['comment'])) { @@ -228,6 +237,18 @@ protected function _getPortableTableColumnDefinition(array $tableColumn): Column return $column; } + /** @return list */ + private function parseEnumExpression(string $expression): array + { + $result = preg_match_all("/'([^']*(?:''[^']*)*)'/", $expression, $matches); + assert($result !== false); + + return array_map( + static fn (string $match): string => strtr($match, ["''" => "'"]), + $matches[1], + ); + } + /** * Return Doctrine/Mysql-compatible column default values for MariaDB 10.2.7+ servers. * diff --git a/src/Types/EnumType.php b/src/Types/EnumType.php new file mode 100644 index 00000000000..489dc4b5c7d --- /dev/null +++ b/src/Types/EnumType.php @@ -0,0 +1,18 @@ +getEnumDeclarationSQL($column); + } +} diff --git a/src/Types/Type.php b/src/Types/Type.php index bc4d3aaf417..ee7797f0960 100644 --- a/src/Types/Type.php +++ b/src/Types/Type.php @@ -34,6 +34,7 @@ abstract class Type Types::DATETIMETZ_MUTABLE => DateTimeTzType::class, Types::DATETIMETZ_IMMUTABLE => DateTimeTzImmutableType::class, Types::DECIMAL => DecimalType::class, + Types::ENUM => EnumType::class, Types::FLOAT => FloatType::class, Types::GUID => GuidType::class, Types::INTEGER => IntegerType::class, diff --git a/src/Types/Types.php b/src/Types/Types.php index 6fef4cfce08..319218b021a 100644 --- a/src/Types/Types.php +++ b/src/Types/Types.php @@ -23,6 +23,7 @@ final class Types public const DATETIMETZ_IMMUTABLE = 'datetimetz_immutable'; public const DECIMAL = 'decimal'; public const FLOAT = 'float'; + public const ENUM = 'enum'; public const GUID = 'guid'; public const INTEGER = 'integer'; public const JSON = 'json'; diff --git a/tests/Functional/Schema/MySQLSchemaManagerTest.php b/tests/Functional/Schema/MySQLSchemaManagerTest.php index 852eb555423..893f673ca3a 100644 --- a/tests/Functional/Schema/MySQLSchemaManagerTest.php +++ b/tests/Functional/Schema/MySQLSchemaManagerTest.php @@ -561,7 +561,10 @@ public function testColumnIntrospection(): void $doctrineTypes = array_keys(Type::getTypesMap()); foreach ($doctrineTypes as $type) { - $table->addColumn('col_' . $type, $type, ['length' => 8, 'precision' => 8, 'scale' => 2]); + $table->addColumn('col_' . $type, $type, match ($type) { + Types::ENUM => ['values' => ['foo', 'bar']], + default => ['length' => 8, 'precision' => 8, 'scale' => 2], + }); } $this->dropAndCreateTable($table); diff --git a/tests/Functional/Types/EnumTypeTest.php b/tests/Functional/Types/EnumTypeTest.php new file mode 100644 index 00000000000..0f73b426d37 --- /dev/null +++ b/tests/Functional/Types/EnumTypeTest.php @@ -0,0 +1,132 @@ +dropTableIfExists('my_enum_table'); + } + + public function testIntrospectEnum(): void + { + if (! $this->connection->getDatabasePlatform() instanceof AbstractMySQLPlatform) { + self::markTestSkipped('This test requires MySQL or MariaDB.'); + } + + $this->connection->executeStatement(<<< 'SQL' + CREATE TABLE my_enum_table ( + id BIGINT NOT NULL PRIMARY KEY, + suit ENUM('hearts', 'diamonds', 'clubs', 'spades') NOT NULL DEFAULT 'hearts' + ); + SQL); + + $schemaManager = $this->connection->createSchemaManager(); + $table = $schemaManager->introspectTable('my_enum_table'); + + self::assertCount(2, $table->getColumns()); + self::assertTrue($table->hasColumn('suit')); + self::assertInstanceOf(EnumType::class, $table->getColumn('suit')->getType()); + self::assertSame(['hearts', 'diamonds', 'clubs', 'spades'], $table->getColumn('suit')->getValues()); + self::assertSame('hearts', $table->getColumn('suit')->getDefault()); + } + + public function testDeployEnum(): void + { + $schemaManager = $this->connection->createSchemaManager(); + $schema = new Schema(schemaConfig: $schemaManager->createSchemaConfig()); + $table = $schema->createTable('my_enum_table'); + $table->addColumn('id', Types::BIGINT, ['notnull' => true]); + $table->addColumn('suit', Types::ENUM, [ + 'values' => ['hearts', 'diamonds', 'clubs', 'spades'], + 'notnull' => true, + 'default' => 'hearts', + ]); + $table->setPrimaryKey(['id']); + + $schemaManager->createSchemaObjects($schema); + + $introspectedTable = $schemaManager->introspectTable('my_enum_table'); + + self::assertTrue($schemaManager->createComparator()->compareTables($table, $introspectedTable)->isEmpty()); + + $this->connection->insert('my_enum_table', ['id' => 1, 'suit' => 'hearts'], ['suit' => Types::ENUM]); + $this->connection->insert( + 'my_enum_table', + ['id' => 2, 'suit' => 'diamonds'], + ['suit' => Type::getType(Types::ENUM)], + ); + + self::assertEquals( + [[1, 'hearts'], [2, 'diamonds']], + $this->connection->fetchAllNumeric('SELECT id, suit FROM my_enum_table ORDER BY id ASC'), + ); + } + + public function testDeployEmptyEnum(): void + { + $schemaManager = $this->connection->createSchemaManager(); + $schema = new Schema(schemaConfig: $schemaManager->createSchemaConfig()); + $table = $schema->createTable('my_enum_table'); + $table->addColumn('id', Types::BIGINT, ['notnull' => true]); + $table->addColumn('suit', Types::ENUM); + $table->setPrimaryKey(['id']); + + $this->expectException(ColumnValuesRequired::class); + + $schemaManager->createSchemaObjects($schema); + } + + /** @param list $expectedValues */ + #[DataProvider('provideEnumDefinitions')] + public function testIntrospectEnumValues(string $definition, array $expectedValues): void + { + if (! $this->connection->getDatabasePlatform() instanceof AbstractMySQLPlatform) { + self::markTestSkipped('This test requires MySQL or MariaDB.'); + } + + $this->connection->executeStatement(<<< SQL + CREATE TABLE my_enum_table ( + id BIGINT NOT NULL PRIMARY KEY, + my_enum $definition DEFAULT NULL + ); + SQL); + + $schemaManager = $this->connection->createSchemaManager(); + $table = $schemaManager->introspectTable('my_enum_table'); + + self::assertInstanceOf(EnumType::class, $table->getColumn('my_enum')->getType()); + self::assertSame($expectedValues, $table->getColumn('my_enum')->getValues()); + self::assertNull($table->getColumn('my_enum')->getDefault()); + } + + /** @return iterable}> */ + public static function provideEnumDefinitions(): iterable + { + yield 'simple' => ['ENUM("a", "b", "c")', ['a', 'b', 'c']]; + yield 'empty first' => ['ENUM("", "a", "b", "c")', ['', 'a', 'b', 'c']]; + yield 'empty in the middle' => ['ENUM("a", "", "b", "c")', ['a', '', 'b', 'c']]; + yield 'empty last' => ['ENUM("a", "b", "c", "")', ['a', 'b', 'c', '']]; + yield 'with spaces' => ['ENUM("a b", "c d", "e f")', ['a b', 'c d', 'e f']]; + yield 'with quotes' => ['ENUM("a\'b", "c\'d", "e\'f")', ['a\'b', 'c\'d', 'e\'f']]; + yield 'with commas' => ['ENUM("a,b", "c,d", "e,f")', ['a,b', 'c,d', 'e,f']]; + yield 'with parentheses' => ['ENUM("(a)", "(b)", "(c)")', ['(a)', '(b)', '(c)']]; + yield 'with quotes and commas' => ['ENUM("a\'b", "c\'d", "e\'f")', ['a\'b', 'c\'d', 'e\'f']]; + yield 'with quotes and parentheses' => ['ENUM("(a)", "(b)", "(c)")', ['(a)', '(b)', '(c)']]; + yield 'with commas and parentheses' => ['ENUM("(a,b)", "(c,d)", "(e,f)")', ['(a,b)', '(c,d)', '(e,f)']]; + yield 'with quotes, commas and parentheses' + => ['ENUM("(a\'b)", "(c\'d)", "(e\'f)")', ['(a\'b)', '(c\'d)', '(e\'f)']]; + } +} diff --git a/tests/Schema/ColumnTest.php b/tests/Schema/ColumnTest.php index 4e99bba7ba2..c10bdd7be3e 100644 --- a/tests/Schema/ColumnTest.php +++ b/tests/Schema/ColumnTest.php @@ -52,6 +52,7 @@ public function testToArray(): void 'autoincrement' => false, 'columnDefinition' => null, 'comment' => '', + 'values' => [], 'foo' => 'bar', ];