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


Making Dynamic Queries Static


Making Dynamic Queries Static

Author
Message
Leon Platt
Leon Platt
SSC Veteran
SSC Veteran (275 reputation)SSC Veteran (275 reputation)SSC Veteran (275 reputation)SSC Veteran (275 reputation)SSC Veteran (275 reputation)SSC Veteran (275 reputation)SSC Veteran (275 reputation)SSC Veteran (275 reputation)

Group: General Forum Members
Points: 275 Visits: 1
Comments posted to this topic are about the content posted at http://www.sqlservercentral.com/columnists/lplatt/makingdynamicqueriesstatic.asp



jodiem
jodiem
Valued Member
Valued Member (66 reputation)Valued Member (66 reputation)Valued Member (66 reputation)Valued Member (66 reputation)Valued Member (66 reputation)Valued Member (66 reputation)Valued Member (66 reputation)Valued Member (66 reputation)

Group: General Forum Members
Points: 66 Visits: 1
Thanks for the article, it is very useful.
I would love to see your > solution and can I ask for a between solution also.
This is the query that I'm trying to do at the moment:

I need a query that does both And's or Ors and works on multiple tables. Eg the query is about house features The Square foot is stored in one table The rooms are stored in another table The features are stored in another table again (Similar to your scenario in your article).

The user wants to query a house that is between 2000 and 3000 square foot, with 3 bathrooms (from the rooms table) and with the following features eg porch, fireplace (each stored as a record in the features table)

That was the simplified version, I would love to be able to expand it to query other things that we store about the houses.

Jodie



Robert W Marda
Robert W Marda
SSCrazy
SSCrazy (2.9K reputation)SSCrazy (2.9K reputation)SSCrazy (2.9K reputation)SSCrazy (2.9K reputation)SSCrazy (2.9K reputation)SSCrazy (2.9K reputation)SSCrazy (2.9K reputation)SSCrazy (2.9K reputation)

Group: General Forum Members
Points: 2855 Visits: 113
One way to modify solution 2 to work with the mentioned operators (=, <>, > , <, IN) is to create the WHERE clause like this:

WHERE (A.name = @Aname or @Aname = '') and (C.firstName like @Cfirst or @Cfirst = '') and (C.lastName like @Clast or @Clast = '') and (D.city like @city or @city = '') and (D.state = @state or D.state = '') and (D.phone like @phone or @phone = '')

This solution removes the assumption that a NULL record is included. It also means that if you do not want to limit the result set by a city name simply send in @city = '' and that part of the WHERE clause will be completely ignored. It will just limit the result set on all other parameters that are not equal to ''.

Robert Marda

Robert W. Marda
Billing and OSS Specialist - SQL Programmer
MCL Systems
steven powell
steven powell
SSC Veteran
SSC Veteran (229 reputation)SSC Veteran (229 reputation)SSC Veteran (229 reputation)SSC Veteran (229 reputation)SSC Veteran (229 reputation)SSC Veteran (229 reputation)SSC Veteran (229 reputation)SSC Veteran (229 reputation)

Group: General Forum Members
Points: 229 Visits: 2
here's one way to solve the problem posed by soln. number two

and isnull(ColumnOne, '%') like @pSearchArg

to use other operators (=, > etc.) try something like

and ColumnOne = insnull(@pSearchArg, ColumnOne)

the optimiser can still use an index on ColumnOne if there is one



Andy Jones, DBA
Andy Jones, DBA
UDP Broadcaster
UDP Broadcaster (1.5K reputation)UDP Broadcaster (1.5K reputation)UDP Broadcaster (1.5K reputation)UDP Broadcaster (1.5K reputation)UDP Broadcaster (1.5K reputation)UDP Broadcaster (1.5K reputation)UDP Broadcaster (1.5K reputation)UDP Broadcaster (1.5K reputation)

Group: General Forum Members
Points: 1499 Visits: 552
Hi, how about :-

SELECT
*
from
account A
inner Join Contact C on a.primarykey=c.accountkey
inner join Address D on A.primarykey=D.foreignkey
WHERE
case
when @Aname is null then A.Name
else @Aname
end = A.Name
and
case
when @Cfirst is null then C.firstName
else @Cfirst
end = C.firstName
and
case
when @Clast is null then C.lastName
else @Clast
end = C.lastName
and
case
when @city is null then D.city
else @city
end = D.city
and
case
when @state is null then D.state
else @state
end = D.state
and
case
when @phone is null then D.phone
else @phone
end = D.phone

Andy
andyj93@hotmail.com

