sp_query_store_unforce_plan (Transact-SQL)

Applies to: SQL Server 2016 (13.x) and later Azure SQL Database Azure SQL Managed Instance

Enables unforcing a previously forced plan for a particular query in the Query Store.

Transact-SQL syntax conventions

Syntax

sp_query_store_unforce_plan
    [ @query_id = ] query_id ,
    [ @plan_id = ] plan_id ,
    [ @force_plan_scope = ] 'replica_group_id'
[ ; ]

Arguments

Important

Arguments for extended stored procedures must be entered in the specific order as described in the Syntax section. If the parameters are entered out of order, an error message occurs.

[ @query_id = ] query_id

The ID of the query. @query_id is bigint, with no default.

[ @plan_id = ] plan_id

The ID of the query plan that will no longer be enforced. @plan_id is bigint, with no default.

[ @force_plan_scope = ] 'replica_group_id'

You can force and unforce plans on a secondary replica when Query Store for secondary replicas is enabled. Execute sp_query_store_force_plan and sp_query_store_unforce_plan on the secondary replica. The optional @force_plan_scope argument defaults only to the local replica, but you can optionally specify a replica_group_id referencing sys.query_store_plan_forcing_locations.

Return code values

0 (success) or 1 (failure).

Permissions

Requires the ALTER permission on the database.

Examples

The following example returns information about the queries in the Query Store.

SELECT txt.query_text_id,
    txt.query_sql_text,
    pl.plan_id,
    qry.*
FROM sys.query_store_plan AS pl
INNER JOIN sys.query_store_query AS qry
    ON pl.query_id = qry.query_id
INNER JOIN sys.query_store_query_text AS txt
    ON qry.query_text_id = txt.query_text_id;

After you identify the query_id and plan_id that you want to unforce, use the following example to unforce the plan.

EXEC sp_query_store_unforce_plan 3, 3;