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


How to optimize case statement


How to optimize case statement

Author
Message
thbaig
thbaig
SSC Veteran
SSC Veteran (253 reputation)SSC Veteran (253 reputation)SSC Veteran (253 reputation)SSC Veteran (253 reputation)SSC Veteran (253 reputation)SSC Veteran (253 reputation)SSC Veteran (253 reputation)SSC Veteran (253 reputation)

Group: General Forum Members
Points: 253 Visits: 496
Hi,
I have several rule on my item name to compute its gender. I know this structure might need to tune , but currently can't changeSad
I wrote sql and its working perfect. But as it has many cases and left and right functions,there are more conditions but I am posting just basic one. I would love to optimize my code.

Do you have any suggestion to modify my TSQL ?

Table tblBrand
BrandId int identity,
BrandName varchar(3)

Sample Data
BrandId BrandName
1 brand1
2 brand2
3 brand3
4 brand4
5 brand5
6 brand5

table tblItem
ItemId int identity,
ItemName varchar(10),
BrandId int (FK->tblBrand.BrandId)

ItemId ItemName BrandId
1 YItem 1
2 LItem 1
3 abc 1
4 ItemB 6
.........
.........
SELECT 
IT.ItemName,
-- Case for Gender
CASE WHEN br.BrandName IN ( 'brand1', 'brand2', 'brand3' )
AND LEFT(it.ItemName, 1) = 'L' THEN 'Ladies'
WHEN br.BrandName IN ( 'brand1', 'brand2', 'brand3' )
AND LEFT(it.ItemName, 1) = 'Y' THEN 'Youth'
WHEN br.BrandName IN ( 'brand1', 'brand2', 'brand3' )
AND (LEFT(it.ItemName, 1) <> 'Y'
OR LEFT(it.ItemName, 1) <> 'L'
) THEN 'Adult'
WHEN br.BrandName = 'brand4' THEN 'Adult'
WHEN br.BrandName = 'brand5'
AND RIGHT(it.ItemName,1) IN ( 'B', 'Y' )
THEN 'Youth'
WHEN br.BrandName = 'brand6'
AND RIGHT(it.ItemName,1) = 'B' THEN 'Youth'
WHEN br.BrandName = 'brand6'
AND RIGHT(it.ItemName,1) = 'L' THEN 'Ladies'
ELSE ''
END AS Gender, -- Case for Gender end


FROM tblBrand br
INNER JOIN tblItem it ON it.BrandId = br.BrandId


Luis Cazares
Luis Cazares
SSCoach
SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)

Group: General Forum Members
Points: 16816 Visits: 19122
I'm not sure if it will help performance wise, but it might improve readability if you include your cases in a lookup table (or cte).


Luis C.
General Disclaimer:
Are you seriously taking the advice and code from someone from the internet without testing it? Do you at least understand it? Or can it easily kill your server?


How to post data/code on a forum to get the best help: Option 1 / Option 2
dwain.c
dwain.c
SSCertifiable
SSCertifiable (7.4K reputation)SSCertifiable (7.4K reputation)SSCertifiable (7.4K reputation)SSCertifiable (7.4K reputation)SSCertifiable (7.4K reputation)SSCertifiable (7.4K reputation)SSCertifiable (7.4K reputation)SSCertifiable (7.4K reputation)

Group: General Forum Members
Points: 7425 Visits: 6431
Or you could put this convoluted Gender computation into a computed column.


My mantra: No loops! No CURSORs! No RBAR! Hoo-uh!

My thought question: Have you ever been told that your query runs too fast?

My advice:
INDEXing a poor-performing query is like putting sugar on cat food. Yeah, it probably tastes better but are you sure you want to eat it?
The path of least resistance can be a slippery slope. Take care that fixing your fixes of fixes doesn't snowball and end up costing you more than fixing the root cause would have in the first place.


