1
+ /*
2
+ This stored procedure sets or clears Query Store hints
3
+ for all queries with the specified query hash
4
+ that are present in Query Store in the current database.
5
+
6
+ For more information about Query Store hints, see:
7
+ Overview: https://learn.microsoft.com/sql/relational-databases/performance/query-store-hints.
8
+ Best practices: https://learn.microsoft.com/sql/relational-databases/performance/query-store-hints-best-practices.
9
+ Usage scenarios: https://learn.microsoft.com/sql/relational-databases/performance/query-store-usage-scenarios.
10
+
11
+ Usage examples:
12
+
13
+ /* Set query hints for all queries with the specified query hash */
14
+ EXEC dbo .sp_query_store_modify_hints_by_query_hash
15
+ @action = ' set' ,
16
+ @query_hint_text = ' OPTION (MAXDOP 1, USE HINT ('' ENABLE_QUERY_OPTIMIZER_HOTFIXES'' ))' ,
17
+ @query_hash = 0xB5AF960709ADE6F2;
18
+
19
+ /* Clear query hints for all queries with the specified query hash */
20
+ EXEC dbo .sp_query_store_modify_hints_by_query_hash
21
+ @action = ' clear' ,
22
+ @query_hash = 0xB5AF960709ADE6F2;
23
+ * /
24
+
25
+ CREATE OR ALTER PROCEDURE dbo .sp_query_store_modify_hints_by_query_hash
26
+ @action nvarchar (5 ),
27
+ @query_hash binary (8 ),
28
+ @query_hint_text nvarchar (max ) = NULL ,
29
+ @replica_group_id bigint = NULL
30
+ AS
31
+ SET NOCOUNT , XACT_ABORT ON ;
32
+ SET DEADLOCK_PRIORITY LOW;
33
+ SET LOCK_TIMEOUT 3000 ;
34
+
35
+ BEGIN TRY
36
+
37
+ DECLARE @sql_server_2022 bit = IIF (CAST (SERVERPROPERTY (' ProductMajorVersion' ) AS nvarchar (128 )) COLLATE DATABASE_DEFAULT = N ' 16' AND CAST (SERVERPROPERTY (' EngineEdition' ) AS int ) IN (1 ,2 ,3 ,4 ), 1 , 0 ),
38
+ @sql_server_2025_later bit = IIF (CAST (SERVERPROPERTY (' ProductMajorVersion' ) AS nvarchar (128 )) COLLATE DATABASE_DEFAULT >= N ' 17' AND CAST (SERVERPROPERTY (' EngineEdition' ) AS int ) IN (1 ,2 ,3 ,4 ), 1 , 0 ),
39
+ @sql_mi_2022 bit = IIF (CAST (SERVERPROPERTY (' EngineEdition' ) AS int ) = 8 AND CAST (SERVERPROPERTY (' ProductMajorVersion' ) AS nvarchar (128 )) COLLATE DATABASE_DEFAULT < N ' 17' AND CAST (SERVERPROPERTY (' ProductUpdateType' ) AS nvarchar (128 )) COLLATE DATABASE_DEFAULT = ' CU' , 1 , 0 ),
40
+ @sql_mi_2025_later bit = IIF (CAST (SERVERPROPERTY (' EngineEdition' ) AS int ) = 8 AND CAST (SERVERPROPERTY (' ProductMajorVersion' ) AS nvarchar (128 )) COLLATE DATABASE_DEFAULT >= N ' 17' AND CAST (SERVERPROPERTY (' ProductUpdateType' ) AS nvarchar (128 )) COLLATE DATABASE_DEFAULT = ' CU' , 1 , 0 ),
41
+ @sql_mi_always_up_to_date bit = IIF (CAST (SERVERPROPERTY (' EngineEdition' ) AS int ) = 8 AND CAST (SERVERPROPERTY (' ProductUpdateType' ) AS nvarchar (128 )) COLLATE DATABASE_DEFAULT = ' Continuous' , 1 , 0 ),
42
+ @sql_db bit = IIF (CAST (SERVERPROPERTY (' EngineEdition' ) AS int ) = 5 , 1 , 0 ),
43
+ @return int = - 1111 ,
44
+ @resource sysname = LOWER (OBJECT_NAME (@@PROCID )),
45
+ @query_id bigint ,
46
+ @message nvarchar (max ),
47
+ @count_queries_with_existing_hints bigint = 0 ,
48
+ @existing_hints_sample_query_id bigint ,
49
+ @existing_hints_sample_text nvarchar (max ),
50
+ @multiple_query_hints_sample_query_id bigint ,
51
+ @multiple_query_hints_sample_replica_group_id bigint ,
52
+ @hint_replica_group_id bigint ;
53
+
54
+ /* Start validation */
55
+
56
+ IF NOT (
57
+ @sql_server_2022 = 1 OR @sql_server_2025_later = 1 OR @sql_mi_2022 = 1 OR @sql_mi_always_up_to_date = 1 OR @sql_db = 1
58
+ )
59
+ THROW 50001 , ' Query Store hints are not supported in this database engine version. Use this stored procedure in SQL Server 2022 and later, in Azure SQL Database, and in Azure SQL Managed Instance.' , 1 ;
60
+
61
+ EXEC @return = sys .sp_getapplock @Resource = @resource,
62
+ @LockMode = ' Exclusive' ,
63
+ @LockOwner = ' Session' ,
64
+ @LockTimeout = 0 ;
65
+ IF @return <> 0
66
+ THROW 50002 , ' Could not acquire a lock on the execution of this stored procedure. Multiple concurrent executions are not allowed.' , 1 ;
67
+
68
+ IF DB_ID () IN (1 ,2 )
69
+ THROW 50003 , ' This stored procedure cannot be executed in the '' master'' or '' tempdb'' databases. Create this stored procedure in another database and execute it in the context of that database.' , 1 ;
70
+
71
+ IF LOWER (@action) COLLATE DATABASE_DEFAULT NOT IN (' set' ,' clear' )
72
+ BEGIN
73
+ SELECT @message = FORMATMESSAGE (' The value '' %s'' specified for the @action parameter is invalid. The valid values are '' set'' and '' clear'' .' , @action);
74
+ THROW 50004 , @message, 1 ;
75
+ END ;
76
+
77
+ IF LOWER (@action) COLLATE DATABASE_DEFAULT = ' set' AND @query_hint_text IS NULL
78
+ THROW 50005 , ' Parameter @query_hint_text is required when parameter @action is '' set'' .' , 1 ;
79
+
80
+ IF LOWER (@action) COLLATE DATABASE_DEFAULT = ' clear' AND @query_hint_text IS NOT NULL
81
+ THROW 50006 , ' Parameter @query_hint_text must not be specified when parameter @action is '' clear'' .' , 1 ;
82
+
83
+ IF NOT (@sql_server_2025_later = 1 OR @sql_mi_2025_later = 1 OR @sql_mi_always_up_to_date = 1 OR @sql_db = 1 ) AND @replica_group_id IS NOT NULL
84
+ THROW 50007 , ' Parameter @replica_group_id cannot be specified in this database engine version.' , 1 ;
85
+
86
+ /*
87
+ Do not overwrite existing hints if they are different
88
+ */
89
+ SELECT @count_queries_with_existing_hints = COUNT (1 ),
90
+ @existing_hints_sample_query_id = MIN (q .query_id ),
91
+ @existing_hints_sample_text = MIN (qh .query_hint_text )
92
+ FROM sys .query_store_query AS q
93
+ INNER JOIN sys .query_store_query_hints AS qh
94
+ ON q .query_id = qh .query_id
95
+ WHERE q .query_hash = @query_hash
96
+ AND
97
+ LOWER (qh .query_hint_text ) <> LOWER (@query_hint_text) COLLATE DATABASE_DEFAULT
98
+ AND
99
+ (@replica_group_id IS NULL OR qh .replica_group_id = @replica_group_id)
100
+ AND
101
+ LOWER (@action) COLLATE DATABASE_DEFAULT = ' set' ;
102
+
103
+ IF @count_queries_with_existing_hints > 0
104
+ BEGIN
105
+ SELECT @message = FORMATMESSAGE (
106
+ ' %I64d queries with query hash %s, including query ID %I64d, already have query hints that are different from those specified, for example '' %s'' . Clear existing hints from all queries with this query hash and try again.' ,
107
+ @count_queries_with_existing_hints, CONVERT (varchar (18 ), @query_hash, 1 ), @existing_hints_sample_query_id, @existing_hints_sample_text
108
+ );
109
+ THROW 50008 , @message, 1 ;
110
+ END ;
111
+
112
+ /*
113
+ The uniqueness of {query_id, replica_group_id} in sys.query_store_query_hints is not enforced.
114
+ Abort if there is more than one row per {query_id, replica_group_id}.
115
+ */
116
+ WITH query_replica_group_hint AS
117
+ (
118
+ SELECT qh .query_id ,
119
+ qh .replica_group_id ,
120
+ COUNT (1 ) OVER (PARTITION BY qh .query_id , qh .replica_group_id ) AS count_hints
121
+ FROM sys .query_store_query AS q
122
+ INNER JOIN sys .query_store_query_hints AS qh
123
+ ON q .query_id = qh .query_id
124
+ WHERE q .query_hash = @query_hash
125
+ )
126
+ SELECT TOP (1 ) @multiple_query_hints_sample_query_id = query_id,
127
+ @multiple_query_hints_sample_replica_group_id = replica_group_id
128
+ FROM query_replica_group_hint
129
+ WHERE count_hints > 1
130
+ ORDER BY query_id ASC , replica_group_id ASC ;
131
+
132
+ IF @@ROWCOUNT > 0
133
+ BEGIN
134
+ SELECT @message = FORMATMESSAGE (
135
+ ' Some queries with query hash %s, including query ID %I64d with replica group ID %I64d, unexpectedly have multiple query hint rows in sys.query_store_query_hints.' ,
136
+ CONVERT (varchar (18 ), @query_hash, 1 ), @multiple_query_hints_sample_query_id, @multiple_query_hints_sample_replica_group_id
137
+ );
138
+ THROW 50009 , @message, 1 ;
139
+ END ;
140
+
141
+ /* End validation */
142
+
143
+ /* Loop over all queries matching the specified query hash, with or without existing query hints */
144
+
145
+ DECLARE query_hints CURSOR LOCAL STATIC FOR
146
+ SELECT q .query_id ,
147
+ qh .replica_group_id
148
+ FROM sys .query_store_query AS q
149
+ LEFT JOIN sys .query_store_query_hints AS qh
150
+ ON q .query_id = qh .query_id
151
+ WHERE q .query_hash = @query_hash
152
+ ORDER BY query_id ASC ;
153
+
154
+ OPEN query_hints;
155
+
156
+ WHILE 1 = 1
157
+ BEGIN
158
+
159
+ FETCH NEXT FROM query_hints
160
+ INTO @query_id, @hint_replica_group_id;
161
+
162
+ IF @@FETCH_STATUS <> 0
163
+ BREAK ;
164
+
165
+ /* Set or clear hints for each eligible query */
166
+
167
+ IF LOWER (@action) COLLATE DATABASE_DEFAULT = ' set'
168
+ BEGIN
169
+ IF (@sql_server_2025_later = 1 OR @sql_mi_2025_later = 1 OR @sql_mi_always_up_to_date = 1 OR @sql_db = 1 )
170
+ AND
171
+ @replica_group_id IS NOT NULL
172
+ BEGIN
173
+ EXEC sys .sp_query_store_set_hints @query_id = @query_id,
174
+ @query_hints = @query_hint_text,
175
+ @replica_group_id = @replica_group_id;
176
+
177
+ SELECT @message = FORMATMESSAGE (' Executed sys.sp_query_store_set_hints to set hints '' %s'' for query ID %I64d and replica group ID %I64d.' , @query_hint_text, @query_id, @replica_group_id);
178
+ END ;
179
+ ELSE
180
+ BEGIN
181
+ EXEC sys .sp_query_store_set_hints @query_id = @query_id,
182
+ @query_hints = @query_hint_text;
183
+
184
+ SELECT @message = FORMATMESSAGE (' Executed sys.sp_query_store_set_hints to set hints '' %s'' for query ID %I64d.' , @query_hint_text, @query_id);
185
+ END ;
186
+
187
+ PRINT @message;
188
+ END
189
+ ELSE IF LOWER (@action) COLLATE DATABASE_DEFAULT = ' clear'
190
+ BEGIN
191
+ IF @replica_group_id <> @hint_replica_group_id
192
+ BEGIN
193
+ SELECT @message = FORMATMESSAGE (
194
+ ' Skipped executing sys.sp_query_store_clear_hints for query ID %I64d because the replica group ID of the current hint %I64d is different from the specified replica group ID %I64d.' ,
195
+ @query_id, @hint_replica_group_id, @replica_group_id
196
+ );
197
+ END
198
+ ELSE IF (@sql_server_2025_later = 1 OR @sql_mi_2025_later = 1 OR @sql_mi_always_up_to_date = 1 OR @sql_db = 1 )
199
+ AND
200
+ @replica_group_id IS NOT NULL
201
+ BEGIN
202
+ EXEC sys .sp_query_store_clear_hints @query_id = @query_id,
203
+ @replica_group_id = @replica_group_id;
204
+
205
+ SELECT @message = FORMATMESSAGE (' Executed sys.sp_query_store_clear_hints for query ID %I64d and replica group ID %I64d.' , @query_id, @replica_group_id);
206
+ END ;
207
+ ELSE
208
+ BEGIN
209
+ EXEC sys .sp_query_store_clear_hints @query_id = @query_id;
210
+
211
+ SELECT @message = FORMATMESSAGE (' Executed sys.sp_query_store_clear_hints for query ID %I64d.' , @query_id);
212
+ END ;
213
+
214
+ PRINT @message;
215
+ END ;
216
+
217
+ END ;
218
+
219
+ SELECT @message = FORMATMESSAGE (
220
+ CONCAT (CHAR (13 ), CHAR (10 ), ' Query hash: %s. Queries processed: %d' ),
221
+ CONVERT (varchar (18 ), @query_hash, 1 ), @@CURSOR_ROWS
222
+ );
223
+ PRINT @message;
224
+
225
+ CLOSE query_hints;
226
+ DEALLOCATE query_hints;
227
+
228
+ END TRY
229
+ BEGIN CATCH
230
+ THROW ;
231
+ END CATCH ;
232
+
233
+ BEGIN TRY
234
+ EXEC sys .sp_releaseapplock @Resource = @resource,
235
+ @LockOwner = ' Session' ;
236
+ END TRY
237
+ BEGIN CATCH
238
+ END CATCH ;
239
+ GO
0 commit comments