Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Add support for creating temporary tables in schema #6409

Open
wants to merge 15 commits into
base: 4.3.x
Choose a base branch
from
Open
Show file tree
Hide file tree
Changes from 13 commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
27 changes: 26 additions & 1 deletion docs/en/reference/schema-representation.rst
Original file line number Diff line number Diff line change
Expand Up @@ -93,7 +93,32 @@ and absolutely not portable.
- **engine** (string): The DB engine used for the table. Currently only supported on MySQL.

- **unlogged** (boolean): Set a PostgreSQL table type as
`unlogged <https://www.postgresql.org/docs/current/sql-createtable.htmll>`_
`unlogged <https://www.postgresql.org/docs/current/sql-createtable.html#SQL-CREATETABLE-UNLOGGED>`_

- **temporary** (boolean or string): Set table type as temporary
Supported on DB2, MySQL, MariaDB, Oracle, PostgreSQL and SQLite. SQL Server does not have a specific DML for temporary tables.

Option values for MySQL, MariaDB, PostgreSQL and SQLite:

- true (bool)
- false (bool)

Option values for Oracle:

- global (string): emits CREATE GLOBAL TEMPORARY TABLE statement
- private (string): emits CREATE PRIVATE TEMPORARY TABLE statement, table name must begin with PRIVATE_TEMP_TABLE_PREFIX, default 'ORA$PTT'

Option values for DB2:

- created (string): emits CREATE GLOBAL TEMPORARY TABLE statement
- declared (string): emits DECLARE GLOBAL TEMPORARY TABLE statement

- **on_commit** (string): declare table's commit options, only used if option **temporary** is set.
Supported on Oracle and PostgreSQL

- ``preserve``: preserve rows on commit
- ``delete``: delete rows on commit
- ``drop``: drop table on commit - only supported by PostgreSQL

Column
~~~~~~
Expand Down
12 changes: 11 additions & 1 deletion src/Platforms/AbstractMySQLPlatform.php
Original file line number Diff line number Diff line change
Expand Up @@ -6,6 +6,7 @@

