SQL Clone
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


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


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

Author
Message
charlesirwincbe
charlesirwincbe
Forum Newbie
Forum Newbie (1 reputation)Forum Newbie (1 reputation)Forum Newbie (1 reputation)Forum Newbie (1 reputation)Forum Newbie (1 reputation)Forum Newbie (1 reputation)Forum Newbie (1 reputation)Forum Newbie (1 reputation)

Group: General Forum Members
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
milos.radivojevic
milos.radivojevic
SSC Veteran
SSC Veteran (267 reputation)SSC Veteran (267 reputation)SSC Veteran (267 reputation)SSC Veteran (267 reputation)SSC Veteran (267 reputation)SSC Veteran (267 reputation)SSC Veteran (267 reputation)SSC Veteran (267 reputation)

Group: General Forum Members
Points: 267 Visits: 774
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!
Jeff Moden
Jeff Moden
SSC Guru
SSC Guru (91K reputation)SSC Guru (91K reputation)SSC Guru (91K reputation)SSC Guru (91K reputation)SSC Guru (91K reputation)SSC Guru (91K reputation)SSC Guru (91K reputation)SSC Guru (91K reputation)

Group: General Forum Members
Points: 91374 Visits: 41151
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.
If you think its expensive to hire a professional to do the job, wait until you hire an amateur. -- Red Adair

Helpful Links:
How to post code problems
How to post performance problems
Forum FAQs
Go


Permissions

You can't post new topics.
You can't post topic replies.
You can't post new polls.
You can't post replies to polls.
You can't edit your own topics.
You can't delete your own topics.
You can't edit other topics.
You can't delete other topics.
You can't edit your own posts.
You can't edit other posts.
You can't delete your own posts.
You can't delete other posts.
You can't post events.
You can't edit your own events.
You can't edit other events.
You can't delete your own events.
You can't delete other events.
You can't send private messages.
You can't send emails.
You can read topics.
You can't vote in polls.
You can't upload attachments.
You can download attachments.
You can't post HTML code.
You can't edit HTML code.
You can't post IFCode.
You can't post JavaScript.
You can post emoticons.
You can't post or upload images.

Select a forum

































































































































































SQLServerCentral


Search