Nested Loop Join – Temp Table versus Table variable

Hi Friends,

In my previous blog post, I have shown you the working of nested loop join in SQL Server. Today, I am going to show you the Nested Loop Join – Temp Table versus Table variable.

Before executing a query, SQL Server generates an estimated execution plan on the basis of various server settings and then uses that plan for actual execution of the query.

Nested Loop Join with Temp Table:

Here, I am using AdventureWorks2014 database. In my previous post, I have shown that during nested loop join SQL Server uses one input as outer and other as inner. Generally, out input will be the input, which has less number of rows.

In the below queries, I am creating a temp table and populating it with the data from [Sales].[SalesOrderDetail] table. Next, I am executing a query which has a join condition:

Select * 
INTO #SalesOrderDetail
from [Sales].[SalesOrderDetail]
GO
CREATE NONCLUSTERED INDEX NC1_Temp_SalesOrderDetail
ON [dbo].[#SalesOrderDetail] ([SalesOrderID])
INCLUDE ([UnitPrice])
GO
SET STATISTICS TIME ON

Select SOD.UnitPrice,
SOH.DueDate, SOH.OrderDate
from #SalesOrderDetail SOD
join [Sales].[SalesOrderHeader] SOH
on sod.SalesOrderID=SOH.SalesOrderID
Where SOH.OrderDate between '2011-07-01' AND '2011-07-31'
GO

TempTable_Plan

In the above query plan, you can see that SQL Server decides to use the temp table as an inner input. Now the question is why it is selected as inner input, why not selected as outer input? The answer is based on the statistics, SQL Server knows that temp table has more number of rows as compared to [Sales].[SalesOrderHeader]. So, for nested loop join this temp table has been selected as inner input. You can see the number of rows from the operator properties:

TempTableQuery

Nested Loop Join with Temp Table:

Now let me try to replace the temp table with table variable and see the impact.

   
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

TableVariable_Plan

From the above plan, you can see, this time SQL Server selected the table variable as an outer input while it is having more number of rows as compared to another input table i.e. [Sales].[SalesOrderHeader]. You can see this in the operator properties:

TableVariableQuery

Actually, the reason behind the selection of the table variable as an outer input is the difference between Actual and Estimated number of rows and you can compare these values in the above operator properties image.

So, if you are using table variables in the join queries, then keep in mind that selection of an operator depends on the estimated number of rows not on the actual number of rows. If there is a situation, where you know that your table variable will contain more than 100 rows, then it’s always better to use temp table instead of using table variable.

Is there any impact on my execution time due to the table variable? Yes, you can compare the execution time for both from the below time statistics.

For the above temp table query
SQL Server Execution Times:

   CPU time = 16 ms,  elapsed time = 100 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.

For the above table variable query
SQL Server Execution Times:

   CPU time = 188 ms,  elapsed time = 331 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

   

About Prince Rastogi

Prince Rastogi is working as Database Administrator at Elephant Insurance, Richmond. He is having more than 8 years of experience and worked in ERP Domain, Wealth Management Domain. Currently he is working in Insurance domain. In the starting of his career he was working on SQL Server, Internet Information Server and Visual Source Safe. He is post graduate in Computer Science. Prince is ITIL certified professional. Prince likes to explore technical things for Database World and Writing Blogs. He is Technical Editor and Blogger at SQLServerGeeks.com. He is a regular speaker at DataPlatformDay events in Delhi NCR. He has also presented some in depth sessions about SQL Server in SQL Server Conferences in Bangalore.

View all posts by Prince Rastogi →

Leave a Reply

Your email address will not be published.