Difference between a CROSS JOIN and a 'comma'

  • Okay, try this on for size (it's just a wag, but...)

    The order of query evaluation is supposed to be:

    1) FROM

    2) ON

    3) JOIN

    But the FROM clause is a CROSS JOIN, which may be causing the "Role F" (since it is listed second / last) to parse as the table in the FROM with the "Worker M" not parsing until after the ON clause parse.

    Yeah, I know it sounds nuts, but it makes an odd kind of sense to me.

    EDIT: To follow through on that thought, the explicit use of CROSS JOIN actually throws "Worker M" into the FROM part of the parse with "Role F" explicitly in the JOIN part of the parse.

    Brandie Tarvin, MCITP Database AdministratorLiveJournal Blog: http://brandietarvin.livejournal.com/[/url]On LinkedIn!, Google+, and Twitter.Freelance Writer: ShadowrunLatchkeys: Nevermore, Latchkeys: The Bootleg War, and Latchkeys: Roscoes in the Night are now available on Nook and Kindle.

  • Gazareth (9/14/2012)


    SQL Kiwi (9/14/2012)


    The comma form parses correctly if you list Worker second:

    Select M.name, F.name, B.name

    From Role F, Worker M

    LEFT JOIN Worker B ON M.superiour=B.nr

    Where M.Role = code

    It might be a limitation of the parser, or perhaps there is a good logical reason for the order sensitivity, I'm not sure. In any case, it seems sensible not to mix the two styles.

    Interesting, wonder if it's similar to trying to use a table in a join predicate that is joined later in the query?

    No idea, I'm afraid. It's broadly in the same category, I suppose (binding errors) but whether it is by-design-for-a-very-good-reason, or just a weird bug...dunno.

  • Or "by design because they hoped it would never come up and couldn't figure out a good solution for it". I've seen that one before too. (As opposed to "by design for a good reason".)

    - Gus "GSquared", RSVP, OODA, MAP, NMVP, FAQ, SAT, SQL, DNA, RNA, UOI, IOU, AM, PM, AD, BC, BCE, USA, UN, CF, ROFL, LOL, ETC
    Property of The Thread

    "Nobody knows the age of the human race, but everyone agrees it's old enough to know better." - Anon

  • GSquared (9/14/2012)


    Or "by design because they hoped it would never come up and couldn't figure out a good solution for it". I've seen that one before too. (As opposed to "by design for a good reason".)

    "Backward-compatibility" 😀

  • SQL Kiwi (9/14/2012)


    GSquared (9/14/2012)


    Or "by design because they hoped it would never come up and couldn't figure out a good solution for it". I've seen that one before too. (As opposed to "by design for a good reason".)

    "Backward-compatibility" 😀

    i could see this going away in the next version of Sql Server (version after 2012). Reason being *= and =* no longer work as of 2008 (Unless the compatibility level is set to a lower level, i think) i would think if the compatibility level is not set to a lower level the , cross/inner join syntax will not parse.

    its possible but my short hand cross join is great for making cteTally tables with less typing. just like the table value constructors have eliminated the need for UNION ALL (in certain places).


    For faster help in answering any problems Please read How to post data/code on a forum to get the best help - Jeff Moden[/url] for the best way to ask your question.

    For performance Issues see how we like them posted here: How to Post Performance Problems - Gail Shaw[/url]

    Need to Split some strings? Jeff Moden's DelimitedSplit8K[/url]
    Jeff Moden's Cross tab and Pivots Part 1[/url]
    Jeff Moden's Cross tab and Pivots Part 2[/url]

  • capnhector (9/14/2012)


    i could see this going away in the next version of Sql Server (version after 2012). Reason being *= and =* no longer work as of 2008 (Unless the compatibility level is set to a lower level, i think) i would think if the compatibility level is not set to a lower level the , cross/inner join syntax will not parse.

    We are talking about different things. You seem to be wondering if the comma-join syntax will disappear. I would be very surprised if it did. Regardless, no deprecation announcement has been made. Even if an announcement were made, it would be three full versions before anything was removed. So, possibly: deprecated in SQL Server 2015 (or whatever) and removed from SQL Server 2024!?

  • SQL Kiwi (9/14/2012)


    capnhector (9/14/2012)


    i could see this going away in the next version of Sql Server (version after 2012). Reason being *= and =* no longer work as of 2008 (Unless the compatibility level is set to a lower level, i think) i would think if the compatibility level is not set to a lower level the , cross/inner join syntax will not parse.

    We are talking about different things. You seem to be wondering if the comma-join syntax will disappear. I would be very surprised if it did. Regardless, no deprecation announcement has been made. Even if an announcement were made, it would be three full versions before anything was removed. So, possibly: deprecated in SQL Server 2015 (or whatever) and removed from SQL Server 2024!?

    was responding to the backwards compatibility comment. but i learned something new about deprication in sql server.


    For faster help in answering any problems Please read How to post data/code on a forum to get the best help - Jeff Moden[/url] for the best way to ask your question.

    For performance Issues see how we like them posted here: How to Post Performance Problems - Gail Shaw[/url]

    Need to Split some strings? Jeff Moden's DelimitedSplit8K[/url]
    Jeff Moden's Cross tab and Pivots Part 1[/url]
    Jeff Moden's Cross tab and Pivots Part 2[/url]

  • capnhector (9/14/2012)


    was responding to the backwards compatibility comment.

    Ah, that was just a 'joke' comment about the reason behind the parsing behaviour.

  • SQL Kiwi (9/14/2012)


    capnhector (9/14/2012)


    was responding to the backwards compatibility comment.

    Ah, that was just a 'joke' comment about the reason behind the parsing behaviour.

    ahh. i need to get my coffee earlier.


    For faster help in answering any problems Please read How to post data/code on a forum to get the best help - Jeff Moden[/url] for the best way to ask your question.

    For performance Issues see how we like them posted here: How to Post Performance Problems - Gail Shaw[/url]

    Need to Split some strings? Jeff Moden's DelimitedSplit8K[/url]
    Jeff Moden's Cross tab and Pivots Part 1[/url]
    Jeff Moden's Cross tab and Pivots Part 2[/url]

  • GSquared (9/14/2012)


    Gazareth (9/14/2012)


    They are equivalent, but I don't think you can mix the two types of join in the same query.

    That means the two are not semantically identical in the query parsing engine. I always thought they were. I don't use commas in From clauses, I explicitly declare all joins (makes future debugging much easier). "INNER JOIN" not "JOIN", "LEFT OUTER JOIN" not "LEFT JOIN", and "CROSS JOIN" not ",", in all my code. So I've never run into a difference before. Especially a semantic one that allows one to parse and the other not to.

    This is exactly what I thought.

    Sorry for my 'late' response, after isolating the problem and posting the example I did run out of time.

    Now I am free for the weekend :-D, and have a few minutes to respond then I have to go at a theatre.

    Sorry that I wasn't clear that one of the (different) results was that the query did not run. Should have added the error. In the comment there was a Dutch remark about the error, but I did remove that, should have translated the remark or added that to the 'mail'. (At that moment I was to busy translating all the dutch in the example (still some left though).

    Thanks for your response,

    Ben Brugman

  • GSquared (9/14/2012)


    Gazareth (9/14/2012)


    They are equivalent, but I don't think you can mix the two types of join in the same query.

    It's the where clause that's causing the difference in the results, not the join operator.

    Except I'm not getting different results from the two. Copy-and-paste from the posted code generates a binding error on the query with a comma. SQL 2008 R2 can't even parse the query, much less run it and get different results.

    The Cross Join version works just fine. The comma version can't even run. That's what I found interesting.

    I tried replacing the comma with "cross join", just in case I was missing something else in it, and the error goes away when I do.

    That means the two are not semantically identical in the query parsing engine. I always thought they were. I don't use commas in From clauses, I explicitly declare all joins (makes future debugging much easier). "INNER JOIN" not "JOIN", "LEFT OUTER JOIN" not "LEFT JOIN", and "CROSS JOIN" not ",", in all my code. So I've never run into a difference before. Especially a semantic one that allows one to parse and the other not to.

    Glad to see I am not the only one who uses INNER JOIN, LEFT OUTER JOIN, CROSS JOIN, etc.

  • Looking at the syntax definition of the FROM clause the binding error makes perfect sense.

    [ FROM { <table_source> } [ ,...n ] ]

    <table_source> ::=

    {

    table_or_view_name [ [ AS ] table_alias ] [ <tablesample_clause> ]

    [ WITH ( < table_hint > [ [ , ]...n ] ) ]

    | rowset_function [ [ AS ] table_alias ]

    [ ( bulk_column_alias [ ,...n ] ) ]

    | user_defined_function [ [ AS ] table_alias ] ]

    | OPENXML <openxml_clause>

    | derived_table [ AS ] table_alias [ ( column_alias [ ,...n ] ) ]

    | <joined_table>

    | <pivoted_table>

    | <unpivoted_table>

    | @variable [ [ AS ] table_alias ]

    | @variable.function_call ( expression [ ,...n ] ) [ [ AS ] table_alias ] [ (column_alias [ ,...n ] ) ]

    }

    <joined_table> ::=

    {

    <table_source> <join_type> <table_source> ON <search_condition>

    | <table_source> CROSS JOIN <table_source>

    | left_table_source { CROSS | OUTER } APPLY right_table_source

    | [ ( ] <joined_table> [ ) ]

    }

    Select M.name, F.name, B.name

    From Worker M, [Role] F

    LEFT JOIN Worker B ON M.superiour=B.nr

    Where M.Role = code

    is parsed as

    Select M.name, F.name, B.name

    From Worker M, ([Role] F

    LEFT JOIN Worker B ON M.superiour=B.nr)

    Where M.Role = code

    Here Worker is a <table_source> and [Role] F LEFT JOIN Worker B ON ... is a <table_source>, separated by a comma. So M.superiour could not be bound because it's not defined in de second <table_source>.

    This also explains why Paul's alternative exchanging Worker and Role is parsing correctly. Another alternative is

    Select M.name, F.name, B.name

    From Worker M LEFT JOIN Worker B ON M.superiour=B.nr, [Role] F

    Where M.Role = code

  • Peter Brinkhaus (9/14/2012)


    Looking at the syntax definition of the FROM clause the binding error makes perfect sense.

    That does make sense, thanks!

    BTW: Never post anything ever again, Peter. You have the much-coveted 'default port' status (for a point score of 1433).

    edit: Oh. You've changed to 'UDP Broadcaster' (1434).

  • SQL Kiwi (9/14/2012)


    Peter Brinkhaus (9/14/2012)


    Looking at the syntax definition of the FROM clause the binding error makes perfect sense.

    That does make sense, thanks!

    +1

    I had been guessing that was the case from early in the discussion but I'm really glad someone was able to express it better than I could have.

    Kenneth FisherI was once offered a wizards hat but it got in the way of my dunce cap.--------------------------------------------------------------------------------For better, quicker answers on T-SQL questions, click on the following... http://www.sqlservercentral.com/articles/Best+Practices/61537/[/url]For better answers on performance questions, click on the following... http://www.sqlservercentral.com/articles/SQLServerCentral/66909/[/url]Link to my Blog Post --> www.SQLStudies.com[/url]

  • SQL Kiwi (9/14/2012)


    BTW: Never post anything ever again, Peter. You have the much-coveted 'default port' status (for a point score of 1433).

    edit: Oh. You've changed to 'UDP Broadcaster' (1434).

    Too bad, I only saw it after I posted to another thread. But I'm happy with UDP Broadcaster too :-).

Viewing 15 posts - 16 through 30 (of 30 total)

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