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


Is it possible to use a parameter for csv values


Is it possible to use a parameter for csv values

Author
Message
Henk Schreij
Henk Schreij
Ten Centuries
Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)

Group: General Forum Members
Points: 1134 Visits: 840
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?



Adi Cohn
Adi Cohn
SSCertifiable
SSCertifiable (7.7K reputation)SSCertifiable (7.7K reputation)SSCertifiable (7.7K reputation)SSCertifiable (7.7K reputation)SSCertifiable (7.7K reputation)SSCertifiable (7.7K reputation)SSCertifiable (7.7K reputation)SSCertifiable (7.7K reputation)

Group: General Forum Members
Points: 7689 Visits: 6594
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/
Henk Schreij
Henk Schreij
Ten Centuries
Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)

Group: General Forum Members
Points: 1134 Visits: 840
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.



Ed Wagner
Ed Wagner
SSC-Forever
SSC-Forever (43K reputation)SSC-Forever (43K reputation)SSC-Forever (43K reputation)SSC-Forever (43K reputation)SSC-Forever (43K reputation)SSC-Forever (43K reputation)SSC-Forever (43K reputation)SSC-Forever (43K reputation)

Group: General Forum Members
Points: 43898 Visits: 10831
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
Jeff Moden
Jeff Moden
SSC Guru
SSC Guru (203K reputation)SSC Guru (203K reputation)SSC Guru (203K reputation)SSC Guru (203K reputation)SSC Guru (203K reputation)SSC Guru (203K reputation)SSC Guru (203K reputation)SSC Guru (203K reputation)

Group: General Forum Members
Points: 203096 Visits: 41947
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.
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
Henk Schreij
Henk Schreij
Ten Centuries
Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)

Group: General Forum Members
Points: 1134 Visits: 840
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 ;-)



Ed Wagner
Ed Wagner
SSC-Forever
SSC-Forever (43K reputation)SSC-Forever (43K reputation)SSC-Forever (43K reputation)SSC-Forever (43K reputation)SSC-Forever (43K reputation)SSC-Forever (43K reputation)SSC-Forever (43K reputation)SSC-Forever (43K reputation)

Group: General Forum Members
Points: 43898 Visits: 10831
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
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