Skip to content

Commit

Permalink
Merge pull request BrentOzarULTD#3553 from ReeceGoding/dev
Browse files Browse the repository at this point in the history
sp_Blitz: Added check for unusual Query Store configuration and Query Store Trace Flags
  • Loading branch information
BrentOzar authored Jul 24, 2024
2 parents 3446b69 + 29f11bc commit a7359ec
Show file tree
Hide file tree
Showing 2 changed files with 89 additions and 5 deletions.
7 changes: 4 additions & 3 deletions Documentation/sp_Blitz_Checks_by_Priority.md
Original file line number Diff line number Diff line change
Expand Up @@ -6,8 +6,8 @@ Before adding a new check, make sure to add a Github issue for it first, and hav

If you want to change anything about a check - the priority, finding, URL, or ID - open a Github issue first. The relevant scripts have to be updated too.

CURRENT HIGH CHECKID: 264.
If you want to add a new one, start at 265.
CURRENT HIGH CHECKID: 265.
If you want to add a new one, start at 266.

| Priority | FindingsGroup | Finding | URL | CheckID |
|----------|-----------------------------|---------------------------------------------------------|------------------------------------------------------------------------|----------|
Expand Down Expand Up @@ -153,7 +153,7 @@ If you want to add a new one, start at 265.
| 200 | Informational | Tables in the Master Database | https://www.BrentOzar.com/go/mastuser | 27 |
| 200 | Informational | Tables in the Model Database | https://www.BrentOzar.com/go/model | 29 |
| 200 | Informational | Tables in the MSDB Database | https://www.BrentOzar.com/go/msdbuser | 28 |
| 200 | Informational | TraceFlag On | https://www.BrentOzar.com/go/traceflags/ | 74 |
| 200 | Informational | TraceFlag On / Recommended Trace Flag Off | https://www.BrentOzar.com/go/traceflags/ | 74 |
| 200 | Licensing | Enterprise Edition Features In Use | https://www.BrentOzar.com/go/ee | 33 |
| 200 | Licensing | Non-Production License | https://www.BrentOzar.com/go/licensing | 173 |
| 200 | Monitoring | Agent Jobs Without Failure Emails | https://www.BrentOzar.com/go/alerts | 94 |
Expand Down Expand Up @@ -250,6 +250,7 @@ If you want to add a new one, start at 265.
| 200 | Performance | Query Store Wait Stats Disabled | https://www.sqlskills.com/blogs/erin/query-store-settings/ | 262 |
| 200 | Performance | Query Store Effectively Disabled | https://learn.microsoft.com/en-us/sql/relational-databases/performance/best-practice-with-the-query-store#Verify | 263 |
| 200 | Performance | Undesired Query Store State | https://learn.microsoft.com/en-us/sql/relational-databases/performance/best-practice-with-the-query-store#Verify | 264 |
| 200 | Performance | Query Store Unusually Configured | https://www.sqlskills.com/blogs/erin/query-store-best-practices/ | 265 |
| 200 | Performance | Snapshot Backups Occurring | https://www.BrentOzar.com/go/snaps | 178 |
| 200 | Performance | User-Created Statistics In Place | https://www.BrentOzar.com/go/userstats | 122 |
| 200 | Performance | SSAS/SSIS/SSRS Installed | https://www.BrentOzar.com/go/services | 224 |
Expand Down
87 changes: 85 additions & 2 deletions sp_Blitz.sql
Original file line number Diff line number Diff line change
Expand Up @@ -6861,6 +6861,41 @@ IF @ProductVersionMajor >= 10
AND desired_state <> actual_state
OPTION (RECOMPILE)';
END;

IF NOT EXISTS ( SELECT 1
FROM #SkipChecks
WHERE DatabaseName IS NULL AND CheckID = 265 )
AND EXISTS(SELECT * FROM sys.all_objects WHERE name = 'database_query_store_options')
BEGIN
IF @Debug IN (1, 2) RAISERROR('Running CheckId [%d].', 0, 1, 265) WITH NOWAIT;

EXEC dbo.sp_MSforeachdb 'USE [?];
SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED;
INSERT INTO #BlitzResults
(CheckID,
DatabaseName,
Priority,
FindingsGroup,
Finding,
URL,
Details)
SELECT TOP 1 265,
N''?'',
200,
''Performance'',
''Query Store Unusually Configured'',
''https://www.sqlskills.com/blogs/erin/query-store-best-practices/'',
(''The '' + query_capture_mode_desc + '' query capture mode '' +
CASE query_capture_mode_desc
WHEN ''ALL'' THEN ''captures more data than you will probably use. If your workload is heavily ad-hoc, then it can also cause Query Store to capture so much that it turns itself off.''
WHEN ''NONE'' THEN ''stops Query Store capturing data for new queries.''
WHEN ''CUSTOM'' THEN ''suggests that somebody has gone out of their way to only capture exactly what they want.''
ELSE ''is not documented.'' END)
FROM [?].sys.database_query_store_options
WHERE desired_state <> 0 /* No point in checking this if Query Store is off. */
AND query_capture_mode_desc <> ''AUTO''
OPTION (RECOMPILE)';
END;

