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

Keep order for set operators such as UNION / UNION ALL #116

Merged
merged 24 commits into from
May 12, 2018

Conversation

csthomas
Copy link
Contributor

@csthomas csthomas commented Apr 16, 2018

Pull Request for Issue #115

Summary of Changes

  1. Fix UNION/UNION ALL
  2. Allow to mix UNION with UNION ALL and preserve the order.
  3. Allow to support (in the future) more set operators like EXCEPT and INTERSECT
  4. A few B/C breaks
    • Method unionDistinct() - removed, use union() instead.
    • Protected variables $union and $unionAll replaced by variable $merge (array) to preserve the order.
    • Array is not accepted in the $query parameter of union() and unionAll() methods.
  5. New methods DatabaseQuery::querySet($query) and DatabaseQuery::toQuerySet(), see Keep order for set operators such as UNION / UNION ALL #116 (comment)

Testing Instructions

  1. Go to database/src folder.
  2. Run php -a or create a short script like below and execute it. Replace dots ....
require '../vendor/autoload.php';
$db = Joomla\Database\DatabaseDriver::getInstance(['driver' => 'mysqli', 'host' => 'localhost', 'user' => '...', 'password' => '...', 'database' => '...', 'prefix' => '...']);
print_r($db->setQuery($db->getQuery(true)->select('1')->union($db->getQuery(true)->select('2'))->unionAll($db->getQuery(true)->select('3')))->loadColumn());
Array
(
    [0] => 1
    [1] => 2
    [2] => 3
)
print_r($db->setQuery($db->getQuery(true)->select('2')->union($db->getQuery(true)->select('1'))->unionAll($db->getQuery(true)->select('1')))->loadColumn());
Array
(
    [0] => 2
    [1] => 1
    [2] => 1
)
print_r($db->setQuery($db->getQuery(true)->select('2')->unionAll($db->getQuery(true)->select('1'))->union($db->getQuery(true)->select('1')))->loadColumn());
Array
(
    [0] => 2
    [1] => 1
)

Documentation Changes Required

Joomla\Database\DatabaseQuery general changes

Changes in methods union(), unionAll() and unionDistinct()
  • Method unionDistinct() has been removed. Use union() instead.
  • Argument $query stops accepting the array. Only DatabaseQuery object or string.
  • Argument $distinct has been removed from unionAll.
  • Argument $glue has been removed from both.

Method union() by default has $distinct = true.
If $distinct is false then generates UNION ALL sql statement.

Class variables $union and $unionAll has been merged into one variable $merge.
The new variable represents an ordered array of individual elements.

Stop supporting $type = 'union' in method __toString().

Mix of union types

SELECT 1 UNION SELECT 2 UNION ALL SELECT 1 -- > return 3 rows

SELECT 1 UNION ALL SELECT 2 UNION SELECT 1 -- > return 2 rows

You can combine multiple queries using the set operators UNION, UNION ALL, INTERSECT, and MINUS. All set operators have equal precedence. If a SQL statement contains multiple set operators, then Oracle Database evaluates them from the left to right unless parentheses explicitly specify another order.

Source https://docs.oracle.com/cd/B19306_01/server.102/b14200/queries004.htm

@csthomas csthomas mentioned this pull request Apr 16, 2018
@mbabker
Copy link
Contributor

mbabker commented Apr 16, 2018

Seems fair to me. Just add a note to https://github.com/joomla-framework/database/blob/2.0-dev/docs/v1-to-v2-update.md and I'd say this should be fine, we just need to sort out deprecation notices then in the CMS repo and this repo's master (1.x) branch.

@csthomas
Copy link
Contributor Author

I'm not sure about variable name '$merge' but I have not found a better name.

@csthomas
Copy link
Contributor Author

If necessary, correct my documentation.

@csthomas csthomas changed the title [WIP] Keep order for set operators such as UNION / UNION ALL Keep order for set operators such as UNION / UNION ALL Apr 20, 2018
@alikon
Copy link
Contributor

alikon commented Apr 25, 2018

look nice to me too, IIRC UNION in core is used only in com_finder

@csthomas
Copy link
Contributor Author

csthomas commented Apr 25, 2018

Nice, I think about it "too much" and now I have another solution, where we can put ORDER BY and LIMIT before UNION statement. I will prepare another PR for that.

[UPDATED]
Ups, I did it on this PR:)

@alikon
Copy link
Contributor

alikon commented Apr 25, 2018

👍
despite i'm not a fan of "LIMIT" clause on such kind of analytics query 😨

Method `union()` by default has `$distinct = true`.
If `$distinct` is `false` then generates `UNION ALL` sql statement.

