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 ««12345»»»

Parsing Parameters in a Stored Procedure Expand / Collapse
Author
Message
Posted Tuesday, August 10, 2010 6:30 AM
Forum Newbie

Forum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum Newbie

Group: General Forum Members
Last Login: Tuesday, September 28, 2010 5:55 PM
Points: 5, Visits: 11
Nice article to provide help for parsing delimited values, but I like better XML version provided by some user in the comments which is simpler but maybe more resource consuming.
But my question is why this article has title :parsing stored procedure parameters if you just looking for specific switch value in single parameter? You are not looking for pair Name=Value, just for values. Could you provide example how you use values received from your parsing process? Because maybe all your work is not really required if you next do something based on your parsed values using for example CASE statement with fixed values and you have to do word search again later in he code.
Could you provide example of usage of parameter values received from your parse routine?
Post #966611
Posted Tuesday, August 10, 2010 6:33 AM


SSC-Dedicated

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

Group: General Forum Members
Last Login: Today @ 1:31 PM
Points: 35,372, Visits: 31,918
jcboyer-1091017 (8/10/2010)
I have been using an XML string to achieve the same results. Not sure that it is faster, but it is quite flexible as:

EXEC sp_xml_preparedocument @idoc OUTPUT, @XMLParameters
insert into #T
select *
FROM OPENXML (@idoc, '/OrderGroup/Item', 1)
WITH #T
EXEC sp_xml_removedocument @idoc

In this example #T is a large table with over 20 columns. @XMLParameters is varchar(max) to pass as many rows as necessary at once, which is and added bonus, because there is still no Table as parameter. (I am using varchar instead of XML because XML is more strict and we do not need this here.)

Comments on this approach are welcome.

Jerome


Hi Jerome,

Can you provide an example of what the content of @XMLParameters would be for your code? I don't want to presume. Thanks.


--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 #966614
Posted Tuesday, August 10, 2010 6:53 AM


SSCarpal Tunnel

SSCarpal TunnelSSCarpal TunnelSSCarpal TunnelSSCarpal TunnelSSCarpal TunnelSSCarpal TunnelSSCarpal TunnelSSCarpal TunnelSSCarpal Tunnel

Group: General Forum Members
Last Login: Today @ 9:57 AM
Points: 4,406, Visits: 6,270
Didn't we have a MASSIVE thread here on SSC.com on string parsing, with amazing code samples and wonderful benchmarks??

Best,

Kevin G. Boles
SQL Server Consultant
SQL MVP 2007-2012
TheSQLGuru at GMail
Post #966640
Posted Tuesday, August 10, 2010 6:53 AM


SSC-Dedicated

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

Group: General Forum Members
Last Login: Today @ 1:31 PM
Points: 35,372, Visits: 31,918
I'm torn. The article is well written and the code examples are pertinent to the article. However...

It was a quick read I did through the article so I may have missed something, but I didn't see anywhere where non-validated "elements" in the input string were handled. I saw where an "alert" was created if there were no matches, but didn't see anywhere individual elements would produce an alert if the existed.

For all of you good folks using XML to split things... I suppose that XML either does something special for you or that your consider its performance to be good enough. Just be aware that there are faster methods than XML... sometimes a lot faster.

Last but not least, this reminds me of the old "LIKE" method which also failed to notify if a single element of a parameter could not be validated with the only difference being that the validation list is table driven instead of built into code.

I'll try to post some test code tonight to show all of what I believe can happen with the code from the article. I might even have time to show why I don't use XML splitter code.


--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 #966641
Posted Tuesday, August 10, 2010 7:00 AM
Forum Newbie

Forum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum Newbie

Group: General Forum Members
Last Login: Friday, November 26, 2010 7:47 AM
Points: 5, Visits: 68
There is a cute solution which i borrowed from some articles about Tallys on this Web-Site.
Check this out: http://www.sqlservercentral.com/articles/T-SQL/63003/

Here is how i implemented:

1. Create a Tally table. This is simple table with one Column N, which contains (for instance) numbers from 1 to 11000.

--Create a Tally Table

--===== Create and populate the Tally table on the fly SELECT TOP 11000 --equates to more than 30 years of dates IDENTITY(INT,1,1) AS N INTO dbo.Tally FROM Master.dbo.SysColumns sc1, Master.dbo.SysColumns sc2

--===== Add a Primary Key to maximize performance ALTER TABLE dbo.Tally ADD CONSTRAINT PK_Tally_N PRIMARY KEY CLUSTERED (N) WITH FILLFACTOR = 100

--===== Allow the general public to use it GRANT SELECT ON dbo.Tally TO PUBLIC



2. Create a parsing function:

create function [dbo].[FUNC_TBL_TEXT_IN_COL]
(
@Numbers varchar(max)
,@Delimiter char
) returns table

