From 6559c32349d952c246dff62e5ad469c5ef3f118a Mon Sep 17 00:00:00 2001 From: nio-dtp Date: Thu, 21 Nov 2024 12:52:12 +0100 Subject: [PATCH 1/6] Add CTE support to select in QueryBuilder --- docs/en/reference/query-builder.rst | 20 ++++ src/Platforms/AbstractPlatform.php | 6 + src/Platforms/MySQL80Platform.php | 6 + src/Platforms/MySQLPlatform.php | 7 ++ src/Query/QueryBuilder.php | 46 ++++++- src/Query/With.php | 17 +++ src/SQL/Builder/WithSQLBuilder.php | 31 +++++ tests/Functional/Query/QueryBuilderTest.php | 125 ++++++++++++++++++++ tests/Query/QueryBuilderTest.php | 31 +++++ 9 files changed, 288 insertions(+), 1 deletion(-) create mode 100644 src/Query/With.php create mode 100644 src/SQL/Builder/WithSQLBuilder.php diff --git a/docs/en/reference/query-builder.rst b/docs/en/reference/query-builder.rst index 5b54af3ca07..069b64216fe 100644 --- a/docs/en/reference/query-builder.rst +++ b/docs/en/reference/query-builder.rst @@ -368,6 +368,26 @@ or QueryBuilder instances to one of the following methods: ->orderBy('field', 'DESC') ->setMaxResults(100); +WITH-Clause +~~~~~~~~~~~ + +To define Common Table Expressions (CTEs) that can be used in select query. + +* ``with(string $name, string|QueryBuilder $queryBuilder, array $columns = [])`` + +.. code-block:: php + + with('cte_a', 'SELECT id FROM table_a') + ->with('cte_b', 'SELECT id FROM table_b') + ->select('id') + ->from('cte_b', 'b') + ->join('b', 'cte_a', 'a', 'a.id = b.id'); + +Multiple CTEs can be defined by calling the with method multiple times. + Building Expressions -------------------- diff --git a/src/Platforms/AbstractPlatform.php b/src/Platforms/AbstractPlatform.php index d2435c1dd42..5ae993fc9dd 100644 --- a/src/Platforms/AbstractPlatform.php +++ b/src/Platforms/AbstractPlatform.php @@ -31,6 +31,7 @@ use Doctrine\DBAL\SQL\Builder\DefaultUnionSQLBuilder; use Doctrine\DBAL\SQL\Builder\SelectSQLBuilder; use Doctrine\DBAL\SQL\Builder\UnionSQLBuilder; +use Doctrine\DBAL\SQL\Builder\WithSQLBuilder; use Doctrine\DBAL\SQL\Parser; use Doctrine\DBAL\TransactionIsolationLevel; use Doctrine\DBAL\Types; @@ -802,6 +803,11 @@ public function createUnionSQLBuilder(): UnionSQLBuilder return new DefaultUnionSQLBuilder($this); } + public function createWithSQLBuilder(): WithSQLBuilder + { + return new WithSQLBuilder(); + } + /** * @internal * diff --git a/src/Platforms/MySQL80Platform.php b/src/Platforms/MySQL80Platform.php index 547742d6a08..01dcfb40107 100644 --- a/src/Platforms/MySQL80Platform.php +++ b/src/Platforms/MySQL80Platform.php @@ -7,6 +7,7 @@ use Doctrine\DBAL\Platforms\Keywords\KeywordList; use Doctrine\DBAL\Platforms\Keywords\MySQL80Keywords; use Doctrine\DBAL\SQL\Builder\SelectSQLBuilder; +use Doctrine\DBAL\SQL\Builder\WithSQLBuilder; use Doctrine\Deprecations\Deprecation; /** @@ -32,4 +33,9 @@ public function createSelectSQLBuilder(): SelectSQLBuilder { return AbstractPlatform::createSelectSQLBuilder(); } + + public function createWithSQLBuilder(): WithSQLBuilder + { + return AbstractPlatform::createWithSQLBuilder(); + } } diff --git a/src/Platforms/MySQLPlatform.php b/src/Platforms/MySQLPlatform.php index 0d90e38509f..ad804b36aa2 100644 --- a/src/Platforms/MySQLPlatform.php +++ b/src/Platforms/MySQLPlatform.php @@ -4,9 +4,11 @@ namespace Doctrine\DBAL\Platforms; +use Doctrine\DBAL\Platforms\Exception\NotSupported; use Doctrine\DBAL\Platforms\Keywords\KeywordList; use Doctrine\DBAL\Platforms\Keywords\MySQLKeywords; use Doctrine\DBAL\Schema\Index; +use Doctrine\DBAL\SQL\Builder\WithSQLBuilder; use Doctrine\DBAL\Types\BlobType; use Doctrine\DBAL\Types\TextType; use Doctrine\Deprecations\Deprecation; @@ -35,6 +37,11 @@ public function getDefaultValueDeclarationSQL(array $column): string return parent::getDefaultValueDeclarationSQL($column); } + public function createWithSQLBuilder(): WithSQLBuilder + { + throw NotSupported::new(__METHOD__); + } + /** * {@inheritDoc} */ diff --git a/src/Query/QueryBuilder.php b/src/Query/QueryBuilder.php index 3cbde0f035d..8495d9e8424 100644 --- a/src/Query/QueryBuilder.php +++ b/src/Query/QueryBuilder.php @@ -160,6 +160,13 @@ class QueryBuilder */ private array $unionParts = []; + /** + * The common table expression parts. + * + * @var With[] + */ + private array $withParts = []; + /** * The query cache profile used for caching results. */ @@ -557,6 +564,33 @@ public function addUnion(string|QueryBuilder $part, UnionType $type = UnionType: return $this; } + /** + * Add a Common Table Expression to be used for a select query. + * + * + * // WITH cte_name AS (SELECT 1 AS column1) + * $qb = $conn->createQueryBuilder() + * ->with('cte_name', 'SELECT 1 AS column1'); + * + * // WITH cte_name(column1) AS (SELECT 1 AS column1) + * $qb = $conn->createQueryBuilder() + * ->with('cte_name', 'SELECT 1 AS column1', ['column1']); + * + * + * @param string $name The name of the CTE + * @param string[] $columns The optional columns list to select in the CTE. + * + * @return $this This QueryBuilder instance. + */ + public function with(string $name, string|QueryBuilder $part, array $columns = []): self + { + $this->withParts[] = new With($name, $part, $columns); + + $this->sql = null; + + return $this; + } + /** * Specifies an item that is to be returned in the query result. * Replaces any previously specified selections, if any. @@ -1266,7 +1300,15 @@ private function getSQLForSelect(): string throw new QueryException('No SELECT expressions given. Please use select() or addSelect().'); } - return $this->connection->getDatabasePlatform() + $databasePlatform = $this->connection->getDatabasePlatform(); + $selectParts = []; + if (count($this->withParts) > 0) { + $selectParts[] = $databasePlatform + ->createWithSQLBuilder() + ->buildSQL(...$this->withParts); + } + + $selectParts[] = $databasePlatform ->createSelectSQLBuilder() ->buildSQL( new SelectQuery( @@ -1281,6 +1323,8 @@ private function getSQLForSelect(): string $this->forUpdate, ), ); + + return implode(' ', $selectParts); } /** diff --git a/src/Query/With.php b/src/Query/With.php new file mode 100644 index 00000000000..12ec5a0dfe0 --- /dev/null +++ b/src/Query/With.php @@ -0,0 +1,17 @@ +name]; + if (count($part->columns) > 0) { + $withPart[] = '(' . implode(', ', $part->columns) . ')'; + } + + $withPart[] = ' AS (' . $part->query . ')'; + $withParts[] = implode('', $withPart); + } + + return 'WITH ' . implode(', ', $withParts); + } +} diff --git a/tests/Functional/Query/QueryBuilderTest.php b/tests/Functional/Query/QueryBuilderTest.php index b54a9376804..a59808df012 100644 --- a/tests/Functional/Query/QueryBuilderTest.php +++ b/tests/Functional/Query/QueryBuilderTest.php @@ -4,10 +4,12 @@ namespace Doctrine\DBAL\Tests\Functional\Query; +use Doctrine\DBAL\ArrayParameterType; use Doctrine\DBAL\DriverManager; use Doctrine\DBAL\Exception; use Doctrine\DBAL\ParameterType; use Doctrine\DBAL\Platforms\DB2Platform; +use Doctrine\DBAL\Platforms\Exception\NotSupported; use Doctrine\DBAL\Platforms\MariaDB1060Platform; use Doctrine\DBAL\Platforms\MariaDBPlatform; use Doctrine\DBAL\Platforms\MySQL80Platform; @@ -332,6 +334,117 @@ public function testUnionAndAddUnionWorksWithQueryBuilderPartsAndReturnsExpected self::assertSame($expectedRows, $qb->executeQuery()->fetchAllAssociative()); } + public function testSelectWithCTENamedParameter(): void + { + if (! $this->platformSupportsCTEs()) { + self::markTestSkipped('The database platform does not support CTE.'); + } + + if (! $this->platformSupportsCTEColumnDefinition()) { + self::markTestSkipped('The database platform does not support CTE column definition.'); + } + + $expectedRows = $this->prepareExpectedRows([['virtual_id' => 1]]); + $qb = $this->connection->createQueryBuilder(); + + $cteQueryBuilder = $this->connection->createQueryBuilder(); + $cteQueryBuilder->select('id AS virtual_id') + ->from('for_update') + ->where('virtual_id = :id'); + + $qb->with('cte_a', $cteQueryBuilder, ['virtual_id']) + ->select('virtual_id') + ->from('cte_a') + ->setParameter('id', 1); + + self::assertSame($expectedRows, $qb->executeQuery()->fetchAllAssociative()); + } + + public function testSelectWithCTEPositionalParameter(): void + { + if (! $this->platformSupportsCTEs()) { + self::markTestSkipped('The database platform does not support CTE.'); + } + + if (! $this->platformSupportsCTEColumnDefinition()) { + self::markTestSkipped('The database platform does not support CTE column definition.'); + } + + $expectedRows = $this->prepareExpectedRows([['virtual_id' => 1]]); + $qb = $this->connection->createQueryBuilder(); + + $cteQueryBuilder1 = $this->connection->createQueryBuilder(); + $cteQueryBuilder1->select('id AS virtual_id') + ->from('for_update') + ->where($qb->expr()->eq('virtual_id', '?')); + + $cteQueryBuilder2 = $this->connection->createQueryBuilder(); + $cteQueryBuilder2->select('id AS virtual_id') + ->from('for_update') + ->where($qb->expr()->in('id', '?')); + + $qb->with('cte_a', $cteQueryBuilder1, ['virtual_id']) + ->with('cte_b', $cteQueryBuilder2, ['virtual_id']) + ->select('a.virtual_id') + ->from('cte_a', 'a') + ->join('a', 'cte_b', 'b', 'a.virtual_id = b.virtual_id') + ->setParameters([1, [1, 2]], [ParameterType::INTEGER, ArrayParameterType::INTEGER]); + + self::assertSame($expectedRows, $qb->executeQuery()->fetchAllAssociative()); + } + + public function testSelectWithCTEUnion(): void + { + if (! $this->platformSupportsCTEs()) { + self::markTestSkipped('The database platform does not support CTE.'); + } + + $expectedRows = $this->prepareExpectedRows([['id' => 2], ['id' => 1]]); + $qb = $this->connection->createQueryBuilder(); + + $subQueryBuilder1 = $this->connection->createQueryBuilder(); + $subQueryBuilder1->select('id') + ->from('for_update') + ->where($qb->expr()->eq('id', '?')); + + $subQueryBuilder2 = $this->connection->createQueryBuilder(); + $subQueryBuilder2->select('id') + ->from('for_update') + ->where($qb->expr()->eq('id', '?')); + + $subQueryBuilder3 = $this->connection->createQueryBuilder(); + $subQueryBuilder3->union($subQueryBuilder1) + ->addUnion($subQueryBuilder2, UnionType::DISTINCT); + + $qb->with('cte_a', $subQueryBuilder3) + ->select('id') + ->from('cte_a') + ->orderBy('id', 'DESC') + ->setParameters([1, 2]); + + self::assertSame($expectedRows, $qb->executeQuery()->fetchAllAssociative()); + } + + public function testPlatformDoesNotSupportCTE(): void + { + if ($this->platformSupportsCTEs()) { + self::markTestSkipped('The database platform does support CTE.'); + } + + $qb = $this->connection->createQueryBuilder(); + + $cteQueryBuilder = $this->connection->createQueryBuilder(); + $cteQueryBuilder->select('id') + ->from('for_update'); + + $qb->with('cte_a', $cteQueryBuilder) + ->select('id') + ->from('cte_a'); + + self::expectException(NotSupported::class); + $qb->executeQuery(); + } + /** * @param array> $rows * @@ -380,4 +493,16 @@ private function platformSupportsSkipLocked(): bool return ! $platform instanceof SQLitePlatform; } + + private function platformSupportsCTEs(): bool + { + $platform = $this->connection->getDatabasePlatform(); + + return ! $platform instanceof MySQLPlatform || $platform instanceof MySQL80Platform; + } + + private function platformSupportsCTEColumnDefinition(): bool + { + return $this->connection->getDatabasePlatform() instanceof SQLitePlatform; + } } diff --git a/tests/Query/QueryBuilderTest.php b/tests/Query/QueryBuilderTest.php index 5cfa4cb6b01..4c567fc5576 100644 --- a/tests/Query/QueryBuilderTest.php +++ b/tests/Query/QueryBuilderTest.php @@ -16,6 +16,7 @@ use Doctrine\DBAL\Result; use Doctrine\DBAL\SQL\Builder\DefaultSelectSQLBuilder; use Doctrine\DBAL\SQL\Builder\DefaultUnionSQLBuilder; +use Doctrine\DBAL\SQL\Builder\WithSQLBuilder; use Doctrine\DBAL\Types\Types; use PHPUnit\Framework\Attributes\DataProvider; use PHPUnit\Framework\MockObject\MockObject; @@ -48,6 +49,8 @@ protected function setUp(): void ->willReturn(new DefaultSelectSQLBuilder($platform, null, null)); $platform->method('createUnionSQLBuilder') ->willReturn(new DefaultUnionSQLBuilder($platform)); + $platform->method('createWithSQLBuilder') + ->willReturn(new WithSQLBuilder()); $this->conn->method('getDatabasePlatform') ->willReturn($platform); @@ -850,6 +853,34 @@ public function testSelectAllWithoutTableAlias(): void self::assertEquals('SELECT * FROM users', (string) $qb); } + public function testSelectWithCTE(): void + { + $qbWith = new QueryBuilder($this->conn); + $qbWith->select('ta.id', 'ta.name', 'ta.table_b_id') + ->from('table_a', 'ta') + ->where('ta.name LIKE :name'); + + $qbAddWith = new QueryBuilder($this->conn); + $qbAddWith->select('ca.id AS virtual_id, ca.name AS virtual_name') + ->from('cte_a', 'ca') + ->join('ca', 'table_b', 'tb', 'ca.table_b_id = tb.id'); + + $qb = new QueryBuilder($this->conn); + $qb->with('cte_a', $qbWith) + ->with('cte_b', $qbAddWith, ['virtual_id', 'virtual_name']) + ->select('cb.*') + ->from('cte_b', 'cb'); + + self::assertEquals( + 'WITH cte_a AS (SELECT ta.id, ta.name, ta.table_b_id FROM table_a ta WHERE ta.name LIKE :name)' + . ', cte_b(virtual_id, virtual_name) AS ' + . '(SELECT ca.id AS virtual_id, ca.name AS virtual_name ' + . 'FROM cte_a ca INNER JOIN table_b tb ON ca.table_b_id = tb.id) ' + . 'SELECT cb.* FROM cte_b cb', + (string) $qb, + ); + } + public function testGetParameterType(): void { $qb = new QueryBuilder($this->conn); From 11280cdb6f2fee8b46b9a94e6dfcff9178dd8ef5 Mon Sep 17 00:00:00 2001 From: nio-dtp Date: Tue, 3 Dec 2024 22:10:43 +0100 Subject: [PATCH 2/6] Bind parameters to CTE level --- src/Query/QueryBuilder.php | 41 ++++++++++++++++++++- tests/Functional/Query/QueryBuilderTest.php | 17 +++++---- 2 files changed, 49 insertions(+), 9 deletions(-) diff --git a/src/Query/QueryBuilder.php b/src/Query/QueryBuilder.php index 8495d9e8424..10fa13d517f 100644 --- a/src/Query/QueryBuilder.php +++ b/src/Query/QueryBuilder.php @@ -309,14 +309,51 @@ public function fetchFirstColumn(): array */ public function executeQuery(): Result { + [$params, $types] = $this->boundParameters(); + return $this->connection->executeQuery( $this->getSQL(), - $this->params, - $this->types, + $params, + $types, $this->resultCacheProfile, ); } + /** + * Retrieve parameters and types bound to all queries (optional CTEs and main query). + * + * @return array{ + * list|array, + * WrapperParameterTypeArray, + * } The parameters and types bound to the CTE queries merged with those bound to the main query. + */ + private function boundParameters(): array + { + if (count($this->withParts) === 0) { + return [$this->params, $this->types]; + } + + $cteParams = $cteParamsTypes = []; + + foreach ($this->withParts as $withPart) { + if (! $withPart->query instanceof self) { + continue; + } + + $cteParams = array_merge($cteParams, $withPart->query->params); + $cteParamsTypes = array_merge($cteParamsTypes, $withPart->query->types); + } + + if (count($cteParams) === 0) { + return [$this->params, $this->types]; + } + + return [ + array_merge($cteParams, $this->params), + array_merge($cteParamsTypes, $this->types), + ]; + } + /** * Executes an SQL statement and returns the number of affected rows. * diff --git a/tests/Functional/Query/QueryBuilderTest.php b/tests/Functional/Query/QueryBuilderTest.php index a59808df012..09e23d02d19 100644 --- a/tests/Functional/Query/QueryBuilderTest.php +++ b/tests/Functional/Query/QueryBuilderTest.php @@ -350,17 +350,17 @@ public function testSelectWithCTENamedParameter(): void $cteQueryBuilder = $this->connection->createQueryBuilder(); $cteQueryBuilder->select('id AS virtual_id') ->from('for_update') - ->where('virtual_id = :id'); + ->where('virtual_id = :id') + ->setParameter('id', 1); $qb->with('cte_a', $cteQueryBuilder, ['virtual_id']) ->select('virtual_id') - ->from('cte_a') - ->setParameter('id', 1); + ->from('cte_a'); self::assertSame($expectedRows, $qb->executeQuery()->fetchAllAssociative()); } - public function testSelectWithCTEPositionalParameter(): void + public function testSelectWithCTEPositionalParametersBindForEachQuery(): void { if (! $this->platformSupportsCTEs()) { self::markTestSkipped('The database platform does not support CTE.'); @@ -376,19 +376,22 @@ public function testSelectWithCTEPositionalParameter(): void $cteQueryBuilder1 = $this->connection->createQueryBuilder(); $cteQueryBuilder1->select('id AS virtual_id') ->from('for_update') - ->where($qb->expr()->eq('virtual_id', '?')); + ->where($cteQueryBuilder1->expr()->eq('id', '?')) + ->setParameter(0, 1, ParameterType::INTEGER); $cteQueryBuilder2 = $this->connection->createQueryBuilder(); $cteQueryBuilder2->select('id AS virtual_id') ->from('for_update') - ->where($qb->expr()->in('id', '?')); + ->where($cteQueryBuilder2->expr()->in('id', ':id')) + ->setParameter('id', [1, 2], ArrayParameterType::INTEGER); $qb->with('cte_a', $cteQueryBuilder1, ['virtual_id']) ->with('cte_b', $cteQueryBuilder2, ['virtual_id']) ->select('a.virtual_id') ->from('cte_a', 'a') ->join('a', 'cte_b', 'b', 'a.virtual_id = b.virtual_id') - ->setParameters([1, [1, 2]], [ParameterType::INTEGER, ArrayParameterType::INTEGER]); + ->where($qb->expr()->eq('a.virtual_id', '?')) + ->setParameter(0, 1, ParameterType::INTEGER); self::assertSame($expectedRows, $qb->executeQuery()->fetchAllAssociative()); } From 19b6ad3547ba97ffb19167096a0a7a1bf1eae643 Mon Sep 17 00:00:00 2001 From: nio-dtp Date: Sat, 7 Dec 2024 09:12:00 +0100 Subject: [PATCH 3/6] Rework naming to use CTE everywhere --- docs/en/reference/query-builder.rst | 21 +++++++-- src/Query/CommonTableExpression.php | 23 ++++++++++ src/Query/QueryBuilder.php | 51 ++++++++++----------- src/Query/With.php | 17 ------- src/SQL/Builder/WithSQLBuilder.php | 18 ++++---- tests/Functional/Query/QueryBuilderTest.php | 2 +- tests/Query/QueryBuilderTest.php | 21 ++++++--- 7 files changed, 90 insertions(+), 63 deletions(-) create mode 100644 src/Query/CommonTableExpression.php delete mode 100644 src/Query/With.php diff --git a/docs/en/reference/query-builder.rst b/docs/en/reference/query-builder.rst index 069b64216fe..2afe7d16486 100644 --- a/docs/en/reference/query-builder.rst +++ b/docs/en/reference/query-builder.rst @@ -368,26 +368,39 @@ or QueryBuilder instances to one of the following methods: ->orderBy('field', 'DESC') ->setMaxResults(100); -WITH-Clause +Common Table Expressions ~~~~~~~~~~~ To define Common Table Expressions (CTEs) that can be used in select query. -* ``with(string $name, string|QueryBuilder $queryBuilder, array $columns = [])`` +* ``with(string $name, string|QueryBuilder $queryBuilder, ?array $columns = null)`` .. code-block:: php select('id') + ->from('table_a') + ->where('id = :id') + ->setParameter('id', 1); + + $cteQueryBuilder2 + ->select('id') + ->from('table_b'); + $queryBuilder - ->with('cte_a', 'SELECT id FROM table_a') - ->with('cte_b', 'SELECT id FROM table_b') + ->with('cte_a', $cteQueryBuilder1) + ->with('cte_b', $cteQueryBuilder2) ->select('id') ->from('cte_b', 'b') ->join('b', 'cte_a', 'a', 'a.id = b.id'); Multiple CTEs can be defined by calling the with method multiple times. +Parameters used in a CTE should be defined directly in the QueryBuilder of the CTE. +This way, the CTE builders are naturally composable. + Building Expressions -------------------- diff --git a/src/Query/CommonTableExpression.php b/src/Query/CommonTableExpression.php new file mode 100644 index 00000000000..81443adc7a7 --- /dev/null +++ b/src/Query/CommonTableExpression.php @@ -0,0 +1,23 @@ +boundParameters(); + [$params, $types] = $this->buildParametersAndTypes(); return $this->connection->executeQuery( $this->getSQL(), @@ -320,28 +320,24 @@ public function executeQuery(): Result } /** - * Retrieve parameters and types bound to all queries (optional CTEs and main query). + * Build then return parameters and types for the query. * * @return array{ * list|array, * WrapperParameterTypeArray, - * } The parameters and types bound to the CTE queries merged with those bound to the main query. + * } The parameters and types for the query. */ - private function boundParameters(): array + private function buildParametersAndTypes(): array { - if (count($this->withParts) === 0) { - return [$this->params, $this->types]; - } + $cteParams = $cteParamTypes = []; - $cteParams = $cteParamsTypes = []; - - foreach ($this->withParts as $withPart) { - if (! $withPart->query instanceof self) { + foreach ($this->commonTableExpressions as $cte) { + if (! $cte->query instanceof self) { continue; } - $cteParams = array_merge($cteParams, $withPart->query->params); - $cteParamsTypes = array_merge($cteParamsTypes, $withPart->query->types); + $cteParams = array_merge($cteParams, $cte->query->params); + $cteParamTypes = array_merge($cteParamTypes, $cte->query->types); } if (count($cteParams) === 0) { @@ -350,7 +346,7 @@ private function boundParameters(): array return [ array_merge($cteParams, $this->params), - array_merge($cteParamsTypes, $this->types), + array_merge($cteParamTypes, $this->types), ]; } @@ -605,23 +601,26 @@ public function addUnion(string|QueryBuilder $part, UnionType $type = UnionType: * Add a Common Table Expression to be used for a select query. * * - * // WITH cte_name AS (SELECT 1 AS column1) + * // WITH cte_name AS (SELECT id AS column1 FROM table_a) * $qb = $conn->createQueryBuilder() - * ->with('cte_name', 'SELECT 1 AS column1'); + * ->with('cte_name', 'SELECT id AS column1 FROM table_a'); * - * // WITH cte_name(column1) AS (SELECT 1 AS column1) + * // WITH cte_name(column1) AS (SELECT id AS column1 FROM table_a) * $qb = $conn->createQueryBuilder() - * ->with('cte_name', 'SELECT 1 AS column1', ['column1']); + * ->with('cte_name', 'SELECT id AS column1 FROM table_a', ['column1']); * * - * @param string $name The name of the CTE - * @param string[] $columns The optional columns list to select in the CTE. + * @param string $name The name of the CTE + * @param string[]|null $columns The optional columns list to select in the CTE. + * If not provided, the columns are inferred from the CTE. * * @return $this This QueryBuilder instance. + * + * @throws QueryException Setting an empty array as columns is not allowed. */ - public function with(string $name, string|QueryBuilder $part, array $columns = []): self + public function with(string $name, string|QueryBuilder $part, ?array $columns = null): self { - $this->withParts[] = new With($name, $part, $columns); + $this->commonTableExpressions[] = new CommonTableExpression($name, $part, $columns); $this->sql = null; @@ -1339,10 +1338,10 @@ private function getSQLForSelect(): string $databasePlatform = $this->connection->getDatabasePlatform(); $selectParts = []; - if (count($this->withParts) > 0) { + if (count($this->commonTableExpressions) > 0) { $selectParts[] = $databasePlatform ->createWithSQLBuilder() - ->buildSQL(...$this->withParts); + ->buildSQL(...$this->commonTableExpressions); } $selectParts[] = $databasePlatform diff --git a/src/Query/With.php b/src/Query/With.php deleted file mode 100644 index 12ec5a0dfe0..00000000000 --- a/src/Query/With.php +++ /dev/null @@ -1,17 +0,0 @@ -name]; - if (count($part->columns) > 0) { - $withPart[] = '(' . implode(', ', $part->columns) . ')'; + $ctePart = [$part->name]; + if ($part->columns !== null && count($part->columns) > 0) { + $ctePart[] = '(' . implode(', ', $part->columns) . ')'; } - $withPart[] = ' AS (' . $part->query . ')'; - $withParts[] = implode('', $withPart); + $ctePart[] = ' AS (' . $part->query . ')'; + $cteParts[] = implode('', $ctePart); } - return 'WITH ' . implode(', ', $withParts); + return 'WITH ' . implode(', ', $cteParts); } } diff --git a/tests/Functional/Query/QueryBuilderTest.php b/tests/Functional/Query/QueryBuilderTest.php index 09e23d02d19..d3a57cd2cb4 100644 --- a/tests/Functional/Query/QueryBuilderTest.php +++ b/tests/Functional/Query/QueryBuilderTest.php @@ -417,7 +417,7 @@ public function testSelectWithCTEUnion(): void $subQueryBuilder3 = $this->connection->createQueryBuilder(); $subQueryBuilder3->union($subQueryBuilder1) - ->addUnion($subQueryBuilder2, UnionType::DISTINCT); + ->addUnion($subQueryBuilder2); $qb->with('cte_a', $subQueryBuilder3) ->select('id') diff --git a/tests/Query/QueryBuilderTest.php b/tests/Query/QueryBuilderTest.php index 4c567fc5576..82cfda93db4 100644 --- a/tests/Query/QueryBuilderTest.php +++ b/tests/Query/QueryBuilderTest.php @@ -855,19 +855,19 @@ public function testSelectAllWithoutTableAlias(): void public function testSelectWithCTE(): void { - $qbWith = new QueryBuilder($this->conn); - $qbWith->select('ta.id', 'ta.name', 'ta.table_b_id') + $cteQueryBuilder1 = new QueryBuilder($this->conn); + $cteQueryBuilder1->select('ta.id', 'ta.name', 'ta.table_b_id') ->from('table_a', 'ta') ->where('ta.name LIKE :name'); - $qbAddWith = new QueryBuilder($this->conn); - $qbAddWith->select('ca.id AS virtual_id, ca.name AS virtual_name') + $cteQueryBuilder2 = new QueryBuilder($this->conn); + $cteQueryBuilder2->select('ca.id AS virtual_id, ca.name AS virtual_name') ->from('cte_a', 'ca') ->join('ca', 'table_b', 'tb', 'ca.table_b_id = tb.id'); $qb = new QueryBuilder($this->conn); - $qb->with('cte_a', $qbWith) - ->with('cte_b', $qbAddWith, ['virtual_id', 'virtual_name']) + $qb->with('cte_a', $cteQueryBuilder1) + ->with('cte_b', $cteQueryBuilder2, ['virtual_id', 'virtual_name']) ->select('cb.*') ->from('cte_b', 'cb'); @@ -881,6 +881,15 @@ public function testSelectWithCTE(): void ); } + public function testSelectWithCTEAndEmptyColumns(): void + { + $this->expectException(QueryException::class); + $this->expectExceptionMessage('Columns defined in CTE "cte_a" should not be an empty array.'); + + $qb = new QueryBuilder($this->conn); + $qb->with('cte_a', 'SELECT 1 as id', []); + } + public function testGetParameterType(): void { $qb = new QueryBuilder($this->conn); From aab2338cbfc81c39635ccc1fe316fcc9d8bf89b2 Mon Sep 17 00:00:00 2001 From: nio-dtp Date: Tue, 10 Dec 2024 21:38:23 +0100 Subject: [PATCH 4/6] More tests --- src/SQL/Builder/WithSQLBuilder.php | 2 +- tests/Functional/Query/QueryBuilderTest.php | 111 ++++++++++++++++++-- tests/Query/QueryBuilderTest.php | 2 +- 3 files changed, 104 insertions(+), 11 deletions(-) diff --git a/src/SQL/Builder/WithSQLBuilder.php b/src/SQL/Builder/WithSQLBuilder.php index 064b47decae..2813dfb6730 100644 --- a/src/SQL/Builder/WithSQLBuilder.php +++ b/src/SQL/Builder/WithSQLBuilder.php @@ -19,7 +19,7 @@ public function buildSQL(CommonTableExpression $firstExpression, CommonTableExpr foreach (array_merge([$firstExpression], $otherExpressions) as $part) { $ctePart = [$part->name]; if ($part->columns !== null && count($part->columns) > 0) { - $ctePart[] = '(' . implode(', ', $part->columns) . ')'; + $ctePart[] = ' (' . implode(', ', $part->columns) . ')'; } $ctePart[] = ' AS (' . $part->query . ')'; diff --git a/tests/Functional/Query/QueryBuilderTest.php b/tests/Functional/Query/QueryBuilderTest.php index d3a57cd2cb4..66f01b0ee11 100644 --- a/tests/Functional/Query/QueryBuilderTest.php +++ b/tests/Functional/Query/QueryBuilderTest.php @@ -14,6 +14,7 @@ use Doctrine\DBAL\Platforms\MariaDBPlatform; use Doctrine\DBAL\Platforms\MySQL80Platform; use Doctrine\DBAL\Platforms\MySQLPlatform; +use Doctrine\DBAL\Platforms\OraclePlatform; use Doctrine\DBAL\Platforms\SQLitePlatform; use Doctrine\DBAL\Query\ForUpdate\ConflictResolutionMode; use Doctrine\DBAL\Query\UnionType; @@ -340,8 +341,8 @@ public function testSelectWithCTENamedParameter(): void self::markTestSkipped('The database platform does not support CTE.'); } - if (! $this->platformSupportsCTEColumnDefinition()) { - self::markTestSkipped('The database platform does not support CTE column definition.'); + if (! $this->platformSupportsCTEColumnsDefinition()) { + self::markTestSkipped('The database platform does not support columns definition for CTE.'); } $expectedRows = $this->prepareExpectedRows([['virtual_id' => 1]]); @@ -350,7 +351,7 @@ public function testSelectWithCTENamedParameter(): void $cteQueryBuilder = $this->connection->createQueryBuilder(); $cteQueryBuilder->select('id AS virtual_id') ->from('for_update') - ->where('virtual_id = :id') + ->where('id = :id') ->setParameter('id', 1); $qb->with('cte_a', $cteQueryBuilder, ['virtual_id']) @@ -360,14 +361,14 @@ public function testSelectWithCTENamedParameter(): void self::assertSame($expectedRows, $qb->executeQuery()->fetchAllAssociative()); } - public function testSelectWithCTEPositionalParametersBindForEachQuery(): void + public function testSelectWithCTEAndParametersBindForEachQuery(): void { if (! $this->platformSupportsCTEs()) { self::markTestSkipped('The database platform does not support CTE.'); } - if (! $this->platformSupportsCTEColumnDefinition()) { - self::markTestSkipped('The database platform does not support CTE column definition.'); + if (! $this->platformSupportsCTEColumnsDefinition()) { + self::markTestSkipped('The database platform does not support columns definition for CTE.'); } $expectedRows = $this->prepareExpectedRows([['virtual_id' => 1]]); @@ -387,9 +388,95 @@ public function testSelectWithCTEPositionalParametersBindForEachQuery(): void $qb->with('cte_a', $cteQueryBuilder1, ['virtual_id']) ->with('cte_b', $cteQueryBuilder2, ['virtual_id']) - ->select('a.virtual_id') + ->with('cte_c', 'SELECT 1 AS virtual_id') + ->select('c.virtual_id') ->from('cte_a', 'a') ->join('a', 'cte_b', 'b', 'a.virtual_id = b.virtual_id') + ->join('b', 'cte_c', 'c', 'b.virtual_id = c.virtual_id') + ->where($qb->expr()->eq('a.virtual_id', '?')) + ->setParameter(0, 1, ParameterType::INTEGER); + + self::assertSame($expectedRows, $qb->executeQuery()->fetchAllAssociative()); + } + + public function testSelectWithCTEAndCreateNamedParametersForEachQuery(): void + { + if (! $this->platformSupportsCTEs()) { + self::markTestSkipped('The database platform does not support CTE.'); + } + + if (! $this->platformSupportsCTEColumnsDefinition()) { + self::markTestSkipped('The database platform does not support columns definition for CTE.'); + } + + $expectedRows = $this->prepareExpectedRows([['virtual_id' => 1]]); + $qb = $this->connection->createQueryBuilder(); + + $cteQueryBuilder1 = $this->connection->createQueryBuilder(); + $cteQueryBuilder1->select('id AS virtual_id') + ->from('for_update') + ->where($cteQueryBuilder1->expr()->eq( + 'id', + $cteQueryBuilder1->createNamedParameter(1, ParameterType::INTEGER, ':id1'), + )); + + $cteQueryBuilder2 = $this->connection->createQueryBuilder(); + $cteQueryBuilder2->select('id AS virtual_id') + ->from('for_update') + ->where($cteQueryBuilder2->expr()->in( + 'id', + $cteQueryBuilder2->createNamedParameter([1, 2], ArrayParameterType::INTEGER, ':id2'), + )); + + $qb->with('cte_a', $cteQueryBuilder1, ['virtual_id']) + ->with('cte_b', $cteQueryBuilder2, ['virtual_id']) + ->with('cte_c', 'SELECT 1 AS virtual_id') + ->select('c.virtual_id') + ->from('cte_a', 'a') + ->join('a', 'cte_b', 'b', 'a.virtual_id = b.virtual_id') + ->join('b', 'cte_c', 'c', 'b.virtual_id = c.virtual_id') + ->where($qb->expr()->eq('a.virtual_id', '?')) + ->setParameter(0, 1, ParameterType::INTEGER); + + self::assertSame($expectedRows, $qb->executeQuery()->fetchAllAssociative()); + } + + public function testSelectWithCTEAndCreatePositionalParametersForEachQuery(): void + { + if (! $this->platformSupportsCTEs()) { + self::markTestSkipped('The database platform does not support CTE.'); + } + + if (! $this->platformSupportsCTEColumnsDefinition()) { + self::markTestSkipped('The database platform does not support columns definition for CTE.'); + } + + $expectedRows = $this->prepareExpectedRows([['virtual_id' => 1]]); + $qb = $this->connection->createQueryBuilder(); + + $cteQueryBuilder1 = $this->connection->createQueryBuilder(); + $cteQueryBuilder1->select('id AS virtual_id') + ->from('for_update') + ->where($cteQueryBuilder1->expr()->eq( + 'id', + $cteQueryBuilder1->createPositionalParameter(1, ParameterType::INTEGER), + )); + + $cteQueryBuilder2 = $this->connection->createQueryBuilder(); + $cteQueryBuilder2->select('id AS virtual_id') + ->from('for_update') + ->where($cteQueryBuilder2->expr()->in( + 'id', + $cteQueryBuilder2->createPositionalParameter([1, 2], ArrayParameterType::INTEGER), + )); + + $qb->with('cte_a', $cteQueryBuilder1, ['virtual_id']) + ->with('cte_b', $cteQueryBuilder2, ['virtual_id']) + ->with('cte_c', 'SELECT 1 AS virtual_id') + ->select('c.virtual_id') + ->from('cte_a', 'a') + ->join('a', 'cte_b', 'b', 'a.virtual_id = b.virtual_id') + ->join('b', 'cte_c', 'c', 'b.virtual_id = c.virtual_id') ->where($qb->expr()->eq('a.virtual_id', '?')) ->setParameter(0, 1, ParameterType::INTEGER); @@ -504,8 +591,14 @@ private function platformSupportsCTEs(): bool return ! $platform instanceof MySQLPlatform || $platform instanceof MySQL80Platform; } - private function platformSupportsCTEColumnDefinition(): bool + private function platformSupportsCTEColumnsDefinition(): bool { - return $this->connection->getDatabasePlatform() instanceof SQLitePlatform; + $platform = $this->connection->getDatabasePlatform(); + + if ($platform instanceof DB2Platform || $platform instanceof OraclePlatform) { + return false; + } + + return ! $platform instanceof MySQLPlatform || $platform instanceof MySQL80Platform; } } diff --git a/tests/Query/QueryBuilderTest.php b/tests/Query/QueryBuilderTest.php index 82cfda93db4..be273638661 100644 --- a/tests/Query/QueryBuilderTest.php +++ b/tests/Query/QueryBuilderTest.php @@ -873,7 +873,7 @@ public function testSelectWithCTE(): void self::assertEquals( 'WITH cte_a AS (SELECT ta.id, ta.name, ta.table_b_id FROM table_a ta WHERE ta.name LIKE :name)' - . ', cte_b(virtual_id, virtual_name) AS ' + . ', cte_b (virtual_id, virtual_name) AS ' . '(SELECT ca.id AS virtual_id, ca.name AS virtual_name ' . 'FROM cte_a ca INNER JOIN table_b tb ON ca.table_b_id = tb.id) ' . 'SELECT cb.* FROM cte_b cb', From 3fdc8d8207e573d5218914badf08462964c5b13f Mon Sep 17 00:00:00 2001 From: nio-dtp Date: Fri, 13 Dec 2024 22:06:32 +0100 Subject: [PATCH 5/6] Reject any duplicated parameter name --- src/Query/QueryBuilder.php | 34 ++++++++++- tests/Functional/Query/QueryBuilderTest.php | 67 +++++++++++++++++++++ 2 files changed, 100 insertions(+), 1 deletion(-) diff --git a/src/Query/QueryBuilder.php b/src/Query/QueryBuilder.php index 9b727ef29f2..92c2181b39f 100644 --- a/src/Query/QueryBuilder.php +++ b/src/Query/QueryBuilder.php @@ -18,6 +18,8 @@ use Doctrine\DBAL\Statement; use Doctrine\DBAL\Types\Type; +use function array_filter; +use function array_intersect; use function array_key_exists; use function array_keys; use function array_merge; @@ -25,6 +27,7 @@ use function count; use function implode; use function is_object; +use function sprintf; use function substr; /** @@ -332,10 +335,12 @@ private function buildParametersAndTypes(): array $cteParams = $cteParamTypes = []; foreach ($this->commonTableExpressions as $cte) { - if (! $cte->query instanceof self) { + if (! $cte->query instanceof self || count($cte->query->params) === 0) { continue; } + $this->guardDuplicatedParameterNames($cteParams, $cte->query->params); + $cteParams = array_merge($cteParams, $cte->query->params); $cteParamTypes = array_merge($cteParamTypes, $cte->query->types); } @@ -344,12 +349,39 @@ private function buildParametersAndTypes(): array return [$this->params, $this->types]; } + $this->guardDuplicatedParameterNames($cteParams, $this->params); + return [ array_merge($cteParams, $this->params), array_merge($cteParamTypes, $this->types), ]; } + /** + * Guards against duplicated parameter names. + * + * @param list|array $params + * @param list|array $paramsToMerge + * + * @throws QueryException + */ + private function guardDuplicatedParameterNames(array $params, array $paramsToMerge): void + { + if (count($params) === 0 || count($paramsToMerge) === 0) { + return; + } + + $paramKeys = array_filter(array_keys($params), 'is_string'); + $cteParamKeys = array_filter(array_keys($paramsToMerge), 'is_string'); + $duplicated = array_intersect($paramKeys, $cteParamKeys); + if (count($duplicated) > 0) { + throw new QueryException(sprintf( + 'Found duplicated parameter in query. The duplicated parameter names are: "%s".', + implode(', ', $duplicated), + )); + } + } + /** * Executes an SQL statement and returns the number of affected rows. * diff --git a/tests/Functional/Query/QueryBuilderTest.php b/tests/Functional/Query/QueryBuilderTest.php index 66f01b0ee11..db389af120c 100644 --- a/tests/Functional/Query/QueryBuilderTest.php +++ b/tests/Functional/Query/QueryBuilderTest.php @@ -17,6 +17,7 @@ use Doctrine\DBAL\Platforms\OraclePlatform; use Doctrine\DBAL\Platforms\SQLitePlatform; use Doctrine\DBAL\Query\ForUpdate\ConflictResolutionMode; +use Doctrine\DBAL\Query\QueryException; use Doctrine\DBAL\Query\UnionType; use Doctrine\DBAL\Schema\Table; use Doctrine\DBAL\Tests\FunctionalTestCase; @@ -24,6 +25,7 @@ use Doctrine\DBAL\Types\Types; use function array_change_key_case; +use function sprintf; use const CASE_UPPER; @@ -441,6 +443,71 @@ public function testSelectWithCTEAndCreateNamedParametersForEachQuery(): void self::assertSame($expectedRows, $qb->executeQuery()->fetchAllAssociative()); } + /** + * @param array $parameters + * + * @dataProvider selectWithCTEAndCreateNamedParametersAreDuplicatedProvider + */ + public function testSelectWithCTEAndCreateNamedParametersAreDuplicated( + array $parameters, + string $expectedDuplicated, + ): void { + $qb = $this->connection->createQueryBuilder(); + + $cteQueryBuilder1 = $this->connection->createQueryBuilder(); + $cteQueryBuilder1->select('id') + ->from('for_update') + ->where($cteQueryBuilder1->expr()->eq( + 'id', + $cteQueryBuilder1->createNamedParameter(1, ParameterType::INTEGER, $parameters['cte_a']), + )); + + $cteQueryBuilder2 = $this->connection->createQueryBuilder(); + $cteQueryBuilder2->select('id') + ->from('for_update') + ->where($cteQueryBuilder2->expr()->in( + 'id', + $cteQueryBuilder2->createNamedParameter([1, 2], ArrayParameterType::INTEGER, $parameters['cte_b']), + )); + + $qb->with('cte_a', $cteQueryBuilder1) + ->with('cte_b', $cteQueryBuilder2) + ->where($qb->expr()->eq( + 'id', + $qb->createNamedParameter(1, ParameterType::INTEGER, $parameters['main_query']), + )); + + self::expectException(QueryException::class); + self::expectExceptionMessage(sprintf( + 'Found duplicated parameter in query. The duplicated parameter names are: "%s".', + $expectedDuplicated, + )); + $qb->executeQuery(); + } + + /** @return array|string>> */ + public static function selectWithCTEAndCreateNamedParametersAreDuplicatedProvider(): array + { + return [ + 'duplicated parameters in CTE' => [ + 'parameters' => [ + 'cte_a' => ':id1', + 'cte_b' => ':id1', + 'main_query' => ':id2', + ], + 'expectedDuplicated' => 'id1', + ], + 'duplicated parameters in main query' => [ + 'parameters' => [ + 'cte_a' => ':id1', + 'cte_b' => ':id2', + 'main_query' => ':id1', + ], + 'expectedDuplicated' => 'id1', + ], + ]; + } + public function testSelectWithCTEAndCreatePositionalParametersForEachQuery(): void { if (! $this->platformSupportsCTEs()) { From b20f5e67c1897a5bbe82883a682c5de6625b620a Mon Sep 17 00:00:00 2001 From: nio-dtp Date: Sat, 21 Dec 2024 17:57:01 +0100 Subject: [PATCH 6/6] Rollback bind parameters to CTE level --- docs/en/reference/query-builder.rst | 9 +- src/Query/QueryBuilder.php | 66 +------------ tests/Functional/Query/QueryBuilderTest.php | 103 ++++---------------- 3 files changed, 24 insertions(+), 154 deletions(-) diff --git a/docs/en/reference/query-builder.rst b/docs/en/reference/query-builder.rst index 2afe7d16486..d17234d29eb 100644 --- a/docs/en/reference/query-builder.rst +++ b/docs/en/reference/query-builder.rst @@ -382,8 +382,7 @@ To define Common Table Expressions (CTEs) that can be used in select query. $cteQueryBuilder1 ->select('id') ->from('table_a') - ->where('id = :id') - ->setParameter('id', 1); + ->where('id = :id'); $cteQueryBuilder2 ->select('id') @@ -394,12 +393,12 @@ To define Common Table Expressions (CTEs) that can be used in select query. ->with('cte_b', $cteQueryBuilder2) ->select('id') ->from('cte_b', 'b') - ->join('b', 'cte_a', 'a', 'a.id = b.id'); + ->join('b', 'cte_a', 'a', 'a.id = b.id') + ->setParameter('id', 1); Multiple CTEs can be defined by calling the with method multiple times. -Parameters used in a CTE should be defined directly in the QueryBuilder of the CTE. -This way, the CTE builders are naturally composable. +Values of parameters used in a CTE should be defined in the main QueryBuilder. Building Expressions -------------------- diff --git a/src/Query/QueryBuilder.php b/src/Query/QueryBuilder.php index 92c2181b39f..e343309ef71 100644 --- a/src/Query/QueryBuilder.php +++ b/src/Query/QueryBuilder.php @@ -312,76 +312,14 @@ public function fetchFirstColumn(): array */ public function executeQuery(): Result { - [$params, $types] = $this->buildParametersAndTypes(); - return $this->connection->executeQuery( $this->getSQL(), - $params, - $types, + $this->params, + $this->types, $this->resultCacheProfile, ); } - /** - * Build then return parameters and types for the query. - * - * @return array{ - * list|array, - * WrapperParameterTypeArray, - * } The parameters and types for the query. - */ - private function buildParametersAndTypes(): array - { - $cteParams = $cteParamTypes = []; - - foreach ($this->commonTableExpressions as $cte) { - if (! $cte->query instanceof self || count($cte->query->params) === 0) { - continue; - } - - $this->guardDuplicatedParameterNames($cteParams, $cte->query->params); - - $cteParams = array_merge($cteParams, $cte->query->params); - $cteParamTypes = array_merge($cteParamTypes, $cte->query->types); - } - - if (count($cteParams) === 0) { - return [$this->params, $this->types]; - } - - $this->guardDuplicatedParameterNames($cteParams, $this->params); - - return [ - array_merge($cteParams, $this->params), - array_merge($cteParamTypes, $this->types), - ]; - } - - /** - * Guards against duplicated parameter names. - * - * @param list|array $params - * @param list|array $paramsToMerge - * - * @throws QueryException - */ - private function guardDuplicatedParameterNames(array $params, array $paramsToMerge): void - { - if (count($params) === 0 || count($paramsToMerge) === 0) { - return; - } - - $paramKeys = array_filter(array_keys($params), 'is_string'); - $cteParamKeys = array_filter(array_keys($paramsToMerge), 'is_string'); - $duplicated = array_intersect($paramKeys, $cteParamKeys); - if (count($duplicated) > 0) { - throw new QueryException(sprintf( - 'Found duplicated parameter in query. The duplicated parameter names are: "%s".', - implode(', ', $duplicated), - )); - } - } - /** * Executes an SQL statement and returns the number of affected rows. * diff --git a/tests/Functional/Query/QueryBuilderTest.php b/tests/Functional/Query/QueryBuilderTest.php index db389af120c..ce997b77e4c 100644 --- a/tests/Functional/Query/QueryBuilderTest.php +++ b/tests/Functional/Query/QueryBuilderTest.php @@ -17,7 +17,6 @@ use Doctrine\DBAL\Platforms\OraclePlatform; use Doctrine\DBAL\Platforms\SQLitePlatform; use Doctrine\DBAL\Query\ForUpdate\ConflictResolutionMode; -use Doctrine\DBAL\Query\QueryException; use Doctrine\DBAL\Query\UnionType; use Doctrine\DBAL\Schema\Table; use Doctrine\DBAL\Tests\FunctionalTestCase; @@ -25,7 +24,6 @@ use Doctrine\DBAL\Types\Types; use function array_change_key_case; -use function sprintf; use const CASE_UPPER; @@ -353,12 +351,12 @@ public function testSelectWithCTENamedParameter(): void $cteQueryBuilder = $this->connection->createQueryBuilder(); $cteQueryBuilder->select('id AS virtual_id') ->from('for_update') - ->where('id = :id') - ->setParameter('id', 1); + ->where('id = :id'); $qb->with('cte_a', $cteQueryBuilder, ['virtual_id']) ->select('virtual_id') - ->from('cte_a'); + ->from('cte_a') + ->setParameter('id', 1); self::assertSame($expectedRows, $qb->executeQuery()->fetchAllAssociative()); } @@ -379,14 +377,14 @@ public function testSelectWithCTEAndParametersBindForEachQuery(): void $cteQueryBuilder1 = $this->connection->createQueryBuilder(); $cteQueryBuilder1->select('id AS virtual_id') ->from('for_update') - ->where($cteQueryBuilder1->expr()->eq('id', '?')) - ->setParameter(0, 1, ParameterType::INTEGER); + ->where($qb->expr()->eq('id', '?')); + $qb->setParameter(0, 1, ParameterType::INTEGER); $cteQueryBuilder2 = $this->connection->createQueryBuilder(); $cteQueryBuilder2->select('id AS virtual_id') ->from('for_update') - ->where($cteQueryBuilder2->expr()->in('id', ':id')) - ->setParameter('id', [1, 2], ArrayParameterType::INTEGER); + ->where($qb->expr()->in('id', ':id')); + $qb->setParameter('id', [1, 2], ArrayParameterType::INTEGER); $qb->with('cte_a', $cteQueryBuilder1, ['virtual_id']) ->with('cte_b', $cteQueryBuilder2, ['virtual_id']) @@ -396,7 +394,7 @@ public function testSelectWithCTEAndParametersBindForEachQuery(): void ->join('a', 'cte_b', 'b', 'a.virtual_id = b.virtual_id') ->join('b', 'cte_c', 'c', 'b.virtual_id = c.virtual_id') ->where($qb->expr()->eq('a.virtual_id', '?')) - ->setParameter(0, 1, ParameterType::INTEGER); + ->setParameter(1, 1, ParameterType::INTEGER); self::assertSame($expectedRows, $qb->executeQuery()->fetchAllAssociative()); } @@ -417,17 +415,17 @@ public function testSelectWithCTEAndCreateNamedParametersForEachQuery(): void $cteQueryBuilder1 = $this->connection->createQueryBuilder(); $cteQueryBuilder1->select('id AS virtual_id') ->from('for_update') - ->where($cteQueryBuilder1->expr()->eq( + ->where($qb->expr()->eq( 'id', - $cteQueryBuilder1->createNamedParameter(1, ParameterType::INTEGER, ':id1'), + $qb->createNamedParameter(1, ParameterType::INTEGER, ':id1'), )); $cteQueryBuilder2 = $this->connection->createQueryBuilder(); $cteQueryBuilder2->select('id AS virtual_id') ->from('for_update') - ->where($cteQueryBuilder2->expr()->in( + ->where($qb->expr()->in( 'id', - $cteQueryBuilder2->createNamedParameter([1, 2], ArrayParameterType::INTEGER, ':id2'), + $qb->createNamedParameter([1, 2], ArrayParameterType::INTEGER, ':id2'), )); $qb->with('cte_a', $cteQueryBuilder1, ['virtual_id']) @@ -443,71 +441,6 @@ public function testSelectWithCTEAndCreateNamedParametersForEachQuery(): void self::assertSame($expectedRows, $qb->executeQuery()->fetchAllAssociative()); } - /** - * @param array $parameters - * - * @dataProvider selectWithCTEAndCreateNamedParametersAreDuplicatedProvider - */ - public function testSelectWithCTEAndCreateNamedParametersAreDuplicated( - array $parameters, - string $expectedDuplicated, - ): void { - $qb = $this->connection->createQueryBuilder(); - - $cteQueryBuilder1 = $this->connection->createQueryBuilder(); - $cteQueryBuilder1->select('id') - ->from('for_update') - ->where($cteQueryBuilder1->expr()->eq( - 'id', - $cteQueryBuilder1->createNamedParameter(1, ParameterType::INTEGER, $parameters['cte_a']), - )); - - $cteQueryBuilder2 = $this->connection->createQueryBuilder(); - $cteQueryBuilder2->select('id') - ->from('for_update') - ->where($cteQueryBuilder2->expr()->in( - 'id', - $cteQueryBuilder2->createNamedParameter([1, 2], ArrayParameterType::INTEGER, $parameters['cte_b']), - )); - - $qb->with('cte_a', $cteQueryBuilder1) - ->with('cte_b', $cteQueryBuilder2) - ->where($qb->expr()->eq( - 'id', - $qb->createNamedParameter(1, ParameterType::INTEGER, $parameters['main_query']), - )); - - self::expectException(QueryException::class); - self::expectExceptionMessage(sprintf( - 'Found duplicated parameter in query. The duplicated parameter names are: "%s".', - $expectedDuplicated, - )); - $qb->executeQuery(); - } - - /** @return array|string>> */ - public static function selectWithCTEAndCreateNamedParametersAreDuplicatedProvider(): array - { - return [ - 'duplicated parameters in CTE' => [ - 'parameters' => [ - 'cte_a' => ':id1', - 'cte_b' => ':id1', - 'main_query' => ':id2', - ], - 'expectedDuplicated' => 'id1', - ], - 'duplicated parameters in main query' => [ - 'parameters' => [ - 'cte_a' => ':id1', - 'cte_b' => ':id2', - 'main_query' => ':id1', - ], - 'expectedDuplicated' => 'id1', - ], - ]; - } - public function testSelectWithCTEAndCreatePositionalParametersForEachQuery(): void { if (! $this->platformSupportsCTEs()) { @@ -524,17 +457,17 @@ public function testSelectWithCTEAndCreatePositionalParametersForEachQuery(): vo $cteQueryBuilder1 = $this->connection->createQueryBuilder(); $cteQueryBuilder1->select('id AS virtual_id') ->from('for_update') - ->where($cteQueryBuilder1->expr()->eq( + ->where($qb->expr()->eq( 'id', - $cteQueryBuilder1->createPositionalParameter(1, ParameterType::INTEGER), + $qb->createPositionalParameter(1, ParameterType::INTEGER), )); $cteQueryBuilder2 = $this->connection->createQueryBuilder(); $cteQueryBuilder2->select('id AS virtual_id') ->from('for_update') - ->where($cteQueryBuilder2->expr()->in( + ->where($qb->expr()->in( 'id', - $cteQueryBuilder2->createPositionalParameter([1, 2], ArrayParameterType::INTEGER), + $qb->createPositionalParameter([1, 2], ArrayParameterType::INTEGER), )); $qb->with('cte_a', $cteQueryBuilder1, ['virtual_id']) @@ -545,7 +478,7 @@ public function testSelectWithCTEAndCreatePositionalParametersForEachQuery(): vo ->join('a', 'cte_b', 'b', 'a.virtual_id = b.virtual_id') ->join('b', 'cte_c', 'c', 'b.virtual_id = c.virtual_id') ->where($qb->expr()->eq('a.virtual_id', '?')) - ->setParameter(0, 1, ParameterType::INTEGER); + ->setParameter(2, 1, ParameterType::INTEGER); self::assertSame($expectedRows, $qb->executeQuery()->fetchAllAssociative()); } @@ -577,7 +510,7 @@ public function testSelectWithCTEUnion(): void ->select('id') ->from('cte_a') ->orderBy('id', 'DESC') - ->setParameters([1, 2]); + ->setParameters([1, 2], [ParameterType::INTEGER, ParameterType::INTEGER]); self::assertSame($expectedRows, $qb->executeQuery()->fetchAllAssociative()); }