sys.dm_exec_query_optimizer_info (Transact-SQL)

Returns detailed statistics about the operation of the SQL Server query optimizer. You can use this view when tuning a workload to identify query optimization problems or improvements. For example, you can use the total number of optimizations, the elapsed time value, and the final cost value to compare the query optimizations of the current workload and any changes observed during the tuning process. Some counters provide data that is relevant only for SQL Server internal diagnostic use. These counters are marked as "Internal only."

Name

Data type

Description

counter

nvarchar(4000)

Name of optimizer statistics event.

occurrence

bigint

Number of occurrences of optimization event for this counter.

value

float

Average property value per event occurrence.

Permissions

Requires VIEW SERVER STATE permission on the server.

Remarks

sys.dm_exec_query_optimizer_info contains the following properties (counters). All occurrence values are cumulative and are set to 0 at system restart. All values for value fields are set to NULL at system restart. All value-column values that specify an average use the occurrence value from the same row as the denominator in the calculation of the average. All query optimizations are measured when SQL Server determines changes to dm_exec_query_optimizer_info, including both user- and system-generated queries. Execution of an already-cached plan does not change values in dm_exec_query_optimizer_info, only optimizations are significant.

Counter

Occurrence

Value

optimizations

Total number of optimizations.

Not applicable

elapsed time

Total number of optimizations.

Average elapsed time per optimization of an individual statement (query), in seconds.

final cost

Total number of optimizations.

Average estimated cost for an optimized plan in internal cost units.

trivial plan

Internal only

Internal only

tasks

Internal only

Internal only

no plan

Internal only

Internal only

search 0

Internal only

Internal only

search 0 time

Internal only

Internal only

search 0 tasks

Internal only

Internal only

search 1

Internal only

Internal only

search 1 time

Internal only

Internal only

search 1 tasks

Internal only

Internal only

search 2

Internal only

Internal only

search 2 time

Internal only

Internal only

search 2 tasks

Internal only

Internal only

gain stage 0 to stage 1

Internal only

Internal only

gain stage 1 to stage 2

Internal only

Internal only

timeout

Internal only

Internal only

memory limit exceeded

Internal only

Internal only

insert stmt

Number of optimizations that are for INSERT statements.

Not applicable

delete stmt

Number of optimizations that are for DELETE statements.

Not applicable

update stmt

Number of optimizations that are for UPDATE statements.

Not applicable

contains subquery

Number of optimizations for a query that contains at least one subquery.

Not applicable

unnest failed

Internal only

Internal only

tables

Total number of optimizations.

Average number of tables referenced per query optimized.

hints

Number of times some hint was specified. Hints counted include: JOIN, GROUP, UNION and FORCE ORDER query hints, FORCE PLAN set option, and join hints.

Not applicable

order hint

Number of times a force order hint was specified.

Not applicable

join hint

Number of times the join algorithm was forced by a join hint.

Not applicable

view reference

Number of times a view has been referenced in a query.

Not applicable

remote query

Number of optimizations where the query referenced at least one remote data source, such as a table with a four-part name or an OPENROWSET result.

Not applicable

maximum DOP

Total number of optimizations.

Average effective MAXDOP value for an optimized plan. By default, effective MAXDOP is determined by the max degree of parallelism server configuration option, and may be overridden for a specific query by the value of the MAXDOP query hint.

maximum recursion level

Number of optimizations in which a MAXRECURSION level greater than 0 has been specified with the query hint.

Average MAXRECURSION level in optimizations where a maximum recursion level is specified with the query hint.

indexed views loaded

Internal only

Internal only

indexed views matched

Number of optimizations where one or more indexed views have been matched.

Average number of views matched.

indexed views used

Number of optimizations where one or more indexed views are used in the output plan after being matched.

Average number of views used.

indexed views updated

Number of optimizations of a DML statement that produce a plan that maintains one or more indexed views.

Average number of views maintained.

dynamic cursor request

Number of optimizations in which a dynamic cursor request has been specified.

Not applicable

fast forward cursor request

Number of optimizations in which a fast-forward cursor request has been specified.

Not applicable

merge stmt

Number of optimizations that are for MERGE statements.

Not applicable

Examples

A. Viewing statistics on optimizer execution

What are the current optimizer execution statistics for this instance of SQL Server?

SELECT * FROM sys.dm_exec_query_optimizer_info;

B. Viewing the total number of optimizations

How many optimizations are performed?

SELECT occurrence AS Optimizations FROM sys.dm_exec_query_optimizer_info
WHERE counter = 'optimizations';

C. Average elapsed time per optimization

What is the average elapsed time per optimization?

SELECT ISNULL(value,0.0) AS ElapsedTimePerOptimization
FROM sys.dm_exec_query_optimizer_info WHERE counter = 'elapsed time';

D. Fraction of optimizations that involve subqueries

What fraction of optimized queries contained a subquery?

SELECT (SELECT CAST (occurrence AS float) FROM sys.dm_exec_query_optimizer_info WHERE counter = 'contains subquery') /
       (SELECT CAST (occurrence AS float) 
        FROM sys.dm_exec_query_optimizer_info WHERE counter = 'optimizations')
        AS ContainsSubqueryFraction;

See Also

Reference

Dynamic Management Views and Functions (Transact-SQL)

Execution Related Dynamic Management Views and Functions (Transact-SQL)