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

Is this SARGable? Expand / Collapse
Author
Message
Posted Tuesday, February 4, 2014 4:25 PM
SSC Veteran

SSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC Veteran

Group: General Forum Members
Last Login: Thursday, August 14, 2014 9:05 AM
Points: 202, Visits: 566
Assuming we have a players table with a kazillion records with PK and clustered index on playerid (BIGINT) and nonclustered index on column name (VARCHAR(50)). These two columns are the only columns on the table. Lets also assume an application was designed to pass in N'VARCHAR datatype as parameter

Would this be SARGable and if not, how would we fix it:

SELECT * FROM players WHERE name = N'richard sherman'

From my understanding I know the following would be nonSARGable:
SELECT * FROM players WHERE CONVERT(NVARCHAR(50), name) = N'richard sherman'

So to fix this, would we do this?:
WHERE name = CONVERT(VARCHAR(50), N'richard sherman')

Thanks!
Post #1537982
Posted Tuesday, February 4, 2014 4:37 PM


SSC-Dedicated

SSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-Dedicated

Group: General Forum Members
Last Login: Today @ 4:51 PM
Points: 36,944, Visits: 31,450
Correct on all counts. The last bit of code you posted would be correct to make the query SARGable.

--Jeff Moden
"RBAR is pronounced "ree-bar" and is a "Modenism" for "Row-By-Agonizing-Row".

First step towards the paradigm shift of writing Set Based code:
Stop thinking about what you want to do to a row... think, instead, of what you want to do to a column."

(play on words) "Just because you CAN do something in T-SQL, doesn't mean you SHOULDN'T." --22 Aug 2013

Helpful Links:
How to post code problems
How to post performance problems
Post #1537984
Posted Wednesday, February 5, 2014 7:02 AM


SSC-Enthusiastic

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

Group: General Forum Members
Last Login: Tuesday, August 12, 2014 6:44 AM
Points: 156, Visits: 616
As Jeff said you are right, the third query is sargable.

The second query shows exactly how SQL Server rewrites your initail query and it's not SARGable because it always converts non-unicode operand to Unicode when two operands does not have the same text data type. So, the solution is to make an explicit conversion and to convert parameter to the data type of the column.

If your column would be an NVARCHAR and your parameter a VARCHAR, the predicate would be SARGable since an implicit conversion is performed against parameter and not against the column.

Of course, the golden rule is to align data types of parameters and columns and if you have to do something for it do it against parameters (functions, arithemtical operations....) and not with columns.


___________________________
Do Not Optimize for Exceptions!
Post #1538171
« Prev Topic | Next Topic »

Add to briefcase

Permissions Expand / Collapse