Need to UNPIVOT? Why not CROSS APPLY VALUES instead?
Since random numbers are too important to be left to chance, let's generate some!
Learn to understand recursive CTEs by example.
Splitting strings based on patterns can be fast!
My temporal SQL musings: Calendar Tables, an Easter SQL, Time Slots and Self-maintaining, Contiguous Effective Dates in Temporal Tables
GilaMonster
GilaMonster
SSC Guru
SSC Guru (88K reputation)SSC Guru (88K reputation)SSC Guru (88K reputation)SSC Guru (88K reputation)SSC Guru (88K reputation)SSC Guru (88K reputation)SSC Guru (88K reputation)SSC Guru (88K reputation)

Group: General Forum Members
Points: 88855 Visits: 45284
thbaig1 (1/17/2014)
Hi,
I have several rule on my item name to compute its gender. I know this structure might need to tune , but currently can't changeSad
I wrote sql and its working perfect. But as it has many cases and left and right functions,there are more conditions but I am posting just basic one. I would love to optimize my code.


Why do you think it needs tuning? Have you run the query with and without the case and seen what the time difference is? If it enough of a time difference and is the overall query enough of a performance problem to warrant looking at?

Gail Shaw
Microsoft Certified Master: SQL Server, MVP, M.Sc (Comp Sci)
SQL In The Wild: Discussions on DB performance with occasional diversions into recoverability

We walk in the dark places no others will enter
We stand on the bridge and no one may pass


ChrisM@Work
ChrisM@Work
SSCoach
SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)

Group: General Forum Members
Points: 16526 Visits: 19557
Like Gail, I don't think this expression is going to have much impact on performance. Maintainability is another story - updating n queries to account for product changes leaves you wide open to errors. Put the code into an iTVF so you have a common code block for all of the queries which return 'gender' (I'd call it 'fitting' personally because 'youth' isn't a gender). Something like this:

CREATE FUNCTION IF_BrandItemFitting 
(
@BrandName VARCHAR(20),
@ItemName VARCHAR(20)
)
RETURNS TABLE
AS
RETURN
(
SELECT [Fitting] = CASE
WHEN @BrandName IN ( 'brand1', 'brand2', 'brand3' )
AND LEFT(@ItemName, 1) = 'L'
THEN 'Ladies'
WHEN @BrandName IN ( 'brand1', 'brand2', 'brand3' )
AND LEFT(@ItemName, 1) = 'Y'
THEN 'Youth'
WHEN @BrandName IN ( 'brand1', 'brand2', 'brand3' )
--AND (LEFT(@ItemName, 1) <> 'Y' -- not strictly needed - see first 2 cases
-- OR LEFT(@ItemName, 1) <> 'L')
THEN 'Adult'
WHEN @BrandName = 'brand4'
THEN 'Adult'
WHEN @BrandName = 'brand5'
AND RIGHT(@ItemName,1) IN ( 'B', 'Y' )
THEN 'Youth'
WHEN @BrandName = 'brand6'
AND RIGHT(@ItemName,1) = 'B'
THEN 'Youth'
WHEN @BrandName = 'brand6'
AND RIGHT(@ItemName,1) = 'L'
THEN 'Ladies'
ELSE NULL -- NULL, not ''
END
)
GO



Use it like this:
SELECT 
IT.ItemName,
bf.fitting

FROM tblBrand br
INNER JOIN tblItem it
ON it.BrandId = br.BrandId
CROSS APPLY dbo.IF_BrandItemFitting (br.BrandName, it.ItemName) bf



“Write the query the simplest way. If through testing it becomes clear that the performance is inadequate, consider alternative query forms.” - Gail Shaw

For fast, accurate and documented assistance in answering your questions, please read this article.
Understanding and using APPLY, (I) and (II) Paul White
Hidden RBAR: Triangular Joins / The "Numbers" or "Tally" Table: What it is and how it replaces a loop Jeff Moden
Exploring Recursive CTEs by Example Dwain Camps
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