July 9, 2004 at 6:07 pm
Comments posted to this topic are about the content posted at http://www.sqlservercentral.com/col
Sotiris L. Filippidis
July 25, 2004 at 10:42 pm
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.
July 26, 2004 at 1:31 am
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
July 26, 2004 at 2:51 am
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.
July 26, 2004 at 3:04 am
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
July 26, 2004 at 3:14 am
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.
July 26, 2004 at 7:09 am
Please check out MVP Erland Sommarskog's article on this subject:
http://www.sommarskog.se/dyn-search.html
--
Adam Machanic
whoisactive
July 26, 2004 at 7:12 am
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.
July 26, 2004 at 8:06 am
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?
July 26, 2004 at 11:08 am
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
July 26, 2004 at 11:57 am
Thank you very much; every day I find I know very little about sql (Mainly a C/C++ dude).
Hey RonKyle, could you post an example of the join that you're talking about so we can talk about how it would use the indices? It looks like that might be the cleanest solution yet.
Thanks!
August 20, 2004 at 6:17 am
Hi all,
Did RonKyle post a sample of his solution as I have a little task which could use his technique.
If not perhaps he could post a sample so we may see how it works and give some feedback.
Regards Steve
October 26, 2004 at 11:27 pm
My first ever post. Here are my 2 cents:
CREATE PROC usp_GetComstomers@CompY VARCHAR(100)='%',
@ContY VARCHAR(100)='%',
@CompN VARCHAR(100)='NoNothingNoneWhateverString',
@ContN VARCHAR(100)='NoNothingNoneWhateverString'
AS
/*
Example:
EXEC usp_GetComstomers '%','Germany','A%'
EXEC usp_GetComstomers '%the%'
*/
SET NOCOUNT ON
SELECT *
FROM dbo.Customers
WHERE CompanyName LIKE @CompY
AND Country LIKE @ContY
AND CompanyName NOT LIKE @CompN
AND Country NOT LIKE @ContN
This would be fast and not too bad looking. 🙂
September 28, 2007 at 12:25 am
In this case, I prefer dynamic sql and add only conditions I need. Performance are granted more than complex and useless conditions. 🙂
September 28, 2007 at 2:22 am
How about:...?
set @companyname = 'A%'
set @companynameOp = 'ne'
set @country = 'Germany'
set @countryOp = 'eq'
set@companyName =
case @companyNameOp
when '' then null
when 'eq' then -- Operator is "equals"
@companyName
when 'bg' then -- Operator is "begins with"
@companyName +'%'
when 'ed' then -- Operator is "ends with"
'%' + @companyName
when 'ct' then -- Operator is "contains"
'%' + @companyName + '%'
set@country =
case @countryOp
when '' then null
when 'eq' then -- Operator is "equals"
@country
when 'bg' then -- Operator is "begins with"
@country +'%'
when 'ed' then -- Operator is "ends with"
'%' + @country
when 'ct' then -- Operator is "contains"
'%' + @country + '%'
-- Ok, now let's form our query.
select
customerid, companyname, country
from
customers
where
(companyName like @companyName or @companyName is null)
AND
(country like @country or @country is null)
Viewing 15 posts - 1 through 15 (of 35 total)
You must be logged in to reply to this topic. Login to reply