Skip to content

Commit

Permalink
Add intersect and except statements
Browse files Browse the repository at this point in the history
  • Loading branch information
markinigor committed May 29, 2024
1 parent 122163b commit 20d3aee
Show file tree
Hide file tree
Showing 5 changed files with 328 additions and 2 deletions.
48 changes: 47 additions & 1 deletion src/Driver/Compiler.php
Original file line number Diff line number Diff line change
Expand Up @@ -181,7 +181,7 @@ protected function selectQuery(QueryParameters $params, Quoter $q, array $tokens
}

return sprintf(
"SELECT%s %s\nFROM %s%s%s%s%s%s%s%s%s",
"SELECT%s %s\nFROM %s%s%s%s%s%s%s%s%s%s%s",
$this->optional(' ', $this->distinct($params, $q, $tokens['distinct'])),
$this->columns($params, $q, $tokens['columns']),
\implode(', ', $tables),
Expand All @@ -190,6 +190,8 @@ protected function selectQuery(QueryParameters $params, Quoter $q, array $tokens
$this->optional("\nGROUP BY", $this->groupBy($params, $q, $tokens['groupBy']), ' '),
$this->optional("\nHAVING", $this->where($params, $q, $tokens['having'])),
$this->optional("\n", $this->unions($params, $q, $tokens['union'])),
$this->optional("\n", $this->intersects($params, $q, $tokens['intersect'])),
$this->optional("\n", $this->excepts($params, $q, $tokens['except'])),
$this->optional("\nORDER BY", $this->orderBy($params, $q, $tokens['orderBy'])),
$this->optional("\n", $this->limit($params, $q, $tokens['limit'], $tokens['offset'])),
$this->optional(' ', $tokens['forUpdate'] ? 'FOR UPDATE' : '')
Expand Down Expand Up @@ -242,6 +244,50 @@ protected function unions(QueryParameters $params, Quoter $q, array $unions): st
return \ltrim($statement, "\n");
}

protected function intersects(QueryParameters $params, Quoter $q, array $intersects): string
{
if ($intersects === []) {
return '';
}

$statement = '';
foreach ($intersects as $intersect) {
$select = $this->fragment($params, $q, $intersect[1]);

if ($intersect[0] !== '') {
//First key is intersect type, second intersected query (no need to share compiler)
$statement .= "\nINTERSECT {$intersect[0]}\n{$select}";
} else {
//No extra space
$statement .= "\nINTERSECT \n{$select}";
}
}

return \ltrim($statement, "\n");
}

protected function excepts(QueryParameters $params, Quoter $q, array $excepts): string
{
if ($excepts === []) {
return '';
}

$statement = '';
foreach ($excepts as $except) {
$select = $this->fragment($params, $q, $except[1]);

if ($except[0] !== '') {
//First key is except type, second excepted query (no need to share compiler)
$statement .= "\nEXCEPT {$except[0]}\n{$select}";
} else {
//No extra space
$statement .= "\nEXCEPT \n{$select}";
}
}

return \ltrim($statement, "\n");
}

protected function orderBy(QueryParameters $params, Quoter $q, array $orderBy): string
{
$result = [];
Expand Down
22 changes: 22 additions & 0 deletions src/Driver/CompilerCache.php
Original file line number Diff line number Diff line change
Expand Up @@ -210,6 +210,28 @@ protected function hashSelectQuery(QueryParameters $params, array $tokens): stri
$hash .= $union[1];
}

foreach ($tokens['intersect'] as $intersect) {
$hash .= $intersect[0];
if ($intersect[1] instanceof SelectQuery) {
$hash .= $intersect[1]->getPrefix() === null ? '' : 'i_' . $intersect[1]->getPrefix();
$hash .= $this->hashSelectQuery($params, $intersect[1]->getTokens());
continue;
}

$hash .= $intersect[1];
}

foreach ($tokens['except'] as $except) {
$hash .= $except[0];
if ($except[1] instanceof SelectQuery) {
$hash .= $except[1]->getPrefix() === null ? '' : 'e_' . $except[1]->getPrefix();
$hash .= $this->hashSelectQuery($params, $except[1]->getTokens());
continue;
}

$hash .= $except[1];
}

return $hash;
}

Expand Down
4 changes: 3 additions & 1 deletion src/Driver/SQLServer/SQLServerCompiler.php
Original file line number Diff line number Diff line change
Expand Up @@ -179,7 +179,7 @@ private function baseSelect(QueryParameters $params, Quoter $q, array $tokens):
}

