Is any built in function availble in SQL Server 2008 which handle comma seperated values and return as table?

  • Is any built in function availble in SQL Server 2008 which handle comma seperated values and return as table ?

    Means it return as tabular form (column/row).

  • There is no built in function.

    Try this article to get you going though..

    http://www.sqlservercentral.com/articles/T-SQL/62867/



    Clear Sky SQL
    My Blog[/url]

  • There's nothing built in, but you can use this function

    http://www.sqlservercentral.com/Forums/FindPost944589.aspx

    ____________________________________________________

    Deja View - The strange feeling that somewhere, sometime you've optimised this query before

    How to get the best help on a forum

    http://www.sqlservercentral.com/articles/Best+Practices/61537
  • Mark-101232 (4/2/2011)


    There's nothing built in, but you can use this function

    http://www.sqlservercentral.com/Forums/FindPost944589.aspx

    FYI - I have it on good authority that a newer, faster version of this is in the works. Keep your eyes peeled.

    Wayne
    Microsoft Certified Master: SQL Server 2008
    Author - SQL Server T-SQL Recipes


    If you can't explain to another person how the code that you're copying from the internet works, then DON'T USE IT on a production system! After all, you will be the one supporting it!
    Links:
    For better assistance in answering your questions
    Performance Problems
    Common date/time routines
    Understanding and Using APPLY Part 1 & Part 2

  • WayneS (4/2/2011)


    Mark-101232 (4/2/2011)


    There's nothing built in, but you can use this function

    http://www.sqlservercentral.com/Forums/FindPost944589.aspx

    FYI - I have it on good authority that a newer, faster version of this is in the works. Keep your eyes peeled.

    I've heard the same rumor;-)

    Jason...AKA CirqueDeSQLeil
    _______________________________________________
    I have given a name to my pain...MCM SQL Server, MVP
    SQL RNNR
    Posting Performance Based Questions - Gail Shaw[/url]
    Learn Extended Events

  • I wonder how well a CLR function of the .net SPLIT function would perform...?

    Wayne
    Microsoft Certified Master: SQL Server 2008
    Author - SQL Server T-SQL Recipes


    If you can't explain to another person how the code that you're copying from the internet works, then DON'T USE IT on a production system! After all, you will be the one supporting it!
    Links:
    For better assistance in answering your questions
    Performance Problems
    Common date/time routines
    Understanding and Using APPLY Part 1 & Part 2

  • WayneS (4/2/2011)


    I wonder how well a CLR function of the .net SPLIT function would perform...?

    Oddly enough, I've just (sent an email 15 minutes ago) asked Paul White to come up with an SQLCLR function for doing splits for the 2 new articles on splitters I'm working on. The reason I asked him is that he has this slick trick of making it possible to install without having C# available.

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

  • CirquedeSQLeil (4/2/2011)


    WayneS (4/2/2011)


    Mark-101232 (4/2/2011)


    There's nothing built in, but you can use this function

    http://www.sqlservercentral.com/Forums/FindPost944589.aspx

    FYI - I have it on good authority that a newer, faster version of this is in the works. Keep your eyes peeled.

    I've heard the same rumor;-)

    It's no longer a rumor. πŸ™‚ I've not completed the article, yet, but I've just completed (as of about 30 minutes ago) my sanity checking on the new code as well as some qualitative performance testing. No need to keep anyone waiting any longer. This even beats the previous improvements that I've posted a couple of times. Details are, of course, in the code and is a direct replacement for the old code. πŸ˜‰

    DROP FUNCTION dbo.DelimitedSplit8K

    GO

    CREATE FUNCTION dbo.DelimitedSplit8K

    /***************************************************************************************************

    Purpose:

    Split a given string at a given delimiter and return a list of the split elements (items).

    Returns:

    iTVF containing the following:

    ItemNumber = Element position of Item as a BIGINT (not converted to INT to eliminate a CAST)

    Item = Element value as a VARCHAR(8000)

    CROSS APPLY Usage Example:

    ---------------------------------------------------------------------------------------------------

    --===== Conditionally drop the test tables to make reruns easier for testing.

    -- (this is NOT a part of the solution)

    IF OBJECT_ID('tempdb..#JBMTest') IS NOT NULL

    DROP TABLE #JBMTest

    ;

    --===== Create and populate a test table on the fly (this is NOT a part of the solution).

    SELECT *

    INTO #JBMTest

    FROM (

    SELECT 0, NULL UNION ALL

    SELECT 1, '' UNION ALL

    SELECT 2, ' ' UNION ALL

    SELECT 3, ',' UNION ALL

    SELECT 4, '55555' UNION ALL

    SELECT 5, ',55555' UNION ALL

    SELECT 6, ',55555,' UNION ALL

    SELECT 7, '55555,' UNION ALL

    SELECT 8, '55555,1' UNION ALL

    SELECT 9, '1,55555' UNION ALL

    SELECT 10, '55555,4444,333,22,1' UNION ALL

    SELECT 11, '55555,4444,,333,22,1' UNION ALL

    SELECT 12, ',55555,4444,,333,22,1,' UNION ALL

    SELECT 13, 'This,is,a,test.'

    ) d (SomeID, SomeValue)

    ;

    GO

    --===== Split the CSV column for the whole table using CROSS APPLY (this is the solution)

    SELECT test.SomeID, test.SomeValue, split.ItemNumber, split.Item

    FROM #JBMTest test

    CROSS APPLY dbo.DelimitedSplit8k(test.SomeValue,',') split

    ;

    ---------------------------------------------------------------------------------------------------

    Notes:

    1. Optimized for VARCHAR(8000) or less. No testing or error reporting for truncation at 8000

    characters is done.

    2. Optimized for single character delimiter. Multi-character delimiters should be resolved

    externally from this function.

    3. Optimized for use with CROSS APPLY.

    4. Does not "trim" elements just in case leading or trailing blanks are intended.

    5. If you don't know how a Tally table can be used to replace loops, please see the following...

    http://www.sqlservercentral.com/articles/T-SQL/62867/

    6. Changing this function to use VARCHAR(MAX) will cause it to run twice as slow. It's just the

    nature of VARCHAR(MAX) whether it fits in-row or not.

    7. Multi-machine testing for the method of using UNPIVOT instead of 10 SELECT/UNION ALLs shows

    that the UNPIVOT method is quite machine dependent and can slow things down quite a bit.

    8. Performance testing shows using ORDER BY (SELECT x) where "x" is anything is actually

    slower and slightly more CPU intensive than the traditional ORDER BY (SELECT N).

    Credits:

    This code is the product of many people's efforts including but not limited to the following:

    cteTally concept originally by Iztek Ben Gan and "decimalized" by Lynn Pettis (and others) for a

    bit of extra speed and finally redacted by Jeff Moden for a different slant on readability and

    compactness. Hat's off to Paul White for his simple explanations of CROSS APPLY. Finally,

    special thanks to Erland Sommarskog for his tireless efforts to help people understand

    what you can actually do with T-SQL. I also thank whoever wrote the first article I ever saw

    on "numbers tables" which is located at the following URL ...

    http://sqlserver2000.databases.aspfaq.com/why-should-i-consider-using-an-auxiliary-numbers-table.html

    Revision History:

    Rev 00 - 20 Jan 2010 - Concept: Lynn Pettis and others.

    Redaction/Implementation: Jeff Moden

    - Base 10 redaction and reduction for CTE. (Total rewrite)

    Rev 01 - 13 Mar 2010 - Jeff Moden

    - Removed one additional concatenation and one subtraction from the SUBSTRING in the

    SELECT List for that tiny bit of extra speed.

    Rev 02 - 14 Apr 2010 - Jeff Moden

    - No code changes. Added CROSS APPLY usage example to the header, some additional credits,

    and extra documentation.

    Rev 03 - 18 Apr 2010 - Jeff Moden

    - No code changes. Added notes 7, 8, and 9 about certain "optimizations" that dont'

    actually work for this type of function.

    Rev 04 - 29 Jun 2010 - Jeff Moden

    - Added WITH SCHEMABINDING thanks to a note by Paul White. This prevents an unnecessary

    "Table Spool" when the function is used in an UPDATE statement even though the function

    makes no external references.

    Rev 05 - 02 Apr 2011 - Jeff Moden

    - Rewritten for extreme performance improvement especially for larger strings approaching

    the 8K boundary and for strings that have wider elements. The redaction of this code

    involved removing ALL concatenation of delimiters, optimization of the maximum "N" value

    by using TOP instead of including it in the WHERE clause, and the reduction of all

    previous calculations (thanks to the switch to a "zero based" cteTally) to just one

    instance of one add and one instance of a subtract. The length calculation for the final

    element (not followed by a delimiter) in the string to be split has been greatly

    simplified by using the ISNULL/NULLIF combination to determine when the CHARINDEX returned

    a 0 which indicates there are no more delimiters to be had or to start with. Depending on

    the width of the elements, this code is between 4 and 8 times faster on a single CPU box

    than the original code especially near the 8K boundary.

    - Modified comments to include more sanity checks om the usage example, etc.

    ***************************************************************************************************/

    --===== Define I/O parameters

    (

    @pString VARCHAR(8000),

    @pDelimiter CHAR(1)

    )

    RETURNS TABLE

    WITH SCHEMABINDING

    AS

    RETURN

    --===== "Inline" CTE Driven "Tally Table” produces values up to

    -- 10,000... enough to cover VARCHAR(8000)

    WITH E1(N) AS (

    SELECT 1 UNION ALL SELECT 1 UNION ALL SELECT 1 UNION ALL

    SELECT 1 UNION ALL SELECT 1 UNION ALL SELECT 1 UNION ALL

    SELECT 1 UNION ALL SELECT 1 UNION ALL SELECT 1 UNION ALL SELECT 1

    ), --10E+1 or 10 rows

    E2(N) AS (SELECT 1 FROM E1 a, E1 b), --10E+2 or 100 rows

    E4(N) AS (SELECT 1 FROM E2 a, E2 b), --10E+4 or 10,000 rows max

    cteTally(N) AS (--==== This provides the "zero base" and limits the number of rows right up front

    -- for both a performance gain and prevention of accidental "overruns"

    SELECT 0 UNION ALL

    SELECT TOP (DATALENGTH(ISNULL(@pString,1))) ROW_NUMBER() OVER (ORDER BY (SELECT NULL)) FROM E4

    ),

    cteStart(N1) AS (--==== This returns N+1 (starting position of each "element" just once for each delimiter)

    SELECT t.N+1

    FROM cteTally t

    WHERE (SUBSTRING(@pString,t.N,1) = @pDelimiter COLLATE Latin1_General_BIN OR t.N = 0)

    )--===== The ISNULL/NULLIF combo handles the length for the final element when no delimiter is found

    SELECT ItemNumber = ROW_NUMBER() OVER(ORDER BY s.N1),

    Item = SUBSTRING(@pString,s.N1,ISNULL(NULLIF(CHARINDEX(@pDelimiter,@pString,s.N1),0)-s.N1,8000))

    COLLATE Latin1_General_BIN

    FROM cteStart s

    ;

    GO

    I've also solved the problem of splitting VARCHAR(MAX) with a cteTally... I'm just not done with all my sanity checks, yet. And, yes, there will be a separate article on that, as well.

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

  • Heh... SPAM SPAM reported. πŸ˜‰

    {edit} They removed the SPAM I reported so please disregard this message.

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

Viewing 9 posts - 1 through 9 (of 9 total)

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