Hi Friends,
In my previous blog post, we have seen that SQL Sever estimates number of rows in a table variable was 1. Now the question is, Is there any way to make the correct estimation for the number of rows while using table variable?
My today’s blog post is focused on the correct cardinality estimation using table variable. The answer of the above question is: yes, the optimizer can make a correct cardinality estimation for table variables by using OPTION (RECOMPILE) hint for that. Using this hint also has some cons like new plan will generate every time. It’s like a trade-off between both the mechanism. Let me show you the same thing.
First: Use of table variable without Option Recompile
Declare @TV_SalesOrderDetail Table ( [SalesOrderID] [int] NOT NULL, [SalesOrderDetailID] [int] NOT NULL, [CarrierTrackingNumber] [nvarchar](25) NULL, [OrderQty] [smallint] NOT NULL, [ProductID] [int] NOT NULL, [SpecialOfferID] [int] NOT NULL, [UnitPrice] [money] NOT NULL, [UnitPriceDiscount] [money] NOT NULL, [LineTotal] [money], [rowguid] [uniqueidentifier] ROWGUIDCOL, [ModifiedDate] [datetime] NOT NULL ) INSERT INTO @TV_SalesOrderDetail SELECT [SalesOrderID] ,[SalesOrderDetailID] ,[CarrierTrackingNumber] ,[OrderQty] ,[ProductID] ,[SpecialOfferID] ,[UnitPrice] ,[UnitPriceDiscount] ,[LineTotal] ,[rowguid] ,[ModifiedDate] FROM [Sales].[SalesOrderDetail] SET STATISTICS TIME ON Select SOD.UnitPrice, SOH.DueDate, SOH.OrderDate from @TV_SalesOrderDetail SOD join [Sales].[SalesOrderHeader] SOH on sod.SalesOrderID=SOH.SalesOrderID Where SOH.OrderDate between '2011-07-01' AND '2011-07-31' GO
Second: Use of table variable with Option Recompile
Declare @TV_SalesOrderDetail Table ( [SalesOrderID] [int] NOT NULL, [SalesOrderDetailID] [int] NOT NULL, [CarrierTrackingNumber] [nvarchar](25) NULL, [OrderQty] [smallint] NOT NULL, [ProductID] [int] NOT NULL, [SpecialOfferID] [int] NOT NULL, [UnitPrice] [money] NOT NULL, [UnitPriceDiscount] [money] NOT NULL, [LineTotal] [money], [rowguid] [uniqueidentifier] ROWGUIDCOL, [ModifiedDate] [datetime] NOT NULL ) INSERT INTO @TV_SalesOrderDetail SELECT [SalesOrderID] ,[SalesOrderDetailID] ,[CarrierTrackingNumber] ,[OrderQty] ,[ProductID] ,[SpecialOfferID] ,[UnitPrice] ,[UnitPriceDiscount] ,[LineTotal] ,[rowguid] ,[ModifiedDate] FROM [Sales].[SalesOrderDetail] SET STATISTICS TIME ON Select SOD.UnitPrice, SOH.DueDate, SOH.OrderDate from @TV_SalesOrderDetail SOD join [Sales].[SalesOrderHeader] SOH on sod.SalesOrderID=SOH.SalesOrderID Where SOH.OrderDate between '2011-07-01' AND '2011-07-31' OPTION (RECOMPILE) GO
From the above image you can see both actual and estimated number of rows are same and decision of using join also has been changed, the earlier nested loop was used but now it is using hash match.
Is there really a performance improvement due to the above change? Yes, you can see the stats below:
Stats for without Option Recompile SQL Server Execution Times: CPU time = 281 ms, elapsed time = 399 ms. SQL Server parse and compile time: CPU time = 0 ms, elapsed time = 0 ms. SQL Server Execution Times: CPU time = 0 ms, elapsed time = 0 ms. Stats for with Option Recompile SQL Server Execution Times: CPU time = 0 ms, elapsed time = 156 ms. SQL Server parse and compile time: CPU time = 0 ms, elapsed time = 0 ms. SQL Server Execution Times: CPU time = 0 ms, elapsed time = 0 ms.
HAPPY LEARNING!
Regards:
Prince Kumar Rastogi
Like us on FaceBook | Join the fastest growing SQL Server group on FaceBook
Follow Prince Rastogi on Twitter | Follow Prince Rastogi on FaceBook
Much better option install SP2 for 2012 or CU3 for 2014 and use TF 2453 then there is no need to use OPTION(RECOMPILE) for statements using table variables used in joins
Hi Sachin,
Actually I am posting all things one by one in sequence, post on TF 2453 is already scheduled to be published very soon.