return sprintf(
"SELECT%s %s\nFROM %s%s%s%s%s%s%s%s%s",
"SELECT%s %s\nFROM %s%s%s%s%s%s%s%s%s%s%s",
$this->optional(' ', $this->distinct($params, $q, $tokens['distinct'])),
$this->columns($params, $q, $tokens['columns']),
implode(', ', $tables),
Expand All @@ -189,6 +189,8 @@ private function baseSelect(QueryParameters $params, Quoter $q, array $tokens):
$this->optional("\nGROUP BY", $this->groupBy($params, $q, $tokens['groupBy']), ' '),
$this->optional("\nHAVING", $this->where($params, $q, $tokens['having'])),
$this->optional("\n", $this->unions($params, $q, $tokens['union'])),
$this->optional("\n", $this->intersects($params, $q, $tokens['intersect'])),
$this->optional("\n", $this->excepts($params, $q, $tokens['except'])),
$this->optional("\nORDER BY", $this->orderBy($params, $q, $tokens['orderBy'])),
$this->optional("\n", $this->limit($params, $q, $tokens['limit'], $tokens['offset']))
);
Expand Down
44 changes: 44 additions & 0 deletions src/Query/SelectQuery.php
Original file line number Diff line number Diff line change
Expand Up @@ -46,6 +46,8 @@ class SelectQuery extends ActiveQuery implements

protected array $tables = [];
protected array $unionTokens = [];
protected array $exceptTokens = [];
protected array $intersectTokens = [];
protected bool|string|array $distinct = false;
protected array $columns = ['*'];
/** @var FragmentInterface[][]|string[][] */
Expand Down Expand Up @@ -193,6 +195,46 @@ public function unionAll(FragmentInterface $query): self
return $this;
}

/**
* Add select query to be intersected with.
*/
public function intersect(FragmentInterface $query): self
{
$this->intersectTokens[] = ['', $query];

return $this;
}

/**
* Add select query to be intersected with. Duplicate values will be included in result.
*/
public function intersectAll(FragmentInterface $query): self
{
$this->intersectTokens[] = ['ALL', $query];

return $this;
}

/**
* Add select query to be excepted with.
*/
public function except(FragmentInterface $query): self
{
$this->exceptTokens[] = ['', $query];

return $this;
}

/**
* Add select query to be excepted with. Duplicate values will be included in result.
*/
public function exceptAll(FragmentInterface $query): self
{
$this->exceptTokens[] = ['ALL', $query];

return $this;
}

