Skip to content

sub query #225

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

Merged
merged 7 commits into from
Jul 3, 2025
Merged
Show file tree
Hide file tree
Changes from all 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
8 changes: 8 additions & 0 deletions src/Driver/Compiler.php
Original file line number Diff line number Diff line change
Expand Up @@ -126,6 +126,9 @@ protected function fragment(

return $this->selectQuery($params, $q, $tokens);

case self::SUBQUERY:
return $this->subQuery($params, $q, $tokens);

case self::UPDATE_QUERY:
return $this->updateQuery($params, $q, $tokens);

Expand Down Expand Up @@ -198,6 +201,11 @@ protected function selectQuery(QueryParameters $params, Quoter $q, array $tokens
);
}

protected function subQuery(QueryParameters $params, Quoter $q, array $tokens): string
{
return \sprintf('( %s ) AS %s', $this->selectQuery($params, $q, $tokens), $q->quote($tokens['alias']));
}

protected function distinct(QueryParameters $params, Quoter $q, string|bool|array $distinct): string
{
return $distinct === false ? '' : 'DISTINCT';
Expand Down
7 changes: 6 additions & 1 deletion src/Driver/CompilerCache.php
Original file line number Diff line number Diff line change
Expand Up @@ -17,6 +17,7 @@
use Cycle\Database\Injection\JsonExpression;
use Cycle\Database\Injection\Parameter;
use Cycle\Database\Injection\ParameterInterface;
use Cycle\Database\Injection\SubQuery;
use Cycle\Database\Query\QueryInterface;
use Cycle\Database\Query\QueryParameters;
use Cycle\Database\Query\SelectQuery;
Expand Down Expand Up @@ -162,6 +163,10 @@ protected function hashSelectQuery(QueryParameters $params, array $tokens): stri
$hash .= 's_' . ($table->getPrefix() ?? '');
$hash .= $this->hashSelectQuery($params, $table->getTokens());
continue;
} elseif ($table instanceof SubQuery) {
$hash .= 'sb_';
$hash .= $this->hashSelectQuery($params, $table->getTokens());
continue;
}

