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

Subqueries in BaseBuilder #2001

Merged
merged 2 commits into from
Sep 2, 2019
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
87 changes: 57 additions & 30 deletions system/Database/BaseBuilder.php
Original file line number Diff line number Diff line change
Expand Up @@ -40,6 +40,7 @@

use CodeIgniter\Database\Exceptions\DatabaseException;
use CodeIgniter\Database\Exceptions\DataException;
use Closure;

/**
* Class BaseBuilder
Expand Down Expand Up @@ -701,10 +702,18 @@ protected function whereHaving(string $qb_key, $key, $value = null, string $type
}
else
{
$k .= $op;
$k .= " $op";
}

$v = " :$bind:";
if ($v instanceof Closure)
{
$builder = $this->cleanClone();
$v = '(' . str_replace("\n", ' ', $v($builder)->getCompiledSelect()) . ')';
}
else
{
$v = " :$bind:";
}
}
elseif (! $this->hasOperator($k) && $qb_key !== 'QBHaving')
{
Expand Down Expand Up @@ -733,13 +742,13 @@ protected function whereHaving(string $qb_key, $key, $value = null, string $type
* Generates a WHERE field IN('item', 'item') SQL query,
* joined with 'AND' if appropriate.
*
* @param string $key The field to search
* @param array $values The values searched on
* @param boolean $escape
* @param string $key The field to search
* @param array|Closure $values The values searched on, or anonymous function with subquery
* @param boolean $escape
*
* @return BaseBuilder
*/
public function whereIn(string $key = null, array $values = null, bool $escape = null)
public function whereIn(string $key = null, $values = null, bool $escape = null)
{
return $this->_whereIn($key, $values, false, 'AND ', $escape);
}
Expand All @@ -752,13 +761,13 @@ public function whereIn(string $key = null, array $values = null, bool $escape =
* Generates a WHERE field IN('item', 'item') SQL query,
* joined with 'OR' if appropriate.
*
* @param string $key The field to search
* @param array $values The values searched on
* @param boolean $escape
* @param string $key The field to search
* @param array|Closure $values The values searched on, or anonymous function with subquery
* @param boolean $escape
*
* @return BaseBuilder
*/
public function orWhereIn(string $key = null, array $values = null, bool $escape = null)
public function orWhereIn(string $key = null, $values = null, bool $escape = null)
{
return $this->_whereIn($key, $values, false, 'OR ', $escape);
}
Expand All @@ -771,13 +780,13 @@ public function orWhereIn(string $key = null, array $values = null, bool $escape
* Generates a WHERE field NOT IN('item', 'item') SQL query,
* joined with 'AND' if appropriate.
*
* @param string $key The field to search
* @param array $values The values searched on
* @param boolean $escape
* @param string $key The field to search
* @param array|Closure $values The values searched on, or anonymous function with subquery
* @param boolean $escape
*
* @return BaseBuilder
*/
public function whereNotIn(string $key = null, array $values = null, bool $escape = null)
public function whereNotIn(string $key = null, $values = null, bool $escape = null)
{
return $this->_whereIn($key, $values, true, 'AND ', $escape);
}
Expand All @@ -790,13 +799,13 @@ public function whereNotIn(string $key = null, array $values = null, bool $escap
* Generates a WHERE field NOT IN('item', 'item') SQL query,
* joined with 'OR' if appropriate.
*
* @param string $key The field to search
* @param array $values The values searched on
* @param boolean $escape
* @param string $key The field to search
* @param array|Closure $values The values searched on, or anonymous function with subquery
* @param boolean $escape
*
* @return BaseBuilder
*/
public function orWhereNotIn(string $key = null, array $values = null, bool $escape = null)
public function orWhereNotIn(string $key = null, $values = null, bool $escape = null)
{
return $this->_whereIn($key, $values, true, 'OR ', $escape);
}
Expand All @@ -811,17 +820,17 @@ public function orWhereNotIn(string $key = null, array $values = null, bool $esc
* @used-by whereNotIn()
* @used-by orWhereNotIn()
*
* @param string $key The field to search
* @param array $values The values searched on
* @param boolean $not If the statement would be IN or NOT IN
* @param string $type
* @param boolean $escape
* @param string $key The field to search
* @param array|Closure $values The values searched on, or anonymous function with subquery
* @param boolean $not If the statement would be IN or NOT IN
* @param string $type
* @param boolean $escape
*
* @return BaseBuilder
*/
protected function _whereIn(string $key = null, array $values = null, bool $not = false, string $type = 'AND ', bool $escape = null)
protected function _whereIn(string $key = null, $values = null, bool $not = false, string $type = 'AND ', bool $escape = null)
{
if ($key === null || $values === null)
if ($key === null || $values === null || (! is_array($values) && ! ($values instanceof Closure)))
{
return $this;
}
Expand All @@ -837,13 +846,20 @@ protected function _whereIn(string $key = null, array $values = null, bool $not

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

$where_in = array_values($values);
$ok = $this->setBind($ok, $where_in, $escape);
if ($values instanceof Closure)
{
$builder = $this->cleanClone();
$ok = str_replace("\n", ' ', $values($builder)->getCompiledSelect());
}
else
{
$ok = $this->setBind($ok, array_values($values), $escape);
}

$prefix = empty($this->QBWhere) ? $this->groupGetType('') : $this->groupGetType($type);

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

Expand Down Expand Up @@ -2640,7 +2656,6 @@ protected function compileWhereHaving(string $qb_key): string
{
continue;
}

// $matches = array(
// 0 => '(test <= foo)', /* the whole thing */
// 1 => '(', /* optional */
Expand Down Expand Up @@ -2968,7 +2983,7 @@ protected function getOperator(string $str, bool $list = false)
];
}

return preg_match_all('/' . implode('|', $_operators) . '/i', $str, $match) ? ($list ? $match[0] : $match[0][count($match[0]) - 1]) : false;
return preg_match_all('/' . implode('|', $_operators) . '/i', $str, $match) ? ($list ? $match[0] : $match[0][0]) : false;
}

// --------------------------------------------------------------------
Expand Down Expand Up @@ -3013,4 +3028,16 @@ protected function setBind(string $key, $value = null, bool $escape = true): str
}

//--------------------------------------------------------------------

/**
* Returns a clone of a Base Builder with reset query builder values.
*
* @return BaseBuilder
*/
protected function cleanClone()
{
return (clone $this)->from([], true)->resetQuery();
}

//--------------------------------------------------------------------
}
75 changes: 75 additions & 0 deletions tests/system/Database/Builder/WhereTest.php
Original file line number Diff line number Diff line change
@@ -1,5 +1,6 @@
<?php namespace Builder;

use CodeIgniter\Database\BaseBuilder;
use Tests\Support\Database\MockConnection;

class WhereTest extends \CIUnitTestCase
Expand Down Expand Up @@ -118,6 +119,20 @@ public function testWhereCustomString()

//--------------------------------------------------------------------

public function testWhereValueClosure()
{
$builder = $this->db->table('neworder');

$builder->where('advance_amount <', 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->assertEquals($expectedSQL, str_replace("\n", ' ', $builder->getCompiledSelect()));
}

//--------------------------------------------------------------------

public function testOrWhere()
{
$builder = $this->db->table('jobs');
Expand Down Expand Up @@ -191,6 +206,21 @@ public function testWhereIn()

//--------------------------------------------------------------------

public function testWhereInClosure()
{
$builder = $this->db->table('jobs');

$builder->whereIn('id', 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->assertEquals($expectedSQL, str_replace("\n", ' ', $builder->getCompiledSelect()));
}

//--------------------------------------------------------------------

public function testWhereNotIn()
{
$builder = $this->db->table('jobs');
Expand All @@ -214,6 +244,21 @@ public function testWhereNotIn()

//--------------------------------------------------------------------

public function testWhereNotInClosure()
{
$builder = $this->db->table('jobs');

$builder->whereNotIn('id', 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->assertEquals($expectedSQL, str_replace("\n", ' ', $builder->getCompiledSelect()));
}

//--------------------------------------------------------------------

public function testOrWhereIn()
{
$builder = $this->db->table('jobs');
Expand Down Expand Up @@ -241,6 +286,21 @@ public function testOrWhereIn()

//--------------------------------------------------------------------

public function testOrWhereInClosure()
{
$builder = $this->db->table('jobs');

$builder->where('deleted_at', null)->orWhereIn('id', 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->assertEquals($expectedSQL, str_replace("\n", ' ', $builder->getCompiledSelect()));
}

//--------------------------------------------------------------------

public function testOrWhereNotIn()
{
$builder = $this->db->table('jobs');
Expand All @@ -267,4 +327,19 @@ public function testOrWhereNotIn()
}

//--------------------------------------------------------------------

public function testOrWhereNotInClosure()
{
$builder = $this->db->table('jobs');

$builder->where('deleted_at', null)->orWhereNotIn('id', 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->assertEquals($expectedSQL, str_replace("\n", ' ', $builder->getCompiledSelect()));
}

//--------------------------------------------------------------------
}
Loading