Home Forums SQL Server 7,2000 T-SQL Difference Between cross apply and cross join RE: Difference Between cross apply and cross join

  • 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.