.
Lee Dise
Lee Dise
SSC Eights!
SSC Eights! (974 reputation)SSC Eights! (974 reputation)SSC Eights! (974 reputation)SSC Eights! (974 reputation)SSC Eights! (974 reputation)SSC Eights! (974 reputation)SSC Eights! (974 reputation)SSC Eights! (974 reputation)

Group: General Forum Members
Points: 974 Visits: 21
The only time you absolutely need to use dynamic SQL is when, at compile time, you do not know the names of the database or the database objects against which your query will execute.

WHERE criteria do not count: As the author pointed out, there are ways to construct a WHERE clause to go this way or that depending upon whether a parameter value is missing.

It's the FROM clause that makes dynamic SQL essential. If, for example, I wish to write a procedure that performs a query against system tables, and I want at run time to specify which database I'm querying. The only way to turn the database name into a variable is through dynamic SQL. Or if your database contains two or more tables having the same or similar structure, and again you won't know until run-time which tables are to be queried... this is a job for dynamic SQL.



RyanRandall
RyanRandall
SSCarpal Tunnel
SSCarpal Tunnel (4.1K reputation)SSCarpal Tunnel (4.1K reputation)SSCarpal Tunnel (4.1K reputation)SSCarpal Tunnel (4.1K reputation)SSCarpal Tunnel (4.1K reputation)SSCarpal Tunnel (4.1K reputation)SSCarpal Tunnel (4.1K reputation)SSCarpal Tunnel (4.1K reputation)

Group: General Forum Members
Points: 4129 Visits: 4652
I guess you could change your FROM situation to a WHERE situation by creating a view of the union of your similar tables (together with a flag to indicate where they're from).

This would, of course, have other implications.

Ryan Randall

Solutions are easy. Understanding the problem, now, that's the hard part.
toddbkc
toddbkc
SSC Journeyman
SSC Journeyman (86 reputation)SSC Journeyman (86 reputation)SSC Journeyman (86 reputation)SSC Journeyman (86 reputation)SSC Journeyman (86 reputation)SSC Journeyman (86 reputation)SSC Journeyman (86 reputation)SSC Journeyman (86 reputation)

Group: General Forum Members
Points: 86 Visits: 261
I have had good luck using the OR statement instead of LIKE. Often, I find that the LIKE statement doesn't always like to read the index.

So, when I do this, the statement looks like:
select * from table1
where (@first_name IS NULL or first_name = @first_name)
and (@last_name IS NULL or last_name = @last_name) etc...

I've found really great performance overall in the majority of cases. Of course, this doesn't handle if you really wanted the LIKE statement, but often I am looking for an exact match.

Todd


Todd
Leon Platt
Leon Platt
SSC Veteran
SSC Veteran (275 reputation)SSC Veteran (275 reputation)SSC Veteran (275 reputation)SSC Veteran (275 reputation)SSC Veteran (275 reputation)SSC Veteran (275 reputation)SSC Veteran (275 reputation)SSC Veteran (275 reputation)

Group: General Forum Members
Points: 275 Visits: 1
Thanks; everyone for the responses to my article. I will try to address everyone in the next day or two. Lets start with spowell_2 because your solution is basically the same as mine was. My solution was:
isnull(Column, ' ') like @Parameter.
Unfortunately you take a little hit with cpu time to do the isnull function on each column but its a very clean solution.

tbredehoft - what do you do with the parameters where the user does not enter any search critera? You end up with a situation like where (firstName is null or firstname='')



duanxn
duanxn
SSC Rookie
SSC Rookie (26 reputation)SSC Rookie (26 reputation)SSC Rookie (26 reputation)SSC Rookie (26 reputation)SSC Rookie (26 reputation)SSC Rookie (26 reputation)SSC Rookie (26 reputation)SSC Rookie (26 reputation)

Group: General Forum Members
Points: 26 Visits: 1
Hi, I think

ColumnOne = insnull(@pSearchArg, ColumnOne)

whill not work, because null value in ColumnOne will fail this expression.
I'd like to use something like the following if you insist on using "like":

CREATE PROCEDURE sp_MySearch
@p1 varchar(50),
@p2 varchar(50),

AS
select * from t where
isnull(c1, '') like case when len(isnull(@p1,'')) =0 then isnull(c1, '') else '%'+@p1+'%' end and
isnull(c2, '') like case when len(isnull(@p2,'')) =0 then isnull(c2, '') else '%'+@p2+'%' end


Of cause the performance using "like" is far poor than using a "="



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