From 3cfecb61346aa11e4877e31bf8b36aa1b1729387 Mon Sep 17 00:00:00 2001 From: michalsn Date: Sun, 22 Sep 2019 18:37:30 +0200 Subject: [PATCH 1/3] Add support for a new having clauses --- system/Database/BaseBuilder.php | 261 ++++++++++++- tests/system/Database/Builder/GroupTest.php | 402 ++++++++++++++++++++ tests/system/Database/Live/GroupTest.php | 211 ++++++++++ 3 files changed, 867 insertions(+), 7 deletions(-) diff --git a/system/Database/BaseBuilder.php b/system/Database/BaseBuilder.php index ea3488d9e9aa..1206ccd93669 100644 --- a/system/Database/BaseBuilder.php +++ b/system/Database/BaseBuilder.php @@ -829,6 +829,82 @@ public function orWhereNotIn(string $key = null, $values = null, bool $escape = //-------------------------------------------------------------------- + /** + * HAVING IN + * + * Generates a HAVING field IN('item', 'item') SQL query, + * joined with 'AND' if appropriate. + * + * @param string $key The field to search + * @param array|string|Closure $values The values searched on, or anonymous function with subquery + * @param boolean $escape + * + * @return BaseBuilder + */ + public function havingIn(string $key = null, $values = null, bool $escape = null) + { + return $this->_whereIn($key, $values, false, 'AND ', $escape, 'QBHaving'); + } + + //-------------------------------------------------------------------- + + /** + * OR HAVING IN + * + * Generates a HAVING field IN('item', 'item') SQL query, + * joined with 'OR' if appropriate. + * + * @param string $key The field to search + * @param array|string|Closure $values The values searched on, or anonymous function with subquery + * @param boolean $escape + * + * @return BaseBuilder + */ + public function orHavingIn(string $key = null, $values = null, bool $escape = null) + { + return $this->_whereIn($key, $values, false, 'OR ', $escape, 'QBHaving'); + } + + //-------------------------------------------------------------------- + + /** + * HAVING NOT IN + * + * Generates a HAVING field NOT IN('item', 'item') SQL query, + * joined with 'AND' if appropriate. + * + * @param string $key The field to search + * @param array|string|Closure $values The values searched on, or anonymous function with subquery + * @param boolean $escape + * + * @return BaseBuilder + */ + public function havingNotIn(string $key = null, $values = null, bool $escape = null) + { + return $this->_whereIn($key, $values, true, 'AND ', $escape, 'QBHaving'); + } + + //-------------------------------------------------------------------- + + /** + * OR HAVING NOT IN + * + * Generates a HAVING field NOT IN('item', 'item') SQL query, + * joined with 'OR' if appropriate. + * + * @param string $key The field to search + * @param array|string|Closure $values The values searched on, or anonymous function with subquery + * @param boolean $escape + * + * @return BaseBuilder + */ + public function orHavingNotIn(string $key = null, $values = null, bool $escape = null) + { + return $this->_whereIn($key, $values, true, 'OR ', $escape, 'QBHaving'); + } + + //-------------------------------------------------------------------- + /** * Internal WHERE IN * @@ -842,10 +918,11 @@ public function orWhereNotIn(string $key = null, $values = null, bool $escape = * @param boolean $not If the statement would be IN or NOT IN * @param string $type * @param boolean $escape + * @param string $clause (Internal use only) * * @return BaseBuilder */ - protected function _whereIn(string $key = null, $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, string $clause = 'QBWhere') { if ($key === null || $values === null || (! is_array($values) && ! ($values instanceof Closure))) { @@ -874,14 +951,14 @@ protected function _whereIn(string $key = null, $values = null, bool $not = fals $ok = $this->setBind($ok, $whereIn, $escape); } - $prefix = empty($this->QBWhere) ? $this->groupGetType('') : $this->groupGetType($type); + $prefix = empty($this->$clause) ? $this->groupGetType('') : $this->groupGetType($type); $whereIn = [ 'condition' => $prefix . $key . $not . ($values instanceof Closure ? " IN ($ok)" : " IN :{$ok}:"), 'escape' => false, ]; - $this->QBWhere[] = $whereIn; + $this->{$clause}[] = $whereIn; return $this; } @@ -970,6 +1047,86 @@ public function orNotLike($field, string $match = '', string $side = 'both', boo return $this->_like($field, $match, 'OR ', $side, 'NOT', $escape, $insensitiveSearch); } + // -------------------------------------------------------------------- + + /** + * LIKE with HAVING clause + * + * Generates a %LIKE% portion of the query. + * Separates multiple calls with 'AND'. + * + * @param mixed $field + * @param string $match + * @param string $side + * @param boolean $escape + * + * @return BaseBuilder + */ + public function havingLike($field, string $match = '', string $side = 'both', bool $escape = null, bool $insensitiveSearch = false) + { + return $this->_like($field, $match, 'AND ', $side, '', $escape, $insensitiveSearch, 'QBHaving'); + } + + // -------------------------------------------------------------------- + + /** + * NOT LIKE with HAVING clause + * + * Generates a NOT LIKE portion of the query. + * Separates multiple calls with 'AND'. + * + * @param mixed $field + * @param string $match + * @param string $side + * @param boolean $escape + * + * @return BaseBuilder + */ + public function notHavingLike($field, string $match = '', string $side = 'both', bool $escape = null, bool $insensitiveSearch = false) + { + return $this->_like($field, $match, 'AND ', $side, 'NOT', $escape, $insensitiveSearch, 'QBHaving'); + } + + // -------------------------------------------------------------------- + + /** + * OR LIKE with HAVING clause + * + * Generates a %LIKE% portion of the query. + * Separates multiple calls with 'OR'. + * + * @param mixed $field + * @param string $match + * @param string $side + * @param boolean $escape + * + * @return BaseBuilder + */ + public function orHavingLike($field, string $match = '', string $side = 'both', bool $escape = null, bool $insensitiveSearch = false) + { + return $this->_like($field, $match, 'OR ', $side, '', $escape, $insensitiveSearch, 'QBHaving'); + } + + // -------------------------------------------------------------------- + + /** + * OR NOT LIKE with HAVING clause + * + * Generates a NOT LIKE portion of the query. + * Separates multiple calls with 'OR'. + * + * @param mixed $field + * @param string $match + * @param string $side + * @param boolean $escape + * + * @return BaseBuilder + */ + public function orNotHavingLike($field, string $match = '', string $side = 'both', bool $escape = null, bool $insensitiveSearch = false) + { + return $this->_like($field, $match, 'OR ', $side, 'NOT', $escape, $insensitiveSearch, 'QBHaving'); + } + //-------------------------------------------------------------------- /** @@ -979,6 +1136,10 @@ public function orNotLike($field, string $match = '', string $side = 'both', boo * @used-by orLike() * @used-by notLike() * @used-by orNotLike() + * @used-by havingLike() + * @used-by orHavingLike() + * @used-by notHavingLike() + * @used-by orNotHavingLike() * * @param mixed $field * @param string $match @@ -987,10 +1148,11 @@ public function orNotLike($field, string $match = '', string $side = 'both', boo * @param string $not * @param boolean $escape * @param boolean $insensitiveSearch IF true, will force a case-insensitive search + * @param string $clause (Internal use only) * * @return BaseBuilder */ - protected function _like($field, string $match = '', string $type = 'AND ', string $side = 'both', string $not = '', bool $escape = null, bool $insensitiveSearch = false) + protected function _like($field, string $match = '', string $type = 'AND ', string $side = 'both', string $not = '', bool $escape = null, bool $insensitiveSearch = false, string $clause = 'QBWhere') { if (! is_array($field)) { @@ -1004,13 +1166,13 @@ protected function _like($field, string $match = '', string $type = 'AND ', stri foreach ($field as $k => $v) { - $prefix = empty($this->QBWhere) ? $this->groupGetType('') : $this->groupGetType($type); - if ($insensitiveSearch === true) { $v = strtolower($v); } + $prefix = empty($this->$clause) ? $this->groupGetType('') : $this->groupGetType($type); + if ($side === 'none') { $bind = $this->setBind($k, $v, $escape); @@ -1036,7 +1198,7 @@ protected function _like($field, string $match = '', string $type = 'AND ', stri $like_statement .= sprintf($this->db->likeEscapeStr, $this->db->likeEscapeChar); } - $this->QBWhere[] = [ + $this->{$clause}[] = [ 'condition' => $like_statement, 'escape' => $escape, ]; @@ -1152,6 +1314,90 @@ public function groupEnd() return $this; } + // -------------------------------------------------------------------- + + /** + * Starts a query group for HAVING clause. + * + * @param string $not (Internal use only) + * @param string $type (Internal use only) + * + * @return BaseBuilder + */ + public function havingGroupStart(string $not = '', string $type = 'AND ') + { + $type = $this->groupGetType($type); + + $this->QBWhereGroupStarted = true; + $prefix = empty($this->QBHaving) ? '' : $type; + $having = [ + 'condition' => $prefix . $not . str_repeat(' ', ++$this->QBWhereGroupCount) . ' (', + 'value' => null, + 'escape' => false, + ]; + + $this->QBHaving[] = $having; + + return $this; + } + + // -------------------------------------------------------------------- + + /** + * Starts a query group for HAVING clause, but ORs the group. + * + * @return BaseBuilder + */ + public function orHavingGroupStart() + { + return $this->havingGroupStart('', 'OR '); + } + + // -------------------------------------------------------------------- + + /** + * Starts a query group for HAVING clause, but NOTs the group. + * + * @return BaseBuilder + */ + public function notHavingGroupStart() + { + return $this->havingGroupStart('NOT ', 'AND '); + } + + // -------------------------------------------------------------------- + + /** + * Starts a query group for HAVING clause, but OR NOTs the group. + * + * @return BaseBuilder + */ + public function orNotHavingGroupStart() + { + return $this->havingGroupStart('NOT ', 'OR '); + } + + // -------------------------------------------------------------------- + + /** + * Ends a query group for HAVING clause. + * + * @return BaseBuilder + */ + public function havingGroupEnd() + { + $this->QBWhereGroupStarted = false; + $having = [ + 'condition' => str_repeat(' ', $this->QBWhereGroupCount -- ) . ')', + 'value' => null, + 'escape' => false, + ]; + + $this->QBHaving[] = $having; + + return $this; + } + //-------------------------------------------------------------------- /** @@ -1161,6 +1407,7 @@ public function groupEnd() * @used-by _like() * @used-by whereHaving() * @used-by _whereIn() + * @used-by havingGroupStart() * * @param string $type * diff --git a/tests/system/Database/Builder/GroupTest.php b/tests/system/Database/Builder/GroupTest.php index bf957e543862..e5223d3da78a 100644 --- a/tests/system/Database/Builder/GroupTest.php +++ b/tests/system/Database/Builder/GroupTest.php @@ -63,6 +63,408 @@ public function testOrHavingBy() //-------------------------------------------------------------------- + public function testHavingIn() + { + $builder = new BaseBuilder('user', $this->db); + + $builder->select('name') + ->groupBy('name') + ->havingIn('id', [1, 2]); + + $expectedSQL = 'SELECT "name" FROM "user" GROUP BY "name" HAVING "id" IN (1,2)'; + + $this->assertEquals($expectedSQL, str_replace("\n", ' ', $builder->getCompiledSelect())); + } + + //-------------------------------------------------------------------- + + public function testHavingInClosure() + { + $builder = new BaseBuilder('user', $this->db); + + $builder->select('name') + ->groupBy('name'); + + $builder->havingIn('id', function (BaseBuilder $builder) { + return $builder->select('user_id')->from('users_jobs')->where('group_id', 3); + }); + + $expectedSQL = 'SELECT "name" FROM "user" GROUP BY "name" HAVING "id" IN (SELECT "user_id" FROM "users_jobs" WHERE "group_id" = 3)'; + + $this->assertEquals($expectedSQL, str_replace("\n", ' ', $builder->getCompiledSelect())); + } + + //-------------------------------------------------------------------- + + public function testOrHavingIn() + { + $builder = new BaseBuilder('user', $this->db); + + $builder->select('name') + ->groupBy('name') + ->havingIn('id', [1, 2]) + ->orHavingIn('group_id', [5, 6]); + + $expectedSQL = 'SELECT "name" FROM "user" GROUP BY "name" HAVING "id" IN (1,2) OR "group_id" IN (5,6)'; + + $this->assertEquals($expectedSQL, str_replace("\n", ' ', $builder->getCompiledSelect())); + } + + //-------------------------------------------------------------------- + + public function testOrHavingInClosure() + { + $builder = new BaseBuilder('user', $this->db); + + $builder->select('name') + ->groupBy('name'); + + $builder->havingIn('id', function (BaseBuilder $builder) { + return $builder->select('user_id')->from('users_jobs')->where('group_id', 3); + }); + $builder->orHavingIn('group_id', function (BaseBuilder $builder) { + return $builder->select('group_id')->from('groups')->where('group_id', 6); + }); + + $expectedSQL = 'SELECT "name" FROM "user" GROUP BY "name" HAVING "id" IN (SELECT "user_id" FROM "users_jobs" WHERE "group_id" = 3) OR "group_id" IN (SELECT "group_id" FROM "groups" WHERE "group_id" = 6)'; + + $this->assertEquals($expectedSQL, str_replace("\n", ' ', $builder->getCompiledSelect())); + } + + //-------------------------------------------------------------------- + + public function testHavingNotIn() + { + $builder = new BaseBuilder('user', $this->db); + + $builder->select('name') + ->groupBy('name') + ->havingNotIn('id', [1, 2]); + + $expectedSQL = 'SELECT "name" FROM "user" GROUP BY "name" HAVING "id" NOT IN (1,2)'; + + $this->assertEquals($expectedSQL, str_replace("\n", ' ', $builder->getCompiledSelect())); + } + + //-------------------------------------------------------------------- + + public function testHavingNotInClosure() + { + $builder = new BaseBuilder('user', $this->db); + + $builder->select('name') + ->groupBy('name'); + + $builder->havingNotIn('id', function (BaseBuilder $builder) { + return $builder->select('user_id')->from('users_jobs')->where('group_id', 3); + }); + + $expectedSQL = 'SELECT "name" FROM "user" GROUP BY "name" HAVING "id" NOT IN (SELECT "user_id" FROM "users_jobs" WHERE "group_id" = 3)'; + + $this->assertEquals($expectedSQL, str_replace("\n", ' ', $builder->getCompiledSelect())); + } + + //-------------------------------------------------------------------- + + public function testOrHavingNotIn() + { + $builder = new BaseBuilder('user', $this->db); + + $builder->select('name') + ->groupBy('name') + ->havingNotIn('id', [1, 2]) + ->orHavingNotIn('group_id', [5, 6]); + + $expectedSQL = 'SELECT "name" FROM "user" GROUP BY "name" HAVING "id" NOT IN (1,2) OR "group_id" NOT IN (5,6)'; + + $this->assertEquals($expectedSQL, str_replace("\n", ' ', $builder->getCompiledSelect())); + } + + //-------------------------------------------------------------------- + + public function testOrHavingNotInClosure() + { + $builder = new BaseBuilder('user', $this->db); + + $builder->select('name') + ->groupBy('name'); + + $builder->havingNotIn('id', function (BaseBuilder $builder) { + return $builder->select('user_id')->from('users_jobs')->where('group_id', 3); + }); + $builder->orHavingNotIn('group_id', function (BaseBuilder $builder) { + return $builder->select('group_id')->from('groups')->where('group_id', 6); + }); + + $expectedSQL = 'SELECT "name" FROM "user" GROUP BY "name" HAVING "id" NOT IN (SELECT "user_id" FROM "users_jobs" WHERE "group_id" = 3) OR "group_id" NOT IN (SELECT "group_id" FROM "groups" WHERE "group_id" = 6)'; + + $this->assertEquals($expectedSQL, str_replace("\n", ' ', $builder->getCompiledSelect())); + } + + //-------------------------------------------------------------------- + + public function testHavingLike() + { + $builder = new BaseBuilder('user', $this->db); + + $builder->select('name') + ->groupBy('name') + ->havingLike('pet_name', 'a'); + + $expectedSQL = 'SELECT "name" FROM "user" GROUP BY "name" HAVING "pet_name" LIKE \'%a%\' ESCAPE \'!\''; + + $this->assertEquals($expectedSQL, str_replace("\n", ' ', $builder->getCompiledSelect())); + } + + //-------------------------------------------------------------------- + + public function testHavingLikeBefore() + { + $builder = new BaseBuilder('user', $this->db); + + $builder->select('name') + ->groupBy('name') + ->havingLike('pet_name', 'a', 'before'); + + $expectedSQL = 'SELECT "name" FROM "user" GROUP BY "name" HAVING "pet_name" LIKE \'%a\' ESCAPE \'!\''; + + $this->assertEquals($expectedSQL, str_replace("\n", ' ', $builder->getCompiledSelect())); + } + + //-------------------------------------------------------------------- + + public function testHavingLikeAfter() + { + $builder = new BaseBuilder('user', $this->db); + + $builder->select('name') + ->groupBy('name') + ->havingLike('pet_name', 'a', 'after'); + + $expectedSQL = 'SELECT "name" FROM "user" GROUP BY "name" HAVING "pet_name" LIKE \'a%\' ESCAPE \'!\''; + + $this->assertEquals($expectedSQL, str_replace("\n", ' ', $builder->getCompiledSelect())); + } + + //-------------------------------------------------------------------- + + public function testNotHavingLike() + { + $builder = new BaseBuilder('user', $this->db); + + $builder->select('name') + ->groupBy('name') + ->notHavingLike('pet_name', 'a'); + + $expectedSQL = 'SELECT "name" FROM "user" GROUP BY "name" HAVING "pet_name" NOT LIKE \'%a%\' ESCAPE \'!\''; + + $this->assertEquals($expectedSQL, str_replace("\n", ' ', $builder->getCompiledSelect())); + } + + //-------------------------------------------------------------------- + + public function testNotHavingLikeBefore() + { + $builder = new BaseBuilder('user', $this->db); + + $builder->select('name') + ->groupBy('name') + ->notHavingLike('pet_name', 'a', 'before'); + + $expectedSQL = 'SELECT "name" FROM "user" GROUP BY "name" HAVING "pet_name" NOT LIKE \'%a\' ESCAPE \'!\''; + + $this->assertEquals($expectedSQL, str_replace("\n", ' ', $builder->getCompiledSelect())); + } + + //-------------------------------------------------------------------- + + public function testNotHavingLikeAfter() + { + $builder = new BaseBuilder('user', $this->db); + + $builder->select('name') + ->groupBy('name') + ->notHavingLike('pet_name', 'a', 'after'); + + $expectedSQL = 'SELECT "name" FROM "user" GROUP BY "name" HAVING "pet_name" NOT LIKE \'a%\' ESCAPE \'!\''; + + $this->assertEquals($expectedSQL, str_replace("\n", ' ', $builder->getCompiledSelect())); + } + + //-------------------------------------------------------------------- + + public function testOrHavingLike() + { + $builder = new BaseBuilder('user', $this->db); + + $builder->select('name') + ->groupBy('name') + ->havingLike('pet_name', 'a') + ->orHavingLike('pet_color', 'b'); + + $expectedSQL = 'SELECT "name" FROM "user" GROUP BY "name" HAVING "pet_name" LIKE \'%a%\' ESCAPE \'!\' OR "pet_color" LIKE \'%b%\' ESCAPE \'!\''; + + $this->assertEquals($expectedSQL, str_replace("\n", ' ', $builder->getCompiledSelect())); + } + + //-------------------------------------------------------------------- + + public function testOrHavingLikeBefore() + { + $builder = new BaseBuilder('user', $this->db); + + $builder->select('name') + ->groupBy('name') + ->havingLike('pet_name', 'a', 'before') + ->orHavingLike('pet_color', 'b', 'before'); + + $expectedSQL = 'SELECT "name" FROM "user" GROUP BY "name" HAVING "pet_name" LIKE \'%a\' ESCAPE \'!\' OR "pet_color" LIKE \'%b\' ESCAPE \'!\''; + + $this->assertEquals($expectedSQL, str_replace("\n", ' ', $builder->getCompiledSelect())); + } + + //-------------------------------------------------------------------- + + public function testOrHavingLikeAfter() + { + $builder = new BaseBuilder('user', $this->db); + + $builder->select('name') + ->groupBy('name') + ->havingLike('pet_name', 'a', 'after') + ->orHavingLike('pet_color', 'b', 'after'); + + $expectedSQL = 'SELECT "name" FROM "user" GROUP BY "name" HAVING "pet_name" LIKE \'a%\' ESCAPE \'!\' OR "pet_color" LIKE \'b%\' ESCAPE \'!\''; + + $this->assertEquals($expectedSQL, str_replace("\n", ' ', $builder->getCompiledSelect())); + } + + //-------------------------------------------------------------------- + + public function testOrNotHavingLike() + { + $builder = new BaseBuilder('user', $this->db); + + $builder->select('name') + ->groupBy('name') + ->havingLike('pet_name', 'a') + ->orNotHavingLike('pet_color', 'b'); + + $expectedSQL = 'SELECT "name" FROM "user" GROUP BY "name" HAVING "pet_name" LIKE \'%a%\' ESCAPE \'!\' OR "pet_color" NOT LIKE \'%b%\' ESCAPE \'!\''; + + $this->assertEquals($expectedSQL, str_replace("\n", ' ', $builder->getCompiledSelect())); + } + + //-------------------------------------------------------------------- + + public function testOrNotHavingLikeBefore() + { + $builder = new BaseBuilder('user', $this->db); + + $builder->select('name') + ->groupBy('name') + ->havingLike('pet_name', 'a', 'before') + ->orNotHavingLike('pet_color', 'b', 'before'); + + $expectedSQL = 'SELECT "name" FROM "user" GROUP BY "name" HAVING "pet_name" LIKE \'%a\' ESCAPE \'!\' OR "pet_color" NOT LIKE \'%b\' ESCAPE \'!\''; + + $this->assertEquals($expectedSQL, str_replace("\n", ' ', $builder->getCompiledSelect())); + } + + //-------------------------------------------------------------------- + + public function testOrNotHavingLikeAfter() + { + $builder = new BaseBuilder('user', $this->db); + + $builder->select('name') + ->groupBy('name') + ->havingLike('pet_name', 'a', 'after') + ->orNotHavingLike('pet_color', 'b', 'after'); + + $expectedSQL = 'SELECT "name" FROM "user" GROUP BY "name" HAVING "pet_name" LIKE \'a%\' ESCAPE \'!\' OR "pet_color" NOT LIKE \'b%\' ESCAPE \'!\''; + + $this->assertEquals($expectedSQL, str_replace("\n", ' ', $builder->getCompiledSelect())); + } + + //-------------------------------------------------------------------- + + public function testHavingAndGroup() + { + $builder = new BaseBuilder('user', $this->db); + + $builder->select('name') + ->groupBy('name') + ->having('SUM(id) <', 3) + ->havingGroupStart() + ->having('SUM(id)', 2) + ->having('name', 'adam') + ->havingGroupEnd(); + + $expectedSQL = 'SELECT "name" FROM "user" GROUP BY "name" HAVING SUM(id) < 3 AND ( SUM(id) = 2 AND "name" = \'adam\' )'; + + $this->assertEquals($expectedSQL, str_replace("\n", ' ', $builder->getCompiledSelect())); + } + + //-------------------------------------------------------------------- + + public function testHavingOrGroup() + { + $builder = new BaseBuilder('user', $this->db); + + $builder->select('name') + ->groupBy('name') + ->having('SUM(id) >', 3) + ->orHavingGroupStart() + ->having('SUM(id)', 2) + ->having('name', 'adam') + ->havingGroupEnd(); + + $expectedSQL = 'SELECT "name" FROM "user" GROUP BY "name" HAVING SUM(id) > 3 OR ( SUM(id) = 2 AND "name" = \'adam\' )'; + + $this->assertEquals($expectedSQL, str_replace("\n", ' ', $builder->getCompiledSelect())); + } + + //-------------------------------------------------------------------- + + public function testNotHavingAndGroup() + { + $builder = new BaseBuilder('user', $this->db); + + $builder->select('name') + ->groupBy('name') + ->having('SUM(id) <', 3) + ->notHavingGroupStart() + ->having('SUM(id)', 2) + ->having('name', 'adam') + ->havingGroupEnd(); + + $expectedSQL = 'SELECT "name" FROM "user" GROUP BY "name" HAVING SUM(id) < 3 AND NOT ( SUM(id) = 2 AND "name" = \'adam\' )'; + + $this->assertEquals($expectedSQL, str_replace("\n", ' ', $builder->getCompiledSelect())); + } + + //-------------------------------------------------------------------- + + public function testNotHavingOrGroup() + { + $builder = new BaseBuilder('user', $this->db); + + $builder->select('name') + ->groupBy('name') + ->having('SUM(id) <', 3) + ->orNotHavingGroupStart() + ->having('SUM(id)', 2) + ->having('name', 'adam') + ->havingGroupEnd(); + + $expectedSQL = 'SELECT "name" FROM "user" GROUP BY "name" HAVING SUM(id) < 3 OR NOT ( SUM(id) = 2 AND "name" = \'adam\' )'; + + $this->assertEquals($expectedSQL, str_replace("\n", ' ', $builder->getCompiledSelect())); + } + + //-------------------------------------------------------------------- + public function testAndGroups() { $builder = new BaseBuilder('user', $this->db); diff --git a/tests/system/Database/Live/GroupTest.php b/tests/system/Database/Live/GroupTest.php index e58de1ddf226..f40204736c72 100644 --- a/tests/system/Database/Live/GroupTest.php +++ b/tests/system/Database/Live/GroupTest.php @@ -52,6 +52,217 @@ public function testOrHavingBy() //-------------------------------------------------------------------- + public function testHavingIn() + { + $result = $this->db->table('job') + ->select('name') + ->groupBy('name') + ->havingIn('name', ['Developer', 'Politician']) + ->get() + ->getResult(); + + $this->assertCount(2, $result); + $this->assertEquals('Developer', $result[0]->name); + $this->assertEquals('Politician', $result[1]->name); + } + + //-------------------------------------------------------------------- + + public function testorHavingIn() + { + $result = $this->db->table('job') + ->select('name') + ->groupBy('name') + ->havingIn('name', ['Developer']) + ->orHavingIn('name', ['Politician']) + ->get() + ->getResult(); + + $this->assertCount(2, $result); + $this->assertEquals('Developer', $result[0]->name); + $this->assertEquals('Politician', $result[1]->name); + } + + //-------------------------------------------------------------------- + + public function testHavingNotIn() + { + $result = $this->db->table('job') + ->select('name') + ->groupBy('name') + ->havingNotIn('name', ['Developer', 'Politician']) + ->get() + ->getResult(); + + $this->assertCount(2, $result); + $this->assertEquals('Accountant', $result[0]->name); + $this->assertEquals('Musician', $result[1]->name); + } + + //-------------------------------------------------------------------- + + public function testOrHavingNotIn() + { + $result = $this->db->table('job') + ->select('name') + ->groupBy('name') + ->having('SUM(id) > 2') + ->orHavingNotIn('name', ['Developer', 'Politician']) + ->get() + ->getResult(); + + $this->assertCount(2, $result); + $this->assertEquals('Accountant', $result[0]->name); + $this->assertEquals('Musician', $result[1]->name); + } + + //-------------------------------------------------------------------- + + public function testHavingLike() + { + $result = $this->db->table('job') + ->select('name') + ->groupBy('name') + ->havingLike('name', 'elo') + ->get() + ->getResult(); + + $this->assertCount(1, $result); + $this->assertEquals('Developer', $result[0]->name); + } + + //-------------------------------------------------------------------- + + public function testNotHavingLike() + { + $result = $this->db->table('job') + ->select('name') + ->groupBy('name') + ->notHavingLike('name', 'ian') + ->get() + ->getResult(); + + $this->assertCount(2, $result); + $this->assertEquals('Accountant', $result[0]->name); + $this->assertEquals('Developer', $result[1]->name); + } + + //-------------------------------------------------------------------- + + public function testOrHavingLike() + { + $result = $this->db->table('job') + ->select('name') + ->groupBy('name') + ->havingLike('name', 'elo') + ->orHavingLike('name', 'cc') + ->get() + ->getResult(); + + $this->assertCount(2, $result); + $this->assertEquals('Accountant', $result[0]->name); + $this->assertEquals('Developer', $result[1]->name); + } + + //-------------------------------------------------------------------- + + public function testOrNotHavingLike() + { + $result = $this->db->table('job') + ->select('name') + ->groupBy('name') + ->having('SUM(id) > 2') + ->orNotHavingLike('name', 'ian') + ->get() + ->getResult(); + + $this->assertCount(3, $result); + $this->assertEquals('Accountant', $result[0]->name); + $this->assertEquals('Developer', $result[1]->name); + $this->assertEquals('Musician', $result[2]->name); + } + + //-------------------------------------------------------------------- + + public function testAndHavingGroupStart() + { + $result = $this->db->table('job') + ->select('name') + ->groupBy('name') + ->having('SUM(id) > 2') + ->havingGroupStart() + ->having('SUM(id) <= 4') + ->havingLike('name', 'ant', 'before') + ->havingGroupEnd() + ->get() + ->getResult(); + + $this->assertCount(1, $result); + $this->assertEquals('Accountant', $result[0]->name); + } + + //-------------------------------------------------------------------- + + public function testOrHavingGroupStart() + { + $result = $this->db->table('job') + ->select('name') + ->groupBy('name') + ->having('SUM(id) > 2') + ->orHavingGroupStart() + ->having('SUM(id) <= 4') + ->havingLike('name', 'ant', 'before') + ->havingGroupEnd() + ->get() + ->getResult(); + + $this->assertCount(2, $result); + $this->assertEquals('Accountant', $result[0]->name); + $this->assertEquals('Musician', $result[1]->name); + } + + //-------------------------------------------------------------------- + + public function testNotHavingGroupStart() + { + $result = $this->db->table('job') + ->select('name') + ->groupBy('name') + ->having('SUM(id) > 2') + ->notHavingGroupStart() + ->having('SUM(id) <= 4') + ->havingLike('name', 'ant', 'before') + ->havingGroupEnd() + ->get() + ->getResult(); + + $this->assertCount(1, $result); + $this->assertEquals('Musician', $result[0]->name); + } + + //-------------------------------------------------------------------- + + public function testOrNotHavingGroupStart() + { + $result = $this->db->table('job') + ->select('name') + ->groupBy('name') + ->having('SUM(id) > 2') + ->orNotHavingGroupStart() + ->having('SUM(id) < 2') + ->havingLike('name', 'o') + ->havingGroupEnd() + ->get() + ->getResult(); + + $this->assertCount(3, $result); + $this->assertEquals('Accountant', $result[0]->name); + $this->assertEquals('Musician', $result[1]->name); + $this->assertEquals('Politician', $result[2]->name); + } + + //-------------------------------------------------------------------- + public function testAndGroups() { $result = $this->db->table('user') From eb695c6770939397317d2bd94583b7f5f8986843 Mon Sep 17 00:00:00 2001 From: michalsn Date: Sun, 22 Sep 2019 18:50:16 +0200 Subject: [PATCH 2/3] Update user guide for new having clauses --- .../source/database/query_builder.rst | 295 ++++++++++++++++++ 1 file changed, 295 insertions(+) diff --git a/user_guide_src/source/database/query_builder.rst b/user_guide_src/source/database/query_builder.rst index ede8a7b9e7a0..b2201004ea9d 100755 --- a/user_guide_src/source/database/query_builder.rst +++ b/user_guide_src/source/database/query_builder.rst @@ -516,6 +516,158 @@ setting it to FALSE. 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 + + :: + + $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. + + :: + + $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) + +**$builder->orHavingIn()** + +Generates a HAVING field IN ('item', 'item') SQL query joined with OR if +appropriate + + :: + + $groups = [1, 2, 3]; + $builder->orHavingIn('group_id', $groups); + // Produces: OR group_id IN (1, 2, 3) + +You can use subqueries instead of an array of values. + + :: + + $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) + +**$builder->havingNotIn()** + +Generates a HAVING field NOT IN ('item', 'item') SQL query joined with +AND if appropriate + + :: + + $groups = [1, 2, 3]; + $builder->havingNotIn('group_id', $groups); + // Produces: HAVING group_id NOT IN (1, 2, 3) + +You can use subqueries instead of an array of values. + + :: + + $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) + + +**$builder->orHavingNotIn()** + +Generates a HAVING field NOT IN ('item', 'item') SQL query joined with OR +if appropriate + + :: + + $groups = [1, 2, 3]; + $builder->havingNotIn('group_id', $groups); + // Produces: OR group_id NOT IN (1, 2, 3) + +You can use subqueries instead of an array of values. + + :: + + $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) + +**$builder->havingLike()** + +This method enables you to generate **LIKE** clauses for HAVING part or the query, useful for doing +searches. + +.. note:: All values passed to this method are escaped automatically. + +.. note:: All ``havingLike*`` method variations can be forced to perform case-insensitive searches by passing + a fifth parameter of ``true`` to the method. This will use platform-specific features where available + otherwise, will force the values to be lowercase, i.e. ``HAVING LOWER(column) LIKE '%search%'``. This + may require indexes to be made for ``LOWER(column)`` instead of ``column`` to be effective. + +#. **Simple key/value method:** + + :: + + $builder->havingLike('title', 'match'); + // Produces: HAVING `title` LIKE '%match%' ESCAPE '!' + + If you use multiple method calls they will be chained together with + AND between them:: + + $builder->havingLike('title', 'match'); + $builder->havingLike('body', 'match'); + // HAVING `title` LIKE '%match%' ESCAPE '!' AND `body` LIKE '%match% ESCAPE '!' + + If you want to control where the wildcard (%) is placed, you can use + an optional third argument. Your options are 'before', 'after' and + 'both' (which is the default). + + :: + + $builder->havingLike('title', 'match', 'before'); // Produces: HAVING `title` LIKE '%match' ESCAPE '!' + $builder->havingLike('title', 'match', 'after'); // Produces: HAVING `title` LIKE 'match%' ESCAPE '!' + $builder->havingLike('title', 'match', 'both'); // Produces: HAVING `title` LIKE '%match%' ESCAPE '!' + +#. **Associative array method:** + + :: + + $array = ['title' => $match, 'page1' => $match, 'page2' => $match]; + $builder->havingLike($array); + // HAVING `title` LIKE '%match%' ESCAPE '!' AND `page1` LIKE '%match%' ESCAPE '!' AND `page2` LIKE '%match%' ESCAPE '!' + +**$builder->orHavingLike()** + +This method is identical to the one above, except that multiple +instances are joined by OR:: + + $builder->havingLike('title', 'match'); $builder->orHavingLike('body', $match); + // HAVING `title` LIKE '%match%' ESCAPE '!' OR `body` LIKE '%match%' ESCAPE '!' + +**$builder->notHavingLike()** + +This method is identical to ``havingLike()``, except that it generates +NOT LIKE statements:: + + $builder->notHavingLike('title', 'match'); // HAVING `title` NOT LIKE '%match% ESCAPE '!' + +**$builder->orNotHavingLike()** + +This method is identical to ``notHavingLike()``, except that multiple +instances are joined by OR:: + + $builder->havingLike('title', 'match'); + $builder->orNotHavingLike('body', 'match'); + // HAVING `title` LIKE '%match% OR `body` NOT LIKE '%match%' ESCAPE '!' + **************** Ordering results **************** @@ -649,6 +801,26 @@ Starts a new group by adding an opening parenthesis to the WHERE clause of the q Ends the current group by adding a closing parenthesis to the WHERE clause of the query. +**$builder->groupHavingStart()** + +Starts a new group by adding an opening parenthesis to the HAVING clause of the query. + +**$builder->orGroupHavingStart()** + +Starts a new group by adding an opening parenthesis to the HAVING clause of the query, prefixing it with 'OR'. + +**$builder->notGroupHavingStart()** + +Starts a new group by adding an opening parenthesis to the HAVING clause of the query, prefixing it with 'NOT'. + +**$builder->orNotGroupHavingStart()** + +Starts a new group by adding an opening parenthesis to the HAVING clause of the query, prefixing it with 'OR NOT'. + +**$builder->groupHavingEnd()** + +Ends the current group by adding a closing parenthesis to the HAVING clause of the query. + ************** Inserting Data ************** @@ -1332,6 +1504,129 @@ Class Reference Adds a HAVING clause to a query, separating multiple calls with OR. + .. 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 bool $escape: Whether to escape values and identifiers + :returns: BaseBuilder instance + :rtype: object + + Generates a HAVING field IN('item', 'item') SQL query, + joined with 'OR' if appropriate. + + .. 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 bool $escape: Whether to escape values and identifiers + :returns: BaseBuilder instance + :rtype: object + + Generates a HAVING field NOT IN('item', 'item') SQL query, + joined with 'OR' if appropriate. + + .. 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 bool $escape: Whether to escape values and identifiers + :returns: BaseBuilder instance + :rtype: object + + Generates a HAVING field IN('item', 'item') SQL query, + joined with 'AND' if appropriate. + + .. 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 bool $escape: Whether to escape values and identifiers + :returns: BaseBuilder instance + :rtype: object + + Generates a HAVING field NOT IN('item', 'item') SQL query, + joined with 'AND' if appropriate. + + .. php:method:: havingLike($field[, $match = ''[, $side = 'both'[, $escape = NULL]]]) + + :param string $field: Field name + :param string $match: Text portion to match + :param string $side: Which side of the expression to put the '%' wildcard on + :param bool $escape: Whether to escape values and identifiers + :returns: BaseBuilder instance (method chaining) + :rtype: BaseBuilder + + Adds a LIKE clause to a HAVING part of the query, separating multiple calls with AND. + + .. php:method:: orHavingLike($field[, $match = ''[, $side = 'both'[, $escape = NULL]]]) + + :param string $field: Field name + :param string $match: Text portion to match + :param string $side: Which side of the expression to put the '%' wildcard on + :param bool $escape: Whether to escape values and identifiers + :returns: BaseBuilder instance (method chaining) + :rtype: BaseBuilder + + Adds a LIKE clause to a HAVING part of the query, separating multiple class with OR. + + .. php:method:: notHavingLike($field[, $match = ''[, $side = 'both'[, $escape = NULL]]]) + + :param string $field: Field name + :param string $match: Text portion to match + :param string $side: Which side of the expression to put the '%' wildcard on + :param bool $escape: Whether to escape values and identifiers + :returns: BaseBuilder instance (method chaining) + :rtype: BaseBuilder + + Adds a NOT LIKE clause to a HAVING part of the query, separating multiple calls with AND. + + .. php:method:: orNotHavingLike($field[, $match = ''[, $side = 'both'[, $escape = NULL]]]) + + :param string $field: Field name + :param string $match: Text portion to match + :param string $side: Which side of the expression to put the '%' wildcard on + :param bool $escape: Whether to escape values and identifiers + :returns: BaseBuilder instance (method chaining) + :rtype: BaseBuilder + + Adds a NOT LIKE clause to a HAVING part of the query, separating multiple calls with OR. + + .. php:method:: havingGroupStart() + + :returns: BaseBuilder instance (method chaining) + :rtype: BaseBuilder + + Starts a group expression for HAVING clause, using ANDs for the conditions inside it. + + .. php:method:: orHavingGroupStart() + + :returns: BaseBuilder instance (method chaining) + :rtype: BaseBuilder + + Starts a group expression for HAVING clause, using ORs for the conditions inside it. + + .. php:method:: notHavingGroupStart() + + :returns: BaseBuilder instance (method chaining) + :rtype: BaseBuilder + + Starts a group expression for HAVING clause, using AND NOTs for the conditions inside it. + + .. php:method:: orNotHavingGroupStart() + + :returns: BaseBuilder instance (method chaining) + :rtype: BaseBuilder + + Starts a group expression for HAVING clause, using OR NOTs for the conditions inside it. + + .. php:method:: havingGroupEnd() + + :returns: BaseBuilder instance + :rtype: object + + Ends a group expression for HAVING clause. + .. php:method:: groupBy($by[, $escape = NULL]) :param mixed $by: Field(s) to group by; string or array From b9e13e0fb73969a86c55b7e12ffaea7450641fd3 Mon Sep 17 00:00:00 2001 From: michalsn Date: Sun, 22 Sep 2019 19:26:11 +0200 Subject: [PATCH 3/3] Update tests --- tests/system/Database/Live/GroupTest.php | 11 +++++++++++ 1 file changed, 11 insertions(+) diff --git a/tests/system/Database/Live/GroupTest.php b/tests/system/Database/Live/GroupTest.php index f40204736c72..6083d79baef3 100644 --- a/tests/system/Database/Live/GroupTest.php +++ b/tests/system/Database/Live/GroupTest.php @@ -57,6 +57,7 @@ public function testHavingIn() $result = $this->db->table('job') ->select('name') ->groupBy('name') + ->orderBy('name', 'asc') ->havingIn('name', ['Developer', 'Politician']) ->get() ->getResult(); @@ -73,6 +74,7 @@ public function testorHavingIn() $result = $this->db->table('job') ->select('name') ->groupBy('name') + ->orderBy('name', 'asc') ->havingIn('name', ['Developer']) ->orHavingIn('name', ['Politician']) ->get() @@ -90,6 +92,7 @@ public function testHavingNotIn() $result = $this->db->table('job') ->select('name') ->groupBy('name') + ->orderBy('name', 'asc') ->havingNotIn('name', ['Developer', 'Politician']) ->get() ->getResult(); @@ -106,6 +109,7 @@ public function testOrHavingNotIn() $result = $this->db->table('job') ->select('name') ->groupBy('name') + ->orderBy('name', 'asc') ->having('SUM(id) > 2') ->orHavingNotIn('name', ['Developer', 'Politician']) ->get() @@ -138,6 +142,7 @@ public function testNotHavingLike() $result = $this->db->table('job') ->select('name') ->groupBy('name') + ->orderBy('name', 'asc') ->notHavingLike('name', 'ian') ->get() ->getResult(); @@ -154,6 +159,7 @@ public function testOrHavingLike() $result = $this->db->table('job') ->select('name') ->groupBy('name') + ->orderBy('name', 'asc') ->havingLike('name', 'elo') ->orHavingLike('name', 'cc') ->get() @@ -171,6 +177,7 @@ public function testOrNotHavingLike() $result = $this->db->table('job') ->select('name') ->groupBy('name') + ->orderBy('name', 'asc') ->having('SUM(id) > 2') ->orNotHavingLike('name', 'ian') ->get() @@ -189,6 +196,7 @@ public function testAndHavingGroupStart() $result = $this->db->table('job') ->select('name') ->groupBy('name') + ->orderBy('name', 'asc') ->having('SUM(id) > 2') ->havingGroupStart() ->having('SUM(id) <= 4') @@ -208,6 +216,7 @@ public function testOrHavingGroupStart() $result = $this->db->table('job') ->select('name') ->groupBy('name') + ->orderBy('name', 'asc') ->having('SUM(id) > 2') ->orHavingGroupStart() ->having('SUM(id) <= 4') @@ -228,6 +237,7 @@ public function testNotHavingGroupStart() $result = $this->db->table('job') ->select('name') ->groupBy('name') + ->orderBy('name', 'asc') ->having('SUM(id) > 2') ->notHavingGroupStart() ->having('SUM(id) <= 4') @@ -247,6 +257,7 @@ public function testOrNotHavingGroupStart() $result = $this->db->table('job') ->select('name') ->groupBy('name') + ->orderBy('name', 'asc') ->having('SUM(id) > 2') ->orNotHavingGroupStart() ->having('SUM(id) < 2')