CROSS JOIN vs INNER JOIN performance issue.

  • Dear All,

    I have a query which was using CROSS JOIN (with relations) earlier and now we modified it with INNER JOIN.

    As per Prod server report, CROSS JOIN was performing faster but as per my theoretical knowledge, INNER JOIN should perform faster.

    I have attached Queries, IO Stats and Execution plan for your reference.

    Any guidance will be highly appreciated.

  • T.Ashish (5/17/2013)


    Dear All,

    I have a query which was using CROSS JOIN (with relations) earlier and now we modified it with INNER JOIN.

    As per Prod server report, CROSS JOIN was performing faster but as per my theoretical knowledge, INNER JOIN should perform faster.

    I have attached Queries, IO Stats and Execution plan for your reference.

    Any guidance will be highly appreciated.

    It's much easier for folks to look at your problem if you post execution plans as .sqlplan attachments, and put queries directly into your post with the appropriate tags.

    “Write the query the simplest way. If through testing it becomes clear that the performance is inadequate, consider alternative query forms.” - Gail Shaw

    For fast, accurate and documented assistance in answering your questions, please read this article.
    Understanding and using APPLY, (I) and (II) Paul White
    Hidden RBAR: Triangular Joins / The "Numbers" or "Tally" Table: What it is and how it replaces a loop Jeff Moden

  • Query A

    SELECT

    e.es_id,

    e.site_id,

    e.bu_id,

    e.comp_code,

    e.submit_time,

    e.status,

    e.currency,

    j.lt_id

    FROM

    dbo.exp_sheet e(nolock)

    INNER JOIN dbo.work w(nolock) on e.work_id = w.work_id

    INNER JOIN dbo.job_post j(nolock) on w.job_post_id = j.job_post_id

    WHERE

    w.work_type = 1 AND e.status IN (0,1,5,31,97)

    Query B

    SELECT

    e.es_id,

    e.site_id,

    e.bu_id,

    e.comp_code,

    e.submit_time,

    e.status,

    e.currency,

    j.lt_id

    FROM

    dbo.exp_sheet e(nolock) cross JOIN dbo.work w(nolock) cross JOIN dbo.job_post j(nolock)

    WHERE

    e.work_id = w.work_id

    AND w.work_type = 1

    AND w.job_post_id = j.job_post_id

    AND e.status IN (0,1,5,31,97)

    Query C

    SELECT

    e.es_id,

    e.site_id,

    e.bu_id,

    e.comp_code,

    e.submit_time,

    e.status,

    e.currency,

    j.lt_id

    FROM

    dbo.exp_sheet e(nolock),

    dbo.work w(nolock),

    dbo.job_post j(nolock)

    WHERE

    e.work_id = w.work_id

    AND w.work_type = 1

    AND w.job_post_id = j.job_post_id

    AND e.status IN (0,1,5,31,97)

  • The queries are logically equivalent, they generate the same result set. The plans are identical. What was the question again?

    Think of your query as a description of the result set that you want returned, rather than an instruction to SQL Server to do stuff in a particular way.

    “Write the query the simplest way. If through testing it becomes clear that the performance is inadequate, consider alternative query forms.” - Gail Shaw

    For fast, accurate and documented assistance in answering your questions, please read this article.
    Understanding and using APPLY, (I) and (II) Paul White
    Hidden RBAR: Triangular Joins / The "Numbers" or "Tally" Table: What it is and how it replaces a loop Jeff Moden

  • More nolocks... I do hope your users are happy with potentially incorrect data. Nolock is NOT a go-faster switch.

    See - http://blogs.msdn.com/b/davidlean/archive/2009/04/06/sql-server-nolock-hint-other-poor-ideas.aspx

    Gail Shaw
    Microsoft Certified Master: SQL Server, MVP, M.Sc (Comp Sci)
    SQL In The Wild: Discussions on DB performance with occasional diversions into recoverability

    We walk in the dark places no others will enter
    We stand on the bridge and no one may pass
  • Though I know the drawbacks of NOLOCK, it can't be avoided in our case. So, excuse me for that.

    And regarding this post, I know that logically all 3 queries are same, but I'm little confused about how SQL Server is handling the JOINS in these 3 queries!!!

    And if it doesn't matters then why I should not use Query 2 or 3 everywhere!!!

  • T.Ashish (5/17/2013)


    Though I know the drawbacks of NOLOCK, it can't be avoided in our case.

    Really? So you absolutely must allow potentially incorrect data in results because ....

    And regarding this post, I know that logically all 3 queries are same, but I'm little confused about how SQL Server is handling the JOINS in these 3 queries!!!

    They're logically the same, so SQL's handling the joins identically. The fact that some are joined in the FROM and others joined in the WHERE doesn't change the query's form nor the way SQL executes them.

    And if it doesn't matters then why I should not use Query 2 or 3 everywhere!!!

    You can if you wish. They're harder to read, easier to make mistakes with and impossible to convert to outer joins, but if you wish you can use them

    Gail Shaw
    Microsoft Certified Master: SQL Server, MVP, M.Sc (Comp Sci)
    SQL In The Wild: Discussions on DB performance with occasional diversions into recoverability

    We walk in the dark places no others will enter
    We stand on the bridge and no one may pass
  • GilaMonster (5/17/2013)


    T.Ashish (5/17/2013)


    Though I know the drawbacks of NOLOCK, it can't be avoided in our case.

    Really? So you absolutely must allow potentially incorrect data in results because ....

    And regarding this post, I know that logically all 3 queries are same, but I'm little confused about how SQL Server is handling the JOINS in these 3 queries!!!

    They're logically the same, so SQL's handling the joins identically. The fact that some are joined in the FROM and others joined in the WHERE doesn't change the query's form nor the way SQL executes them.

    And if it doesn't matters then why I should not use Query 2 or 3 everywhere!!!

    You can if you wish. They're harder to read, easier to make mistakes with and impossible to convert to outer joins, but if you wish you can use them

    In addition to these points, the type of join used in a query implies intent. Use a CROSS JOIN instead of an INNER JOIN and the next developer who looks at the code will be scratching their head wondering what on earth you were trying to achieve.

    The coding styles you see on ssc aren't accidental - they're based on tens of thousands of hours of experience from thousands of coders, and are well worth a little investment of your time.

    Why do you have silly unnecessary spaces surrounding your object delimiters?

    “Write the query the simplest way. If through testing it becomes clear that the performance is inadequate, consider alternative query forms.” - Gail Shaw

    For fast, accurate and documented assistance in answering your questions, please read this article.
    Understanding and using APPLY, (I) and (II) Paul White
    Hidden RBAR: Triangular Joins / The "Numbers" or "Tally" Table: What it is and how it replaces a loop Jeff Moden

  • Gail, Chris

    Thanks a ton.

    I will go with queru 1, even if there is no performance gain.

    One last qerry you may like to help on:

    If I use query 2/3, then optimizer must be converting it in Inner Join before execution. If I'm right then is there any way I can find out the diferrence between Query I wrote and Query sql executed!!

  • T.Ashish (5/17/2013)


    If I use query 2/3, then optimizer must be converting it in Inner Join before execution. If I'm right then is there any way I can find out the diferrence between Query I wrote and Query sql executed!!

    No, it's not converting it to an inner join, it's already an inner join, just a different way of writing it. Since the queries are logically identical (and the parser and optimiser know that), they are parsed into the same internal format and optimised to the same execution plan.

    Gail Shaw
    Microsoft Certified Master: SQL Server, MVP, M.Sc (Comp Sci)
    SQL In The Wild: Discussions on DB performance with occasional diversions into recoverability

    We walk in the dark places no others will enter
    We stand on the bridge and no one may pass
  • So should I say that it is the old way of INNER JOINing tables, that will not be supported in future versions !!

    Also, when we write "x IN (2,4,6)", optimizer converts it into "x=2 OR x=4 OR x=6", we can see it in execution plan. Does Sql store this optimized query somewhere?

  • T.Ashish (5/17/2013)


    So should I say that it is the old way of INNER JOINing tables, that will not be supported in future versions !!

    It's the old way, but it's not deprecated.

    Also, when we write "x IN (2,4,6)", optimizer converts it into "x=2 OR x=4 OR x=6", we can see it in execution plan. Does Sql store this optimized query somewhere?

    The execution plan is cached in the plan cache.

    Gail Shaw
    Microsoft Certified Master: SQL Server, MVP, M.Sc (Comp Sci)
    SQL In The Wild: Discussions on DB performance with occasional diversions into recoverability

    We walk in the dark places no others will enter
    We stand on the bridge and no one may pass
  • T.Ashish (5/17/2013)


    So should I say that it is the old way of INNER JOINing tables, that will not be supported in future versions !!

    No, that's incorrect. The older (non ANSI) version of outer joins using =* and *= is deprecated. You should be able "INNER JOIN" in where clause...

    Also, when we write "x IN (2,4,6)", optimizer converts it into "x=2 OR x=4 OR x=6", we can see it in execution plan. Does Sql store this optimized query somewhere?

    Yes it does. In a query plan cache. You can access it using sys.dm_exec_text_query_plan

    _____________________________________________
    "The only true wisdom is in knowing you know nothing"
    "O skol'ko nam otkrytiy chudnyh prevnosit microsofta duh!":-D
    (So many miracle inventions provided by MS to us...)

    How to post your question to get the best and quick help[/url]

  • Eugene Elutin (5/17/2013)


    T.Ashish (5/17/2013)


    So should I say that it is the old way of INNER JOINing tables, that will not be supported in future versions !!

    No, that's incorrect. The older (non ANSI) version of outer joins using =* and *= is deprecated. You should be able "INNER JOIN" in where clause...

    Also, when we write "x IN (2,4,6)", optimizer converts it into "x=2 OR x=4 OR x=6", we can see it in execution plan. Does Sql store this optimized query somewhere?

    Yes it does. In a query plan cache. You can access it using sys.dm_exec_text_query_plan

    Actually outer joins using =*, *=, and *=* are the ANSI 89 style joins and are no longer support in SQL Server since the release of SQL Server 2005 (well, it is supported when you run in compatibility mode 80 iirc).

Viewing 14 posts - 1 through 13 (of 13 total)

You must be logged in to reply to this topic. Login to reply