Click here to monitor SSC
SQLServerCentral is supported by Red Gate Software Ltd.
 
Log in  ::  Register  ::  Not logged in
 
 
 
        
Home       Members    Calendar    Who's On


Add to briefcase

How can i loop thru data based on dynamic parameter passed to sp Expand / Collapse
Author
Message
Posted Sunday, February 16, 2014 1:28 AM
Forum Newbie

Forum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum Newbie

Group: General Forum Members
Last Login: Monday, July 28, 2014 2:00 AM
Points: 1, Visits: 55
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
Post #1541892
Posted Sunday, February 16, 2014 4:48 AM


SSC-Enthusiastic

SSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-Enthusiastic

Group: General Forum Members
Last Login: Today @ 7:27 AM
Points: 158, Visits: 627
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!
Post #1541895
Posted Sunday, February 16, 2014 4:05 PM


SSC-Dedicated

SSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-Dedicated

Group: General Forum Members
Last Login: Today @ 7:20 PM
Points: 37,088, Visits: 31,645
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."

(play on words) "Just because you CAN do something in T-SQL, doesn't mean you SHOULDN'T." --22 Aug 2013

Helpful Links:
How to post code problems
How to post performance problems
Post #1541940
« Prev Topic | Next Topic »

Add to briefcase

Permissions Expand / Collapse