diff --git a/system/Database/BaseBuilder.php b/system/Database/BaseBuilder.php index fecf3e10718f..2a431accd2f5 100644 --- a/system/Database/BaseBuilder.php +++ b/system/Database/BaseBuilder.php @@ -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}:"; @@ -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 */ @@ -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 */ @@ -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 */ @@ -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 */ @@ -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 */ @@ -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 */ @@ -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 */ @@ -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 */ @@ -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 * @@ -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'])); } @@ -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, ]; @@ -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; + } } diff --git a/tests/system/Database/Builder/WhereTest.php b/tests/system/Database/Builder/WhereTest.php index e58af53cadab..70463776a3ac 100644 --- a/tests/system/Database/Builder/WhereTest.php +++ b/tests/system/Database/Builder/WhereTest.php @@ -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())); } @@ -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())); } @@ -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())); } @@ -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())); } @@ -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())); } diff --git a/user_guide_src/source/changelogs/v4.1.6.rst b/user_guide_src/source/changelogs/v4.1.6.rst index d53378a6b624..61214596ea97 100644 --- a/user_guide_src/source/changelogs/v4.1.6.rst +++ b/user_guide_src/source/changelogs/v4.1.6.rst @@ -33,6 +33,7 @@ Enhancements ************ - Database pane on debug toolbar now displays location where Query was called from. Also displays full backtrace. +- :ref:`Subqueries ` in QueryBuilder can now be an instance of the BaseBuilder class. Changes ******* @@ -43,6 +44,7 @@ Deprecations ************ - ``Seeder::faker()`` and ``Seeder::$faker`` are deprecated. +- ``BaseBuilder::cleanClone()`` is deprecated. Sending Cookies =============== diff --git a/user_guide_src/source/database/query_builder.rst b/user_guide_src/source/database/query_builder.rst index 7aa8cf69dcdb..2c85a58e63e6 100755 --- a/user_guide_src/source/database/query_builder.rst +++ b/user_guide_src/source/database/query_builder.rst @@ -304,15 +304,24 @@ methods: $where = "name={$name} AND status='boss' OR status='active'"; $builder->where($where); +.. _query-builder-where-subquery: + #. **Subqueries:** - You can use an anonymous function to create a subquery:: + :: + + // With closure $builder->where('advance_amount <', function (BaseBuilder $builder) { return $builder->select('MAX(advance_amount)', false)->from('orders')->where('id >', 2); }); + // Produces: WHERE "advance_amount" < (SELECT MAX(advance_amount) FROM "orders" WHERE "id" > 2) + // With builder directly + $subQuery = $db->table('orders')->select('MAX(advance_amount)', false)->where('id >', 2) + $builder->where('advance_amount <', $subQuery); + **$builder->orWhere()** This function is identical to the one above, except that multiple @@ -333,11 +342,16 @@ appropriate:: You can use subqueries instead of an array of values:: + // With closure $builder->whereIn('id', function (BaseBuilder $builder) { return $builder->select('job_id')->from('users_jobs')->where('user_id', 3); }); // Produces: WHERE "id" IN (SELECT "job_id" FROM "users_jobs" WHERE "user_id" = 3) + // With builder directly + $subQuery = $db->table('users_jobs')->select('job_id')->where('user_id', 3); + $builder->whereIn('id', $subQuery); + **$builder->orWhereIn()** Generates a ``WHERE field IN ('item', 'item')`` SQL query joined with OR if @@ -349,12 +363,17 @@ appropriate:: You can use subqueries instead of an array of values:: + // With closure $builder->orWhereIn('id', function (BaseBuilder $builder) { return $builder->select('job_id')->from('users_jobs')->where('user_id', 3); }); // Produces: OR "id" IN (SELECT "job_id" FROM "users_jobs" WHERE "user_id" = 3) + // With builder directly + $subQuery = $db->table('users_jobs')->select('job_id')->where('user_id', 3); + $builder->orWhereIn('id', $subQuery); + **$builder->whereNotIn()** Generates a WHERE field NOT IN ('item', 'item') SQL query joined with @@ -366,12 +385,17 @@ AND if appropriate:: You can use subqueries instead of an array of values:: + // With closure $builder->whereNotIn('id', function (BaseBuilder $builder) { return $builder->select('job_id')->from('users_jobs')->where('user_id', 3); }); // Produces: WHERE "id" NOT IN (SELECT "job_id" FROM "users_jobs" WHERE "user_id" = 3) + // With builder directly + $subQuery = $db->table('users_jobs')->select('job_id')->where('user_id', 3); + $builder->whereNotIn('id', $subQuery); + **$builder->orWhereNotIn()** Generates a ``WHERE field NOT IN ('item', 'item')`` SQL query joined with OR @@ -383,12 +407,17 @@ if appropriate:: You can use subqueries instead of an array of values:: + // With closure $builder->orWhereNotIn('id', function (BaseBuilder $builder) { return $builder->select('job_id')->from('users_jobs')->where('user_id', 3); }); // Produces: OR "id" NOT IN (SELECT "job_id" FROM "users_jobs" WHERE "user_id" = 3) + // With builder directly + $subQuery = $db->table('users_jobs')->select('job_id')->where('user_id', 3); + $builder->orWhereNotIn('id', $subQuery); + ************************ Looking for Similar Data ************************ @@ -512,23 +541,24 @@ Identical to ``having()``, only separates multiple clauses with "OR". **$builder->havingIn()** Generates a ``HAVING field IN ('item', 'item')`` SQL query joined with AND if -appropriate - -:: +appropriate:: $groups = [1, 2, 3]; $builder->havingIn('group_id', $groups); // Produces: HAVING group_id IN (1, 2, 3) -You can use subqueries instead of an array of values. - -:: +You can use subqueries instead of an array of values.:: + // With closure $builder->havingIn('id', function (BaseBuilder $builder) { return $builder->select('user_id')->from('users_jobs')->where('group_id', 3); }); // Produces: HAVING "id" IN (SELECT "user_id" FROM "users_jobs" WHERE "group_id" = 3) + // With builder directly + $subQuery = $db->table('users_jobs')->select('user_id')->where('group_id', 3); + $builder->havingIn('id', $subQuery); + **$builder->orHavingIn()** Generates a ``HAVING field IN ('item', 'item')`` SQL query joined with OR if @@ -540,16 +570,19 @@ appropriate $builder->orHavingIn('group_id', $groups); // Produces: OR group_id IN (1, 2, 3) -You can use subqueries instead of an array of values. - -:: +You can use subqueries instead of an array of values.:: + //With closure $builder->orHavingIn('id', function (BaseBuilder $builder) { return $builder->select('user_id')->from('users_jobs')->where('group_id', 3); }); // Produces: OR "id" IN (SELECT "user_id" FROM "users_jobs" WHERE "group_id" = 3) + // With builder directly + $subQuery = $db->table('users_jobs')->select('user_id')->where('group_id', 3); + $builder->orHavingIn('id', $subQuery); + **$builder->havingNotIn()** Generates a ``HAVING field NOT IN ('item', 'item')`` SQL query joined with @@ -561,16 +594,18 @@ AND if appropriate $builder->havingNotIn('group_id', $groups); // Produces: HAVING group_id NOT IN (1, 2, 3) -You can use subqueries instead of an array of values. - -:: +You can use subqueries instead of an array of values.:: + //With closure $builder->havingNotIn('id', function (BaseBuilder $builder) { return $builder->select('user_id')->from('users_jobs')->where('group_id', 3); }); // Produces: HAVING "id" NOT IN (SELECT "user_id" FROM "users_jobs" WHERE "group_id" = 3) + // With builder directly + $subQuery = $db->table('users_jobs')->select('user_id')->where('group_id', 3); + $builder->havingNotIn('id', $subQuery); **$builder->orHavingNotIn()** @@ -583,16 +618,19 @@ if appropriate $builder->havingNotIn('group_id', $groups); // Produces: OR group_id NOT IN (1, 2, 3) -You can use subqueries instead of an array of values. - -:: +You can use subqueries instead of an array of values.:: + //With closure $builder->orHavingNotIn('id', function (BaseBuilder $builder) { return $builder->select('user_id')->from('users_jobs')->where('group_id', 3); }); // Produces: OR "id" NOT IN (SELECT "user_id" FROM "users_jobs" WHERE "group_id" = 3) + // With builder directly + $subQuery = $db->table('users_jobs')->select('user_id')->where('group_id', 3); + $builder->orHavingNotIn('id', $subQuery); + **$builder->havingLike()** This method enables you to generate **LIKE** clauses for HAVING part or the query, useful for doing @@ -1397,7 +1435,7 @@ Class Reference .. php:method:: orWhereIn([$key = null[, $values = null[, $escape = null]]]) :param string $key: The field to search - :param array|Closure $values: Array of target values, or anonymous function for subquery + :param array|BaseBulder|Closure $values: Array of target values, or anonymous function for subquery :param bool $escape: Whether to escape values and identifiers :returns: ``BaseBuilder`` instance (method chaining) :rtype: ``BaseBuilder`` @@ -1407,7 +1445,7 @@ Class Reference .. php:method:: orWhereNotIn([$key = null[, $values = null[, $escape = null]]]) :param string $key: The field to search - :param array|Closure $values: Array of target values, or anonymous function for subquery + :param array|BaseBulder|Closure $values: Array of target values, or anonymous function for subquery :param bool $escape: Whether to escape values and identifiers :returns: ``BaseBuilder`` instance (method chaining) :rtype: ``BaseBuilder`` @@ -1417,7 +1455,7 @@ Class Reference .. php:method:: whereIn([$key = null[, $values = null[, $escape = null]]]) :param string $key: Name of field to examine - :param array|Closure $values: Array of target values, or anonymous function for subquery + :param array|BaseBulder|Closure $values: Array of target values, or anonymous function for subquery :param bool $escape: Whether to escape values and identifiers :returns: ``BaseBuilder`` instance (method chaining) :rtype: ``BaseBuilder`` @@ -1427,7 +1465,7 @@ Class Reference .. php:method:: whereNotIn([$key = null[, $values = null[, $escape = null]]]) :param string $key: Name of field to examine - :param array|Closure $values: Array of target values, or anonymous function for subquery + :param array|BaseBulder|Closure $values: Array of target values, or anonymous function for subquery :param bool $escape: Whether to escape values and identifiers :returns: ``BaseBuilder`` instance (method chaining) :rtype: ``BaseBuilder`` @@ -1540,7 +1578,7 @@ Class Reference .. php:method:: orHavingIn([$key = null[, $values = null[, $escape = null]]]) :param string $key: The field to search - :param array|Closure $values: Array of target values, or anonymous function for subquery + :param array|BaseBulder|Closure $values: Array of target values, or anonymous function for subquery :param bool $escape: Whether to escape values and identifiers :returns: ``BaseBuilder`` instance (method chaining) :rtype: ``BaseBuilder`` @@ -1550,7 +1588,7 @@ Class Reference .. php:method:: orHavingNotIn([$key = null[, $values = null[, $escape = null]]]) :param string $key: The field to search - :param array|Closure $values: Array of target values, or anonymous function for subquery + :param array|BaseBulder|Closure $values: Array of target values, or anonymous function for subquery :param bool $escape: Whether to escape values and identifiers :returns: ``BaseBuilder`` instance (method chaining) :rtype: ``BaseBuilder`` @@ -1560,7 +1598,7 @@ Class Reference .. php:method:: havingIn([$key = null[, $values = null[, $escape = null]]]) :param string $key: Name of field to examine - :param array|Closure $values: Array of target values, or anonymous function for subquery + :param array|BaseBulder|Closure $values: Array of target values, or anonymous function for subquery :param bool $escape: Whether to escape values and identifiers :returns: ``BaseBuilder`` instance (method chaining) :rtype: ``BaseBuilder`` @@ -1570,7 +1608,7 @@ Class Reference .. php:method:: havingNotIn([$key = null[, $values = null[, $escape = null]]]) :param string $key: Name of field to examine - :param array|Closure $values: Array of target values, or anonymous function for subquery + :param array|BaseBulder|Closure $values: Array of target values, or anonymous function for subquery :param bool $escape: Whether to escape values and identifiers :param bool $insensitiveSearch: Whether to force a case-insensitive search :returns: ``BaseBuilder`` instance (method chaining)