Skip to content

Commit

Permalink
Merge pull request #5488 from iRedds/subquery-buider
Browse files Browse the repository at this point in the history
Feature: BaseBuilder instance as subquery.
  • Loading branch information
MGatner authored Dec 24, 2021
2 parents 60f1367 + 864d366 commit 7807496
Show file tree
Hide file tree
Showing 4 changed files with 179 additions and 52 deletions.
62 changes: 44 additions & 18 deletions system/Database/BaseBuilder.php
Original file line number Diff line number Diff line change
Expand Up @@ -693,9 +693,8 @@ protected function whereHaving(string $qbKey, $key, $value = null, string $type
$op = ' =';
}

if ($v instanceof Closure) {
$builder = $this->cleanClone();
$v = ' (' . strtr($v($builder)->getCompiledSelect(), "\n", ' ') . ')';
if ($this->isSubquery($v)) {
$v = $this->buildSubquery($v, true);
} else {
$bind = $this->setBind($k, $v, $escape);
$v = " :{$bind}:";
Expand Down Expand Up @@ -723,7 +722,7 @@ protected function whereHaving(string $qbKey, $key, $value = null, string $type
* Generates a WHERE field IN('item', 'item') SQL query,
* joined with 'AND' if appropriate.
*
* @param array|Closure|string $values The values searched on, or anonymous function with subquery
* @param array|BaseBuilder|Closure|string $values The values searched on, or anonymous function with subquery
*
* @return $this
*/
Expand All @@ -736,7 +735,7 @@ public function whereIn(?string $key = null, $values = null, ?bool $escape = nul
* Generates a WHERE field IN('item', 'item') SQL query,
* joined with 'OR' if appropriate.
*
* @param array|Closure|string $values The values searched on, or anonymous function with subquery
* @param array|BaseBuilder|Closure|string $values The values searched on, or anonymous function with subquery
*
* @return $this
*/
Expand All @@ -749,7 +748,7 @@ public function orWhereIn(?string $key = null, $values = null, ?bool $escape = n
* Generates a WHERE field NOT IN('item', 'item') SQL query,
* joined with 'AND' if appropriate.
*
* @param array|Closure|string $values The values searched on, or anonymous function with subquery
* @param array|BaseBuilder|Closure|string $values The values searched on, or anonymous function with subquery
*
* @return $this
*/
Expand All @@ -762,7 +761,7 @@ public function whereNotIn(?string $key = null, $values = null, ?bool $escape =
* Generates a WHERE field NOT IN('item', 'item') SQL query,
* joined with 'OR' if appropriate.
*
* @param array|Closure|string $values The values searched on, or anonymous function with subquery
* @param array|BaseBuilder|Closure|string $values The values searched on, or anonymous function with subquery
*
* @return $this
*/
Expand All @@ -775,7 +774,7 @@ public function orWhereNotIn(?string $key = null, $values = null, ?bool $escape
* Generates a HAVING field IN('item', 'item') SQL query,
* joined with 'AND' if appropriate.
*
* @param array|Closure|string $values The values searched on, or anonymous function with subquery
* @param array|BaseBuilder|Closure|string $values The values searched on, or anonymous function with subquery
*
* @return $this
*/
Expand All @@ -788,7 +787,7 @@ public function havingIn(?string $key = null, $values = null, ?bool $escape = nu
* Generates a HAVING field IN('item', 'item') SQL query,
* joined with 'OR' if appropriate.
*
* @param array|Closure|string $values The values searched on, or anonymous function with subquery
* @param array|BaseBuilder|Closure|string $values The values searched on, or anonymous function with subquery
*
* @return $this
*/
Expand All @@ -801,7 +800,7 @@ public function orHavingIn(?string $key = null, $values = null, ?bool $escape =
* Generates a HAVING field NOT IN('item', 'item') SQL query,
* joined with 'AND' if appropriate.
*
* @param array|Closure|string $values The values searched on, or anonymous function with subquery
* @param array|BaseBuilder|Closure|string $values The values searched on, or anonymous function with subquery
*
* @return $this
*/
Expand All @@ -814,7 +813,7 @@ public function havingNotIn(?string $key = null, $values = null, ?bool $escape =
* Generates a HAVING field NOT IN('item', 'item') SQL query,
* joined with 'OR' if appropriate.
*
* @param array|Closure|string $values The values searched on, or anonymous function with subquery
* @param array|BaseBuilder|Closure|string $values The values searched on, or anonymous function with subquery
*
* @return $this
*/
Expand All @@ -829,7 +828,7 @@ public function orHavingNotIn(?string $key = null, $values = null, ?bool $escape
* @used-by whereNotIn()
* @used-by orWhereNotIn()
*
* @param array|Closure|null $values The values searched on, or anonymous function with subquery
* @param array|BaseBuilder|Closure|null $values The values searched on, or anonymous function with subquery
*
* @throws InvalidArgumentException
*
Expand All @@ -845,7 +844,7 @@ protected function _whereIn(?string $key = null, $values = null, bool $not = fal
return $this; // @codeCoverageIgnore
}

if ($values === null || (! is_array($values) && ! ($values instanceof Closure))) {
if ($values === null || (! is_array($values) && ! $this->isSubquery($values))) {
if (CI_DEBUG) {
throw new InvalidArgumentException(sprintf('%s() expects $values to be of type array or closure', debug_backtrace(0, 2)[1]['function']));
}
Expand All @@ -865,18 +864,19 @@ protected function _whereIn(?string $key = null, $values = null, bool $not = fal

$not = ($not) ? ' NOT' : '';

if ($values instanceof Closure) {
$builder = $this->cleanClone();
$ok = strtr($values($builder)->getCompiledSelect(), "\n", ' ');
if ($this->isSubquery($values)) {
$whereIn = $this->buildSubquery($values, true);
$escape = false;
} else {
$whereIn = array_values($values);
$ok = $this->setBind($ok, $whereIn, $escape);
}

$ok = $this->setBind($ok, $whereIn, $escape);

$prefix = empty($this->{$clause}) ? $this->groupGetType('') : $this->groupGetType($type);

$whereIn = [
'condition' => $prefix . $key . $not . ($values instanceof Closure ? " IN ({$ok})" : " IN :{$ok}:"),
'condition' => "{$prefix}{$key}{$not} IN :{$ok}:",
'escape' => false,
];

Expand Down Expand Up @@ -2724,9 +2724,35 @@ protected function setBind(string $key, $value = null, bool $escape = true): str
* Returns a clone of a Base Builder with reset query builder values.
*
* @return $this
*
* @deprecated
*/
protected function cleanClone()
{
return (clone $this)->from([], true)->resetQuery();
}

/**
* @param mixed $value
*/
protected function isSubquery($value): bool
{
return $value instanceof BaseBuilder || $value instanceof Closure;
}

/**
* @param BaseBuilder|Closure $builder
* @param bool $wrapped Wrap the subquery in brackets
*/
protected function buildSubquery($builder, bool $wrapped = false): string
{
if ($builder instanceof Closure) {
$instance = (clone $this)->from([], true)->resetQuery();
$builder = $builder($instance);
}

$subquery = strtr($builder->getCompiledSelect(), "\n", ' ');

return $wrapped ? '(' . $subquery . ')' : $subquery;
}
}
81 changes: 71 additions & 10 deletions tests/system/Database/Builder/WhereTest.php
Original file line number Diff line number Diff line change
Expand Up @@ -141,14 +141,27 @@ public function testWhereCustomString()
$this->assertSame($expectedBinds, $builder->getBinds());
}

public function testWhereValueClosure()
public function testWhereValueSubQuery()
{
$expectedSQL = 'SELECT * FROM "neworder" WHERE "advance_amount" < (SELECT MAX(advance_amount) FROM "orders" WHERE "id" > 2)';

// Closure
$builder = $this->db->table('neworder');

$builder->where('advance_amount <', static function (BaseBuilder $builder) {
return $builder->select('MAX(advance_amount)', false)->from('orders')->where('id >', 2);
});
$expectedSQL = 'SELECT * FROM "neworder" WHERE "advance_amount" < (SELECT MAX(advance_amount) FROM "orders" WHERE "id" > 2)';

$this->assertSame($expectedSQL, str_replace("\n", ' ', $builder->getCompiledSelect()));

// Builder
$builder = $this->db->table('neworder');

$subQuery = $this->db->table('orders')
->select('MAX(advance_amount)', false)
->where('id >', 2);

$builder->where('advance_amount <', $subQuery);

$this->assertSame($expectedSQL, str_replace("\n", ' ', $builder->getCompiledSelect()));
}
Expand Down Expand Up @@ -218,15 +231,27 @@ public function testWhereIn()
$this->assertSame($expectedBinds, $builder->getBinds());
}

public function testWhereInClosure()
public function testWhereInSubQuery()
{
$expectedSQL = 'SELECT * FROM "jobs" WHERE "id" IN (SELECT "job_id" FROM "users_jobs" WHERE "user_id" = 3)';

// Closure
$builder = $this->db->table('jobs');

$builder->whereIn('id', static function (BaseBuilder $builder) {
return $builder->select('job_id')->from('users_jobs')->where('user_id', 3);
});

$expectedSQL = 'SELECT * FROM "jobs" WHERE "id" IN (SELECT "job_id" FROM "users_jobs" WHERE "user_id" = 3)';
$this->assertSame($expectedSQL, str_replace("\n", ' ', $builder->getCompiledSelect()));

// Builder
$builder = $this->db->table('jobs');

$subQuery = $this->db->table('users_jobs')
->select('job_id')
->where('user_id', 3);

$builder->whereIn('id', $subQuery);

$this->assertSame($expectedSQL, str_replace("\n", ' ', $builder->getCompiledSelect()));
}
Expand Down Expand Up @@ -295,15 +320,27 @@ public function testWhereNotIn()
$this->assertSame($expectedBinds, $builder->getBinds());
}

public function testWhereNotInClosure()
public function testWhereNotInSubQuery()
{
$expectedSQL = 'SELECT * FROM "jobs" WHERE "id" NOT IN (SELECT "job_id" FROM "users_jobs" WHERE "user_id" = 3)';

// Closure
$builder = $this->db->table('jobs');

$builder->whereNotIn('id', static function (BaseBuilder $builder) {
return $builder->select('job_id')->from('users_jobs')->where('user_id', 3);
});

$expectedSQL = 'SELECT * FROM "jobs" WHERE "id" NOT IN (SELECT "job_id" FROM "users_jobs" WHERE "user_id" = 3)';
$this->assertSame($expectedSQL, str_replace("\n", ' ', $builder->getCompiledSelect()));

// Builder
$builder = $this->db->table('jobs');

$subQuery = $this->db->table('users_jobs')
->select('job_id')
->where('user_id', 3);

$builder->whereNotIn('id', $subQuery);

$this->assertSame($expectedSQL, str_replace("\n", ' ', $builder->getCompiledSelect()));
}
Expand Down Expand Up @@ -333,15 +370,27 @@ public function testOrWhereIn()
$this->assertSame($expectedBinds, $builder->getBinds());
}

public function testOrWhereInClosure()
public function testOrWhereInSubQuery()
{
$expectedSQL = 'SELECT * FROM "jobs" WHERE "deleted_at" IS NULL OR "id" IN (SELECT "job_id" FROM "users_jobs" WHERE "user_id" = 3)';

// Closure
$builder = $this->db->table('jobs');

$builder->where('deleted_at', null)->orWhereIn('id', static function (BaseBuilder $builder) {
return $builder->select('job_id')->from('users_jobs')->where('user_id', 3);
});

$expectedSQL = 'SELECT * FROM "jobs" WHERE "deleted_at" IS NULL OR "id" IN (SELECT "job_id" FROM "users_jobs" WHERE "user_id" = 3)';
$this->assertSame($expectedSQL, str_replace("\n", ' ', $builder->getCompiledSelect()));

// Builder
$builder = $this->db->table('jobs');

$subQuery = $this->db->table('users_jobs')
->select('job_id')
->where('user_id', 3);

$builder->where('deleted_at', null)->orWhereIn('id', $subQuery);

$this->assertSame($expectedSQL, str_replace("\n", ' ', $builder->getCompiledSelect()));
}
Expand Down Expand Up @@ -371,15 +420,27 @@ public function testOrWhereNotIn()
$this->assertSame($expectedBinds, $builder->getBinds());
}

public function testOrWhereNotInClosure()
public function testOrWhereNotInSubQuery()
{
$expectedSQL = 'SELECT * FROM "jobs" WHERE "deleted_at" IS NULL OR "id" NOT IN (SELECT "job_id" FROM "users_jobs" WHERE "user_id" = 3)';

// Closure
$builder = $this->db->table('jobs');

$builder->where('deleted_at', null)->orWhereNotIn('id', static function (BaseBuilder $builder) {
return $builder->select('job_id')->from('users_jobs')->where('user_id', 3);
});

$expectedSQL = 'SELECT * FROM "jobs" WHERE "deleted_at" IS NULL OR "id" NOT IN (SELECT "job_id" FROM "users_jobs" WHERE "user_id" = 3)';
$this->assertSame($expectedSQL, str_replace("\n", ' ', $builder->getCompiledSelect()));

// Builder
$builder = $this->db->table('jobs');

$subQuery = $this->db->table('users_jobs')
->select('job_id')
->where('user_id', 3);

$builder->where('deleted_at', null)->orWhereNotIn('id', $subQuery);

$this->assertSame($expectedSQL, str_replace("\n", ' ', $builder->getCompiledSelect()));
}
Expand Down
2 changes: 2 additions & 0 deletions user_guide_src/source/changelogs/v4.1.6.rst
Original file line number Diff line number Diff line change
Expand Up @@ -33,6 +33,7 @@ Enhancements
************

- Database pane on debug toolbar now displays location where Query was called from. Also displays full backtrace.
- :ref:`Subqueries <query-builder-where-subquery>` in QueryBuilder can now be an instance of the BaseBuilder class.

Changes
*******
Expand All @@ -43,6 +44,7 @@ Deprecations
************

- ``Seeder::faker()`` and ``Seeder::$faker`` are deprecated.
- ``BaseBuilder::cleanClone()`` is deprecated.

Sending Cookies
===============
Expand Down
Loading

0 comments on commit 7807496

Please sign in to comment.