Class variables `$union` and `$unionAll` has been merged into one variable `$merge`.
Copy link

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Change has to have

@csthomas
Copy link
Contributor Author

To get ORDER BY or/and LIMIT before the first UNION statement I added to DatabaseQuery class a new type querySet. This is something like subquery in DatabaseQuery object.

Option 1:

$tbl = $db->quoteName('#__foo');

$query = $db->getQuery(true);
$query2 = $db->getQuery(true);
$query3 = $db->getQuery(true);

$query->querySet($query2->select('name')->from($tbl)->order('id DESC')->setLimit(1))
	->unionAll($query3->select('name')->from($tbl)->order('id')->setLimit(1))
	->order('name')
	->setLimit(1)

Option 2:

$tbl = $db->quoteName('#__foo');

$query = $db->getQuery(true);
$query2 = $db->getQuery(true);

$query->select('name')->from($tbl)->order('id DESC')->setLimit(1)
	->toQuerySet()
	->unionAll($query2->select('name')->from($tbl)->order('id')->setLimit(1))
	->order('name')
	->setLimit(1);

Common result:

(
	SELECT name FROM `#__foo` ORDER BY id DESC LIMIT 1
)
UNION (
	SELECT name FROM `#__foo` ORDER BY id LIMIT 1
)
ORDER BY name LIMIT 1

@csthomas
Copy link
Contributor Author

At the end I added new unit tests for PostgreSQL and SQLite.

SqlSrv may still does not work if you use ORDER BY or LIMIT in union query. This is more complicated fix and I would not add it to this PR.

What do you thing about this? @mbabker @alikon @Quy

@mbabker mbabker requested a review from wilsonge May 1, 2018 01:41
@mbabker
Copy link
Contributor

mbabker commented May 1, 2018

Seems fine to me.

SqlSrv may still does not work if you use ORDER BY or LIMIT in union query. This is more complicated fix and I would not add it to this PR.

Well luckily the testing infrastructure here is a lot better off (and you can somewhat copy the current Travis config to get a working SQL Server instance to test against). No tests are failing for now so let's roll with it and we can work on updating the test suite to better cover cases like this.

@simbunch
Copy link

simbunch commented May 2, 2018

Tested successfully.

@csthomas
Copy link
Contributor Author

csthomas commented May 9, 2018

I will spend a little time to fix sqlsrv stuff, I need to back to my previous PR #104

@csthomas
Copy link
Contributor Author

My tests:

require 'vendor/autoload.php';
$db = Joomla\Database\DatabaseDriver::getInstance(['driver' => 'sqlsrv', 'database' => '', 'user' => '', 'password' => '', 'prefix' => 'j38_']);
$q = $db->getQuery(1)->select('id')->from('j38_modules')->where('id <= 5')->order('id DESC')->setLimit(2, 1)->toQuerySet()->unionAll($db->getQuery(1)->select('id')->from('j38_modules')->where('id = 3 OR id = 4')->order('0+id DESC')->setLimit(1, 1))->order('id DESC');

echo $q;

SELECT * FROM (
SELECT * FROM (
SELECT * FROM (
SELECT *, ROW_NUMBER() OVER (ORDER BY (SELECT 0)) AS RowNumber_4c1bcee9724ef8f6f37135d9596d299a
FROM (
SELECT TOP 3 id
FROM j38_modules
WHERE id <= 5
ORDER BY id DESC) AS A
) AS A
WHERE RowNumber_4c1bcee9724ef8f6f37135d9596d299a > 1) AS merge_0
UNION ALL SELECT * FROM (
SELECT * FROM (
SELECT *, ROW_NUMBER() OVER (ORDER BY (SELECT 0)) AS RowNumber_b0af95c67b1589f1db7914ea2e26f658
FROM (
SELECT TOP 2 id
FROM j38_modules
WHERE id = 3 OR id = 4
ORDER BY 0+id DESC) AS A
) AS A
WHERE RowNumber_b0af95c67b1589f1db7914ea2e26f658 > 1) AS merge_1
) AS merges
ORDER BY id DESC

echo $q->setLimit(5, 2);

