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

Is it possible to use a parameter for csv values Expand / Collapse
Author
Message
Posted Wednesday, March 19, 2014 4:22 AM
SSC Veteran

SSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC Veteran

Group: General Forum Members
Last Login: Friday, November 14, 2014 9:44 AM
Points: 251, Visits: 664
I have a query ending with
WHERE MyID IN (12, 14, 18)
and want to replace it by a parameter like
WHERE MyID IN @Param
or
WHERE MyID IN (@PARAM).

Is it possible to use a parameter for this situation?
And what would be the type of it, a VARCHAR?



Post #1552527
Posted Wednesday, March 19, 2014 4:39 AM
SSCrazy

SSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazy

Group: General Forum Members
Last Login: Today @ 12:22 PM
Points: 2,125, Visits: 5,544
The only way to do it is to make it as dynamic SQL. Notice that this will cause concerns about security (permissions issues and SQL injection). If you'll write a little bit more about your problem, maybe someone here will be able to offer you a better design.

Adi


--------------------------------------------------------------
To know how to ask questions and increase the chances of getting asnwers:
http://www.sqlservercentral.com/articles/Best+Practices/61537/

For better answers on performance questions, click on the following...
http://www.sqlservercentral.com/articles/SQLServerCentral/66909/
Post #1552534
Posted Wednesday, March 19, 2014 5:05 AM
SSC Veteran

SSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC Veteran

Group: General Forum Members
Last Login: Friday, November 14, 2014 9:44 AM
Points: 251, Visits: 664
Adi, thank you for you answer.
When I have to use dynamic sql, security is no problem, because it's an "in the house" job, used for reporting.
But I was hoping for better solution, where the user could give an "array of numbers" for choosing the items used in the report.



Post #1552547
Posted Wednesday, March 19, 2014 5:33 AM This worked for the OP Answer marked as solution
SSCarpal Tunnel

SSCarpal TunnelSSCarpal TunnelSSCarpal TunnelSSCarpal TunnelSSCarpal TunnelSSCarpal TunnelSSCarpal TunnelSSCarpal TunnelSSCarpal Tunnel

Group: General Forum Members
Last Login: Today @ 1:43 PM
Points: 4,442, Visits: 3,884
Another approach is to convert the list into a table and then run your query against the table. Here's an example using @strParams as your passed parameter string.

declare @strParams varchar(100) = '1,14,65,234,16443,145,1669,2';

select column_list
from table_name
where exists (select 1
from DelimitedSplit8K(@strParams, ',') s
where s.Item = table_name.some_id_field);

If you haven't used Jeff Moden's string splitter, I highly recommend it. It'll change the way you look at strings and your expectation of performance. It is at http://www.sqlservercentral.com/articles/Tally+Table/72993/.



Tally Tables - Performance Personified
String Splitting with True Performance
Best practices on how to ask questions
Post #1552564
Posted Wednesday, March 19, 2014 9:11 AM


SSC-Dedicated

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

Group: General Forum Members
Last Login: Today @ 3:36 PM
Points: 35,531, Visits: 32,114
Ed Wagner (3/19/2014)
Another approach is to convert the list into a table and then run your query against the table. Here's an example using @strParams as your passed parameter string.

declare @strParams varchar(100) = '1,14,65,234,16443,145,1669,2';

select column_list
from table_name
where exists (select 1
from DelimitedSplit8K(@strParams, ',') s
where s.Item = table_name.some_id_field);

If you haven't used Jeff Moden's string splitter, I highly recommend it. It'll change the way you look at strings and your expectation of performance. It is at http://www.sqlservercentral.com/articles/Tally+Table/72993/.


To add to that, the method above will make it impossible for an SQL Injection attack.


--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 #1552667
Posted Friday, March 21, 2014 2:29 AM
SSC Veteran

SSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC Veteran

Group: General Forum Members
Last Login: Friday, November 14, 2014 9:44 AM
Points: 251, Visits: 664
Ad and Jeff, thanks for your answer.
The solution presented in this article is superb.
But before I could implement it (I had to make a Tally table and the function) the user decided to another outcome (in an Excel report). I had to add an extra column with the parameter numbers in it. So the user could select the wanted numbers in Excel in stead of in a given parameter-list.
So I didn't use the given solution. But next time I will



Post #1553349
Posted Friday, March 21, 2014 5:49 AM
SSCarpal Tunnel

SSCarpal TunnelSSCarpal TunnelSSCarpal TunnelSSCarpal TunnelSSCarpal TunnelSSCarpal TunnelSSCarpal TunnelSSCarpal TunnelSSCarpal Tunnel

Group: General Forum Members
Last Login: Today @ 1:43 PM
Points: 4,442, Visits: 3,884
Henk Schreij (3/21/2014)
Ad and Jeff, thanks for your answer.
The solution presented in this article is superb.
But before I could implement it (I had to make a Tally table and the function) the user decided to another outcome (in an Excel report). I had to add an extra column with the parameter numbers in it. So the user could select the wanted numbers in Excel in stead of in a given parameter-list.
So I didn't use the given solution. But next time I will

Glad we could help. You know, now that you have the Tally table and the DelimitedSplit8K function, take some time to play around and get used to it. I've heard it described as the "Swiss Army Knife of SQL" by some people. It really does lend itself to some very high performance code. It's another tool you can keep in your toolbox for when you need it.



Tally Tables - Performance Personified
String Splitting with True Performance
Best practices on how to ask questions
Post #1553440
« Prev Topic | Next Topic »

Add to briefcase

Permissions Expand / Collapse