From a3ccae4722a261859ebba5f11d87c2696510e333 Mon Sep 17 00:00:00 2001 From: Andrey Pyzhikov <5071@mail.ru> Date: Wed, 25 May 2022 15:47:20 +0800 Subject: [PATCH] rebase Signed-off-by: Andrey Pyzhikov <5071@mail.ru> --- system/Database/BaseBuilder.php | 65 ++++++++++++- system/Database/SQLSRV/Builder.php | 2 +- tests/system/Database/Builder/UnionTest.php | 92 +++++++++++++++++++ tests/system/Database/Live/UnionTest.php | 62 +++++++++++++ user_guide_src/source/changelogs/v4.2.0.rst | 1 + .../source/database/query_builder.rst | 51 ++++++++++ .../source/database/query_builder/103.php | 11 +++ .../source/database/query_builder/104.php | 14 +++ 8 files changed, 295 insertions(+), 3 deletions(-) create mode 100644 tests/system/Database/Builder/UnionTest.php create mode 100644 tests/system/Database/Live/UnionTest.php create mode 100644 user_guide_src/source/database/query_builder/103.php create mode 100644 user_guide_src/source/database/query_builder/104.php diff --git a/system/Database/BaseBuilder.php b/system/Database/BaseBuilder.php index 818d4d31deda..ca983691ea0c 100644 --- a/system/Database/BaseBuilder.php +++ b/system/Database/BaseBuilder.php @@ -109,6 +109,13 @@ class BaseBuilder */ public $QBOrderBy = []; + /** + * QB UNION data + * + * @var array + */ + protected array $QBUnion = []; + /** * QB NO ESCAPE data * @@ -1138,6 +1145,48 @@ protected function _like_statement(?string $prefix, string $column, ?string $not return "{$prefix} {$column} {$not} LIKE :{$bind}:"; } + /** + * Add UNION statement + * + * @param BaseBuilder|Closure $union + * + * @return $this + */ + public function union($union) + { + return $this->addUnionStatement($union); + } + + /** + * Add UNION ALL statement + * + * @param BaseBuilder|Closure $union + * + * @return $this + */ + public function unionAll($union) + { + return $this->addUnionStatement($union, true); + } + + /** + * @used-by union() + * @used-by unionAll() + * + * @param BaseBuilder|Closure $union + * + * @return $this + */ + protected function addUnionStatement($union, bool $all = false) + { + $this->QBUnion[] = "\n" . 'UNION ' + . ($all ? 'ALL ' : '') + . 'SELECT * FROM ' + . $this->buildSubquery($union, true, 'uwrp' . (count($this->QBUnion) + 1)); + + return $this; + } + /** * Starts a query group. * @@ -2427,10 +2476,10 @@ protected function compileSelect($selectOverride = false): string . $this->compileOrderBy(); if ($this->QBLimit) { - return $this->_limit($sql . "\n"); + $sql = $this->_limit($sql . "\n"); } - return $sql; + return $this->unionInjection($sql); } /** @@ -2585,6 +2634,17 @@ protected function compileOrderBy(): string return ''; } + protected function unionInjection(string $sql): string + { + if ($this->QBUnion === []) { + return $sql; + } + + return 'SELECT * FROM (' . $sql . ') ' + . ($this->db->protectIdentifiers ? $this->db->escapeIdentifiers('uwrp0') : 'uwrp0') + . implode("\n", $this->QBUnion); + } + /** * Takes an object as input and converts the class variables to array key/vals * @@ -2704,6 +2764,7 @@ protected function resetSelect() 'QBDistinct' => false, 'QBLimit' => false, 'QBOffset' => false, + 'QBUnion' => [], ]); if (! empty($this->db)) { diff --git a/system/Database/SQLSRV/Builder.php b/system/Database/SQLSRV/Builder.php index f84d1dfddd07..a5bf829a6b74 100755 --- a/system/Database/SQLSRV/Builder.php +++ b/system/Database/SQLSRV/Builder.php @@ -597,7 +597,7 @@ protected function compileSelect($selectOverride = false): string $sql = $this->_limit($sql . "\n"); } - return $sql; + return $this->unionInjection($sql); } /** diff --git a/tests/system/Database/Builder/UnionTest.php b/tests/system/Database/Builder/UnionTest.php new file mode 100644 index 000000000000..10ff971acf7b --- /dev/null +++ b/tests/system/Database/Builder/UnionTest.php @@ -0,0 +1,92 @@ + + * + * For the full copyright and license information, please view + * the LICENSE file that was distributed with this source code. + */ + +namespace CodeIgniter\Database\Builder; + +use CodeIgniter\Database\BaseBuilder; +use CodeIgniter\Database\SQLSRV\Connection as SQLSRVConnection; +use CodeIgniter\Test\CIUnitTestCase; +use CodeIgniter\Test\Mock\MockConnection; + +/** + * @internal + */ +final class UnionTest extends CIUnitTestCase +{ + /** + * @var MockConnection + */ + protected $db; + + protected function setUp(): void + { + parent::setUp(); + + $this->db = new MockConnection([]); + } + + public function testUnion(): void + { + $expected = 'SELECT * FROM (SELECT * FROM "test") "uwrp0" UNION SELECT * FROM (SELECT * FROM "test") "uwrp1"'; + $builder = $this->db->table('test'); + + $builder->union($this->db->table('test')); + $this->assertSame($expected, $this->buildSelect($builder)); + + $builder = $this->db->table('test'); + + $builder->union(static fn ($builder) => $builder->from('test')); + $this->assertSame($expected, $this->buildSelect($builder)); + } + + public function testUnionAll(): void + { + $expected = 'SELECT * FROM (SELECT * FROM "test") "uwrp0"' + . ' UNION ALL SELECT * FROM (SELECT * FROM "test") "uwrp1"'; + $builder = $this->db->table('test'); + + $builder->unionAll($this->db->table('test')); + $this->assertSame($expected, $this->buildSelect($builder)); + } + + public function testOrderLimit(): void + { + $expected = 'SELECT * FROM (SELECT * FROM "test" ORDER BY "id" DESC LIMIT 10) "uwrp0"' + . ' UNION SELECT * FROM (SELECT * FROM "test") "uwrp1"'; + $builder = $this->db->table('test'); + + $builder->union($this->db->table('test'))->limit(10)->orderBy('id', 'DESC'); + $this->assertSame($expected, $this->buildSelect($builder)); + } + + public function testUnionSQLSRV(): void + { + $expected = 'SELECT * FROM (SELECT * FROM "test"."dbo"."users") "uwrp0"' + . ' UNION SELECT * FROM (SELECT * FROM "test"."dbo"."users") "uwrp1"'; + + $db = new SQLSRVConnection(['DBDriver' => 'SQLSRV', 'database' => 'test', 'schema' => 'dbo']); + + $builder = $db->table('users'); + + $builder->union($db->table('users')); + $this->assertSame($expected, $this->buildSelect($builder)); + + $builder = $db->table('users'); + + $builder->union(static fn ($builder) => $builder->from('users')); + $this->assertSame($expected, $this->buildSelect($builder)); + } + + protected function buildSelect(BaseBuilder $builder): string + { + return str_replace("\n", ' ', $builder->getCompiledSelect()); + } +} diff --git a/tests/system/Database/Live/UnionTest.php b/tests/system/Database/Live/UnionTest.php new file mode 100644 index 000000000000..cd27da0a3689 --- /dev/null +++ b/tests/system/Database/Live/UnionTest.php @@ -0,0 +1,62 @@ + + * + * For the full copyright and license information, please view + * the LICENSE file that was distributed with this source code. + */ + +namespace CodeIgniter\Database\Live; + +use CodeIgniter\Test\CIUnitTestCase; +use CodeIgniter\Test\DatabaseTestTrait; +use Tests\Support\Database\Seeds\CITestSeeder; + +/** + * @group DatabaseLive + * + * @internal + */ +final class UnionTest extends CIUnitTestCase +{ + use DatabaseTestTrait; + + protected $refresh = true; + protected $seed = CITestSeeder::class; + + public function testUnion(): void + { + $union = $this->db->table('user') + ->limit(1) + ->orderBy('id', 'ASC'); + $builder = $this->db->table('user'); + + $builder->union($union) + ->limit(1) + ->orderBy('id', 'DESC'); + + $result = $this->db->newQuery() + ->fromSubquery($builder, 'q') + ->orderBy('id', 'DESC') + ->get(); + + $this->assertSame(2, $result->getNumRows()); + + $rows = $result->getResult(); + $this->assertSame(4, (int) $rows[0]->id); + $this->assertSame(1, (int) $rows[1]->id); + } + + public function testUnionAll(): void + { + $union = $this->db->table('user'); + $builder = $this->db->table('user'); + + $result = $builder->unionAll($union)->get(); + + $this->assertSame(8, $result->getNumRows()); + } +} diff --git a/user_guide_src/source/changelogs/v4.2.0.rst b/user_guide_src/source/changelogs/v4.2.0.rst index 082311eca8d3..f440076b5987 100644 --- a/user_guide_src/source/changelogs/v4.2.0.rst +++ b/user_guide_src/source/changelogs/v4.2.0.rst @@ -73,6 +73,7 @@ Database - Added the class ``CodeIgniter\Database\RawSql`` which expresses raw SQL strings. - :ref:`select() `, :ref:`where() `, :ref:`like() `, :ref:`join() ` accept the ``CodeIgniter\Database\RawSql`` instance. - ``DBForge::addField()`` default value raw SQL string support. See :ref:`forge-addfield-default-value-rawsql`. +- QueryBuilder. Union queries. See :ref:`query-builder-union`. Others ====== diff --git a/user_guide_src/source/database/query_builder.rst b/user_guide_src/source/database/query_builder.rst index 0d1d219a127e..032407c5de30 100755 --- a/user_guide_src/source/database/query_builder.rst +++ b/user_guide_src/source/database/query_builder.rst @@ -679,6 +679,41 @@ As is in ``countAllResult()`` method, this method resets any field values that y to ``select()`` as well. If you need to keep them, you can pass ``false`` as the first parameter. +.. _query-builder-union: + +************* +Union queries +************* + +Union +===== + +$builder->union() +----------------- + +Is used to combine the result-set of two or more SELECT statements. + +.. literalinclude:: query_builder/103.php + +.. note:: For correct work with DBMS (such as MSSQL and Oracle) queries are wrapped in ``SELECT * FROM ( ... ) alias`` + The main query will always have an alias of ``uwrp0``. Each subsequent query added via ``union()`` will have an + alias ``uwrpN+1``. + +All union queries will be added after the main query, regardless of the order in which the ``union()`` method was +called. That is, the ``limit()`` or ``orderBy()`` methods will be relative to the main query, even if called after +``union()``. + +In some cases, it may be necessary, for example, to sort or limit the number of records of the query result. +The solution is to use the wrapper created via ``$db->newQuery()``. +In the example below, we get the first 5 users + the last 5 users and sort the result by id: + +.. literalinclude:: query_builder/104.php + +$builder->unionAll() +-------------------- + +The behavior is the same as the ``union()`` method. + ************** Query grouping ************** @@ -1495,6 +1530,22 @@ Class Reference Adds an ``OFFSET`` clause to a query. + .. php:method:: union($union) + + :param BaseBulder|Closure $union: Union query + :returns: ``BaseBuilder`` instance (method chaining) + :rtype: ``BaseBuilder`` + + Adds a ``UNION`` clause. + + .. php:method:: unionAll($union) + + :param BaseBulder|Closure $union: Union query + :returns: ``BaseBuilder`` instance (method chaining) + :rtype: ``BaseBuilder`` + + Adds a ``UNION ALL`` clause. + .. php:method:: set($key[, $value = ''[, $escape = null]]) :param mixed $key: Field name, or an array of field/value pairs diff --git a/user_guide_src/source/database/query_builder/103.php b/user_guide_src/source/database/query_builder/103.php new file mode 100644 index 000000000000..ffe869181fc7 --- /dev/null +++ b/user_guide_src/source/database/query_builder/103.php @@ -0,0 +1,11 @@ +db->table('users')->select('id', 'name'); +$builder = $this->db->table('users')->select('id', 'name'); + +$builder->union($union)->limit(10)->get(); +/* + * Produces: + * SELECT * FROM (SELECT `id`, `name` FROM `users` LIMIT 10) uwrp0 + * UNION SELECT * FROM (SELECT `id`, `name` FROM `users`) uwrp1 + */ diff --git a/user_guide_src/source/database/query_builder/104.php b/user_guide_src/source/database/query_builder/104.php new file mode 100644 index 000000000000..11c716dea999 --- /dev/null +++ b/user_guide_src/source/database/query_builder/104.php @@ -0,0 +1,14 @@ +db->table('users')->select('id', 'name')->orderBy('id', 'DESC')->limit(5); +$builder = $this->db->table('users')->select('id', 'name')->orderBy('id', 'ASC')->limit(5)->union($union); + +$this->db->newQuery()->fromSubquery($builder, 'q')->orderBy('id', 'DESC')->get(); +/* + * Produces: + * SELECT * FROM ( + * SELECT * FROM (SELECT `id`, `name` FROM `users` ORDER BY `id` ASC LIMIT 5) uwrp0 + * UNION + * SELECT * FROM (SELECT `id`, `name` FROM `users` ORDER BY `id` DESC LIMIT 5) uwrp1 + * ) q ORDER BY `id` DESC + */