Is this SARGable?

  • 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!

  • 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.

    Change is inevitable... Change for the better is not.


    Helpful Links:
    How to post code problems
    How to Post Performance Problems
    Create a Tally Function (fnTally)

  • 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!

Viewing 3 posts - 1 through 2 (of 2 total)

You must be logged in to reply to this topic. Login to reply