Query Store hints (Preview)

Applies to: YesAzure SQL Database YesAzure SQL Managed Instance

This article outlines the Query Store hints feature of the Query Store. The Query Store hints feature provides an easy-to-use method for shaping query plans without changing application code.

Note

Query Store hints are a public preview feature currently available in Azure SQL Database – including in Azure SQL single databases, elastic pools, managed instances, and hyperscale databases.

Overview

Ideally the Query Optimizer selects an optimal execution plan for a query. When this doesn't happen, a developer or DBA may wish to manually optimize for specific conditions. Query hints are specified via the OPTION clause and can be used to affect query execution behavior. While query hints help provide localized solutions to various performance-related issues, they do require a rewrite of the original query text. Database administrators and developers may not always be able to make changes directly to Transact-SQL code to inject a query hint. The Transact-SQL may be hard-coded into an application or automatically generated by the application. Previously, a developer may have to rely on plan guides, which can be complex to use.

When to use Query Store hints

As the name suggests, this feature extends and depends on the Query Store. Query Store enables the capturing of queries, execution plans, and associated runtime statistics. Introduced in SQL Server 2016 (13.x) and on-by-default in Azure SQL Database, Query Store greatly simplifies the overall performance tuning customer experience.

The workflow for Query Store Hints.

  First the query is executed, then captured by Query Store. Then the DBA creates a Query Store hint on a query. Thereafter, the query is executed using the Query Store hint.

Examples where Query Store hints can help with query-level performance issues:

  • Recompile a query on each execution.
  • Cap the memory grant size for a bulk insert operation.
  • Limit the maximum degree of parallelism for a statistics update operation.
  • Use a Hash join instead of a Nested Loops join.
  • Use compatibility level 110 for a specific query while keeping everything else in the database at compatibility level 150.
  • Disable row goal optimization for a SELECT TOP query.

To use Query Store hints, do the following:

  1. Identify the Query Store query_id of the query statement you wish to modify. You can do this in various ways: 1.1. Querying the Query Store catalog views. 1.2. Using SQL Server Management Studio built-in Query Store reports. 1.3. Using Azure portal Query Performance Insight for Azure SQL Database.
  2. Execute sp_query_store_set_hints with the query_id and query hint string you wish to apply to the query. This string can contain one or more query hints. For complete information, see sys.sp_query_store_set_hints.

Once created, Query Store hints are persisted and survive restarts and failovers. Query Store hints override hard-coded statement level hints and existing plan guide hints.

If a query hint contradicts what is possible for query optimization, the hint will not block query execution and the hint will not be applied. In the cases where a hint would cause a query to fail, the hint is ignored and the latest failure details can be viewed in sys.query_store_query_hints.

Watch this video for an overview of Query Store hints:

Query Store hints system stored procedures

To create or update hints, use sys.sp_query_store_set_hints.

Hints are specified in a valid string format N'OPTION (...)'.

Note

For a complete list of hints that are supported, see sys.sp_query_store_set_hints.

  • If no Query Store hint exists for a specific query_id, a new Query Store hint will be created.
  • If a Query Store hint already exists for a specific query_id, the last value provided will override previously specified values for the associated query.
  • If a query_id doesn't exist, an error will be raised.

To remove hints associated with a query_id, use sys.sp_query_store_clear_hints.

Execution Plan XML attributes

When hints are applied, the following will be surfaced in the StmtSimple element of the Execution Plan in XML format:

Attribute Description
QueryStoreStatementHintText Actual Query Store hint(s) applied to the query
QueryStoreStatementHintId Unique identifier of a query hint
QueryStoreStatementHintSource Source of Query Store hint (ex: "User")

Note

During the Query Store hints public preview, these XML elements will be available only via the output of the Transact-SQL commands SET STATISTICS XML and SET SHOWPLAN XML.

Examples

A. Query Store hints demo

The following walk-through of the Query Store hints feature in Azure SQL Database uses an imported database via a BACPAC file (.bacpac). Learn how to import a new database to an Azure SQL Database server, see Quickstart: Import a BACPAC file to a database.

-- ************************************************************************ --
-- Query Store hints demo

-- Demo uses "PropertyMLS" database which can be imported from BACPAC here:
-- https://github.com/microsoft/sql-server-samples/tree/master/samples/features/query-store

-- Email QSHintsFeedback@microsoft.com for questions\feedback
-- ************************************************************************ --

/*
    Demo prep, connect to the PropertyMLS database
*/

ALTER DATABASE [PropertyMLS] SET QUERY_STORE CLEAR;
ALTER DATABASE CURRENT SET QUERY_STORE = ON;
ALTER DATABASE CURRENT SET QUERY_STORE  (QUERY_CAPTURE_MODE = ALL);
GO

-- Should be READ_WRITE
SELECT actual_state_desc 
FROM sys.database_query_store_options;
GO