$hash .= $table;
Expand Down Expand Up @@ -330,7 +335,7 @@ protected function hashColumns(QueryParameters $params, array $columns): string
{
$hash = '';
foreach ($columns as $column) {
if ($column instanceof Expression || $column instanceof Fragment) {
if ($column instanceof Expression || $column instanceof Fragment || $column instanceof SubQuery) {
foreach ($column->getTokens()['parameters'] as $param) {
$params->push($param);
}
Expand Down
2 changes: 1 addition & 1 deletion src/Driver/CompilerInterface.php
Original file line number Diff line number Diff line change
Expand Up @@ -24,6 +24,7 @@ interface CompilerInterface
public const UPDATE_QUERY = 6;
public const DELETE_QUERY = 7;
public const JSON_EXPRESSION = 8;
public const SUBQUERY = 9;
public const TOKEN_AND = '@AND';
public const TOKEN_OR = '@OR';
public const TOKEN_AND_NOT = '@AND NOT';
Expand All @@ -33,7 +34,6 @@ public function quoteIdentifier(string $identifier): string;

/**
* Compile the query fragment.
*
*/
public function compile(
QueryParameters $params,
Expand Down
2 changes: 1 addition & 1 deletion src/Driver/Jsoner.php
Original file line number Diff line number Diff line change
Expand Up @@ -32,7 +32,7 @@ public static function toJson(mixed $value, bool $encode = true, bool $validate

$result = (string) $value;

if ($validate && !\json_validate($result)) {
if ($validate && !json_validate($result)) {
throw new BuilderException('Invalid JSON value.');
}

Expand Down
2 changes: 0 additions & 2 deletions src/Injection/FragmentInterface.php
Original file line number Diff line number Diff line change
Expand Up @@ -18,13 +18,11 @@ interface FragmentInterface
{
/**
* Return the fragment type.
*
*/
public function getType(): int;

/**
* Return the fragment tokens.
*
*/
public function getTokens(): array;
}
87 changes: 87 additions & 0 deletions src/Injection/SubQuery.php
Original file line number Diff line number Diff line change
@@ -0,0 +1,87 @@
<?php

/**
* This file is part of Cycle ORM package.
*
* For the full copyright and license information, please view the LICENSE
* file that was distributed with this source code.
*/

declare(strict_types=1);

namespace Cycle\Database\Injection;

use Cycle\Database\Driver\CompilerInterface;
use Cycle\Database\Query\Interpolator;
use Cycle\Database\Query\QueryParameters;
use Cycle\Database\Query\SelectQuery;

/**
* This fragment is used to inject a whole select statement into
* FROM and SELECT parts of the query.
*
* Examples:
*
* ```
* $subQuery = new SubQuery($queryBuilder->select()->from(['users']),'u');
* $query = $queryBuilder->select()->from($subQuery);
* ```
*
* Will provide SQL like this: SELECT * FROM (SELECT * FROM users) AS u
*
* ```
* $subQuery = new SubQuery($queryBuilder->select()->from(['users']),'u');
* $query = $queryBuilder->select($subQuery)->from(['employee']);
* ```
*
* Will provide SQL like this: SELECT *, (SELECT * FROM users) AS u FROM employee
*/
class SubQuery implements FragmentInterface
{
private SelectQuery $query;
private string $alias;

/** @var ParameterInterface[] */
private array $parameters;

public function __construct(SelectQuery $query, string $alias)
{
$this->query = $query;
$this->alias = $alias;

$parameters = new QueryParameters();
$this->query->sqlStatement($parameters);
$this->parameters = $parameters->getParameters();
}

public function getType(): int
{
return CompilerInterface::SUBQUERY;
}

public function getTokens(): array
{
return \array_merge(
[
'alias' => $this->alias,
'parameters' => $this->parameters,
],
$this->query->getTokens(),
);
}

public function getQuery(): SelectQuery
{
return $this->query;
}

public function __toString(): string
{
$parameters = new QueryParameters();

return Interpolator::interpolate(
$this->query->sqlStatement($parameters),
$parameters->getParameters(),
);
}
}
11 changes: 11 additions & 0 deletions src/Query/SelectQuery.php
Original file line number Diff line number Diff line change
Expand Up @@ -13,6 +13,7 @@

use Cycle\Database\Injection\Expression;
use Cycle\Database\Injection\Fragment;
use Cycle\Database\Injection\SubQuery;
use Cycle\Database\Query\Traits\WhereJsonTrait;
use Cycle\Database\Driver\CompilerInterface;
use Cycle\Database\Injection\FragmentInterface;
Expand Down Expand Up @@ -84,6 +85,16 @@ public function distinct(bool|string|FragmentInterface $distinct = true): self
/**
* Set table names SELECT query should be performed for. Table names can be provided with
* specified alias (AS construction).
* Also, it is possible to use SubQuery.
*
* Following example will provide SQL like this: SELECT * FROM (SELECT * FROM users) AS u
*
* ```
* $subQuery = new SubQuery($queryBuilder->select()->from(['users']),'u');
* $query = $queryBuilder->select()->from($subQuery);
* ```
*
* @see SubQuery
*/
public function from(mixed $tables): self
{
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -10,6 +10,7 @@
use Cycle\Database\Injection\Expression;
use Cycle\Database\Injection\Fragment;
use Cycle\Database\Injection\Parameter;
use Cycle\Database\Injection\SubQuery;
use Cycle\Database\Query\SelectQuery;
use Cycle\Database\Tests\Functional\Driver\Common\BaseTest;
use Spiral\Pagination\PaginableInterface;
Expand Down Expand Up @@ -2639,4 +2640,98 @@ public function testOrWhereNotWithArrayAnd(): void
$select,
);
}

public function testSelectFromSubQuery(): void
{
$innerSelect = $this->database
->select()
->from(['users'])
->where(['name' => 'John Doe']);
$injection = new SubQuery($innerSelect, 'u');

$outerSelect = $this->database
->select()
->from($injection)
->where('u.id', '>', 10);

$this->assertSameQuery(
<<<SQL
SELECT *
FROM (SELECT * FROM {users} WHERE {name} = ?) AS {u}
WHERE {u}.{id} > ?
SQL,
$outerSelect,
);

$this->assertSameParameters(
[
'John Doe',
10,
],
$outerSelect,
);
}

public function testSelectFromTwoSubQuery(): void
{
$innerSelect1 = $this->database
->select()
->from(['users'])
->where(['name' => 'John Doe']);
$injection1 = new SubQuery($innerSelect1, 'u');

$innerSelect2 = $this->database
->select()
->from(['apartments'])
->where(['dom' => 12]);
$injection2 = new SubQuery($innerSelect2, 'a');


$outerSelect = $this->database
->select()
->from($injection1, $injection2);

$this->assertSameQuery(
<<<SQL
SELECT *
FROM
(SELECT * FROM {users} WHERE {name} = ?) AS {u},
(SELECT * FROM {apartments} WHERE {dom} = ?) AS {a}
SQL,
$outerSelect,
);

$this->assertSameParameters(
[
'John Doe',
12,
],
$outerSelect,
);
}

public function testSelectSelectSubQuery(): void
{
$innerSelect = $this->database
->select()
->from(['users'])
->where(['name' => 'John Doe']);
$injection = new SubQuery($innerSelect, 'u');

$outerSelect = $this->database
->select(['*', $injection])
->from(['apartments']);

$this->assertSameQuery(
'SELECT *, (SELECT * FROM {users} WHERE {name} = ?) AS {u} FROM {apartments}',
$outerSelect,
);

$this->assertSameParameters(
[
'John Doe',
],
$outerSelect,
);
}
}
Loading