THE SQL Server Blog Spot on the Web

Welcome to SQLblog.com - The SQL Server blog spot on the web Sign in | |
in Search

Kalen Delaney

Did You Know? Estimated vs Actual Plans

In my previous post, I mentioned that it is important to understand the difference between estimated and actual query plans, so I decided to go into a few more details regarding the differences.

Optimization takes place before execution, so in one sense, any query plan is an estimated plan. But when you request an actual plan, SQL Server will actually execute each statement as it displays the plan, so the plan for subsequent statements can change after the earlier statements are executed.  In addition, SQL Server adds additional information to the actual plan, after the execution takes place. As mentioned last time, the actual plan includes the number of processors used to execute the query. It will also include the number of rows returned from each step of the plan as it is executed, and the number of times each step is executed.  If you are executing a plan that has already been cached and is now being reused, the actual plan will include both the parameter values the plan was originally compiled with and the parameter values used during execution.

You can request that SQL Server display ESTIMATED plans without executing the query with any of the following options:

SET SHOWPLAN_TEXT ON

SET SHOWPLAN_ALL ON

SET SHOWPLAN_XML ON

For graphical estimated plans, you can use the Query | Display Estimated Execution Plan menu option. This can be invoked with a toolbar button, or with Cntl-L.

 

You can request that SQL Server display actual plans with any of the following options:

SET STATISTICS PROFILE ON

SET STATISTICS XML ON

For graphical actual plans, you can use the Query | Include Actual Execution Plan menu option. This can be invoked with a toolbar button, or with Cntl-K.

I'll show you 3 examples of ways in which the actual plan can be useful. They require that you have the AdventureWorks database installed.

Example 1:

First, create a stored procedure called 'testtemp' that will build a temporary table.

USE AdventureWorks
GO
IF EXISTS (SELECT 1 FROM sys.procedures
WHERE name = 'testtemp')
DROP PROC testtemp
GO
CREATE PROC testtemp
(@p int)
AS
SELECT * INTO #t
FROM Sales.SalesOrderDetail
CREATE INDEX t_index ON #t (ProductID)
SELECT * FROM #t
WHERE ProductID < @p
RETURN
GO

Try to look at the estimated plan for the procedure, and you will get an error because the plan for the SELECT cannot be generated when the temp table #t does not exist:

-- Estimated plan
SET SHOWPLAN_TEXT ON 
GO
EXEC testtemp 896
-- error is generated
GO
SET SHOWPLAN_TEXT OFF 
GO

Now look at the actual plan and you will see plans for the temp table creation and for the SELECT from the temp table.

SET STATISTICS PROFILE ON 
GO
EXEC testtemp 896
GO
SET STATISTICS PROFILE OFF 
GO

 

Example 2:

One of the main reasons that the actual plan may different from the estimated plan is because of data changes to your data. In general (and assuming you have the option 'auto update statistics' enabled) if more than 20% of the data in a table changes, the optimizer will detect stale statistics and update them automatically. The updated statistics will then trigger a recompile.

This example makes a copy of Sales.SalesOrderDetail in the AdventureWorks database and builds an index on the table. 

SELECT * INTO NewOrders
FROM Sales.SalesOrderDetail
GO

CREATE INDEX IX_NewOrders_ProductID on NewOrders(ProductID)
GO

SET SHOWPLAN_ALL ON -- Estimated Plan
GO

-- The estimated plan shows us that a seek is done on the SELECT from NewOrders because at optimization time
-- there are only a few rows that have a ProductID value of 897.

BEGIN TRAN
UPDATE NewOrders
SET ProductID = 897
WHERE ProductID between 800 and 900

SELECT OrderQty, CarrierTrackingNumber
FROM NewOrders
WHERE ProductID = 897
ROLLBACK TRAN
GO

SET SHOWPLAN_ALL OFF
GO

 

-- The actual plan shows us that a table scan is done on the SELECT from NewOrders because after the update is executed,
--  statistics are updated and the query is recompiled. Now there are lots of rows that have a ProductID value of 897.

SET STATISTICS PROFILE ON -- Actual Plan
GO

BEGIN TRAN
UPDATE NewOrders
SET ProductID = 897
WHERE ProductID between 800 and 900

SELECT OrderQty, CarrierTrackingNumber
FROM NewOrders
WHERE ProductID = 897
ROLLBACK TRAN
GO

SET STATISTICS PROFILE OFF
GO

Example 3:

For this example, you can create a stored procedure that uses a parameter to determine which rows from the Sales.SalesOrderDetail table to select.

USE AdventureWorks
GO
IF EXISTS (SELECT 1 FROM sys.procedures
WHERE name = 'GetProducts')
DROP PROC GetProducts
GO
CREATE PROC GetProducts
(@p int)
AS
SELECT *
FROM Sales.SalesOrderDetail
WHERE ProductID = @p
RETURN
GO

The first time you run the procedure, a plan will be built based on the first parameter. The second time you run the procedure, the original plan will be used, and the statistics should show that SQL Server is performing more reads than there are pages in the table. (There are 1238 pages in the table.)

SET STATISTICS IO ON
GO
EXEC GetProducts 710  -- using nc index takes 145 logical reads
GO
EXEC GetProducts 707  -- using nc index takes 9458 logical reads.
GO

You can look at the actual plan in XML to see the parameters used for compile and execute.

SET STATISTICS XML ON
GO
EXEC GetProducts 707
GO

Near the bottom of the XML document, you should see the following:

<ParameterList>

                  <ColumnReference Column="@p" ParameterCompiledValue="(710)" ParameterRuntimeValue="(707)" />

</ParameterList>

Seeing the different values used for compilation and execution can lead you to suspect an issue with parameter sniffing. There are several ways around this problem, but that's the topic for another day.

 

Have fun!

~Kalen

Published Monday, July 30, 2007 12:41 PM by Kalen Delaney

Comment Notification

If you would like to receive an email when updates are made to this post, please register here

Subscribe to this post's comments using RSS

Comments

 

david wei said:

Good post.

In your example 2:

I also found that even you roll back the update transacation, the statistics is not rolled back.

Could you please explain more on this, Thanks!

DBCC show_statistics(NewOrders,IX_NewOrders_ProductID)

RANGE_HI_KEY RANGE_ROWS    EQ_ROWS

897 0 40010.7

David Wei

July 30, 2007 8:16 PM
 

Kalen Delaney said:

Hi David

Very interesting observation. I don't think there is anything more to explain, other than what you noticed. The update of stats is not considered part of the transaction.  I'll see if I can find out if Microsoft is considering changing this.

~Kalen

July 30, 2007 10:08 PM
 

Aaron Bertrand said:

You can also see this kind of symptom in the index usage DMVs.  An update that is rolled back or that affects 0 rows still updates columns like last_user_update.  I filed a bug on connect but it was closed as "by design."

July 31, 2007 4:37 PM
 

SAKC said:

I am interested in the workarounds for example 3. This is the burning problem for us from an application where we have not been able to justify the number of reads happening in the actual execution plan. The estimated execution plan is not complaining at all.

September 24, 2008 10:00 AM
 

karan said:

Any body tell clear explanation about estimation plan and acutal plan

January 16, 2013 5:10 AM

Leave a Comment

(required) 
(required) 
Submit

This Blog

Syndication

Favorite Non-technical Sites or Blogs

Powered by Community Server (Commercial Edition), by Telligent Systems
  Privacy Statement