January 17, 2014 at 8:06 am
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 change:(
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
1YItem 1
2LItem 1
3abc 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
January 17, 2014 at 8:59 am
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).
January 21, 2014 at 7:54 pm
Or you could put this convoluted Gender computation into a computed column.
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?[/url]
Since random numbers are too important to be left to chance, let's generate some![/url]
Learn to understand recursive CTEs by example.[/url]
[url url=http://www.sqlservercentral.com/articles/St
January 22, 2014 at 12:12 am
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 change:(
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
January 22, 2014 at 1:56 am
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
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
Viewing 5 posts - 1 through 4 (of 4 total)
You must be logged in to reply to this topic. Login to reply