DISABLE_PARAMETER_SNIFFING

 According to MSDN article, 'DISABLE_PARAMETER_SNIFFING' instructs Query Optimizer to use average data distribution while compiling a query with one or more parameters. This instruction makes the query plan independent on the parameter value that was first used when the query was compiled. This hint name is equivalent to trace flag 4136 or Database Scoped Configuration setting PARAMETER_SNIFFING = OFF.

 

 

Looks like it's a pretty good hint, However, it doesn't means you can resolve all parameter sniffing issue by using this query hint.

 

Actually,  the sentence 'Query Optimizer to use average data distribution while compiling a query with one or more parameters' is not 100% correct. It really depends on what symbol you used in the where clause.

 

'DISABLE_PARAMETER_SNIFFING' is a replacement of variable, and it has same effect as 'OPTIMIZE FOR UNKNOWN' , These three have exactly same effect.  If you are not familiar with selectivity of variable, please review  my post Selectivity and Estimated Row: Variable - Microsoft Tech Community

I'm going to use AdventureWorks 2019 in this post.

--------------------Please run this script---------------

use AdventureWorks2019

go

IF exists(select 1 from sys.tables where name='SalesOrderDetail' and schema_id=schema_id('dbo'))

      drop table SalesOrderDetail

go

select * into SalesOrderDetail from [Sales].[SalesOrderDetail]

go

create statistics iProductID ON SalesOrderDetail(productid) with fullscan

Go

dbcc traceon(3604,2363)

--------------------Please run this script---------------

 

 

 

For example, following three stored procedures return exactly same Estimated rows 456.

 

create proc ptest1

@pid int

as

select * from SalesOrderDetail where productid=@pid option(use hint('DISABLE_PARAMETER_SNIFFING'))

go

create proc ptest2

@pid int

as

select * from SalesOrderDetail where productid=@pid option(recompile,OPTIMIZE FOR UNKNOWN)

Go

create proc ptest3

@pid int

as

declare @pid1 int =@pid

select * from SalesOrderDetail where productid=@pid1

Go

undefined

 

 

 

 

 

Trace flag 2363 displays more detail about the selectivity.

undefined

 

 

----------------------------------trace flag 2363 output----------------------------------

Begin selectivity computation

Input tree:

  LogOp_Select

      CStCollBaseTable(ID=1, CARD=121317 TBL: Sales.SalesOrderDetail)

      ScaOp_Comp x_cmpEq

          ScaOp_Identifier QCOL: [AdventureWorks2019].[Sales].[SalesOrderDetail].ProductID

          ScaOp_Identifier COL: @pid

Plan for computation:

  CSelCalcHistogramComparison(POINT PREDICATE)

Loaded histogram for column QCOL: [AdventureWorks2019].[Sales].[SalesOrderDetail].ProductID from stats with id 3

Selectivity: 0.0037594

Stats collection generated:

  CStCollFilter(ID=2, CARD=456.079)

      CStCollBaseTable(ID=1, CARD=121317 TBL: Sales.SalesOrderDetail)

End selectivity computation

----------------------------------trace flag 2363 output----------------------------------

 121317*0.0037594=456

 

 

Please review Selectivity and Estimated Row: Variable (sqlserverbang.blogspot.com for other inequations.

Comments

popular posts

SQL Server Polybase in Failover cluster instance

Tutorial: Create SQL Cluster(FCI) on RHEL

Configure multiple-subnet Always On Availability Groups and failover cluster instances by modifying CIB

Realcase: Failed to upgrade SQL Server 2016 SP2 CU11. (Installation success or error status: 1648)

How to find SQL Server Replication related jobs and T-SQL statements

SQL Server Extents, PFS, GAM, SGAM and IAM and related corruptions

Tutorial: Add a node to SQL cluster on RHEL

Password is required when adding a database to AG group if the database has a master key

You may fail to backup log or restore log after TDE certification/key rotation

SQL Server GAM corruption samples