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


Conditional Statements in WHERE Clauses


Conditional Statements in WHERE Clauses

Author
Message
Sotiris Filippidis
Sotiris Filippidis
Valued Member
Valued Member (50 reputation)Valued Member (50 reputation)Valued Member (50 reputation)Valued Member (50 reputation)Valued Member (50 reputation)Valued Member (50 reputation)Valued Member (50 reputation)Valued Member (50 reputation)

Group: General Forum Members
Points: 50 Visits: 9
Comments posted to this topic are about the content posted at http://www.sqlservercentral.com/col

Sotiris L. Filippidis
laperrej
laperrej
SSC Rookie
SSC Rookie (32 reputation)SSC Rookie (32 reputation)SSC Rookie (32 reputation)SSC Rookie (32 reputation)SSC Rookie (32 reputation)SSC Rookie (32 reputation)SSC Rookie (32 reputation)SSC Rookie (32 reputation)

Group: General Forum Members
Points: 32 Visits: 68

Although an interesting technique, from a database performance point of view, this is not a very good idea. SARGs are turned into non-SARGs, so indexes won't be used (for an example, rewrite

SELECT * FROM authors WHERE au_lname LIKE 'm%' AND state = 'CA'

in the pubs database with conditional statements in the WHERE clause and compare the execution plans. You will see that the query above uses an index, the query with conditional statements in the WHERE clause does not.





Sotiris Filippidis
Sotiris Filippidis
Valued Member
Valued Member (50 reputation)Valued Member (50 reputation)Valued Member (50 reputation)Valued Member (50 reputation)Valued Member (50 reputation)Valued Member (50 reputation)Valued Member (50 reputation)Valued Member (50 reputation)

Group: General Forum Members
Points: 50 Visits: 9

You are right. My point, though, was to show how an operator-driven query could be performed, actually neglecting any performance issues. There are some cases, for example, a custom query builder inside an application, where a technique like that could prove handy, especially when dealing with ad hoc reporting inside a database with limited data but needing to have many different views.

I will investigate further and maybe come out with an even better solution. Thank you for your comments!



Sotiris L. Filippidis
AKM
AKM
Mr or Mrs. 500
Mr or Mrs. 500 (514 reputation)Mr or Mrs. 500 (514 reputation)Mr or Mrs. 500 (514 reputation)Mr or Mrs. 500 (514 reputation)Mr or Mrs. 500 (514 reputation)Mr or Mrs. 500 (514 reputation)Mr or Mrs. 500 (514 reputation)Mr or Mrs. 500 (514 reputation)

Group: General Forum Members
Points: 514 Visits: 1

I would be interested to see the relative performance of the article's method versus the following approach, which is equally powerful but (I think) can be optimised much more easily by the query engine:

-- declare condition variables as in the article
if @companynameOp='' and @countryOp=''
  select customerid, companyname, country from customers
else if @companynameOp='' and @countryOp='eq'
  select customerid, companyname, country from customers where country like @country
else if @companynameOp='' and @countryOp='bg'
  select customerid, companyname, country from customers where country like @country+'%'
-- etc etc
else if @companynameOp='ct' and @countryOp='ne'
  select customerid, companyname, country from customers where companyname like '%' + @companyName +'%' and country not like @country
-- etc etc

OK it's much more typing but that shouldn't really be considered an issue. As you can see, we are handling each possible pair of comparison operators separately, and each select statement can use indexes, be optimised, etc.



Sotiris Filippidis
Sotiris Filippidis
Valued Member
Valued Member (50 reputation)Valued Member (50 reputation)Valued Member (50 reputation)Valued Member (50 reputation)Valued Member (50 reputation)Valued Member (50 reputation)Valued Member (50 reputation)Valued Member (50 reputation)

Group: General Forum Members
Points: 50 Visits: 9

When I was assigned this task, I first thought of a similar approach. But when you have over 10 fields to filter by this can be rather big. You also have to type a lot if / when something like a field name changes.

I created this example having in mind not only the use of operators but also the extension of this query to accept different logical operators between criteria too. Think of it as a dynamic environment where you can add filters to fields and also add operators like AND, OR between criteria. This would be too much typing if you wanted to cover all possible combinations.



Sotiris L. Filippidis
Henrik Staun Poulsen-105872
Henrik Staun Poulsen-105872
Old Hand
Old Hand (373 reputation)Old Hand (373 reputation)Old Hand (373 reputation)Old Hand (373 reputation)Old Hand (373 reputation)Old Hand (373 reputation)Old Hand (373 reputation)Old Hand (373 reputation)

Group: General Forum Members
Points: 373 Visits: 1

Performance might be an issue, but this solution is great when security is an issue. It is very easy to grant execution rights to a sproc, and then block the Select command.

See http://www.novicksoftware.com/Articles/crud-operations-using-sql-server-stored-procedures-part-1.htm about application roles.





Adam Machanic
Adam Machanic
SSCarpal Tunnel
SSCarpal Tunnel (4.8K reputation)SSCarpal Tunnel (4.8K reputation)SSCarpal Tunnel (4.8K reputation)SSCarpal Tunnel (4.8K reputation)SSCarpal Tunnel (4.8K reputation)SSCarpal Tunnel (4.8K reputation)SSCarpal Tunnel (4.8K reputation)SSCarpal Tunnel (4.8K reputation)

Group: General Forum Members
Points: 4765 Visits: 735
Please check out MVP Erland Sommarskog's article on this subject:

http://www.sommarskog.se/dyn-search.html

--
Adam Machanic
whoisactive
RonKyle
RonKyle
SSChampion
SSChampion (11K reputation)SSChampion (11K reputation)SSChampion (11K reputation)SSChampion (11K reputation)SSChampion (11K reputation)SSChampion (11K reputation)SSChampion (11K reputation)SSChampion (11K reputation)

Group: General Forum Members
Points: 11960 Visits: 3751

We create a temp table which is then filled in with the resulting values which are then joined through a stored proc to a fixed statement.

In this case, we would populate a temp table with the company codes that meet the desired criteria. We then join that table to the query. The temp table acts as a filter.

It's much simpler than the way described in the article.





thormj
thormj
Old Hand
Old Hand (333 reputation)Old Hand (333 reputation)Old Hand (333 reputation)Old Hand (333 reputation)Old Hand (333 reputation)Old Hand (333 reputation)Old Hand (333 reputation)Old Hand (333 reputation)

Group: General Forum Members
Points: 333 Visits: 1

I like RonKyle's solution -- its one I haven't seen before.

But why not a query like this:

select * from customers where

((@countryOP='bg' AND country like @country+'%') or
(@countryOP='eq' AND country = @country) or
(@countryOP='ne' AND country <> @country) or
(@countryOP='')) AND
((@companyOP='') or
(@companyOP='bg' AND comany like @company+'%') or
...

9/10ths of the statements would be false, but how much of a problem is that?





Adam Machanic
Adam Machanic
SSCarpal Tunnel
SSCarpal Tunnel (4.8K reputation)SSCarpal Tunnel (4.8K reputation)SSCarpal Tunnel (4.8K reputation)SSCarpal Tunnel (4.8K reputation)SSCarpal Tunnel (4.8K reputation)SSCarpal Tunnel (4.8K reputation)SSCarpal Tunnel (4.8K reputation)SSCarpal Tunnel (4.8K reputation)

Group: General Forum Members
Points: 4765 Visits: 735
thormj,

The problem is that unfortunately that query will be unable to seek indexes as the optimizer will evaluate ALL of the possible conditions (therefore, a scan will be necessary).

--
Adam Machanic
whoisactive
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