as

return SELECT SUBSTRING(@Delimiter+@Numbers+@Delimiter,N+1,CHARINDEX(@Delimiter,@Delimiter+@Numbers+@Delimiter,N+1)-N-1) as X
FROM dbo.Tally
WHERE N < LEN(@Delimiter+@Numbers+@Delimiter)
AND SUBSTRING(@Delimiter+@Numbers+@Delimiter,N,1) = @Delimiter

3. Run an example:

select X
from [dbo].[FUNC_TBL_TEXT_IN_COL]
(
'Jones,Schneider,68,whatever',','
)

Result is:

X
----
Jones
Schneider
68
whatever
Post #966649
Posted Tuesday, August 10, 2010 7:06 AM


SSC-Dedicated

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

Group: General Forum Members
Last Login: Today @ 1:31 PM
Points: 35,372, Visits: 31,918
Be careful with the code in the article. Be aware that it doesn't do full validation. It only evaluates what's right and give no indication as to what is wrong. If that's good for you, so be it (although I believe there are better ways). Just make sure it's good for you.

The following example has been copied from the article code. "XX" has been added to the parameter. See for yourself that "XX" produces no error and no alert because "XX" isn't even considered in the validation.

-- Imagine this table exists previously in your database ----
Declare @T_STATES table ( state char(2) )

Insert @T_STATES Values ( 'AZ' )
Insert @T_STATES Values ( 'CA' )
Insert @T_STATES Values ( 'MT' )
Insert @T_STATES Values ( 'TX' )
Insert @T_STATES Values ( 'WA' )
Insert @T_STATES Values ( 'TS' )

-- Suppose this is the parameter ----
Declare @sParameter varchar(8000)
Set @sParameter = 'WA,AZ,CA,TS,XX' --<<< Code doesn't catch the invalid parameter

Declare @tStates table ( state char(2) )

Insert @tStates
Select state
From @T_STATES
Where CharIndex( state, @sParameter ) > 0

Select *
From @tStates


Even the final bit of code doesn't catch the fact that an invalid element was passed...

-- Imagine this table exists previously in your database ----
Declare @T_STATES table ( state char(2) )

Insert @T_STATES Values ( 'AZ' )
Insert @T_STATES Values ( 'CA' )
Insert @T_STATES Values ( 'MT' )
Insert @T_STATES Values ( 'TX' )
Insert @T_STATES Values ( 'WA' )
Insert @T_STATES Values ( 'TS' )

-- Suppose this is the parameter ----
Declare @sParameter varchar(8000)
Set @sParameter = 'WA,AZ,CA,TS,XX' --<<< Code doesn't catch the invalid parameter

Declare @tStates table ( state char(2) )

Insert @tStates
Select state
From @T_STATES
Where CharIndex( state, @sParameter ) > 0

If @@RowCount < 1
Begin
Select 'No matches. Valid values are:' As InfoMessage
Union All
Select state
From @T_STATES
Return
End




--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 #966656
Posted Tuesday, August 10, 2010 7:21 AM
Forum Newbie

Forum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum Newbie

Group: General Forum Members
Last Login: Monday, March 3, 2014 4:39 AM
Points: 6, Visits: 49
something like:
set @XMLParameters =
'<OrderGroup>
<Item TargetPrinterType="DIAMOND_X" GroupStatus="ACTIVE_cc" ReferenceNo="Joe" />
</OrderGroup>'
Post #966669
Posted Tuesday, August 10, 2010 7:22 AM
Forum Newbie

Forum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum Newbie

Group: General Forum Members
Last Login: Thursday, October 9, 2014 12:37 PM
Points: 9, Visits: 146
With SQL2008 you do have the option of a table variable. I was using XML and found that the table variable provided all the flexibility but was much faster.
Post #966671
Posted Tuesday, August 10, 2010 7:24 AM


SSC-Dedicated

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

Group: General Forum Members
Last Login: Today @ 1:31 PM
Points: 35,372, Visits: 31,918
tom.groszko (8/10/2010)
With SQL2008 you do have the option of a table variable. I was using XML and found that the table variable provided all the flexibility but was much faster.


Any chance of you posting some code that others can run to demonstrate that?


--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 #966673
Posted Tuesday, August 10, 2010 7:26 AM


SSC-Dedicated

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

Group: General Forum Members
Last Login: Today @ 1:31 PM
Points: 35,372, Visits: 31,918
jcboyer-1091017 (8/10/2010)
something like:
set @XMLParameters =
'<OrderGroup>
<Item TargetPrinterType="DIAMOND_X" GroupStatus="ACTIVE_cc" ReferenceNo="Joe" />
</OrderGroup>'


Thanks, Jerome...


--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 #966676
« Prev Topic | Next Topic »

Add to briefcase ««12345»»»

Permissions Expand / Collapse