• Ok... here we go with a test for Alex's function. I was right about the CTE still being "Hidden RBAR" even though it uses all variables and is an InLine Table Valued Function (iTVF).

    Here's the data generation code again...

    --=================================================================================================

    -- Create a CSV test table with 10000 rows and 10 random CSV elements per row.

    -- The randomness of the elements also prevents the delimiters for showing up in the same

    -- position for each row. SQL Server would figure that out and cache the information making

    -- some splitting techniques seem faster than they really are.

    -- This section of the code takes just a couple of seconds to run because XML concatenation

    -- is very fast (especially when compared to XML splitting or shredding).

    -- Jeff Moden

    --=================================================================================================

    --===== Conditionally drop the test table to make reruns easier

    IF OBJECT_ID('TempDB..#CsvTest','U') IS NOT NULL

    DROP TABLE #CsvTest

    --===== This creates and populates a test table on the fly containing a

    -- sequential column and a randomly generated CSV Parameter column.

    SELECT TOP (10000) --Controls the number of rows in the test table

    ISNULL(ROW_NUMBER() OVER (ORDER BY(SELECT NULL)),0) AS RowNum,

    (

    SELECT CAST(STUFF( --=== STUFF get's rid of the leading comma

    ( --=== This builds CSV row with a leading comma

    SELECT TOP (10) --Controls the number of CSV elements in each row

    ','+CAST(ABS(CHECKSUM(NEWID()))%100000 AS VARCHAR(10))

    FROM Master.sys.All_Columns ac3 --Classic cross join pseudo-cursor

    CROSS JOIN Master.sys.All_Columns ac4 --can produce row sets up 16 million

    WHERE ac3.Object_ID = ac1.Object_ID --Without this, all rows would be the same

    FOR XML PATH('')

    )

    ,1,1,'') AS VARCHAR(8000))

    ) AS CsvParameter

    INTO #CsvTest

    FROM Master.sys.All_Columns ac1 --Classic cross join pseudo-cursor

    CROSS JOIN Master.sys.All_Columns ac2 --can produce row sets up 16 million

    --===== Let's add a PK just for grins. Since it's a temp table, we won't name it.

    ALTER TABLE #CsvTest

    ADD PRIMARY KEY CLUSTERED (RowNum) WITH FILLFACTOR = 100

    --===== Sanity check... let's see what we've got in the test table

    SELECT * FROM #CsvTest

    Here's the test code comparing the method I've demo'd several times with Alex's recursive CTE...

    --===== DelimitedSplit8k solution

    SELECT test.RowNum, split.ItemNumber, split.Item

    INTO #Result1

    FROM #CsvTest test

    CROSS APPLY

    (

    SELECT ItemNumber, Item

    FROM dbo.DelimitedSplit8k(test.CsvParameter,',')

    ) split

    ;

    GO

    --===== Alex's Recursive CTE solution

    SELECT test.RowNum, split.RowID, split.SplitedValue

    INTO #Result2

    FROM #CsvTest test

    CROSS APPLY

    (

    SELECT RowID, SplitedValue

    FROM [StringToTable](test.CsvParameter,',')

    ) split

    ;

    GO

    And, here are the results from the Profiler run... I'd strongly recommend that recursive CTE methods be avoided at all costs because they cost so much and are so very slow... this difference was only on 10,000 rows by 10 elements (100,000 rows total output) which can easily represent the number of hits on a busy server in a second or two.

    Of course, this is one of the places where a CLR comes in handy. It'll be about twice as fast in this case.

    --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)