Skip to content

Commit 9661ea3

Browse files
authored
Merge pull request #3382 from Montro1981/SQL-Server-First-Responder-Kit_3362
#3362 Rewrite of check 192 and 193
2 parents b0b2875 + a2bea2f commit 9661ea3

File tree

1 file changed

+134
-115
lines changed

1 file changed

+134
-115
lines changed

sp_Blitz.sql

Lines changed: 134 additions & 115 deletions
Original file line numberDiff line numberDiff line change
@@ -8704,122 +8704,141 @@ IF @ProductVersionMajor >= 10 AND NOT EXISTS ( SELECT 1
87048704
EXECUTE(@StringToExecute);
87058705
END;
87068706

8707-
/*
8708-
Starting with SQL Server 2014 SP2, Instant File Initialization
8709-
is logged in the SQL Server Error Log.
8710-
*/
8711-
IF NOT EXISTS ( SELECT 1
8712-
FROM #SkipChecks
8713-
WHERE DatabaseName IS NULL AND CheckID = 193 )
8714-
AND ((@ProductVersionMajor >= 13) OR (@ProductVersionMajor = 12 AND @ProductVersionMinor >= 5000))
8715-
BEGIN
8716-
8717-
IF @Debug IN (1, 2) RAISERROR('Running CheckId [%d].', 0, 1, 193) WITH NOWAIT;
8718-
8719-
-- If this is Amazon RDS, use rdsadmin.dbo.rds_read_error_log
8720-
IF LEFT(CAST(SERVERPROPERTY('ComputerNamePhysicalNetBIOS') AS VARCHAR(8000)), 8) = 'EC2AMAZ-'
8721-
AND LEFT(CAST(SERVERPROPERTY('MachineName') AS VARCHAR(8000)), 8) = 'EC2AMAZ-'
8722-
AND db_id('rdsadmin') IS NOT NULL
8723-
AND EXISTS(SELECT * FROM master.sys.all_objects WHERE name IN ('rds_startup_tasks', 'rds_help_revlogin', 'rds_hexadecimal', 'rds_failover_tracking', 'rds_database_tracking', 'rds_track_change'))
8724-
BEGIN
8725-
INSERT INTO #ErrorLog
8726-
EXEC rdsadmin.dbo.rds_read_error_log 0, 1, N'Database Instant File Initialization: enabled';
8727-
END
8728-
ELSE
8729-
BEGIN
8730-
BEGIN TRY
8731-
INSERT INTO #ErrorLog
8732-
EXEC sys.xp_readerrorlog 0, 1, N'Database Instant File Initialization: enabled';
8733-
END TRY
8734-
BEGIN CATCH
8735-
IF @Debug IN (1, 2) RAISERROR('No permissions to execute xp_readerrorlog.', 0, 1) WITH NOWAIT;
8736-
END CATCH
8737-
END
8738-
8739-
IF EXISTS
8740-
(
8741-
SELECT 1/0
8742-
FROM #ErrorLog
8743-
WHERE LEFT([Text], 45) = N'Database Instant File Initialization: enabled'
8744-
)
8745-
BEGIN
8746-
INSERT INTO #BlitzResults
8747-
( CheckID ,
8748-
[Priority] ,
8749-
FindingsGroup ,
8750-
Finding ,
8751-
URL ,
8752-
Details
8753-
)
8754-
SELECT
8755-
193 AS [CheckID] ,
8756-
250 AS [Priority] ,
8757-
'Server Info' AS [FindingsGroup] ,
8758-
'Instant File Initialization Enabled' AS [Finding] ,
8759-
'https://www.brentozar.com/go/instant' AS [URL] ,
8760-
'The service account has the Perform Volume Maintenance Tasks permission.';
8761-
END;
8762-
else -- if version of sql server has instant_file_initialization_enabled column in dm_server_services, check that too
8763-
-- in the event the error log has been cycled and the startup messages are not in the current error log
8764-
begin
8765-
if EXISTS ( SELECT *
8766-
FROM sys.all_objects o
8767-
INNER JOIN sys.all_columns c ON o.object_id = c.object_id
8768-
WHERE o.name = 'dm_server_services'
8769-
AND c.name = 'instant_file_initialization_enabled' )
8770-
begin
8771-
SET @StringToExecute = N'
8772-
INSERT INTO #BlitzResults
8773-
( CheckID ,
8774-
[Priority] ,
8775-
FindingsGroup ,
8776-
Finding ,
8777-
URL ,
8778-
Details
8779-
)
8780-
SELECT
8781-
193 AS [CheckID] ,
8782-
250 AS [Priority] ,
8783-
''Server Info'' AS [FindingsGroup] ,
8784-
''Instant File Initialization Enabled'' AS [Finding] ,
8785-
''https://www.brentozar.com/go/instant'' AS [URL] ,
8786-
''The service account has the Perform Volume Maintenance Tasks permission.''
8787-
where exists (select 1 FROM sys.dm_server_services
8788-
WHERE instant_file_initialization_enabled = ''Y''
8789-
AND filename LIKE ''%sqlservr.exe%'')
8790-
OPTION (RECOMPILE);';
8791-
EXEC(@StringToExecute);
8792-
end;
8793-
end;
8794-
END;
8707+
/* Performance - Instant File Initialization Not Enabled - Check 192 */
8708+
/* Server Info - Instant File Initialization Enabled - Check 193 */
8709+
IF NOT EXISTS ( SELECT 1/0
8710+
FROM #SkipChecks
8711+
WHERE DatabaseName IS NULL AND CheckID = 192 /* IFI disabled check disabled */
8712+
) OR NOT EXISTS
8713+
( SELECT 1/0
8714+
FROM #SkipChecks
8715+
WHERE DatabaseName IS NULL AND CheckID = 193 /* IFI enabled check disabled */
8716+
)
8717+
BEGIN
8718+
IF @Debug IN (1, 2) RAISERROR('Running CheckId [%d] and CheckId [%d].', 0, 1, 192, 193) WITH NOWAIT;
8719+
8720+
DECLARE @IFISetting varchar(1) = N'N'
8721+
,@IFIReadDMVFailed bit = 0
8722+
,@IFIAllFailed bit = 0;
8723+
8724+
BEGIN TRY
8725+
/* See if we can get the instant_file_initialization_enabled column from sys.dm_server_services */
8726+
SET @StringToExecute = N'
8727+
SELECT @IFISetting = instant_file_initialization_enabled
8728+
FROM sys.dm_server_services
8729+
WHERE filename LIKE ''%sqlservr.exe%''
8730+
OPTION (RECOMPILE);';
8731+
8732+
IF @Debug = 2 AND @StringToExecute IS NOT NULL PRINT @StringToExecute;
8733+
IF @Debug = 2 AND @StringToExecute IS NULL PRINT '@StringToExecute has gone NULL, for some reason.';
8734+
8735+
EXEC dbo.sp_executesql
8736+
@StringToExecute
8737+
,N'@IFISetting varchar(1) OUTPUT'
8738+
,@IFISetting = @IFISetting OUTPUT
8739+
END TRY
8740+
BEGIN CATCH
8741+
/* We couldn't get the instant_file_initialization_enabled column from sys.dm_server_services, fall back to read error log */
8742+
SET @IFIReadDMVFailed = 1;
8743+
END CATCH;
8744+
8745+
IF @IFIReadDMVFailed = 1
8746+
BEGIN
8747+
/* If this is Amazon RDS, we'll use the rdsadmin.dbo.rds_read_error_log */
8748+
IF LEFT(CAST(SERVERPROPERTY('ComputerNamePhysicalNetBIOS') AS VARCHAR(8000)), 8) = 'EC2AMAZ-'
8749+
AND LEFT(CAST(SERVERPROPERTY('MachineName') AS VARCHAR(8000)), 8) = 'EC2AMAZ-'
8750+
AND db_id('rdsadmin') IS NOT NULL
8751+
AND EXISTS ( SELECT 1/0
8752+
FROM master.sys.all_objects
8753+
WHERE name IN ('rds_startup_tasks', 'rds_help_revlogin', 'rds_hexadecimal', 'rds_failover_tracking', 'rds_database_tracking', 'rds_track_change')
8754+
)
8755+
BEGIN
8756+
/* Amazon RDS detected, read rdsadmin.dbo.rds_read_error_log */
8757+
INSERT INTO #ErrorLog
8758+
EXEC rdsadmin.dbo.rds_read_error_log 0, 1, N'Database Instant File Initialization: enabled';
8759+
END
8760+
ELSE
8761+
BEGIN
8762+
/* Try to read the error log, this might fail due to permissions */
8763+
BEGIN TRY
8764+
INSERT INTO #ErrorLog
8765+
EXEC sys.xp_readerrorlog 0, 1, N'Database Instant File Initialization: enabled';
8766+
END TRY
8767+
BEGIN CATCH
8768+
IF @Debug IN (1, 2) RAISERROR('No permissions to execute xp_readerrorlog.', 0, 1) WITH NOWAIT;
8769+
SET @IFIAllFailed = 1;
8770+
END CATCH
8771+
END;
8772+
END;
8773+
8774+
IF @IFIAllFailed = 0
8775+
BEGIN
8776+
IF @IFIReadDMVFailed = 1
8777+
/* We couldn't read the DMV so set the @IFISetting variable using the error log */
8778+
BEGIN
8779+
IF EXISTS ( SELECT 1/0
8780+
FROM #ErrorLog
8781+
WHERE LEFT([Text], 45) = N'Database Instant File Initialization: enabled'
8782+
)
8783+
BEGIN
8784+
SET @IFISetting = 'Y';
8785+
END
8786+
ELSE
8787+
BEGIN
8788+
SET @IFISetting = 'N';
8789+
END;
8790+
END;
8791+
8792+
IF NOT EXISTS ( SELECT 1/0
8793+
FROM #SkipChecks
8794+
WHERE DatabaseName IS NULL AND CheckID = 192 /* IFI disabled check disabled */
8795+
) AND @IFISetting = 'N'
8796+
BEGIN
8797+
INSERT INTO #BlitzResults
8798+
(
8799+
CheckID ,
8800+
[Priority] ,
8801+
FindingsGroup ,
8802+
Finding ,
8803+
URL ,
8804+
Details
8805+
)
8806+
SELECT
8807+
192 AS [CheckID] ,
8808+
50 AS [Priority] ,
8809+
'Performance' AS [FindingsGroup] ,
8810+
'Instant File Initialization Not Enabled' AS [Finding] ,
8811+
'https://www.brentozar.com/go/instant' AS [URL] ,
8812+
'Consider enabling IFI for faster restores and data file growths.' AS [Details]
8813+
END;
8814+
8815+
IF NOT EXISTS ( SELECT 1/0
8816+
FROM #SkipChecks
8817+
WHERE DatabaseName IS NULL AND CheckID = 193 /* IFI enabled check disabled */
8818+
) AND @IFISetting = 'Y'
8819+
BEGIN
8820+
INSERT INTO #BlitzResults
8821+
(
8822+
CheckID ,
8823+
[Priority] ,
8824+
FindingsGroup ,
8825+
Finding ,
8826+
URL ,
8827+
Details
8828+
)
8829+
SELECT
8830+
193 AS [CheckID] ,
8831+
250 AS [Priority] ,
8832+
'Server Info' AS [FindingsGroup] ,
8833+
'Instant File Initialization Enabled' AS [Finding] ,
8834+
'https://www.brentozar.com/go/instant' AS [URL] ,
8835+
'The service account has the Perform Volume Maintenance Tasks permission.' AS [Details]
8836+
END;
8837+
END;
8838+
END;
87958839

8796-
/* Server Info - Instant File Initialization Not Enabled - Check 192 - SQL Server 2016 SP1 and newer */
8797-
IF NOT EXISTS ( SELECT 1
8798-
FROM #SkipChecks
8799-
WHERE DatabaseName IS NULL AND CheckID = 192 )
8800-
AND EXISTS ( SELECT *
8801-
FROM sys.all_objects o
8802-
INNER JOIN sys.all_columns c ON o.object_id = c.object_id
8803-
WHERE o.name = 'dm_server_services'
8804-
AND c.name = 'instant_file_initialization_enabled' )
8805-
BEGIN
8806-
8807-
IF @Debug IN (1, 2) RAISERROR('Running CheckId [%d].', 0, 1, 192) WITH NOWAIT;
8808-
8809-
SET @StringToExecute = 'INSERT INTO #BlitzResults (CheckID, Priority, FindingsGroup, Finding, URL, Details)
8810-
SELECT 192 AS CheckID ,
8811-
50 AS Priority ,
8812-
''Server Info'' AS FindingsGroup ,
8813-
''Instant File Initialization Not Enabled'' AS Finding ,
8814-
''https://www.brentozar.com/go/instant'' AS URL ,
8815-
''Consider enabling IFI for faster restores and data file growths.''
8816-
FROM sys.dm_server_services WHERE instant_file_initialization_enabled <> ''Y'' AND filename LIKE ''%sqlservr.exe%'' OPTION (RECOMPILE);';
8817-
8818-
IF @Debug = 2 AND @StringToExecute IS NOT NULL PRINT @StringToExecute;
8819-
IF @Debug = 2 AND @StringToExecute IS NULL PRINT '@StringToExecute has gone NULL, for some reason.';
8820-
8821-
EXECUTE(@StringToExecute);
8822-
END;
8840+
/* End of checkId 192 */
8841+
/* End of checkId 193 */
88238842

88248843
IF NOT EXISTS ( SELECT 1
88258844
FROM #SkipChecks

0 commit comments

Comments
 (0)