Performance hit using CAST in T-SQL

If the cast of the column is to exactly the same datatype and length and the seek predicate is a literal it does indeed seem to disregard it or treat it as a no-op and does an index seek on equality.

Seek Keys[1]: Prefix: [tempdb].[dbo].[#test].name = Scalar Operator(N'rpc')

If the cast of the column is to the same datatype but greater length and the seek predicate is a string literal it causes an index scan. This is obviously to be avoided.

If the cast of the column is to the same datatype and the same or greater length and the seek predicate is a local variable it adds a compute scalar operator to the execution plan. This calls GetRangeThroughConvert and outputs a range.

This range is used to do an index seek and seems pretty efficient

Seek Keys[1]: 
Start: [tempdb].[dbo].[#test].name > Scalar Operator([Expr1006]), 
End: [tempdb].[dbo].[#test].name < Scalar Operator([Expr1007])

Testing Code

SELECT *
 INTO #test
  FROM [master].[dbo].[spt_values]

CREATE NONCLUSTERED INDEX [ixname] ON #test
(
    [name] ASC
)

DECLARE @name NVARCHAR(MAX)

SET @name = 'rpc'

SELECT name
FROM #test
WHERE CAST(name AS NVARCHAR(35))= @name --Cast the same and local variable

SELECT name
FROM #test
WHERE CAST(name AS NVARCHAR(MAX))=@name --Cast to longer and local variable

SELECT name
FROM #test
WHERE CAST(name AS NVARCHAR(35))='rpc' --Cast the same and literal

SELECT name
FROM #test
WHERE CAST(name AS NVARCHAR(MAX))='rpc' --Cast to longer and literal

In general, the CAST will kill performance because it invalidates any use of index seeks as Martin Smith's last example shows. Casting to nvarchar(max) or to a different length means a different data type: the fact it's all nvarchar is irrelevant.

On top of that, the datatype of the right hand side of the compare matters too. If it's a local variable or parameter of a different length then one side will be implicitly CAST to the widest of the 2 datatypes (see datatype precedence).

Basically, if you have a general CAST to nvarchar(max) it will bollix things up. I would consider fixing the use of ntext before I added CAST all over.

The conversion may not show in the query plan. See Paul White's blog article


Just a note, Casting like this where Datecreated is datetime

 Cast (Datecreated as date) = cast(@MydatetimeValue as date)

Does not break SQL's ability to use indexes if indexes exist, and if they don't exist, may result in logging a missing index.

Similarly, when casting from int to tinyint or bigint to int etc, the cast function does not stop SQL from using indexes IF the optimiser knows that the cast operation does not change the sort order of the 2 comparable datatypes.

Here are a bunch of tests you can run and view actual plan using Adventureworks2008R2

select count(*) from Sales.SalesOrderDetail where SalesOrderID = 8 --1
select top 10 * from Sales.SalesOrderDetail where cast(SalesOrderID as tinyint) = 8  --2
select top 10 * from Sales.SalesOrderDetail where cast(SalesOrderID as bigint) = 8  --3
select top 10 SalesOrderID from Sales.SalesOrderDetail where cast(ModifiedDate  as date) = '19780322' --4
select top 10 SalesOrderID from Sales.SalesOrderDetail where convert(date,ModifiedDate) = '19780322'  --5
select top 10 SalesOrderID from Sales.SalesOrderDetail where cast(ModifiedDate as varchar(20)) = '1978'  --6 -- THIS WILL NOT USE INDEX
select  SalesOrderID from Sales.SalesOrderDetail where cast(ModifiedDate  as date) between '19780101' and '19780109'  --7