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


Case Statement using Where Clause


Case Statement using Where Clause

Author
Message
Saravanakumar.Rathinam
Saravanakumar.Rathinam
SSC-Addicted
SSC-Addicted (477 reputation)SSC-Addicted (477 reputation)SSC-Addicted (477 reputation)SSC-Addicted (477 reputation)SSC-Addicted (477 reputation)SSC-Addicted (477 reputation)SSC-Addicted (477 reputation)SSC-Addicted (477 reputation)

Group: General Forum Members
Points: 477 Visits: 493
It takes the Index scan eventhough 'sCustomerSys' column is Clustered Index.
Please suggest if any alternative query on these ?

DECLARE @StatusOp as VARCHAR(20)
DECLARE @Status as VARCHAR(20)
SET @StatusOp = ' '
SET @Status = 'UNET'
SELECT (dateadd(dd,datediff(dd,0,dtOrigRecv),0)) InquiryDate, SUBSTRING(sRefDocId,4,5) as JulianDate,
COUNT(sProcessProject) Volume FROM mxDocument
where (DATEADD(dd,DATEDIFF(dd,0,dtOrigRecv),0) BETWEEN '01/15/2008' AND '01/20/2008')
AND sProcessProject LIKE 'GRP%'
AND Case @StatusOp
when ' ' then 1
When 'eq' then
case when sCustomerSys like (@Status) then 1 else 0 end
end = 1
GROUP BY (dateadd(dd,datediff(dd,0,dtOrigRecv),0)),SUBSTRING(sRefDocId,4,5)
ORDER BY (dateadd(dd,datediff(dd,0,dtOrigRecv),0))

thanks & regards
Saravanakumar.R
Saravanakumar.Rathinam
Saravanakumar.Rathinam
SSC-Addicted
SSC-Addicted (477 reputation)SSC-Addicted (477 reputation)SSC-Addicted (477 reputation)SSC-Addicted (477 reputation)SSC-Addicted (477 reputation)SSC-Addicted (477 reputation)SSC-Addicted (477 reputation)SSC-Addicted (477 reputation)

Group: General Forum Members
Points: 477 Visits: 493
any hope on these ?
Grant Fritchey
Grant Fritchey
SSC Guru
SSC Guru (145K reputation)SSC Guru (145K reputation)SSC Guru (145K reputation)SSC Guru (145K reputation)SSC Guru (145K reputation)SSC Guru (145K reputation)SSC Guru (145K reputation)SSC Guru (145K reputation)

Group: General Forum Members
Points: 145135 Visits: 33199
Can you post the full execution plan? You might be hitting the scan because of other things within the query, such as performing functions on the columns then using them as part of the WHERE clause.

----------------------------------------------------
The credit belongs to the man who is actually in the arena, whose face is marred by dust and sweat and blood...
Theodore Roosevelt

The Scary DBA
Author of: SQL Server Query Performance Tuning and SQL Server Execution Plans
Product Evangelist for Red Gate Software
antonio.collins
antonio.collins
Hall of Fame
Hall of Fame (3.6K reputation)Hall of Fame (3.6K reputation)Hall of Fame (3.6K reputation)Hall of Fame (3.6K reputation)Hall of Fame (3.6K reputation)Hall of Fame (3.6K reputation)Hall of Fame (3.6K reputation)Hall of Fame (3.6K reputation)

Group: General Forum Members
Points: 3552 Visits: 921
Saravanakumar.Rathinam (2/20/2008)
It takes the Index scan eventhough 'sCustomerSys' column is Clustered Index.
Please suggest if any alternative query on these ?


The case statement prevents the search on sCustomerSys from being optimized. The only 'hard' criteria provided is on sProcessProject.

It appears you want to optionally search on sCustomerSys for @Status based on the value of @StatusOp. If so, set @Status to '%' if @StatusOp is 'eq'.


-- existing
DECLARE @StatusOp as VARCHAR(20)
DECLARE @Status as VARCHAR(20)
SET @StatusOp = ' '
SET @Status = 'UNET'
SELECT ...
FROM mxDocument
where (DATEADD(dd,DATEDIFF(dd,0,dtOrigRecv),0)
BETWEEN '01/15/2008' AND '01/20/2008')
AND sProcessProject LIKE 'GRP%'
AND Case @StatusOp
when ' ' then 1
When 'eq' then
case when sCustomerSys like (@Status) then 1 else 0 end
end = 1
....

-- suggestion
DECLARE @StatusOp as VARCHAR(20)
DECLARE @Status as VARCHAR(20)
SET @StatusOp = ' '
SET @Status = 'UNET'

IF @StatusOp = 'eq' SET @Status = '%'
-- now @Status will always have the search value

SELECT ...
FROM mxDocument
where
dtOrigRecv >= '01/15/2008'
and dtOrigRecv < dateadd(day,1,'01/20/2008')
-- adjust end date of range so any index on dtOrigRecv can be used
AND sProcessProject LIKE 'GRP%'
AND sCustomerSys like @Status
...


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