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 1234»»»

Conditional Statements in WHERE Clauses Expand / Collapse
Author
Message
Posted Friday, July 9, 2004 6:07 PM


Forum Newbie

Forum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum Newbie

Group: General Forum Members
Last Login: Wednesday, October 10, 2007 6:26 AM
Points: 6, Visits: 9
Comments posted to this topic are about the content posted at http://www.sqlservercentral.com/col

Sotiris L. Filippidis
Post #125791
Posted Sunday, July 25, 2004 10:42 PM
Grasshopper

GrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopper

Group: General Forum Members
Last Login: Friday, February 3, 2012 12:19 AM
Points: 22, 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.




Post #128102
Posted Monday, July 26, 2004 1:31 AM


Forum Newbie

Forum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum Newbie

Group: General Forum Members
Last Login: Wednesday, October 10, 2007 6:26 AM
Points: 6, 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
Post #128123
Posted Monday, July 26, 2004 2:51 AM
SSC-Enthusiastic

SSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-Enthusiastic

Group: General Forum Members
Last Login: Monday, August 22, 2005 4:01 AM
Points: 118, 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.


 

Post #128129
Posted Monday, July 26, 2004 3:04 AM


Forum Newbie

Forum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum Newbie

Group: General Forum Members
Last Login: Wednesday, October 10, 2007 6:26 AM
Points: 6, 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
Post #128131
Posted Monday, July 26, 2004 3:14 AM
Old Hand

Old HandOld HandOld HandOld HandOld HandOld HandOld HandOld Hand

Group: General Forum Members
Last Login: Wednesday, April 27, 2005 2:37 AM
Points: 311, 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.

 




Post #128134
Posted Monday, July 26, 2004 7:09 AM


Ten Centuries

Ten CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen Centuries

Group: General Forum Members
Last Login: Thursday, September 25, 2014 9:01 PM
Points: 1,113, Visits: 705
Please check out MVP Erland Sommarskog's article on this subject:

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


--
Adam Machanic
SQL Server MVP
SQLblog.com: THE SQL Server Blog Spot on the Web
Post #128159
Posted Monday, July 26, 2004 7:12 AM
SSC Eights!

SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!

Group: General Forum Members
Last Login: Yesterday @ 9:35 AM
Points: 818, Visits: 2,074

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.




Post #128161
Posted Monday, July 26, 2004 8:06 AM
SSC-Enthusiastic

SSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-Enthusiastic

Group: General Forum Members
Last Login: Tuesday, September 6, 2005 10:53 AM
Points: 107, 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?

 




Post #128201
Posted Monday, July 26, 2004 11:08 AM


Ten Centuries

Ten CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen Centuries

Group: General Forum Members
Last Login: Thursday, September 25, 2014 9:01 PM
Points: 1,113, Visits: 705
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
SQL Server MVP
SQLblog.com: THE SQL Server Blog Spot on the Web
Post #128236
« Prev Topic | Next Topic »

Add to briefcase 1234»»»

Permissions Expand / Collapse