use Doctrine\DBAL\Connection;
use Doctrine\DBAL\Exception;
use Doctrine\DBAL\Exception\InvalidArgumentException;
use Doctrine\DBAL\Platforms\Keywords\KeywordList;
use Doctrine\DBAL\Platforms\Keywords\MySQLKeywords;
use Doctrine\DBAL\Schema\AbstractAsset;
Expand All @@ -24,6 +25,7 @@
use function count;
use function implode;
use function in_array;
use function is_bool;
use function is_numeric;
use function sprintf;
use function str_replace;
Expand Down Expand Up @@ -254,7 +256,15 @@ protected function _getCreateTableSQL(string $name, array $columns, array $optio

$sql = ['CREATE'];

if (! empty($options['temporary'])) {
$temporary = $options['temporary'] ?? false;
if (! is_bool($temporary)) {
throw new InvalidArgumentException(sprintf(
'invalid temporary specification for table %s',
$name,
));
}

if ($temporary === true) {
Comment on lines -257 to +267
Copy link
Member

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

This looks like a BC break. Do we need this additional strictness?

$sql[] = 'TEMPORARY';
}

Expand Down
49 changes: 41 additions & 8 deletions src/Platforms/DB2Platform.php
Original file line number Diff line number Diff line change
Expand Up @@ -5,6 +5,7 @@
namespace Doctrine\DBAL\Platforms;

use Doctrine\DBAL\Connection;
use Doctrine\DBAL\Exception\InvalidArgumentException;
use Doctrine\DBAL\Platforms\Exception\NotSupported;
use Doctrine\DBAL\Platforms\Keywords\DB2Keywords;
use Doctrine\DBAL\Platforms\Keywords\KeywordList;
Expand All @@ -20,6 +21,8 @@
use Doctrine\DBAL\Types\Types;

use function array_merge;
use function array_unique;
use function array_values;
use function count;
use function current;
use function explode;
Expand Down Expand Up @@ -241,20 +244,50 @@ public function getIndexDeclarationSQL(Index $index): string
*/
protected function _getCreateTableSQL(string $name, array $columns, array $options = []): array
{
$indexes = [];
if (isset($options['indexes'])) {
$indexes = $options['indexes'];
$columnListSql = $this->getColumnDeclarationListSQL($columns);

if (isset($options['uniqueConstraints']) && ! empty($options['uniqueConstraints'])) {
foreach ($options['uniqueConstraints'] as $definition) {
$columnListSql .= ', ' . $this->getUniqueConstraintDeclarationSQL($definition);
}
}

$options['indexes'] = [];
if (isset($options['primary']) && ! empty($options['primary'])) {
$columnListSql .= ', PRIMARY KEY(' . implode(', ', array_unique(array_values($options['primary']))) . ')';
}

$statement = match ($options['temporary'] ?? '') {
'' => 'CREATE TABLE ',
'created' => 'CREATE GLOBAL TEMPORARY TABLE ',
'declared' => 'DECLARE GLOBAL TEMPORARY TABLE ',
default => throw new InvalidArgumentException(sprintf(
'invalid temporary specification for table %s',
$name,
))
};
Comment on lines +259 to +267
Copy link
Member

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Okay, so for MySQL we demand that the temporary property is a bool, but for DB2 we want it to be a string? Can you elaborate on the difference between those two options? Do we need to support both?


$query = $statement . $name . ' (' . $columnListSql;
$check = $this->getCheckDeclarationSQL($columns);

if (! empty($check)) {
$query .= ', ' . $check;
}

$sqls = parent::_getCreateTableSQL($name, $columns, $options);
Copy link
Member

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Removing the call to the parent implementation seems to bloat this method big time. Can we somehow restore that call and make the diff smaller?

$query .= ')';

$sql = [$query];

if (isset($options['foreignKeys'])) {
foreach ($options['foreignKeys'] as $definition) {
$sql[] = $this->getCreateForeignKeySQL($definition, $name);
}
}

foreach ($indexes as $definition) {
$sqls[] = $this->getCreateIndexSQL($definition, $name);
foreach ($options['indexes'] ?? [] as $definition) {
$sql[] = $this->getCreateIndexSQL($definition, $name);
}

return $sqls;
return $sql;
}

/**
Expand Down
67 changes: 62 additions & 5 deletions src/Platforms/OraclePlatform.php
Original file line number Diff line number Diff line change
Expand Up @@ -5,6 +5,7 @@
namespace Doctrine\DBAL\Platforms;

use Doctrine\DBAL\Connection;
use Doctrine\DBAL\Exception\InvalidArgumentException;
use Doctrine\DBAL\Exception\InvalidColumnType\ColumnLengthRequired;
use Doctrine\DBAL\Platforms\Keywords\KeywordList;
use Doctrine\DBAL\Platforms\Keywords\OracleKeywords;
Expand All @@ -17,15 +18,18 @@
use Doctrine\DBAL\TransactionIsolationLevel;
use Doctrine\DBAL\Types\BinaryType;
use Doctrine\DBAL\Types\Types;
use InvalidArgumentException;

use function array_merge;
use function array_unique;
use function array_values;
use function count;
use function explode;
use function implode;
use function sprintf;
use function str_contains;
use function str_starts_with;
use function strlen;
use function strtolower;
use function strtoupper;
use function substr;

Expand Down Expand Up @@ -313,9 +317,62 @@ public function getListSequencesSQL(string $database): string
*/
protected function _getCreateTableSQL(string $name, array $columns, array $options = []): array
{
$indexes = $options['indexes'] ?? [];
$options['indexes'] = [];
$sql = parent::_getCreateTableSQL($name, $columns, $options);
Copy link
Member

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Same question here. Do we have to remove the call to the parent method?

$columnListSql = $this->getColumnDeclarationListSQL($columns);

if (isset($options['uniqueConstraints']) && ! empty($options['uniqueConstraints'])) {
foreach ($options['uniqueConstraints'] as $definition) {
$columnListSql .= ', ' . $this->getUniqueConstraintDeclarationSQL($definition);
}
}

if (isset($options['primary']) && ! empty($options['primary'])) {
$columnListSql .= ', PRIMARY KEY(' . implode(', ', array_unique(array_values($options['primary']))) . ')';
}

$temporary = match ($options['temporary'] ?? '') {
'' => '',
'global' => 'GLOBAL TEMPORARY ',
'private' => 'PRIVATE TEMPORARY ',
default => throw new InvalidArgumentException(sprintf(
'invalid temporary specification for table %s',
$name,
))
};
Comment on lines +332 to +340
Copy link
Member

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Same question here. Why are my options for temporary different for each platform?


if (($options['temporary'] ?? '') === 'private' && str_starts_with('ora$ptt_', strtolower($name)) === false) {
throw new InvalidArgumentException(sprintf(
'invalid name "%s" for private temporary table',
$name,
));
}

$onCommit = $temporary !== ''
? match ($options['on_commit'] ?? '') {
'' => '',
'preserve' => ' ON COMMIT PRESERVE ROWS',
'delete' => ' ON COMMIT DELETE ROWS',
default => throw new InvalidArgumentException(sprintf(
'invalid on commit clause on table %s',
$name,
))
} : '';

$query = 'CREATE ' . $temporary . 'TABLE ' . $name . ' (' . $columnListSql;
$check = $this->getCheckDeclarationSQL($columns);

if (! empty($check)) {
$query .= ', ' . $check;
}

$query .= ')' . $onCommit;

$sql = [$query];

if (isset($options['foreignKeys'])) {
foreach ($options['foreignKeys'] as $definition) {
$sql[] = $this->getCreateForeignKeySQL($definition, $name);
}
}

foreach ($columns as $column) {
if (isset($column['sequence'])) {
Expand All @@ -331,7 +388,7 @@ protected function _getCreateTableSQL(string $name, array $columns, array $optio
$sql = array_merge($sql, $this->getCreateAutoincrementSql($column['name'], $name));
}

foreach ($indexes as $index) {
foreach ($options['indexes'] as $index) {
$sql[] = $this->getCreateIndexSQL($index, $name);
}

Expand Down
25 changes: 24 additions & 1 deletion src/Platforms/PostgreSQLPlatform.php
Original file line number Diff line number Diff line change
Expand Up @@ -5,6 +5,7 @@
namespace Doctrine\DBAL\Platforms;

use Doctrine\DBAL\Connection;
use Doctrine\DBAL\Exception\InvalidArgumentException;
use Doctrine\DBAL\Platforms\Keywords\KeywordList;
use Doctrine\DBAL\Platforms\Keywords\PostgreSQLKeywords;
use Doctrine\DBAL\Schema\ForeignKeyConstraint;
Expand Down Expand Up @@ -383,9 +384,31 @@ protected function _getCreateTableSQL(string $name, array $columns, array $optio
$queryFields .= ', PRIMARY KEY(' . implode(', ', $keyColumns) . ')';
}

$temporary = $options['temporary'] ?? false;
if (! is_bool($temporary)) {
throw new InvalidArgumentException(sprintf(
'invalid temporary specification for table %s',
$name,
));
}

$onCommit = $temporary
? match ($options['on_commit'] ?? '') {
'' => '',
'preserve' => ' ON COMMIT PRESERVE ROWS',
'delete' => ' ON COMMIT DELETE ROWS',
'drop' => ' ON COMMIT DROP',
default => throw new InvalidArgumentException(sprintf(
'invalid on commit clause on table %s',
$name,
))
} : '';

$temporary = $temporary ? ' TEMPORARY' : '';

$unlogged = isset($options['unlogged']) && $options['unlogged'] === true ? ' UNLOGGED' : '';

$query = 'CREATE' . $unlogged . ' TABLE ' . $name . ' (' . $queryFields . ')';
$query = 'CREATE' . $temporary . $unlogged . ' TABLE ' . $name . ' (' . $queryFields . ')' . $onCommit;

$sql = [$query];

Expand Down
13 changes: 12 additions & 1 deletion src/Platforms/SQLitePlatform.php
Original file line number Diff line number Diff line change
Expand Up @@ -32,6 +32,7 @@
use function count;
use function explode;
use function implode;
use function is_bool;
use function sprintf;
use function str_replace;
use function strpos;
Expand Down Expand Up @@ -293,7 +294,17 @@ protected function _getCreateTableSQL(string $name, array $columns, array $optio
$tableComment = $this->getInlineTableCommentSQL($comment);
}

$query = ['CREATE TABLE ' . $name . ' ' . $tableComment . '(' . $queryFields . ')'];
$temporary = $options['temporary'] ?? false;
if (! is_bool($temporary)) {
throw new \Doctrine\DBAL\Exception\InvalidArgumentException(sprintf(
'invalid temporary specification for table %s',
$name,
));
}

$temporary = $temporary ? 'TEMPORARY ' : '';

$query = ['CREATE ' . $temporary . 'TABLE ' . $name . ' ' . $tableComment . '(' . $queryFields . ')'];

if (isset($options['alter']) && $options['alter'] === true) {
return $query;
Expand Down
49 changes: 49 additions & 0 deletions tests/Platforms/AbstractMySQLPlatformTestCase.php
Original file line number Diff line number Diff line change
Expand Up @@ -4,6 +4,7 @@

namespace Doctrine\DBAL\Tests\Platforms;

use Doctrine\DBAL\Exception\InvalidArgumentException;
use Doctrine\DBAL\Exception\InvalidColumnDeclaration;
use Doctrine\DBAL\Platforms\AbstractMySQLPlatform;
use Doctrine\DBAL\Platforms\MySQL;
Expand All @@ -14,6 +15,8 @@
use Doctrine\DBAL\Schema\Table;
use Doctrine\DBAL\TransactionIsolationLevel;
use Doctrine\DBAL\Types\Types;
use Generator;
use PHPUnit\Framework\Attributes\DataProvider;

use function array_shift;

Expand Down Expand Up @@ -176,6 +179,52 @@ public function testGetDateTimeTypeDeclarationSql(): void
self::assertEquals('DATETIME', $this->platform->getDateTimeTypeDeclarationSQL([]));
}

#[DataProvider('mysqlTemporaryProvider')]
public function testGenerateTemporaryTable(
bool $temporary,
string $expectedSQL,
): void {
$table = new Table('mytable');
$table->addOption('temporary', $temporary);

$table->addColumn('foo', Types::STRING, ['length' => 255]);

self::assertEquals(
[$expectedSQL],
$this->platform->getCreateTableSQL($table),
);
}

public static function mysqlTemporaryProvider(): Generator
{
yield 'temporary' => [true, 'CREATE TEMPORARY TABLE mytable (foo VARCHAR(255) NOT NULL)'];
yield 'non temporary' => [false, 'CREATE TABLE mytable (foo VARCHAR(255) NOT NULL)'];
}

#[DataProvider('mysqlInvalidTemporaryProvider')]
public function testInvalidTemporaryTableOptions(
string $table,
mixed $temporary,
string $expectedException,
string $expectedMessage,
): void {
$this->expectException($expectedException);
$this->expectExceptionMessage($expectedMessage);

$table = new Table($table);
$table->addOption('temporary', $temporary);

$table->addColumn('foo', Types::STRING, ['length' => 255]);

$this->platform->getCreateTableSQL($table);
}

public static function mysqlInvalidTemporaryProvider(): Generator
{
yield 'invalid temporary specification' =>
['mytable', 'invalid', InvalidArgumentException::class, 'invalid temporary specification for table mytable'];
}

/** @return string[] */
protected function getQuotedColumnInPrimaryKeySQL(): array
{
Expand Down
Loading