Difference Between cross apply and cross join

  • What is the Difference Between cross apply and cross join

  • You have posted your question in a SQL 2000 forum ... CROSS APPLY WAS introduced in SQL Server 2005 ...

    For SQL 2000 CROSS JOINS exist and they exist in SQL 2005 as well ... so the difference is .. one exists one does not.

    Now if you question pertains to SQL 2005 or 2008 use Books On Line for an explanation and sample code ....

    If everything seems to be going well, you have obviously overlooked something.

    Ron

    Please help us, help you -before posting a question please read[/url]
    Before posting a performance problem please read[/url]

  • CROSS JOIN returns a Cartesian product so if you have 10 rows in each table the query will return 100 rows, 1 row for each combination.

    CROSS APPLY from BOL:

    The APPLY operator allows you to invoke a table-valued function for each row returned by an outer table expression of a query. The table-valued function acts as the right input and the outer table expression acts as the left input. The right input is evaluated for each row from the left input and the rows produced are combined for the final output. The list of columns produced by the APPLY operator is the set of columns in the left input followed by the list of columns returned by the right input.

    CROSS APPLY is similar to, but in most cased not the same as an INNER JOIN. When calling a TVF the TVF is called/executed for each row in the outer table/left input.

    You pass one of the columns from the outer table to the function and the TVF returns the matching rows. You can also use APPLY to supply a value to "join" on a derived table. Here's a simple example of both CROSS JOIN and CROSS APPLY (the cross apply with the derived table in this example would be better written as an INNER JOIN and the Optimizer converts it to one):

    -- create a table to run the function against

    CREATE TABLE test2 (id INT, col1 CHAR(1))

    GO

    -- create the TVF

    CREATE FUNCTION test (@id INT)

    RETURNS @table TABLE (id INT, col1 CHAR(1))

    AS BEGIN

    INSERT INTO

    @table

    SELECT

    *

    FROM

    test2 AS T

    WHERE

    id = @id ;

    RETURN

    END

    GO

    -- table variable for outer/left input

    DECLARE @test1 TABLE (id INT, col1 CHAR(1))

    -- insert test data

    INSERT INTO

    @test1 (id, col1)

    SELECT TOP 10

    ROW_NUMBER() OVER (ORDER BY OBJECT_ID),

    CHAR(ROW_NUMBER() OVER (ORDER BY OBJECT_ID) + 60)

    FROM

    sys.all_columns AS AC

    INSERT INTO

    test2 (id, col1)

    SELECT TOP 10

    ROW_NUMBER() OVER (ORDER BY OBJECT_ID),

    CHAR(ROW_NUMBER() OVER (ORDER BY OBJECT_ID) + 60)

    FROM

    sys.all_columns AS AC

    -- cross join Cartesian product

    SELECT

    *

    FROM

    @test1 CROSS JOIN

    test2

    -- outer apply on a derived table

    SELECT

    *

    FROM

    @test1 AS one CROSS APPLY

    (

    SELECT

    *

    FROM

    test2 AS two

    WHERE

    one.id = two.id

    ) AS test2

    -- outer apply TVF

    SELECT

    *

    FROM

    @test1 AS one CROSS APPLY

    dbo.test(one.id) ;

    DROP TABLE test2 ;

    GO

    DROP FUNCTION dbo.test ;

    If you SET STATISTICS IO ON you will see that the last query (CROSS APPLY to the TVF) has 10 scans because for each row in @test1 the TVF is being called and going out and scanning the test2 table.

  • Thank you Jack Corbett.

    nice explanation and example

    Balamurugan

  • @jack-2 Nice response, Very helpful.

  • Y'all are welcome. I'm glad it made sense.

  • bitbucket-25253....wasted my time what a response

  • daniarchitect (6/19/2014)


    bitbucket-25253....wasted my time what a response

    If Bitbucket's explanation doesn't exactly meet your requirements, then simply ask what you need to know. Rudeness is unnecessary and unprofessional.

    โ€œ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

  • daniarchitect (6/19/2014)


    bitbucket-25253....wasted my time what a response

    BWAA-HAA!!! Considering that you even went back and edited your response, I suspect you voluntarily wasted more time on your own that what you claim BitBucket did. ๐Ÿ˜‰

    --Jeff Moden


    RBAR is pronounced "ree-bar" and is a "Modenism" for Row-By-Agonizing-Row.
    First step towards the paradigm shift of writing Set Based code:
    ________Stop thinking about what you want to do to a ROW... think, instead, of what you want to do to a COLUMN.

    Change is inevitable... Change for the better is not.


    Helpful Links:
    How to post code problems
    How to Post Performance Problems
    Create a Tally Function (fnTally)

  • bitbucket-25253 (1/7/2010)


    You have posted your question in a SQL 2000 forum ... CROSS APPLY WAS introduced in SQL Server 2005 ...

    For SQL 2000 CROSS JOINS exist and they exist in SQL 2005 as well ... so the difference is .. one exists one does not.

    Now if you question pertains to SQL 2005 or 2008 use Books On Line for an explanation and sample code ....

    That's a pretty jerk answer.

  • That's a pretty jerk answer.

    Sorry, but I don't agree. Maybe it could have been phrased differently, although I don't see anything wrong with it. But the help on this site is free. And it would be helpful if questions were appropriately addressed. It would also be helpful to know some little bit of research has been done.

  • RonKyle (12/24/2015)


    That's a pretty jerk answer.

    Sorry, but I don't agree. Maybe it could have been phrased differently, although I don't see anything wrong with it. But the help on this site is free. And it would be helpful if questions were appropriately addressed. It would also be helpful to know some little bit of research has been done.

    +1000. And the answer was much more helpful than what I was going to post and didn't, which would have been a LMGTFY response.

    --Jeff Moden


    RBAR is pronounced "ree-bar" and is a "Modenism" for Row-By-Agonizing-Row.
    First step towards the paradigm shift of writing Set Based code:
    ________Stop thinking about what you want to do to a ROW... think, instead, of what you want to do to a COLUMN.

    Change is inevitable... Change for the better is not.


    Helpful Links:
    How to post code problems
    How to Post Performance Problems
    Create a Tally Function (fnTally)

  • Jeff Moden (12/24/2015)


    RonKyle (12/24/2015)


    That's a pretty jerk answer.

    Sorry, but I don't agree. Maybe it could have been phrased differently, although I don't see anything wrong with it. But the help on this site is free. And it would be helpful if questions were appropriately addressed. It would also be helpful to know some little bit of research has been done.

    +1000. And the answer was much more helpful than what I was going to post and didn't, which would have been a LMGTFY response.

    I also agree. If the SQL 2000 point was skipped, the next response would have been "Hey, your code sucks because it doesn't work on my SQL 2000 instance." No matter how it was phrased, it was correct. Then again, Books Online was available back in 2010 when the question was originally posted. I don't think SQL 2000 has changed much since then.

  • If the SQL 2000 point was skipped, the next response would have been "Hey, your code sucks because it doesn't work on my SQL 2000 instance."

    A good point. Maybe he posted it in the correct forum. Given the way he phrased the question, I don't think so. But maybe not safe to assume.

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

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