How can i loop thru data based on dynamic parameter passed to sp

  • i have an sp and passing values like 'xxx~yyy', '10~12~15', '1~2~7' and i have to loop thru the data to get the resultset

    i need to loop thru like

    1. xxx-10-1

    2. xxx-10-2

    3. xxx-10-7

    4. xxx-12-1

    5. xxx-12-2

    6. xxx-12-7

    ...................

    ...................

    yyy-15-1

    yyy-15-2

    yyy-15-7

    how to acheive this with in sp

  • First you can create a function converting a string to table. For instance you can use this one:

    CREATE FUNCTION dbo.StringToTable

    (

    @Input NVARCHAR (4000),

    @Delimiter NVARCHAR(1)

    )

    RETURNS @OutputTable TABLE (val NVARCHAR(50))

    AS

    BEGIN

    DECLARE @val NVARCHAR(50);

    WHILE LEN(@Input) > 0

    BEGIN

    SET @val = LEFT(@Input, ISNULL(NULLIF(CHARINDEX(@Delimiter, @Input) - 1, -1), LEN(@Input)));

    SET @Input = SUBSTRING(@Input, ISNULL(NULLIF(CHARINDEX(@Delimiter, @Input), 0), LEN(@Input)) + 1, LEN(@Input));

    INSERT INTO @OutputTable (val) VALUES (@val);

    END

    RETURN

    END

    GO

    Let's write a query which uses this function and generate the result you want to see:

    DECLARE @P1 AS NVARCHAR(100) = N'xxx~yyy',

    @P2 AS NVARCHAR(100) = N'10~12~15',

    @P3 AS NVARCHAR(100) = N'1~2~7';

    SELECT

    ROW_NUMBER() OVER( ORDER BY t1.val, t2.val, t3.val) AS rn, *

    FROM dbo.StringToTable(@P1, N'~') AS t1

    CROSS JOIN dbo.StringToTable(@P2, N'~') AS t2

    CROSS JOIN dbo.StringToTable(@P3, N'~') AS t3

    ___________________________
    Do Not Optimize for Exceptions!

  • milos.radivojevic (2/16/2014)


    First you can create a function converting a string to table. For instance you can use this one:

    CREATE FUNCTION dbo.StringToTable

    (

    @Input NVARCHAR (4000),

    @Delimiter NVARCHAR(1)

    )

    RETURNS @OutputTable TABLE (val NVARCHAR(50))

    AS

    BEGIN

    DECLARE @val NVARCHAR(50);

    WHILE LEN(@Input) > 0

    BEGIN

    SET @val = LEFT(@Input, ISNULL(NULLIF(CHARINDEX(@Delimiter, @Input) - 1, -1), LEN(@Input)));

    SET @Input = SUBSTRING(@Input, ISNULL(NULLIF(CHARINDEX(@Delimiter, @Input), 0), LEN(@Input)) + 1, LEN(@Input));

    INSERT INTO @OutputTable (val) VALUES (@val);

    END

    RETURN

    END

    GO

    Let's write a query which uses this function and generate the result you want to see:

    DECLARE @P1 AS NVARCHAR(100) = N'xxx~yyy',

    @P2 AS NVARCHAR(100) = N'10~12~15',

    @P3 AS NVARCHAR(100) = N'1~2~7';

    SELECT

    ROW_NUMBER() OVER( ORDER BY t1.val, t2.val, t3.val) AS rn, *

    FROM dbo.StringToTable(@P1, N'~') AS t1

    CROSS JOIN dbo.StringToTable(@P2, N'~') AS t2

    CROSS JOIN dbo.StringToTable(@P3, N'~') AS t3

    Good solution and great use of CROSS JOIN.

    Just a comment on the splitter function. I strongly recommend against using a WHILE loop for splitting especially if it's going to be something common place. Please see the following article for some performance tests among splitting methods. The method you have above is known as a "Nibbler".

    http://www.sqlservercentral.com/articles/Tally+Table/72993/

    If you can't use the SQLCLR method for something like this, then the UDF in the article will provide a close second for performance for anything 8K or less. Here's one of performance charts from the article. The skinny black line is the performance before the function was increased in performance by another 10-15% by a suggestion in the discussions that followed the article. As it was, the new function is about 3 times faster than either type of WHILE loop solution. Of course, the SQLCLR is more than twice as fast as even the new solution (again, the skinny black line).

    --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 3 posts - 1 through 2 (of 2 total)

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