IF @ProductVersionMajor = 13 AND @ProductVersionMinor < 2149 --2016 CU1 has the fix in it
AND NOT EXISTS ( SELECT 1
Expand Down Expand Up @@ -8490,11 +8525,11 @@ IF @ProductVersionMajor >= 10
WHEN [T].[TraceFlag] = '3226' THEN '3226 enabled globally, which keeps the event log clean by not reporting successful backups.'
WHEN [T].[TraceFlag] = '3505' THEN '3505 enabled globally, which disables Checkpoints. This is usually a very bad idea.'
WHEN [T].[TraceFlag] = '4199' THEN '4199 enabled globally, which enables non-default Query Optimizer fixes, changing query plans from the default behaviors.'
WHEN [T].[TraceFlag] = '7745' AND @ProductVersionMajor > 12 AND @QueryStoreInUse = 1 THEN '7745 enabled globally, which makes shutdowns/failovers quicker by not waiting for Query Store to flush to disk. This good idea loses you the non-flushed Query Store data.'
WHEN [T].[TraceFlag] = '7745' AND @QueryStoreInUse = 1 THEN '7745 enabled globally, which makes shutdowns/failovers quicker by not waiting for Query Store to flush to disk. This good idea loses you the non-flushed Query Store data.'
WHEN [T].[TraceFlag] = '7745' AND @ProductVersionMajor > 12 THEN '7745 enabled globally, which is for Query Store. None of your databases have Query Store enabled, so why do you have this turned on?'
WHEN [T].[TraceFlag] = '7745' AND @ProductVersionMajor <= 12 THEN '7745 enabled globally, which is for Query Store. Query Store does not exist on your SQL Server version, so why do you have this turned on?'
WHEN [T].[TraceFlag] = '7752' AND @ProductVersionMajor > 14 THEN '7752 enabled globally, which is for Query Store. However, it has no effect in your SQL Server version. Consider turning it off.'
WHEN [T].[TraceFlag] = '7752' AND @ProductVersionMajor > 12 AND @QueryStoreInUse = 1 THEN '7752 enabled globally, which stops queries needing to wait on Query Store loading up after database recovery.'
WHEN [T].[TraceFlag] = '7752' AND @QueryStoreInUse = 1 THEN '7752 enabled globally, which stops queries needing to wait on Query Store loading up after database recovery.'
WHEN [T].[TraceFlag] = '7752' AND @ProductVersionMajor > 12 THEN '7752 enabled globally, which is for Query Store. None of your databases have Query Store enabled, so why do you have this turned on?'
WHEN [T].[TraceFlag] = '7752' AND @ProductVersionMajor <= 12 THEN '7752 enabled globally, which is for Query Store. Query Store does not exist on your SQL Server version, so why do you have this turned on?'
WHEN [T].[TraceFlag] = '8048' THEN '8048 enabled globally, which tries to reduce CMEMTHREAD waits on servers with a lot of logical processors.'
Expand All @@ -8504,6 +8539,54 @@ IF @ProductVersionMajor >= 10
ELSE [T].[TraceFlag] + ' is enabled globally.' END
AS Details
FROM #TraceStatus T;


IF NOT EXISTS ( SELECT 1
FROM #TraceStatus T
WHERE [T].[TraceFlag] = '7745' )
AND @QueryStoreInUse = 1

BEGIN
INSERT INTO #BlitzResults
( CheckID ,
Priority ,
FindingsGroup ,
Finding ,
URL ,
Details
)
SELECT 74 AS CheckID ,
200 AS Priority ,
'Informational' AS FindingsGroup ,
'Recommended Trace Flag Off' AS Finding ,
'https://www.sqlskills.com/blogs/erin/query-store-trace-flags/' AS URL ,
'Trace Flag 7745 not enabled globally. It makes shutdowns/failovers quicker by not waiting for Query Store to flush to disk. It is recommended, but it loses you the non-flushed Query Store data.' AS Details
FROM #TraceStatus T
END;

IF NOT EXISTS ( SELECT 1
FROM #TraceStatus T
WHERE [T].[TraceFlag] = '7752' )
AND @ProductVersionMajor < 15
AND @QueryStoreInUse = 1

BEGIN
INSERT INTO #BlitzResults
( CheckID ,
Priority ,
FindingsGroup ,
Finding ,
URL ,
Details
)
SELECT 74 AS CheckID ,
200 AS Priority ,
'Informational' AS FindingsGroup ,
'Recommended Trace Flag Off' AS Finding ,
'https://www.sqlskills.com/blogs/erin/query-store-trace-flags/' AS URL ,
'Trace Flag 7752 not enabled globally. It stops queries needing to wait on Query Store loading up after database recovery. It is so recommended that it is enabled by default as of SQL Server 2019.' AS Details
FROM #TraceStatus T
END;
END;

/* High CMEMTHREAD waits that could need trace flag 8048.
Expand Down

0 comments on commit a7359ec

Please sign in to comment.