/*
    You can verify Query Store Hints in sys.query_store_query_hints.
    Checking if any already exist (should be none).
*/
SELECT	query_hint_id,
        query_id,
        query_hint_text,
        last_query_hint_failure_reason,
        last_query_hint_failure_reason_desc,
        query_hint_failure_count,
        source,
        source_desc
FROM sys.query_store_query_hints;
GO

/*
     The PropertySearchByAgent stored procedure has a parameter
     used to filter AgentId.  Looking at the statistics for AgentId,
     you will see that there is a big skew for AgentId 101.
*/
SELECT	hist.range_high_key AS [AgentId], 
        hist.equal_rows
FROM sys.stats AS s
CROSS APPLY sys.dm_db_stats_histogram(s.[object_id], s.stats_id) AS hist
WHERE s.[name] = N'NCI_Property_AgentId';


-- Show actual query execution plan to see plan compiled.
-- Agent with many properties will have a scan with parallelism.
EXEC [dbo].[PropertySearchByAgent] 101;

-- Agents with few properties still re-use this plan (assuming no recent plan eviction).
EXEC [dbo].[PropertySearchByAgent] 4;


/*
    Now let's find the query_id associated with this query.
*/
SELECT query_sql_text, q.query_id
FROM sys.query_store_query_text qt 
INNER JOIN sys.query_store_query q ON 
    qt.query_text_id = q.query_text_id 
WHERE query_sql_text like N'%ORDER BY ListingPrice DESC%' and query_sql_text not like N'%query_store%';
GO

/*
     We can set the hint associated with the query_id returned in the previous result set, as below.
     Note, we can designate one or more query hints
*/
EXEC sp_query_store_set_hints @query_id=5, @value = N'OPTION(RECOMPILE)';
GO

/*
    You can verify Query Store Hints in sys.query_store_query_hints
*/
SELECT	query_hint_id,
        query_id,
        query_hint_text,
        last_query_hint_failure_reason,
        last_query_hint_failure_reason_desc,
        query_hint_failure_count,
        source,
        source_desc
FROM sys.query_store_query_hints;
GO

-- Execute both at the same time and show actual query execution plan.
-- You should see two different plans, one for AgentId 101 and one for AgentId 4.
EXEC [dbo].[PropertySearchByAgent] 101;
EXEC [dbo].[PropertySearchByAgent] 4;
GO

SELECT	query_hint_id,
        query_id,
        query_hint_text,
        last_query_hint_failure_reason,
        last_query_hint_failure_reason_desc,
        query_hint_failure_count,
        source,
        source_desc
FROM sys.query_store_query_hints;
GO

/*
    We can remove the hint using sp_query_store_clear_query_hints
*/
EXEC sp_query_store_clear_hints @query_id = 10;
GO

/*
    That Query Store Hint is now removed
*/
SELECT	query_hint_id,
        query_id,
        query_hint_text,
        last_query_hint_failure_reason,
        last_query_hint_failure_reason_desc,
        query_hint_failure_count,
        source,
        source_desc
FROM sys.query_store_query_hints;
GO

-- Execute both at the same time and show actual query execution plan.
-- You should see one plan again.
EXEC [dbo].[PropertySearchByAgent] 101;
EXEC [dbo].[PropertySearchByAgent] 4;
GO

B. Identify a query in Query Store

The following example queries sys.query_store_query_text and sys.query_store_query to return the query_id for an executed query text fragment:

SELECT q.query_id, qt.query_sql_text
FROM sys.query_store_query_text qt 
INNER JOIN sys.query_store_query q ON 
    qt.query_text_id = q.query_text_id 
WHERE query_sql_text like N'%ORDER BY ListingPrice DESC%'  
  AND query_sql_text not like N'%query_store%';
GO

Then, apply the hint to enforce a maximum memory grant size in percent of configured memory limit to the query_id (in this example, query_id in the previous query's resultset was 39):

EXEC sys.sp_query_store_set_hints @query_id= 39, @query_hints = N'OPTION(MAX_GRANT_PERCENT=10)';

You can also apply query hints with the following syntax, for example the option to force the legacy cardinality estimator:

EXEC sys.sp_query_store_set_hints @query_id= 39, @query_hints = N'OPTION(USE HINT(''FORCE_LEGACY_CARDINALITY_ESTIMATION''))';

You can apply multiple query hints with a comma-separated list:

EXEC sys.sp_query_store_set_hints @query_id= 39, @query_hints = N'OPTION(RECOMPILE, MAXDOP 1, USE HINT(''QUERY_OPTIMIZER_COMPATIBILITY_LEVEL_110''))';

Review the Query Store hint in place for query_id 39:

SELECT query_hint_id, query_id, query_hint_text, last_query_hint_failure_reason, last_query_hint_failure_reason_desc, query_hint_failure_count, source, source_desc 
FROM sys.query_store_query_hints 
WHERE query_id = 39;

Next steps

See also