SELECT * FROM (
SELECT *, ROW_NUMBER() OVER (ORDER BY (SELECT 0)) AS RowNumber_e89d72665d4b94533c8b495e1eebf7ee
FROM (
SELECT TOP 7 * FROM (
SELECT * FROM (
SELECT * FROM (
SELECT *, ROW_NUMBER() OVER (ORDER BY (SELECT 0)) AS RowNumber_4c1bcee9724ef8f6f37135d9596d299a
FROM (
SELECT TOP 3 id
FROM j38_modules
WHERE id <= 5
ORDER BY id DESC) AS A
) AS A
WHERE RowNumber_4c1bcee9724ef8f6f37135d9596d299a > 1) AS merge_0
UNION ALL SELECT * FROM (
SELECT * FROM (
SELECT *, ROW_NUMBER() OVER (ORDER BY (SELECT 0)) AS RowNumber_b0af95c67b1589f1db7914ea2e26f658
FROM (
SELECT TOP 2 id
FROM j38_modules
WHERE id = 3 OR id = 4
ORDER BY 0+id DESC) AS A
) AS A
WHERE RowNumber_b0af95c67b1589f1db7914ea2e26f658 > 1) AS merge_1
) AS merges
ORDER BY id DESC) AS A
) AS A
WHERE RowNumber_e89d72665d4b94533c8b495e1eebf7ee > 2

It looks a little ugly but we can only remove ROW_NUMBER() after we bump to SQL Server 2012

@csthomas
Copy link
Contributor Author

Since the minimum version of SQL Server is now 2012, it would be good to wait for the new SqlsrvQuery::processList () from #124

@csthomas
Copy link
Contributor Author

Now unit tests execute real query tests for UNIONs on sqlite, mysqli, pgsql and sqlsrv.

@csthomas
Copy link
Contributor Author

Unit tests passed.

@@ -681,7 +681,7 @@ protected function prepareStatement(string $query): StatementInterface
}
catch (\PDOException $exception)
{
throw new PrepareStatementFailureException($exception->getMessage(), $exception->getCode(), $exception);
throw new PrepareStatementFailureException($exception->getMessage() . $query, (int) $exception->getCode(), $exception);
Copy link
Contributor

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

If we really need the query as part of the Exception, it should be a separate property similar to the query failure exception so the query isn't shown plain text as part of the message.

Also, we shouldn't cast the exception code to integer here. It is correct that the DB drivers don't strictly use numeric codes and Exception codes aren't type enforced.

Copy link
Contributor

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

This should also be consistently done for all drivers (i.e. the non-PDO ones), not just PDO.

Copy link
Contributor Author

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Ups, it was only for debug, I will remove it

@csthomas
Copy link
Contributor Author

Also, we shouldn't cast the exception code to integer here. It is correct that the DB drivers don't strictly use numeric codes and Exception codes aren't type enforced.

Yes, but try to do a bug in code:

diff --git a/src/Sqlite/SqliteQuery.php b/src/Sqlite/SqliteQuery.php
index 940d030..b196fcc 100644
--- a/src/Sqlite/SqliteQuery.php
+++ b/src/Sqlite/SqliteQuery.php
@@ -73,7 +73,7 @@ class SqliteQuery extends PdoQuery
                        case 'querySet':
                                $query = $this->querySet;
 
-                               if ($query->order || $query->limit || $query->offset)
+                               if (0)//$query->order || $query->limit || $query->offset)

Then run phpunit by php phpunit Tests/Sqlite/SqliteDriverTest.php

Then I got:

  1. Joomla\Database\Tests\Sqlite\SqliteDriverTest::testQuerySetWithUnionAll
    Error: Wrong parameters for Joomla\Database\Exception\PrepareStatementFailureException([string $message [, long $code [, Throwable $previous = NULL]]])

Maybe override constructor for PrepareStatementFailureException could be better?

@mbabker
Copy link
Contributor

mbabker commented May 11, 2018

If it really comes down to that yes the constructor should be overloaded. Now I'm curious what is overloading core PHP's RuntimeException, or even root Exception, definition because last I was unaware the root constructor was not typed.

@csthomas
Copy link
Contributor Author

php7.1 -a
Interactive mode enabled

php > new RuntimeException('', '');
PHP Warning:  Uncaught Error: Wrong parameters for RuntimeException([string $message [, long $code [, Throwable $previous = NULL]]]) in php shell code:1
Stack trace:
#0 php shell code(1): Exception->__construct('', '')
#1 {main}
  thrown in php shell code on line 1

@mbabker
Copy link
Contributor

mbabker commented May 12, 2018

:eyeroll:

@csthomas
Copy link
Contributor Author

It seems to be a known issue http://php.net/manual/en/class.pdoexception.php#95812

Should I add the constructor for PrepareStatementFailureException at this PR?

@mbabker
Copy link
Contributor

mbabker commented May 12, 2018

Might as well.

@csthomas
Copy link
Contributor Author

Done

@mbabker mbabker merged commit 83f016d into joomla-framework:2.0-dev May 12, 2018
@csthomas csthomas deleted the db_union branch May 12, 2018 18:51
Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment
Labels
None yet
Projects
None yet
Development

Successfully merging this pull request may close these issues.

5 participants