/**
* Set selection limit. Attention, this limit value does not affect values set in paginator but
* only changes pagination window. Set to 0 to disable limiting.
Expand Down Expand Up @@ -362,6 +404,8 @@ public function getTokens(): array
'limit' => $this->limit,
'offset' => $this->offset,
'union' => $this->unionTokens,
'intersect' => $this->intersectTokens,
'except' => $this->exceptTokens,
];
}

Expand Down
212 changes: 212 additions & 0 deletions tests/Database/Functional/Driver/Common/Query/NestedQueriesTest.php
Original file line number Diff line number Diff line change
Expand Up @@ -335,6 +335,218 @@ public function testUnionWithPrefixes2(): void
);
}

public function testIntersectWithPrefixes(): void
{
$select = $this->db('prefixed', 'prefix_')
->select('*')
->from('table AS u')
->where('type', 'user')->orWhere('table.id', '<', 100);

$select->intersect(
$this->db('prefixed', 'prefix_2_')
->select('*')
->from('table AS u')
->where('type', 'admin')->orWhere('table.id', '>', 800)
);

$this->assertSameQuery(
'SELECT * FROM {prefix_table} AS {u} WHERE {type} = ? OR {prefix_table}.{id} < ?
INTERSECT
(SELECT * FROM {prefix_2_table} AS {u} WHERE {type} = ? OR {prefix_2_table}.{id} > ?)',
$select
);

$this->assertSameParameters(
[
'user',
100,
'admin',
800,
],
$select
);
}

public function testIntersectWithPrefixes1(): void
{
$select = $this->db('prefixed', 'prefix_')
->select('*')
->from('table AS u')
->where('type', 'user')->orWhere('table.id', '<', 100);

$select->intersectAll(
$this->db('prefixed', 'prefix_2_')
->select('*')
->from('table AS u')
->where('type', 'admin')->orWhere('table.id', '>', 800)
);

$this->assertSameQuery(
'SELECT * FROM {prefix_table} AS {u} WHERE {type} = ? OR {prefix_table}.{id} < ?
INTERSECT ALL
(SELECT * FROM {prefix_2_table} AS {u} WHERE {type} = ? OR {prefix_2_table}.{id} > ?)',
$select
);

$this->assertSameParameters(
[
'user',
100,
'admin',
800,
],
$select
);
}

public function testIntersectWithPrefixes2(): void
{
$select = $this->db('prefixed', 'prefix_')
->select('*')
->from('table AS u')
->where('type', 'user')->orWhere('table.id', '<', 100);

$select->intersect(
$this->db('prefixed', 'prefix_2_')
->select('*')
->from('table AS u')
->where('type', 'admin')->orWhere('table.id', '>', 800)
);

$select->intersectAll(
$this->db('prefixed', 'prefix_3_')->select('*')
->from('table')->where('x', 'IN', new Parameter([8, 9, 10]))
);

$this->assertSameQuery(
'SELECT * FROM {prefix_table} AS {u} WHERE {type} = ? OR {prefix_table}.{id} < ?
INTERSECT
(SELECT * FROM {prefix_2_table} AS {u} WHERE {type} = ? OR {prefix_2_table}.{id} > ?)
INTERSECT ALL
(SELECT * FROM {prefix_3_table} WHERE {x} IN (?, ?, ?))',
$select
);

$this->assertSameParameters(
[
'user',
100,
'admin',
800,
8,
9,
10,
],
$select
);
}

public function testExceptWithPrefixes(): void
{
$select = $this->db('prefixed', 'prefix_')
->select('*')
->from('table AS u')
->where('type', 'user')->orWhere('table.id', '<', 100);

$select->except(
$this->db('prefixed', 'prefix_2_')
->select('*')
->from('table AS u')
->where('type', 'admin')->orWhere('table.id', '>', 800)
);

$this->assertSameQuery(
'SELECT * FROM {prefix_table} AS {u} WHERE {type} = ? OR {prefix_table}.{id} < ?
EXCEPT
(SELECT * FROM {prefix_2_table} AS {u} WHERE {type} = ? OR {prefix_2_table}.{id} > ?)',
$select
);

$this->assertSameParameters(
[
'user',
100,
'admin',
800,
],
$select
);
}

public function testExceptWithPrefixes1(): void
{
$select = $this->db('prefixed', 'prefix_')
->select('*')
->from('table AS u')
->where('type', 'user')->orWhere('table.id', '<', 100);

$select->exceptAll(
$this->db('prefixed', 'prefix_2_')
->select('*')
->from('table AS u')
->where('type', 'admin')->orWhere('table.id', '>', 800)
);

$this->assertSameQuery(
'SELECT * FROM {prefix_table} AS {u} WHERE {type} = ? OR {prefix_table}.{id} < ?
EXCEPT ALL
(SELECT * FROM {prefix_2_table} AS {u} WHERE {type} = ? OR {prefix_2_table}.{id} > ?)',
$select
);

$this->assertSameParameters(
[
'user',
100,
'admin',
800,
],
$select
);
}

public function testExceptWithPrefixes2(): void
{
$select = $this->db('prefixed', 'prefix_')
->select('*')
->from('table AS u')
->where('type', 'user')->orWhere('table.id', '<', 100);

$select->except(
$this->db('prefixed', 'prefix_2_')
->select('*')
->from('table AS u')
->where('type', 'admin')->orWhere('table.id', '>', 800)
);

$select->exceptAll(
$this->db('prefixed', 'prefix_3_')->select('*')
->from('table')->where('x', 'IN', new Parameter([8, 9, 10]))
);

$this->assertSameQuery(
'SELECT * FROM {prefix_table} AS {u} WHERE {type} = ? OR {prefix_table}.{id} < ?
EXCEPT
(SELECT * FROM {prefix_2_table} AS {u} WHERE {type} = ? OR {prefix_2_table}.{id} > ?)
EXCEPT ALL
(SELECT * FROM {prefix_3_table} WHERE {x} IN (?, ?, ?))',
$select
);

$this->assertSameParameters(
[
'user',
100,
'admin',
800,
8,
9,
10,
],
$select
);
}

public function testSubQueryInUpdate(): void
{
$select = $this->database->update()
Expand Down

0 comments on commit 20d3aee

Please sign in to comment.