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

Fix DISTINCT queries with LIMIT and no ORDER on SQLServer 2012 #827

Merged

Conversation

billschaller
Copy link
Member

On SQLServer2012Platform, doModifyLimitQuery adds a do-nothing ORDER BY clause, because this is required in order to use OFFSET...FETCH NEXT N ROWS ONLY.

DISTINCT queries run via the paginator without an ORDER BY clause on SQL Server 2012 were failing with this error:

ORDER BY items must appear in the select list if SELECT DISTINCT is specified.

This PR fixes the error by adding 0 to the select list and changing the generated ORDER BY clause to read ORDER BY 1.

So a query that would have been generated as:

SELECT DISTINCT id_0
FROM (
    SELECT p0_.id AS id_0
        ,p0_.preference_code AS preference_code_1
        ,p0_.id_zone AS id_zone_2
    FROM preference p0_
    WHERE (p0_.id_zone IN (2))
    ) dctrn_result
ORDER BY (SELECT 0) 
OFFSET 0 ROWS FETCH NEXT 30 ROWS ONLY

Will now be generated as:

SELECT DISTINCT 0, id_0
FROM (
    SELECT p0_.id AS id_0
        ,p0_.preference_code AS preference_code_1
        ,p0_.id_zone AS id_zone_2
    FROM preference p0_
    WHERE (p0_.id_zone IN (2))
    ) dctrn_result
ORDER BY 1
OFFSET 0 ROWS FETCH NEXT 30 ROWS ONLY

@doctrinebot
Copy link

Hello,

thank you for creating this pull request. I have automatically opened an issue
on our Jira Bug Tracker for you. See the issue link:

http://www.doctrine-project.org/jira/browse/DBAL-1187

We use Jira to track the state of pull requests and the versions they got
included in.

// In another DBMS, we could do ORDER BY 0, but SQL Server gets angry if you use constant expressions in
// the order by list.
$query .= " ORDER BY (SELECT 0)";
if (strtoupper(substr($query, 0, 15)) == 'SELECT DISTINCT') {
Copy link
Member

Choose a reason for hiding this comment

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

Nitpicking: stripos($query, 'SELECT DISTINCT') === 0

$query .= " ORDER BY (SELECT 0)";
if (stripos($query, 'SELECT DISTINCT') === 0) {
// SQL Server won't let us order by a non-selected column in a DISTINCT query,
// so we have to do this madness. This says, order by the first column in the
Copy link
Member

Choose a reason for hiding this comment

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

Since it's quite the madness: is there a way to integration-test this as well?

Copy link
Member Author

Choose a reason for hiding this comment

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

There is, but there is no existing functional test suite for DBAL that covers this kind of stuff, and I don't have time to write one. Ideally we should have a testsuite that covers actually executing these queries on all platforms, but we don't :(

I've been using the ORM as my integration testsuite for DBAL, bad as that is.

Copy link
Member

Choose a reason for hiding this comment

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

I'm fine with this PR as is for now. We should add the integration tests for the limit/offset modifications in seperate PR anyways.

deeky666 added a commit that referenced this pull request Apr 8, 2015
…itquery

Fix DISTINCT queries with limit and no order on SQL Server 2012
@deeky666 deeky666 merged commit 26195be into doctrine:master Apr 8, 2015
@deeky666
Copy link
Member

deeky666 commented Apr 8, 2015

Thanks @zeroedin-bill

@Ocramius Ocramius added this to the 2.6 milestone Jul 22, 2017
@Ocramius Ocramius self-assigned this Jul 22, 2017
@Ocramius Ocramius changed the title Fix DISTINCT queries with limit and no order on SQL Server 2012 Fix DISTINCT queries with LIMIT and no ORDER on SQLServer 2012 Jul 22, 2017
@github-actions github-actions bot locked as resolved and limited conversation to collaborators Aug 17, 2022
Sign up for free to subscribe to this conversation on GitHub. Already have an account? Sign in.
Projects
None yet
Development

Successfully merging this pull request may close these issues.

4 participants