How to make one innerjoin to bring all value of all the substrings within a string separated by a comma

  • Hi, 
    I have two tables, answers and lookup, In my answer table I have a field named: value, it my contain many values separated by comma example value = '22,1,3', theses values are the id of the lookup table.
    my lookup table are the text describing the answer.
    the issue is that I couldn't bring all the text of the id's, I just bring one text value.
    This is my code, 

    Create table #answers
    (
    id int,
    value varchar(50),
    )
    go

    INSERT INTO #answers
    VALUES(1,'1,2,3,4,'),
    (2,'5,2,'),
    (3,'3,4,')
    GO

    Create table #lookup
    (
    id int,
    text varchar(50),
    )
    go

    INSERT INTO #lookup
    VALUES(1,'txt1'),
    (2,'txt2'),
    (3,'txt3'),
    (4,'txt4'),
    (5,'txt5'),
    GO
    select ans.id as AnswerID, look.text as AnswerValue from #answers as ans
    innerjoin #lookup as look
    on look.id = substring(ans.value, 1,charindex(',',ans.value,1)-1)[/code]

    the expected result is :
     https://www.sqlservercentral.com/Forums/Uploads/Images/e9a0c9a9-3b02-4990-a4d7-4692.PNG

    Thank you.


  • INSERT INTO #answers
    VALUES(1,'1,2,3,4,'),
    (2,'5,2,'),
    (3,'3,4,')
    GO

    These values all have a blank at the end of them. Is that intended?

  • benkraiemchedlia - Friday, March 3, 2017 12:39 PM

    Hi, 
    I have two tables, answers and lookup, In my answer table I have a field named: value, it my contain many values separated by comma example value = '22,1,3', theses values are the id of the lookup table.
    my lookup table are the text describing the answer.
    the issue is that I couldn't bring all the text of the id's, I just bring one text value.
    This is my code, 

    Create table #answers
    (
    id int,
    value varchar(50),
    )
    go

    INSERT INTO #answers
    VALUES(1,'1,2,3,4,'),
    (2,'5,2,'),
    (3,'3,4,')
    GO

    Create table #lookup
    (
    id int,
    text varchar(50),
    )
    go

    INSERT INTO #lookup
    VALUES(1,'txt1'),
    (2,'txt2'),
    (3,'txt3'),
    (4,'txt4'),
    (5,'txt5'),
    GO
    select ans.id as AnswerID, look.text as AnswerValue from #answers as ans
    innerjoin #lookup as look
    on look.id = substring(ans.value, 1,charindex(',',ans.value,1)-1)[/code]

    the expected result is :
     https://www.sqlservercentral.com/Forums/Uploads/Images/e9a0c9a9-3b02-4990-a4d7-4692.PNG

    Thank you.

    You need to normalize your tables in order to join them as you want. For some help on doing it, check the following article: http://www.sqlservercentral.com/articles/Tally+Table/72993/

    Luis C.
    General Disclaimer:
    Are you seriously taking the advice and code from someone from the internet without testing it? Do you at least understand it? Or can it easily kill your server?

    How to post data/code on a forum to get the best help: Option 1 / Option 2
  • You could normalize it with this:


    WITH CTE AS
    (
    SELECT id
        ,LTRIM(RTRIM(m.n.value('.[1]','varchar(8000)'))) AS value
    FROM
    (
    SELECT id
        ,CAST('<XMLRoot><RowData>' + REPLACE(value,',','</RowData><RowData>') + '</RowData></XMLRoot>' AS XML) AS S
    FROM #answers
    ) AS t
    CROSS APPLY S.nodes('/XMLRoot/RowData')m(n)
    ), CTE2 AS
    (
    SELECT C.id, L.text
    FROM #lookup AS L
    JOIN CTE AS C
    ON L.id = C.value
    )
    SELECT *
    FROM CTE2

    But then you're still left with flipping that back into a comma separated list.

  • As a side note, storing values like that in comma separated list is a poor design. If you have control over the design then void it.  Here's a good book to read on the subject. The first chapter talks about this exact issue:

    SQL Antipatterns Book

  • First, you need the following itvf:

    USE [Sandbox]
    GO

    /****** Object:  UserDefinedFunction [dbo].[DelimitedSplit8K]    Script Date: 3/3/2017 1:25:30 PM ******/
    SET ANSI_NULLS ON
    GO

    SET QUOTED_IDENTIFIER ON
    GO


     CREATE FUNCTION [dbo].[DelimitedSplit8K]
    /**********************************************************************************************************************
     Purpose:
     Split a given string at a given delimiter and return a list of the split elements (items).

     Notes:
     1.  Leading a trailing delimiters are treated as if an empty string element were present.
     2.  Consecutive delimiters are treated as if an empty string element were present between them.
     3.  Except when spaces are used as a delimiter, all spaces present in each element are preserved.

     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)

     Statistics on this function may be found at the following URL:
     http://www.sqlservercentral.com/Forums/Topic1101315-203-4.aspx

     CROSS APPLY Usage Examples and Tests:
    --=====================================================================================================================
    -- TEST 1:
    -- This tests for various possible conditions in a string using a comma as the delimiter.  The expected results are
    -- laid out in the comments
    --=====================================================================================================================
    --===== 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).
         -- In the following comments, "b" is a blank and "E" is an element in the left to right order.
         -- Double Quotes are used to encapsulate the output of "Item" so that you can see that all blanks
         -- are preserved no matter where they may appear.
     SELECT *
       INTO #JBMTest
       FROM (                                               --# & type of Return Row(s)
             SELECT  0, NULL                      UNION ALL --1 NULL
             SELECT  1, SPACE(0)                  UNION ALL --1 b (Empty String)
             SELECT  2, SPACE(1)                  UNION ALL --1 b (1 space)
             SELECT  3, SPACE(5)                  UNION ALL --1 b (5 spaces)
             SELECT  4, ','                       UNION ALL --2 b b (both are empty strings)
             SELECT  5, '55555'                   UNION ALL --1 E
             SELECT  6, ',55555'                  UNION ALL --2 b E
             SELECT  7, ',55555,'                 UNION ALL --3 b E b
             SELECT  8, '55555,'                  UNION ALL --2 b B
             SELECT  9, '55555,1'                 UNION ALL --2 E E
             SELECT 10, '1,55555'                 UNION ALL --2 E E
             SELECT 11, '55555,4444,333,22,1'     UNION ALL --5 E E E E E
             SELECT 12, '55555,4444,,333,22,1'    UNION ALL --6 E E b E E E
             SELECT 13, ',55555,4444,,333,22,1,'  UNION ALL --8 b E E b E E E b
             SELECT 14, ',55555,4444,,,333,22,1,' UNION ALL --9 b E E b b E E E b
             SELECT 15, ' 4444,55555 '            UNION ALL --2 E (w/Leading Space) E (w/Trailing Space)
             SELECT 16, 'This,is,a,test.'                   --E E E E
            ) d (SomeID, SomeValue)
    ;
    --===== Split the CSV column for the whole table using CROSS APPLY (this is the solution)
     SELECT test.SomeID, test.SomeValue, split.ItemNumber, Item = QUOTENAME(split.Item,'"')
       FROM #JBMTest test
      CROSS APPLY dbo.DelimitedSplit8K(test.SomeValue,',') split
    ;
    --=====================================================================================================================
    -- TEST 2:
    -- This tests for various "alpha" splits and COLLATION using all ASCII characters from 0 to 255 as a delimiter against
    -- a given string.  Note that not all of the delimiters will be visible and some will show up as tiny squares because
    -- they are "control" characters.  More specifically, this test will show you what happens to various non-accented
    -- letters for your given collation depending on the delimiter you chose.
    --=====================================================================================================================
    WITH
    cteBuildAllCharacters (String,Delimiter) AS
    (
     SELECT TOP 256
            'ABCDEFGHIJKLMNOPQRSTUVWXYZabcdefghijklmnopqrstuvwxyz0123456789',
            CHAR(ROW_NUMBER() OVER (ORDER BY (SELECT NULL))-1)
       FROM master.sys.all_columns
    )
     SELECT ASCII_Value = ASCII(c.Delimiter), c.Delimiter, split.ItemNumber, Item = QUOTENAME(split.Item,'"')
       FROM cteBuildAllCharacters c
      CROSS APPLY dbo.DelimitedSplit8K(c.String,c.Delimiter) split
      ORDER BY ASCII_Value, split.ItemNumber
    ;
    -----------------------------------------------------------------------------------------------------------------------
     Other 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 resolvedexternally 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 NVARCHAR(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.
    -----------------------------------------------------------------------------------------------------------------------
     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 and for his detailed testing efforts. Last but not least, thanks to
     Ron "BitBucket" McCullough and Wayne Sheffield for their extreme performance testing across multiple machines and
     versions of SQL Server.  The latest improvement brought an additional 15-20% improvement over Rev 05.  Special thanks
     to "Nadrek" and "peter-757102" (aka Peter de Heer) for bringing such improvements to light.  Nadrek's original
     improvement brought about a 10% performance gain and Peter followed that up with the content of Rev 07. 

     I also thank whoever wrote the first article I ever saw on "numbers tables" which is located at the following URL
     and to Adam Machanic for leading me to it many years ago.
     http://sqlserver2000.databases.aspfaq.com/why-should-i-consider-using-an-auxiliary-numbers-table.html
    -----------------------------------------------------------------------------------------------------------------------
     Revision History:
     Rev 00 - 20 Jan 2010 - Concept for inline cteTally: 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 don't 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 on the usage example, etc.
            - Removed "other" notes 8 and 9 as they were no longer applicable.

     Rev 06 - 12 Apr 2011 - Jeff Moden
            - Based on a suggestion by Ron "Bitbucket" McCullough, additional test rows were added to the sample code and
              the code was changed to encapsulate the output in pipes so that spaces and empty strings could be perceived
              in the output.  The first "Notes" section was added.  Finally, an extra test was added to the comments above.

     Rev 07 - 06 May 2011 - Peter de Heer, a further 15-20% performance enhancement has been discovered and incorporated
              into this code which also eliminated the need for a "zero" position in the cteTally table.
    **********************************************************************************************************************/
    --===== Define I/O parameters
            (@pString VARCHAR(8000), @pDelimiter CHAR(1))
    RETURNS TABLE WITH SCHEMABINDING AS
     RETURN
    --===== "Inline" CTE Driven "Tally Table" produces values from 0 up to 10,000...
         -- enough to cover NVARCHAR(4000)
      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 "base" CTE and limits the number of rows right up front
                         -- for both a performance gain and prevention of accidental "overruns"
                     SELECT TOP (ISNULL(DATALENGTH(@pString),0)) 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 1 UNION ALL
                     SELECT t.N+1 FROM cteTally t WHERE SUBSTRING(@pString,t.N,1) = @pDelimiter
                    ),
    cteLen(N1,L1) AS(--==== Return start and length (for use in substring)
                     SELECT s.N1,
                            ISNULL(NULLIF(CHARINDEX(@pDelimiter,@pString,s.N1),0)-s.N1,8000)
                       FROM cteStart s
                    )
    --===== Do the actual split. The ISNULL/NULLIF combo handles the length for the final element when no delimiter is found.
     SELECT ItemNumber = ROW_NUMBER() OVER(ORDER BY l.N1),
            Item       = SUBSTRING(@pString, l.N1, l.L1)
       FROM cteLen l;

    GO

    With that, the following works:


    if OBJECT_ID('tempdb..#answers') is not null
      drop table #answers;

    Create table #answers
    (
     id int,
     value varchar(50),
    )
    go

    INSERT INTO #answers
    VALUES(1,'1,2,3,4'),
     (2,'5,2'),
     (3,'3,4')
    GO

    if OBJECT_ID('tempdb..#lookup') is not null
      drop table #lookup;

    Create table #lookup
    (
     id int,
     text varchar(50),
    )
    go

    INSERT INTO #lookup
    VALUES(1,'txt1'),
     (2,'txt2'),
     (3,'txt3'),
     (4,'txt4'),
     (5,'txt5')
    GO

    select * from #answers
    select * from #lookup

    select
      a.*,
      ca.*
    from
      #answers a
      cross apply (select
                     stuff((select
                              ',' + l.[text]
                            from
                              #lookup l
                              inner join dbo.DelimitedSplit8K(a.[value],',') ds
                                on l.id = ds.Item
                            order by
                              ds.ItemNumber
                            for xml path(''),type).value('.','varchar(max)'),1,1,'')) ca(AnswerValue);

    You should have questions about how this works, please ask.

  • Jeff Atherton - Friday, March 3, 2017 1:09 PM

    As a side note, storing values like that in comma separated list is a poor design. If you have control over the design then void it.  Here's a good book to read on the subject. The first chapter talks about this exact issue:

    SQL Antipatterns Book

    Hi Jeff, 
    I don't have the right to change the DB design, I m just collecting results.

  • Jeff Atherton - Friday, March 3, 2017 12:55 PM


    INSERT INTO #answers
    VALUES(1,'1,2,3,4,'),
    (2,'5,2,'),
    (3,'3,4,')
    GO

    These values all have a blank at the end of them. Is that intended?

    Yes this is the actual design of the DB, 
    I was thinking of counting the substring delimited by comma, then to loop one by one and insert in answers table the new value, but I don't know if it will be a nice idea

  • benkraiemchedlia - Saturday, March 4, 2017 12:55 AM

    Yes this is the actual design of the DB, 
    I was thinking of counting the substring delimited by comma, then to loop one by one and insert in answers table the new value, but I don't know if it will be a nice idea

    No.  It won't be a nice idea unless you're interested in slowness and burning clock cycles in the process.  See the post by Lynn Pettis above.

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

  • Lynn Pettis - Friday, March 3, 2017 1:30 PM

    First, you need the following itvf:

    USE [Sandbox]
    GO

    /****** Object:  UserDefinedFunction [dbo].[DelimitedSplit8K]    Script Date: 3/3/2017 1:25:30 PM ******/
    SET ANSI_NULLS ON
    GO

    SET QUOTED_IDENTIFIER ON
    GO


     CREATE FUNCTION [dbo].[DelimitedSplit8K]
    /**********************************************************************************************************************
     Purpose:
     Split a given string at a given delimiter and return a list of the split elements (items).

     Notes:
     1.  Leading a trailing delimiters are treated as if an empty string element were present.
     2.  Consecutive delimiters are treated as if an empty string element were present between them.
     3.  Except when spaces are used as a delimiter, all spaces present in each element are preserved.

     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)

     Statistics on this function may be found at the following URL:
     http://www.sqlservercentral.com/Forums/Topic1101315-203-4.aspx

     CROSS APPLY Usage Examples and Tests:
    --=====================================================================================================================
    -- TEST 1:
    -- This tests for various possible conditions in a string using a comma as the delimiter.  The expected results are
    -- laid out in the comments
    --=====================================================================================================================
    --===== 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).
         -- In the following comments, "b" is a blank and "E" is an element in the left to right order.
         -- Double Quotes are used to encapsulate the output of "Item" so that you can see that all blanks
         -- are preserved no matter where they may appear.
     SELECT *
       INTO #JBMTest
       FROM (                                               --# & type of Return Row(s)
             SELECT  0, NULL                      UNION ALL --1 NULL
             SELECT  1, SPACE(0)                  UNION ALL --1 b (Empty String)
             SELECT  2, SPACE(1)                  UNION ALL --1 b (1 space)
             SELECT  3, SPACE(5)                  UNION ALL --1 b (5 spaces)
             SELECT  4, ','                       UNION ALL --2 b b (both are empty strings)
             SELECT  5, '55555'                   UNION ALL --1 E
             SELECT  6, ',55555'                  UNION ALL --2 b E
             SELECT  7, ',55555,'                 UNION ALL --3 b E b
             SELECT  8, '55555,'                  UNION ALL --2 b B
             SELECT  9, '55555,1'                 UNION ALL --2 E E
             SELECT 10, '1,55555'                 UNION ALL --2 E E
             SELECT 11, '55555,4444,333,22,1'     UNION ALL --5 E E E E E
             SELECT 12, '55555,4444,,333,22,1'    UNION ALL --6 E E b E E E
             SELECT 13, ',55555,4444,,333,22,1,'  UNION ALL --8 b E E b E E E b
             SELECT 14, ',55555,4444,,,333,22,1,' UNION ALL --9 b E E b b E E E b
             SELECT 15, ' 4444,55555 '            UNION ALL --2 E (w/Leading Space) E (w/Trailing Space)
             SELECT 16, 'This,is,a,test.'                   --E E E E
            ) d (SomeID, SomeValue)
    ;
    --===== Split the CSV column for the whole table using CROSS APPLY (this is the solution)
     SELECT test.SomeID, test.SomeValue, split.ItemNumber, Item = QUOTENAME(split.Item,'"')
       FROM #JBMTest test
      CROSS APPLY dbo.DelimitedSplit8K(test.SomeValue,',') split
    ;
    --=====================================================================================================================
    -- TEST 2:
    -- This tests for various "alpha" splits and COLLATION using all ASCII characters from 0 to 255 as a delimiter against
    -- a given string.  Note that not all of the delimiters will be visible and some will show up as tiny squares because
    -- they are "control" characters.  More specifically, this test will show you what happens to various non-accented
    -- letters for your given collation depending on the delimiter you chose.
    --=====================================================================================================================
    WITH
    cteBuildAllCharacters (String,Delimiter) AS
    (
     SELECT TOP 256
            'ABCDEFGHIJKLMNOPQRSTUVWXYZabcdefghijklmnopqrstuvwxyz0123456789',
            CHAR(ROW_NUMBER() OVER (ORDER BY (SELECT NULL))-1)
       FROM master.sys.all_columns
    )
     SELECT ASCII_Value = ASCII(c.Delimiter), c.Delimiter, split.ItemNumber, Item = QUOTENAME(split.Item,'"')
       FROM cteBuildAllCharacters c
      CROSS APPLY dbo.DelimitedSplit8K(c.String,c.Delimiter) split
      ORDER BY ASCII_Value, split.ItemNumber
    ;
    -----------------------------------------------------------------------------------------------------------------------
     Other 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 resolvedexternally 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 NVARCHAR(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.
    -----------------------------------------------------------------------------------------------------------------------
     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 and for his detailed testing efforts. Last but not least, thanks to
     Ron "BitBucket" McCullough and Wayne Sheffield for their extreme performance testing across multiple machines and
     versions of SQL Server.  The latest improvement brought an additional 15-20% improvement over Rev 05.  Special thanks
     to "Nadrek" and "peter-757102" (aka Peter de Heer) for bringing such improvements to light.  Nadrek's original
     improvement brought about a 10% performance gain and Peter followed that up with the content of Rev 07. 

     I also thank whoever wrote the first article I ever saw on "numbers tables" which is located at the following URL
     and to Adam Machanic for leading me to it many years ago.
     http://sqlserver2000.databases.aspfaq.com/why-should-i-consider-using-an-auxiliary-numbers-table.html
    -----------------------------------------------------------------------------------------------------------------------
     Revision History:
     Rev 00 - 20 Jan 2010 - Concept for inline cteTally: 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 don't 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 on the usage example, etc.
            - Removed "other" notes 8 and 9 as they were no longer applicable.

     Rev 06 - 12 Apr 2011 - Jeff Moden
            - Based on a suggestion by Ron "Bitbucket" McCullough, additional test rows were added to the sample code and
              the code was changed to encapsulate the output in pipes so that spaces and empty strings could be perceived
              in the output.  The first "Notes" section was added.  Finally, an extra test was added to the comments above.

     Rev 07 - 06 May 2011 - Peter de Heer, a further 15-20% performance enhancement has been discovered and incorporated
              into this code which also eliminated the need for a "zero" position in the cteTally table.
    **********************************************************************************************************************/
    --===== Define I/O parameters
            (@pString VARCHAR(8000), @pDelimiter CHAR(1))
    RETURNS TABLE WITH SCHEMABINDING AS
     RETURN
    --===== "Inline" CTE Driven "Tally Table" produces values from 0 up to 10,000...
         -- enough to cover NVARCHAR(4000)
      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 "base" CTE and limits the number of rows right up front
                         -- for both a performance gain and prevention of accidental "overruns"
                     SELECT TOP (ISNULL(DATALENGTH(@pString),0)) 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 1 UNION ALL
                     SELECT t.N+1 FROM cteTally t WHERE SUBSTRING(@pString,t.N,1) = @pDelimiter
                    ),
    cteLen(N1,L1) AS(--==== Return start and length (for use in substring)
                     SELECT s.N1,
                            ISNULL(NULLIF(CHARINDEX(@pDelimiter,@pString,s.N1),0)-s.N1,8000)
                       FROM cteStart s
                    )
    --===== Do the actual split. The ISNULL/NULLIF combo handles the length for the final element when no delimiter is found.
     SELECT ItemNumber = ROW_NUMBER() OVER(ORDER BY l.N1),
            Item       = SUBSTRING(@pString, l.N1, l.L1)
       FROM cteLen l;

    GO

    With that, the following works:


    if OBJECT_ID('tempdb..#answers') is not null
      drop table #answers;

    Create table #answers
    (
     id int,
     value varchar(50),
    )
    go

    INSERT INTO #answers
    VALUES(1,'1,2,3,4'),
     (2,'5,2'),
     (3,'3,4')
    GO

    if OBJECT_ID('tempdb..#lookup') is not null
      drop table #lookup;

    Create table #lookup
    (
     id int,
     text varchar(50),
    )
    go

    INSERT INTO #lookup
    VALUES(1,'txt1'),
     (2,'txt2'),
     (3,'txt3'),
     (4,'txt4'),
     (5,'txt5')
    GO

    select * from #answers
    select * from #lookup

    select
      a.*,
      ca.*
    from
      #answers a
      cross apply (select
                     stuff((select
                              ',' + l.[text]
                            from
                              #lookup l
                              inner join dbo.DelimitedSplit8K(a.[value],',') ds
                                on l.id = ds.Item
                            order by
                              ds.ItemNumber
                            for xml path(''),type).value('.','varchar(max)'),1,1,'')) ca(AnswerValue);

    You should have questions about how this works, please ask.

    it works, many thanks

  • benkraiemchedlia - Monday, March 6, 2017 12:00 AM

    Lynn Pettis - Friday, March 3, 2017 1:30 PM

    First, you need the following itvf:

    USE [Sandbox]
    GO

    /****** Object:  UserDefinedFunction [dbo].[DelimitedSplit8K]    Script Date: 3/3/2017 1:25:30 PM ******/
    SET ANSI_NULLS ON
    GO

    SET QUOTED_IDENTIFIER ON
    GO


     CREATE FUNCTION [dbo].[DelimitedSplit8K]
    /**********************************************************************************************************************
     Purpose:
     Split a given string at a given delimiter and return a list of the split elements (items).

     Notes:
     1.  Leading a trailing delimiters are treated as if an empty string element were present.
     2.  Consecutive delimiters are treated as if an empty string element were present between them.
     3.  Except when spaces are used as a delimiter, all spaces present in each element are preserved.

     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)

     Statistics on this function may be found at the following URL:
     http://www.sqlservercentral.com/Forums/Topic1101315-203-4.aspx

     CROSS APPLY Usage Examples and Tests:
    --=====================================================================================================================
    -- TEST 1:
    -- This tests for various possible conditions in a string using a comma as the delimiter.  The expected results are
    -- laid out in the comments
    --=====================================================================================================================
    --===== 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).
         -- In the following comments, "b" is a blank and "E" is an element in the left to right order.
         -- Double Quotes are used to encapsulate the output of "Item" so that you can see that all blanks
         -- are preserved no matter where they may appear.
     SELECT *
       INTO #JBMTest
       FROM (                                               --# & type of Return Row(s)
             SELECT  0, NULL                      UNION ALL --1 NULL
             SELECT  1, SPACE(0)                  UNION ALL --1 b (Empty String)
             SELECT  2, SPACE(1)                  UNION ALL --1 b (1 space)
             SELECT  3, SPACE(5)                  UNION ALL --1 b (5 spaces)
             SELECT  4, ','                       UNION ALL --2 b b (both are empty strings)
             SELECT  5, '55555'                   UNION ALL --1 E
             SELECT  6, ',55555'                  UNION ALL --2 b E
             SELECT  7, ',55555,'                 UNION ALL --3 b E b
             SELECT  8, '55555,'                  UNION ALL --2 b B
             SELECT  9, '55555,1'                 UNION ALL --2 E E
             SELECT 10, '1,55555'                 UNION ALL --2 E E
             SELECT 11, '55555,4444,333,22,1'     UNION ALL --5 E E E E E
             SELECT 12, '55555,4444,,333,22,1'    UNION ALL --6 E E b E E E
             SELECT 13, ',55555,4444,,333,22,1,'  UNION ALL --8 b E E b E E E b
             SELECT 14, ',55555,4444,,,333,22,1,' UNION ALL --9 b E E b b E E E b
             SELECT 15, ' 4444,55555 '            UNION ALL --2 E (w/Leading Space) E (w/Trailing Space)
             SELECT 16, 'This,is,a,test.'                   --E E E E
            ) d (SomeID, SomeValue)
    ;
    --===== Split the CSV column for the whole table using CROSS APPLY (this is the solution)
     SELECT test.SomeID, test.SomeValue, split.ItemNumber, Item = QUOTENAME(split.Item,'"')
       FROM #JBMTest test
      CROSS APPLY dbo.DelimitedSplit8K(test.SomeValue,',') split
    ;
    --=====================================================================================================================
    -- TEST 2:
    -- This tests for various "alpha" splits and COLLATION using all ASCII characters from 0 to 255 as a delimiter against
    -- a given string.  Note that not all of the delimiters will be visible and some will show up as tiny squares because
    -- they are "control" characters.  More specifically, this test will show you what happens to various non-accented
    -- letters for your given collation depending on the delimiter you chose.
    --=====================================================================================================================
    WITH
    cteBuildAllCharacters (String,Delimiter) AS
    (
     SELECT TOP 256
            'ABCDEFGHIJKLMNOPQRSTUVWXYZabcdefghijklmnopqrstuvwxyz0123456789',
            CHAR(ROW_NUMBER() OVER (ORDER BY (SELECT NULL))-1)
       FROM master.sys.all_columns
    )
     SELECT ASCII_Value = ASCII(c.Delimiter), c.Delimiter, split.ItemNumber, Item = QUOTENAME(split.Item,'"')
       FROM cteBuildAllCharacters c
      CROSS APPLY dbo.DelimitedSplit8K(c.String,c.Delimiter) split
      ORDER BY ASCII_Value, split.ItemNumber
    ;
    -----------------------------------------------------------------------------------------------------------------------
     Other 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 resolvedexternally 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 NVARCHAR(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.
    -----------------------------------------------------------------------------------------------------------------------
     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 and for his detailed testing efforts. Last but not least, thanks to
     Ron "BitBucket" McCullough and Wayne Sheffield for their extreme performance testing across multiple machines and
     versions of SQL Server.  The latest improvement brought an additional 15-20% improvement over Rev 05.  Special thanks
     to "Nadrek" and "peter-757102" (aka Peter de Heer) for bringing such improvements to light.  Nadrek's original
     improvement brought about a 10% performance gain and Peter followed that up with the content of Rev 07. 

     I also thank whoever wrote the first article I ever saw on "numbers tables" which is located at the following URL
     and to Adam Machanic for leading me to it many years ago.
     http://sqlserver2000.databases.aspfaq.com/why-should-i-consider-using-an-auxiliary-numbers-table.html
    -----------------------------------------------------------------------------------------------------------------------
     Revision History:
     Rev 00 - 20 Jan 2010 - Concept for inline cteTally: 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 don't 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 on the usage example, etc.
            - Removed "other" notes 8 and 9 as they were no longer applicable.

     Rev 06 - 12 Apr 2011 - Jeff Moden
            - Based on a suggestion by Ron "Bitbucket" McCullough, additional test rows were added to the sample code and
              the code was changed to encapsulate the output in pipes so that spaces and empty strings could be perceived
              in the output.  The first "Notes" section was added.  Finally, an extra test was added to the comments above.

     Rev 07 - 06 May 2011 - Peter de Heer, a further 15-20% performance enhancement has been discovered and incorporated
              into this code which also eliminated the need for a "zero" position in the cteTally table.
    **********************************************************************************************************************/
    --===== Define I/O parameters
            (@pString VARCHAR(8000), @pDelimiter CHAR(1))
    RETURNS TABLE WITH SCHEMABINDING AS
     RETURN
    --===== "Inline" CTE Driven "Tally Table" produces values from 0 up to 10,000...
         -- enough to cover NVARCHAR(4000)
      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 "base" CTE and limits the number of rows right up front
                         -- for both a performance gain and prevention of accidental "overruns"
                     SELECT TOP (ISNULL(DATALENGTH(@pString),0)) 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 1 UNION ALL
                     SELECT t.N+1 FROM cteTally t WHERE SUBSTRING(@pString,t.N,1) = @pDelimiter
                    ),
    cteLen(N1,L1) AS(--==== Return start and length (for use in substring)
                     SELECT s.N1,
                            ISNULL(NULLIF(CHARINDEX(@pDelimiter,@pString,s.N1),0)-s.N1,8000)
                       FROM cteStart s
                    )
    --===== Do the actual split. The ISNULL/NULLIF combo handles the length for the final element when no delimiter is found.
     SELECT ItemNumber = ROW_NUMBER() OVER(ORDER BY l.N1),
            Item       = SUBSTRING(@pString, l.N1, l.L1)
       FROM cteLen l;

    GO

    With that, the following works:


    if OBJECT_ID('tempdb..#answers') is not null
      drop table #answers;

    Create table #answers
    (
     id int,
     value varchar(50),
    )
    go

    INSERT INTO #answers
    VALUES(1,'1,2,3,4'),
     (2,'5,2'),
     (3,'3,4')
    GO

    if OBJECT_ID('tempdb..#lookup') is not null
      drop table #lookup;

    Create table #lookup
    (
     id int,
     text varchar(50),
    )
    go

    INSERT INTO #lookup
    VALUES(1,'txt1'),
     (2,'txt2'),
     (3,'txt3'),
     (4,'txt4'),
     (5,'txt5')
    GO

    select * from #answers
    select * from #lookup

    select
      a.*,
      ca.*
    from
      #answers a
      cross apply (select
                     stuff((select
                              ',' + l.[text]
                            from
                              #lookup l
                              inner join dbo.DelimitedSplit8K(a.[value],',') ds
                                on l.id = ds.Item
                            order by
                              ds.ItemNumber
                            for xml path(''),type).value('.','varchar(max)'),1,1,'')) ca(AnswerValue);

    You should have questions about how this works, please ask.

    it works, many thanks

    Okay, I waiting a bit but now I need to ask you a question.  Do you understand how it works?  I ask this as if it fails in the future or needs tweaking to meet changing requirements, you will be responsible for making those fixes or changes.  When I posted the solution, I expected you to have questions.

  • benkraiemchedlia - Friday, March 3, 2017 12:39 PM

    Hi, 
    I have two tables, answers and lookup, In my answer table I have a field named: value, it my contain many values separated by comma example value = '22,1,3', theses values are the id of the lookup table.
    my lookup table are the text describing the answer.
    the issue is that I couldn't bring all the text of the id's, I just bring one text value.
    This is my code, 

    Create table #answers
    (
    id int,
    value varchar(50),
    )
    go

    INSERT INTO #answers
    VALUES(1,'1,2,3,4,'),
    (2,'5,2,'),
    (3,'3,4,')
    GO

    Create table #lookup
    (
    id int,
    text varchar(50),
    )
    go

    INSERT INTO #lookup
    VALUES(1,'txt1'),
    (2,'txt2'),
    (3,'txt3'),
    (4,'txt4'),
    (5,'txt5'),
    GO
    select ans.id as AnswerID, look.text as AnswerValue from #answers as ans
    innerjoin #lookup as look
    on look.id = substring(ans.value, 1,charindex(',',ans.value,1)-1)[/code]

    the expected result is :
     https://www.sqlservercentral.com/Forums/Uploads/Images/e9a0c9a9-3b02-4990-a4d7-4692.PNG

    Thank you.

    Try below code to get the expected result:

    select id,
                 (
                    select AnsValue
                            =
                            stuff((select ',' + l.text
                            from #lookup l
                            where a.value like '%'+cast(l.id as varchar(2))+'%'
                            for xml path('')
                            ),1,1,'')
                 ) AS AnsValue
    from #answers a

Viewing 12 posts - 1 through 11 (of 11 total)

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