diff --git a/Install-All-Scripts.sql b/Install-All-Scripts.sql index a78d6e77..cd6a0269 100644 --- a/Install-All-Scripts.sql +++ b/Install-All-Scripts.sql @@ -8,21 +8,29 @@ SET STATISTICS IO OFF; SET STATISTICS TIME OFF; GO -IF OBJECT_ID('dbo.sp_AllNightLog') IS NULL - EXEC ('CREATE PROCEDURE dbo.sp_AllNightLog AS RETURN 0;') +IF OBJECT_ID('dbo.sp_AllNightLog_Setup') IS NULL + EXEC ('CREATE PROCEDURE dbo.sp_AllNightLog_Setup AS RETURN 0;'); GO -ALTER PROCEDURE dbo.sp_AllNightLog - @PollForNewDatabases BIT = 0, /* Formerly Pollster */ - @Backup BIT = 0, /* Formerly LogShaming */ - @PollDiskForNewDatabases BIT = 0, - @Restore BIT = 0, - @Debug BIT = 0, - @Help BIT = 0, - @Version VARCHAR(30) = NULL OUTPUT, - @VersionDate DATETIME = NULL OUTPUT, - @VersionCheckMode BIT = 0 +ALTER PROCEDURE dbo.sp_AllNightLog_Setup + @RPOSeconds BIGINT = 30, + @RTOSeconds BIGINT = 30, + @BackupPath NVARCHAR(MAX) = NULL, + @RestorePath NVARCHAR(MAX) = NULL, + @Jobs TINYINT = 10, + @RunSetup BIT = 0, + @UpdateSetup BIT = 0, + @EnableBackupJobs INT = NULL, + @EnableRestoreJobs INT = NULL, + @Debug BIT = 0, + @FirstFullBackup BIT = 0, + @FirstDiffBackup BIT = 0, + @MoveFiles BIT = 1, + @Help BIT = 0, + @Version VARCHAR(30) = NULL OUTPUT, + @VersionDate DATETIME = NULL OUTPUT, + @VersionCheckMode BIT = 0 WITH RECOMPILE AS SET NOCOUNT ON; @@ -30,8 +38,7 @@ SET STATISTICS XML OFF; BEGIN; - -SELECT @Version = '8.12', @VersionDate = '20221213'; +SELECT @Version = '8.13', @VersionDate = '20230215'; IF(@VersionCheckMode = 1) BEGIN @@ -46,15 +53,35 @@ BEGIN /* - sp_AllNightLog from http://FirstResponderKit.org + sp_AllNightLog_Setup from http://FirstResponderKit.org - * @PollForNewDatabases = 1 polls sys.databases for new entries - * Unfortunately no other way currently to automate new database additions when restored from backups - * No triggers or extended events that easily do this + This script sets up a database, tables, rows, and jobs for sp_AllNightLog, including: + + * Creates a database + * Right now it''s hard-coded to use msdbCentral, that might change later - * @Backup = 1 polls msdbCentral.dbo.backup_worker for databases not backed up in [RPO], takes LOG backups - * Will switch to a full backup if none exists + * Creates tables in that database! + * dbo.backup_configuration + * Hold variables used by stored proc to make runtime decisions + * RPO: Seconds, how often we look for databases that need log backups + * Backup Path: The path we feed to Ola H''s backup proc + * dbo.backup_worker + * Holds list of databases and some information that helps our Agent jobs figure out if they need to take another log backup + + * Creates tables in msdb + * dbo.restore_configuration + * Holds variables used by stored proc to make runtime decisions + * RTO: Seconds, how often to look for log backups to restore + * Restore Path: The path we feed to sp_DatabaseRestore + * Move Files: Whether to move files to default data/log directories. + * dbo.restore_worker + * Holds list of databases and some information that helps our Agent jobs figure out if they need to look for files to restore + * Creates agent jobs + * 1 job that polls sys.databases for new entries + * 10 jobs that run to take log backups + * Based on a queue table + * Requires Ola Hallengren''s Database Backup stored proc To learn more, visit http://FirstResponderKit.org where you can download new versions for free, watch training videos on how it works, get more info on @@ -62,7 +89,7 @@ BEGIN Known limitations of this version: - Only Microsoft-supported versions of SQL Server. Sorry, 2005 and 2000! And really, maybe not even anything less than 2016. Heh. - - When restoring encrypted backups, the encryption certificate must already be installed. + - The repository database name is hard-coded to msdbCentral. Unknown limitations of this version: - None. (If we knew them, they would be known. Duh.) @@ -73,17 +100,26 @@ BEGIN Parameter explanations: - @PollForNewDatabases BIT, defaults to 0. When this is set to 1, runs in a perma-loop to find new entries in sys.databases - @Backup BIT, defaults to 0. When this is set to 1, runs in a perma-loop checking the backup_worker table for databases that need to be backed up - @Debug BIT, defaults to 0. Whent this is set to 1, it prints out dynamic SQL commands + @RunSetup BIT, defaults to 0. When this is set to 1, it will run the setup portion to create database, tables, and worker jobs. + @UpdateSetup BIT, defaults to 0. When set to 1, will update existing configs for RPO/RTO and database backup/restore paths. @RPOSeconds BIGINT, defaults to 30. Value in seconds you want to use to determine if a new log backup needs to be taken. - @BackupPath NVARCHAR(MAX), defaults to = ''D:\Backup''. You 99.99999% will need to change this path to something else. This tells Ola''s job where to put backups. + @BackupPath NVARCHAR(MAX), This is REQUIRED if @Runsetup=1. This tells Ola''s job where to put backups. + @MoveFiles BIT, defaults to 1. When this is set to 1, it will move files to default data/log directories + @Debug BIT, defaults to 0. Whent this is set to 1, it prints out dynamic SQL commands + Sample call: + EXEC dbo.sp_AllNightLog_Setup + @RunSetup = 1, + @RPOSeconds = 30, + @BackupPath = N''M:\MSSQL\Backup'', + @Debug = 1 + + For more documentation: https://github.com/BrentOzarULTD/SQL-Server-First-Responder-Kit/ MIT License - Copyright (c) 2021 Brent Ozar Unlimited + Copyright (c) Brent Ozar Unlimited Permission is hereby granted, free of charge, to any person obtaining a copy of this software and associated documentation files (the "Software"), to deal @@ -106,8 +142,8 @@ BEGIN */'; -RETURN -END +RETURN; +END; /* IF @Help = 1 */ DECLARE @database NVARCHAR(128) = NULL; --Holds the database that's currently being processed DECLARE @error_number INT = NULL; --Used for TRY/CATCH @@ -115,45 +151,110 @@ DECLARE @error_severity INT; --Used for TRY/CATCH DECLARE @error_state INT; --Used for TRY/CATCH DECLARE @msg NVARCHAR(4000) = N''; --Used for RAISERROR DECLARE @rpo INT; --Used to hold the RPO value in our configuration table -DECLARE @rto INT; --Used to hold the RPO value in our configuration table DECLARE @backup_path NVARCHAR(MAX); --Used to hold the backup path in our configuration table -DECLARE @changebackuptype NVARCHAR(MAX); --Config table: Y = escalate to full backup, MSDB = escalate if MSDB history doesn't show a recent full. -DECLARE @encrypt NVARCHAR(MAX); --Config table: Y = encrypt the backup. N (default) = do not encrypt. -DECLARE @encryptionalgorithm NVARCHAR(MAX); --Config table: native 2014 choices include TRIPLE_DES_3KEY, AES_128, AES_192, AES_256 -DECLARE @servercertificate NVARCHAR(MAX); --Config table: server certificate that is used to encrypt the backup -DECLARE @restore_path_base NVARCHAR(MAX); --Used to hold the base backup path in our configuration table -DECLARE @restore_path_full NVARCHAR(MAX); --Used to hold the full backup path in our configuration table -DECLARE @restore_path_log NVARCHAR(MAX); --Used to hold the log backup path in our configuration table -DECLARE @restore_move_files INT; -- used to hold the move files bit in our configuration table DECLARE @db_sql NVARCHAR(MAX) = N''; --Used to hold the dynamic SQL to create msdbCentral DECLARE @tbl_sql NVARCHAR(MAX) = N''; --Used to hold the dynamic SQL that creates tables in msdbCentral DECLARE @database_name NVARCHAR(256) = N'msdbCentral'; --Used to hold the name of the database we create to centralize data --Right now it's hardcoded to msdbCentral, but I made it dynamic in case that changes down the line -DECLARE @cmd NVARCHAR(4000) = N'' --Holds dir cmd -DECLARE @FileList TABLE ( BackupFile NVARCHAR(255) ); --Where we dump @cmd -DECLARE @restore_full BIT = 0 --We use this one -DECLARE @only_logs_after NVARCHAR(30) = N'' +/*These variables control the loop to create/modify jobs*/ +DECLARE @job_sql NVARCHAR(MAX) = N''; --Used to hold the dynamic SQL that creates Agent jobs +DECLARE @counter INT = 0; --For looping to create 10 Agent jobs +DECLARE @job_category NVARCHAR(MAX) = N'''Database Maintenance'''; --Job category +DECLARE @job_owner NVARCHAR(128) = QUOTENAME(SUSER_SNAME(0x01), ''''); -- Admin user/owner +DECLARE @jobs_to_change TABLE(name SYSNAME); -- list of jobs we need to enable or disable +DECLARE @current_job_name SYSNAME; -- While looping through Agent jobs to enable or disable +DECLARE @active_start_date INT = (CONVERT(INT, CONVERT(VARCHAR(10), GETDATE(), 112))); +DECLARE @started_waiting_for_jobs DATETIME; --We need to wait for a while when disabling jobs + +/*Specifically for Backups*/ +DECLARE @job_name_backups NVARCHAR(MAX) = N'''sp_AllNightLog_Backup_Job_'''; --Name of log backup job +DECLARE @job_description_backups NVARCHAR(MAX) = N'''This is a worker for the purposes of taking log backups from msdbCentral.dbo.backup_worker queue table.'''; --Job description +DECLARE @job_command_backups NVARCHAR(MAX) = N'''EXEC sp_AllNightLog @Backup = 1'''; --Command the Agent job will run + +/*Specifically for Restores*/ +DECLARE @job_name_restores NVARCHAR(MAX) = N'''sp_AllNightLog_Restore_Job_'''; --Name of log backup job +DECLARE @job_description_restores NVARCHAR(MAX) = N'''This is a worker for the purposes of restoring log backups from msdb.dbo.restore_worker queue table.'''; --Job description +DECLARE @job_command_restores NVARCHAR(MAX) = N'''EXEC sp_AllNightLog @Restore = 1'''; --Command the Agent job will run + /* -Make sure we're doing something +Sanity check some variables */ -IF ( - @PollForNewDatabases = 0 - AND @PollDiskForNewDatabases = 0 - AND @Backup = 0 - AND @Restore = 0 - AND @Help = 0 -) - BEGIN - RAISERROR('You don''t seem to have picked an action for this stored procedure to take.', 0, 1) WITH NOWAIT - + + +IF ((@RunSetup = 0 OR @RunSetup IS NULL) AND (@UpdateSetup = 0 OR @UpdateSetup IS NULL)) + + BEGIN + + RAISERROR('You have to either run setup or update setup. You can''t not do neither nor, if you follow. Or not.', 0, 1) WITH NOWAIT; + + RETURN; + + END; + + +/* + +Should be a positive number + +*/ + +IF (@RPOSeconds < 0) + + BEGIN + RAISERROR('Please choose a positive number for @RPOSeconds', 0, 1) WITH NOWAIT; + RETURN; - END + END; + + +/* + +Probably shouldn't be more than 20 + +*/ + +IF (@Jobs > 20) OR (@Jobs < 1) + + BEGIN + RAISERROR('We advise sticking with 1-20 jobs.', 0, 1) WITH NOWAIT; + + RETURN; + END; + +/* + +Probably shouldn't be more than 4 hours + +*/ + +IF (@RPOSeconds >= 14400) + BEGIN + + RAISERROR('If your RPO is really 4 hours, perhaps you''d be interested in a more modest recovery model, like SIMPLE?', 0, 1) WITH NOWAIT; + + RETURN; + END; + + +/* + +Can't enable both the backup and restore jobs at the same time + +*/ + +IF @EnableBackupJobs = 1 AND @EnableRestoreJobs = 1 + BEGIN + + RAISERROR('You are not allowed to enable both the backup and restore jobs at the same time. Pick one, bucko.', 0, 1) WITH NOWAIT; + + RETURN; + END; /* Make sure xp_cmdshell is enabled @@ -192,1330 +293,1055 @@ IF NOT EXISTS (SELECT * FROM sys.procedures WHERE name = 'sp_DatabaseRestore') RETURN; END +/* -IF (@PollDiskForNewDatabases = 1 OR @Restore = 1) AND OBJECT_ID('msdb.dbo.restore_configuration') IS NOT NULL - BEGIN - - IF @Debug = 1 RAISERROR('Checking restore path', 0, 1) WITH NOWAIT; - - SELECT @restore_path_base = CONVERT(NVARCHAR(512), configuration_setting) - FROM msdb.dbo.restore_configuration c - WHERE configuration_name = N'log restore path'; +Basic path sanity checks +*/ - IF @restore_path_base IS NULL - BEGIN - RAISERROR('@restore_path cannot be NULL. Please check the msdb.dbo.restore_configuration table', 0, 1) WITH NOWAIT; +IF @RunSetup = 1 and @BackupPath is NULL + BEGIN + + RAISERROR('@BackupPath is required during setup', 0, 1) WITH NOWAIT; + RETURN; - END; + END - IF CHARINDEX('**', @restore_path_base) <> 0 - BEGIN +IF (@BackupPath NOT LIKE '[c-zC-Z]:\%') --Local path, don't think anyone has A or B drives +AND (@BackupPath NOT LIKE '\\[a-zA-Z0-9]%\%') --UNC path + + BEGIN + RAISERROR('Are you sure that''s a real path?', 0, 1) WITH NOWAIT; + + RETURN; + END; - /* If they passed in a dynamic **DATABASENAME**, stop at that folder looking for databases. More info: https://github.com/BrentOzarULTD/SQL-Server-First-Responder-Kit/issues/993 */ - IF CHARINDEX('**DATABASENAME**', @restore_path_base) <> 0 - BEGIN - SET @restore_path_base = SUBSTRING(@restore_path_base, 1, CHARINDEX('**DATABASENAME**',@restore_path_base) - 2); - END; +/* - SET @restore_path_base = REPLACE(@restore_path_base, '**AVAILABILITYGROUP**', ''); - SET @restore_path_base = REPLACE(@restore_path_base, '**BACKUPTYPE**', 'FULL'); - SET @restore_path_base = REPLACE(@restore_path_base, '**SERVERNAME**', REPLACE(CAST(SERVERPROPERTY('servername') AS nvarchar(max)),'\','$')); +If you want to update the table, one of these has to not be NULL - IF CHARINDEX('\',CAST(SERVERPROPERTY('servername') AS nvarchar(max))) > 0 - BEGIN - SET @restore_path_base = REPLACE(@restore_path_base, '**SERVERNAMEWITHOUTINSTANCE**', SUBSTRING(CAST(SERVERPROPERTY('servername') AS nvarchar(max)), 1, (CHARINDEX('\',CAST(SERVERPROPERTY('servername') AS nvarchar(max))) - 1))); - SET @restore_path_base = REPLACE(@restore_path_base, '**INSTANCENAME**', SUBSTRING(CAST(SERVERPROPERTY('servername') AS nvarchar(max)), CHARINDEX('\',CAST(SERVERPROPERTY('servername') AS nvarchar(max))), (LEN(CAST(SERVERPROPERTY('servername') AS nvarchar(max))) - CHARINDEX('\',CAST(SERVERPROPERTY('servername') AS nvarchar(max)))) + 1)); - END - ELSE /* No instance installed */ - BEGIN - SET @restore_path_base = REPLACE(@restore_path_base, '**SERVERNAMEWITHOUTINSTANCE**', CAST(SERVERPROPERTY('servername') AS nvarchar(max))); - SET @restore_path_base = REPLACE(@restore_path_base, '**INSTANCENAME**', 'DEFAULT'); - END +*/ - IF CHARINDEX('**CLUSTER**', @restore_path_base) <> 0 - BEGIN - DECLARE @ClusterName NVARCHAR(128); - IF EXISTS(SELECT * FROM sys.all_objects WHERE name = 'dm_hadr_cluster') - BEGIN - SELECT @ClusterName = cluster_name FROM sys.dm_hadr_cluster; - END - SET @restore_path_base = REPLACE(@restore_path_base, '**CLUSTER**', COALESCE(@ClusterName,'')); - END; +IF @UpdateSetup = 1 + AND ( @RPOSeconds IS NULL + AND @BackupPath IS NULL + AND @RPOSeconds IS NULL + AND @RestorePath IS NULL + AND @EnableBackupJobs IS NULL + AND @EnableRestoreJobs IS NULL + ) - END /* IF CHARINDEX('**', @restore_path_base) <> 0 */ - - SELECT @restore_move_files = CONVERT(BIT, configuration_setting) - FROM msdb.dbo.restore_configuration c - WHERE configuration_name = N'move files'; - - IF @restore_move_files is NULL BEGIN - -- Set to default value of 1 - SET @restore_move_files = 1 - END - END /* IF @PollDiskForNewDatabases = 1 OR @Restore = 1 */ + RAISERROR('If you want to update configuration settings, they can''t be NULL. Please Make sure @RPOSeconds / @RTOSeconds or @BackupPath / @RestorePath has a value', 0, 1) WITH NOWAIT; + RETURN; -/* + END; -Certain variables necessarily skip to parts of this script that are irrelevant -in both directions to each other. They are used for other stuff. -*/ +IF @UpdateSetup = 1 + GOTO UpdateConfigs; +IF @RunSetup = 1 +BEGIN + BEGIN TRY -/* + BEGIN + -Pollster use happens strictly to check for new databases in sys.databases to place them in a worker queue + /* + + First check to see if Agent is running -- we'll get errors if it's not + + */ + + + IF ( SELECT 1 + FROM sys.all_objects + WHERE name = 'dm_server_services' ) IS NOT NULL -*/ + BEGIN -IF @PollForNewDatabases = 1 - GOTO Pollster; + IF EXISTS ( + SELECT 1 + FROM sys.dm_server_services + WHERE servicename LIKE 'SQL Server Agent%' + AND status_desc = 'Stopped' + ) + + BEGIN + + RAISERROR('SQL Server Agent is not currently running -- it needs to be enabled to add backup worker jobs and the new database polling job', 0, 1) WITH NOWAIT; + + RETURN; + + END; + + END + -/* + BEGIN -LogShamer happens when we need to find and assign work to a worker job for backups -*/ + /* + + Check to see if the database exists -IF @Backup = 1 - GOTO LogShamer; + */ + + RAISERROR('Checking for msdbCentral', 0, 1) WITH NOWAIT; -/* + SET @db_sql += N' -Pollster use happens strictly to check for new databases in sys.databases to place them in a worker queue + IF DATABASEPROPERTYEX(' + QUOTENAME(@database_name, '''') + ', ''Status'') IS NULL -*/ + BEGIN -IF @PollDiskForNewDatabases = 1 - GOTO DiskPollster; + RAISERROR(''Creating msdbCentral'', 0, 1) WITH NOWAIT; + CREATE DATABASE ' + QUOTENAME(@database_name) + '; + + ALTER DATABASE ' + QUOTENAME(@database_name) + ' SET RECOVERY FULL; + + END -/* + '; -Restoregasm Addict happens when we need to find and assign work to a worker job for restores -*/ + IF @Debug = 1 + BEGIN + RAISERROR(@db_sql, 0, 1) WITH NOWAIT; + END; -IF @Restore = 1 - GOTO Restoregasm_Addict; + IF @db_sql IS NULL + BEGIN + RAISERROR('@db_sql is NULL for some reason', 0, 1) WITH NOWAIT; + END; -/* + EXEC sp_executesql @db_sql; -Begin Polling section -*/ + /* + + Check for tables and stuff + */ + + RAISERROR('Checking for tables in msdbCentral', 0, 1) WITH NOWAIT; -/* + SET @tbl_sql += N' + + USE ' + QUOTENAME(@database_name) + ' + + + IF OBJECT_ID(''' + QUOTENAME(@database_name) + '.dbo.backup_configuration'') IS NULL + + BEGIN + + RAISERROR(''Creating table dbo.backup_configuration'', 0, 1) WITH NOWAIT; + + CREATE TABLE dbo.backup_configuration ( + database_name NVARCHAR(256), + configuration_name NVARCHAR(512), + configuration_description NVARCHAR(512), + configuration_setting NVARCHAR(MAX) + ); + + END + + ELSE + + BEGIN + + + RAISERROR(''Backup configuration table exists, truncating'', 0, 1) WITH NOWAIT; + + + TRUNCATE TABLE dbo.backup_configuration -This section runs in a loop checking for new databases added to the server, or broken backups + + END -*/ + RAISERROR(''Inserting configuration values'', 0, 1) WITH NOWAIT; -Pollster: + + INSERT dbo.backup_configuration (database_name, configuration_name, configuration_description, configuration_setting) + VALUES (''all'', ''log backup frequency'', ''The length of time in second between Log Backups.'', ''' + CONVERT(NVARCHAR(10), @RPOSeconds) + '''); + + INSERT dbo.backup_configuration (database_name, configuration_name, configuration_description, configuration_setting) + VALUES (''all'', ''log backup path'', ''The path to which Log Backups should go.'', ''' + @BackupPath + '''); + + INSERT dbo.backup_configuration (database_name, configuration_name, configuration_description, configuration_setting) + VALUES (''all'', ''change backup type'', ''For Ola Hallengren DatabaseBackup @ChangeBackupType param: Y = escalate to fulls, MSDB = escalate by checking msdb backup history.'', ''MSDB''); + + INSERT dbo.backup_configuration (database_name, configuration_name, configuration_description, configuration_setting) + VALUES (''all'', ''encrypt'', ''For Ola Hallengren DatabaseBackup: Y = encrypt the backup. N (default) = do not encrypt.'', NULL); + + INSERT dbo.backup_configuration (database_name, configuration_name, configuration_description, configuration_setting) + VALUES (''all'', ''encryptionalgorithm'', ''For Ola Hallengren DatabaseBackup: native 2014 choices include TRIPLE_DES_3KEY, AES_128, AES_192, AES_256.'', NULL); + + INSERT dbo.backup_configuration (database_name, configuration_name, configuration_description, configuration_setting) + VALUES (''all'', ''servercertificate'', ''For Ola Hallengren DatabaseBackup: server certificate that is used to encrypt the backup.'', NULL); + + + IF OBJECT_ID(''' + QUOTENAME(@database_name) + '.dbo.backup_worker'') IS NULL + + BEGIN + + + RAISERROR(''Creating table dbo.backup_worker'', 0, 1) WITH NOWAIT; + + CREATE TABLE dbo.backup_worker ( + id INT IDENTITY(1, 1) PRIMARY KEY CLUSTERED, + database_name NVARCHAR(256), + last_log_backup_start_time DATETIME DEFAULT ''19000101'', + last_log_backup_finish_time DATETIME DEFAULT ''99991231'', + is_started BIT DEFAULT 0, + is_completed BIT DEFAULT 0, + error_number INT DEFAULT NULL, + last_error_date DATETIME DEFAULT NULL, + ignore_database BIT DEFAULT 0, + full_backup_required BIT DEFAULT ' + CASE WHEN @FirstFullBackup = 0 THEN N'0,' ELSE N'1,' END + CHAR(10) + + N'diff_backup_required BIT DEFAULT ' + CASE WHEN @FirstDiffBackup = 0 THEN N'0' ELSE N'1' END + CHAR(10) + + N'); + + END; + + ELSE - IF @Debug = 1 RAISERROR('Beginning Pollster', 0, 1) WITH NOWAIT; - - IF OBJECT_ID('msdbCentral.dbo.backup_worker') IS NOT NULL - - BEGIN - - WHILE @PollForNewDatabases = 1 - - BEGIN - - BEGIN TRY - - IF @Debug = 1 RAISERROR('Checking for new databases...', 0, 1) WITH NOWAIT; + BEGIN - /* - - Look for new non-system databases -- there should probably be additional filters here for accessibility, etc. - */ - - INSERT msdbCentral.dbo.backup_worker (database_name) - SELECT d.name - FROM sys.databases d - WHERE NOT EXISTS ( - SELECT 1 - FROM msdbCentral.dbo.backup_worker bw - WHERE bw.database_name = d.name - ) - AND d.database_id > 4; + RAISERROR(''Backup worker table exists, truncating'', 0, 1) WITH NOWAIT; + + + TRUNCATE TABLE dbo.backup_worker - IF @Debug = 1 RAISERROR('Checking for wayward databases', 0, 1) WITH NOWAIT; - /* - - This section aims to find databases that have - * Had a log backup ever (the default for finish time is 9999-12-31, so anything with a more recent finish time has had a log backup) - * Not had a log backup start in the last 5 minutes (this could be trouble! or a really big log backup) - * Also checks msdb.dbo.backupset to make sure the database has a full backup associated with it (otherwise it's the first full, and we don't need to start taking log backups yet) + END - */ - - IF EXISTS ( - - SELECT 1 - FROM msdbCentral.dbo.backup_worker bw WITH (READPAST) - WHERE bw.last_log_backup_finish_time < '99991231' - AND bw.last_log_backup_start_time < DATEADD(SECOND, (@rpo * -1), GETDATE()) - AND EXISTS ( - SELECT 1 - FROM msdb.dbo.backupset b - WHERE b.database_name = bw.database_name - AND b.type = 'D' - ) - ) - - BEGIN + + RAISERROR(''Inserting databases for backups'', 0, 1) WITH NOWAIT; - IF @Debug = 1 RAISERROR('Resetting databases with a log backup and no log backup in the last 5 minutes', 0, 1) WITH NOWAIT; + INSERT ' + QUOTENAME(@database_name) + '.dbo.backup_worker (database_name) + SELECT d.name + FROM sys.databases d + WHERE NOT EXISTS ( + SELECT * + FROM msdbCentral.dbo.backup_worker bw + WHERE bw.database_name = d.name + ) + AND d.database_id > 4; + + '; - - UPDATE bw - SET bw.is_started = 0, - bw.is_completed = 1, - bw.last_log_backup_start_time = '19000101' - FROM msdbCentral.dbo.backup_worker bw - WHERE bw.last_log_backup_finish_time < '99991231' - AND bw.last_log_backup_start_time < DATEADD(SECOND, (@rpo * -1), GETDATE()) - AND EXISTS ( - SELECT 1 - FROM msdb.dbo.backupset b - WHERE b.database_name = bw.database_name - AND b.type = 'D' - ); + + IF @Debug = 1 + BEGIN + SET @msg = SUBSTRING(@tbl_sql, 0, 2044) + RAISERROR(@msg, 0, 1) WITH NOWAIT; + SET @msg = SUBSTRING(@tbl_sql, 2044, 4088) + RAISERROR(@msg, 0, 1) WITH NOWAIT; + SET @msg = SUBSTRING(@tbl_sql, 4088, 6132) + RAISERROR(@msg, 0, 1) WITH NOWAIT; + SET @msg = SUBSTRING(@tbl_sql, 6132, 8176) + RAISERROR(@msg, 0, 1) WITH NOWAIT; + END; - - END; --End check for wayward databases + + IF @tbl_sql IS NULL + BEGIN + RAISERROR('@tbl_sql is NULL for some reason', 0, 1) WITH NOWAIT; + END; + + EXEC sp_executesql @tbl_sql; + + /* - Wait 1 minute between runs, we don't need to be checking this constantly + This section creates tables for restore workers to work off of */ - - IF @Debug = 1 RAISERROR('Waiting for 1 minute', 0, 1) WITH NOWAIT; - - WAITFOR DELAY '00:01:00.000'; + + /* + + In search of msdb + + */ + + RAISERROR('Checking for msdb. Yeah, I know...', 0, 1) WITH NOWAIT; + + IF DATABASEPROPERTYEX('msdb', 'Status') IS NULL - END TRY + BEGIN - BEGIN CATCH + RAISERROR('YOU HAVE NO MSDB WHY?!', 0, 1) WITH NOWAIT; + RETURN; + + END; - SELECT @msg = N'Error inserting databases to msdbCentral.dbo.backup_worker, error number is ' + CONVERT(NVARCHAR(10), ERROR_NUMBER()) + ', error message is ' + ERROR_MESSAGE(), - @error_severity = ERROR_SEVERITY(), - @error_state = ERROR_STATE(); - RAISERROR(@msg, @error_severity, @error_state) WITH NOWAIT; + /* In search of restore_configuration */ - - WHILE @@TRANCOUNT > 0 - ROLLBACK; + RAISERROR('Checking for Restore Worker tables in msdb', 0, 1) WITH NOWAIT; + IF OBJECT_ID('msdb.dbo.restore_configuration') IS NULL - END CATCH; - - - END; + BEGIN - /* Check to make sure job is still enabled */ - IF NOT EXISTS ( - SELECT * - FROM msdb.dbo.sysjobs - WHERE name = 'sp_AllNightLog_PollForNewDatabases' - AND enabled = 1 - ) - BEGIN - RAISERROR('sp_AllNightLog_PollForNewDatabases job is disabled, so gracefully exiting. It feels graceful to me, anyway.', 0, 1) WITH NOWAIT; - RETURN; - END - - END;-- End Pollster loop - - ELSE - - BEGIN - - RAISERROR('msdbCentral.dbo.backup_worker does not exist, please create it.', 0, 1) WITH NOWAIT; - RETURN; - - END; - RETURN; + RAISERROR('Creating restore_configuration table in msdb', 0, 1) WITH NOWAIT; + CREATE TABLE msdb.dbo.restore_configuration ( + database_name NVARCHAR(256), + configuration_name NVARCHAR(512), + configuration_description NVARCHAR(512), + configuration_setting NVARCHAR(MAX) + ); -/* + END; -End of Pollster -*/ + ELSE -/* + BEGIN -Begin DiskPollster + RAISERROR('Restore configuration table exists, truncating', 0, 1) WITH NOWAIT; -*/ + TRUNCATE TABLE msdb.dbo.restore_configuration; + + END; -/* + RAISERROR('Inserting configuration values to msdb.dbo.restore_configuration', 0, 1) WITH NOWAIT; + + INSERT msdb.dbo.restore_configuration (database_name, configuration_name, configuration_description, configuration_setting) + VALUES ('all', 'log restore frequency', 'The length of time in second between Log Restores.', @RTOSeconds); + + INSERT msdb.dbo.restore_configuration (database_name, configuration_name, configuration_description, configuration_setting) + VALUES ('all', 'log restore path', 'The path to which Log Restores come from.', @RestorePath); -This section runs in a loop checking restore path for new databases added to the server, or broken restores + INSERT msdb.dbo.restore_configuration (database_name, configuration_name, configuration_description, configuration_setting) + VALUES ('all', 'move files', 'Determines if we move database files to default data/log directories.', @MoveFiles); -*/ + IF OBJECT_ID('msdb.dbo.restore_worker') IS NULL + + BEGIN + + + RAISERROR('Creating table msdb.dbo.restore_worker', 0, 1) WITH NOWAIT; + + CREATE TABLE msdb.dbo.restore_worker ( + id INT IDENTITY(1, 1) PRIMARY KEY CLUSTERED, + database_name NVARCHAR(256), + last_log_restore_start_time DATETIME DEFAULT '19000101', + last_log_restore_finish_time DATETIME DEFAULT '99991231', + is_started BIT DEFAULT 0, + is_completed BIT DEFAULT 0, + error_number INT DEFAULT NULL, + last_error_date DATETIME DEFAULT NULL, + ignore_database BIT DEFAULT 0, + full_backup_required BIT DEFAULT 0, + diff_backup_required BIT DEFAULT 0 + ); + + + RAISERROR('Inserting databases for restores', 0, 1) WITH NOWAIT; + + INSERT msdb.dbo.restore_worker (database_name) + SELECT d.name + FROM sys.databases d + WHERE NOT EXISTS ( + SELECT * + FROM msdb.dbo.restore_worker bw + WHERE bw.database_name = d.name + ) + AND d.database_id > 4; + + + END; -DiskPollster: - IF @Debug = 1 RAISERROR('Beginning DiskPollster', 0, 1) WITH NOWAIT; - - IF OBJECT_ID('msdb.dbo.restore_configuration') IS NOT NULL - - BEGIN - WHILE @PollDiskForNewDatabases = 1 + /* + + Add Jobs + + */ + + + + /* + + Look for our ten second schedule -- all jobs use this to restart themselves if they fail + + Fun fact: you can add the same schedule name multiple times, so we don't want to just stick it in there + + */ + + + RAISERROR('Checking for ten second schedule', 0, 1) WITH NOWAIT; + + IF NOT EXISTS ( + SELECT 1 + FROM msdb.dbo.sysschedules + WHERE name = 'ten_seconds' + ) - BEGIN + BEGIN + + + RAISERROR('Creating ten second schedule', 0, 1) WITH NOWAIT; + + + EXEC msdb.dbo.sp_add_schedule @schedule_name= ten_seconds, + @enabled = 1, + @freq_type = 4, + @freq_interval = 1, + @freq_subday_type = 2, + @freq_subday_interval = 10, + @freq_relative_interval = 0, + @freq_recurrence_factor = 0, + @active_start_date = @active_start_date, + @active_end_date = 99991231, + @active_start_time = 0, + @active_end_time = 235959; - BEGIN TRY + END; + - IF @Debug = 1 RAISERROR('Checking for new databases in: ', 0, 1) WITH NOWAIT; - IF @Debug = 1 RAISERROR(@restore_path_base, 0, 1) WITH NOWAIT; + /* + + Look for Backup Pollster job -- this job sets up our watcher for new databases to back up + + */ - /* + + RAISERROR('Checking for pollster job', 0, 1) WITH NOWAIT; + + + IF NOT EXISTS ( + SELECT 1 + FROM msdb.dbo.sysjobs + WHERE name = 'sp_AllNightLog_PollForNewDatabases' + ) + + + BEGIN - Look for new non-system databases -- there should probably be additional filters here for accessibility, etc. + + RAISERROR('Creating pollster job', 0, 1) WITH NOWAIT; + + IF @EnableBackupJobs = 1 + BEGIN + EXEC msdb.dbo.sp_add_job @job_name = sp_AllNightLog_PollForNewDatabases, + @description = 'This is a worker for the purposes of polling sys.databases for new entries to insert to the worker queue table.', + @category_name = 'Database Maintenance', + @owner_login_name = 'sa', + @enabled = 1; + END + ELSE + BEGIN + EXEC msdb.dbo.sp_add_job @job_name = sp_AllNightLog_PollForNewDatabases, + @description = 'This is a worker for the purposes of polling sys.databases for new entries to insert to the worker queue table.', + @category_name = 'Database Maintenance', + @owner_login_name = 'sa', + @enabled = 0; + END + + + RAISERROR('Adding job step', 0, 1) WITH NOWAIT; - */ - /* + EXEC msdb.dbo.sp_add_jobstep @job_name = sp_AllNightLog_PollForNewDatabases, + @step_name = sp_AllNightLog_PollForNewDatabases, + @subsystem = 'TSQL', + @command = 'EXEC sp_AllNightLog @PollForNewDatabases = 1'; + + + + RAISERROR('Adding job server', 0, 1) WITH NOWAIT; + - This setups up the @cmd variable to check the restore path for new folders + EXEC msdb.dbo.sp_add_jobserver @job_name = sp_AllNightLog_PollForNewDatabases; + + + + RAISERROR('Attaching schedule', 0, 1) WITH NOWAIT; + - In our case, a new folder means a new database, because we assume a pristine path + EXEC msdb.dbo.sp_attach_schedule @job_name = sp_AllNightLog_PollForNewDatabases, + @schedule_name = ten_seconds; + + + END; + - */ - SET @cmd = N'DIR /b "' + @restore_path_base + N'"'; - - IF @Debug = 1 - BEGIN - PRINT @cmd; - END - + /* + + Look for Restore Pollster job -- this job sets up our watcher for new databases to back up + + */ + + + RAISERROR('Checking for restore pollster job', 0, 1) WITH NOWAIT; + + + IF NOT EXISTS ( + SELECT 1 + FROM msdb.dbo.sysjobs + WHERE name = 'sp_AllNightLog_PollDiskForNewDatabases' + ) + + + BEGIN + + + RAISERROR('Creating restore pollster job', 0, 1) WITH NOWAIT; + - DELETE @FileList; - INSERT INTO @FileList (BackupFile) - EXEC master.sys.xp_cmdshell @cmd; + IF @EnableRestoreJobs = 1 + BEGIN + EXEC msdb.dbo.sp_add_job @job_name = sp_AllNightLog_PollDiskForNewDatabases, + @description = 'This is a worker for the purposes of polling your restore path for new entries to insert to the worker queue table.', + @category_name = 'Database Maintenance', + @owner_login_name = 'sa', + @enabled = 1; + END + ELSE + BEGIN + EXEC msdb.dbo.sp_add_job @job_name = sp_AllNightLog_PollDiskForNewDatabases, + @description = 'This is a worker for the purposes of polling your restore path for new entries to insert to the worker queue table.', + @category_name = 'Database Maintenance', + @owner_login_name = 'sa', + @enabled = 0; + END + + + + RAISERROR('Adding restore job step', 0, 1) WITH NOWAIT; + - IF ( - SELECT COUNT(*) - FROM @FileList AS fl - WHERE fl.BackupFile = 'The system cannot find the path specified.' - OR fl.BackupFile = 'File Not Found' - ) = 1 + EXEC msdb.dbo.sp_add_jobstep @job_name = sp_AllNightLog_PollDiskForNewDatabases, + @step_name = sp_AllNightLog_PollDiskForNewDatabases, + @subsystem = 'TSQL', + @command = 'EXEC sp_AllNightLog @PollDiskForNewDatabases = 1'; + + + + RAISERROR('Adding restore job server', 0, 1) WITH NOWAIT; - BEGIN - RAISERROR('No rows were returned for that database\path', 0, 1) WITH NOWAIT; + EXEC msdb.dbo.sp_add_jobserver @job_name = sp_AllNightLog_PollDiskForNewDatabases; - END; + + + RAISERROR('Attaching schedule', 0, 1) WITH NOWAIT; + + + EXEC msdb.dbo.sp_attach_schedule @job_name = sp_AllNightLog_PollDiskForNewDatabases, + @schedule_name = ten_seconds; + + + END; - IF ( - SELECT COUNT(*) - FROM @FileList AS fl - WHERE fl.BackupFile = 'Access is denied.' - ) = 1 - BEGIN - - RAISERROR('Access is denied to %s', 16, 1, @restore_path_base) WITH NOWAIT; - END; + /* + + This section creates @Jobs (quantity) of worker jobs to take log backups with - IF ( - SELECT COUNT(*) - FROM @FileList AS fl - ) = 1 - AND ( - SELECT COUNT(*) - FROM @FileList AS fl - WHERE fl.BackupFile IS NULL - ) = 1 + They work in a queue - BEGIN - - RAISERROR('That directory appears to be empty', 0, 1) WITH NOWAIT; - - RETURN; - - END + It's queuete + + */ - IF ( - SELECT COUNT(*) - FROM @FileList AS fl - WHERE fl.BackupFile = 'The user name or password is incorrect.' - ) = 1 - BEGIN - - RAISERROR('Incorrect user name or password for %s', 16, 1, @restore_path_base) WITH NOWAIT; + RAISERROR('Checking for sp_AllNightLog backup jobs', 0, 1) WITH NOWAIT; + + + SELECT @counter = COUNT(*) + 1 + FROM msdb.dbo.sysjobs + WHERE name LIKE 'sp[_]AllNightLog[_]Backup[_]%'; - END; + SET @msg = 'Found ' + CONVERT(NVARCHAR(10), (@counter - 1)) + ' backup jobs -- ' + CASE WHEN @counter < @Jobs THEN + 'starting loop!' + WHEN @counter >= @Jobs THEN 'skipping loop!' + ELSE 'Oh woah something weird happened!' + END; - INSERT msdb.dbo.restore_worker (database_name) - SELECT fl.BackupFile - FROM @FileList AS fl - WHERE fl.BackupFile IS NOT NULL - AND fl.BackupFile COLLATE DATABASE_DEFAULT NOT IN (SELECT name from sys.databases where database_id < 5) - AND NOT EXISTS - ( - SELECT 1 - FROM msdb.dbo.restore_worker rw - WHERE rw.database_name = fl.BackupFile - ) + RAISERROR(@msg, 0, 1) WITH NOWAIT; - IF @Debug = 1 RAISERROR('Checking for wayward databases', 0, 1) WITH NOWAIT; + + WHILE @counter <= @Jobs - /* - This section aims to find databases that have - * Had a log restore ever (the default for finish time is 9999-12-31, so anything with a more recent finish time has had a log restore) - * Not had a log restore start in the last 5 minutes (this could be trouble! or a really big log restore) - * Also checks msdb.dbo.backupset to make sure the database has a full backup associated with it (otherwise it's the first full, and we don't need to start adding log restores yet) + BEGIN - */ - - IF EXISTS ( - - SELECT 1 - FROM msdb.dbo.restore_worker rw WITH (READPAST) - WHERE rw.last_log_restore_finish_time < '99991231' - AND rw.last_log_restore_start_time < DATEADD(SECOND, (@rto * -1), GETDATE()) - AND EXISTS ( - SELECT 1 - FROM msdb.dbo.restorehistory r - WHERE r.destination_database_name = rw.database_name - AND r.restore_type = 'D' - ) - ) - - BEGIN - IF @Debug = 1 RAISERROR('Resetting databases with a log restore and no log restore in the last 5 minutes', 0, 1) WITH NOWAIT; - - - UPDATE rw - SET rw.is_started = 0, - rw.is_completed = 1, - rw.last_log_restore_start_time = '19000101' - FROM msdb.dbo.restore_worker rw - WHERE rw.last_log_restore_finish_time < '99991231' - AND rw.last_log_restore_start_time < DATEADD(SECOND, (@rto * -1), GETDATE()) - AND EXISTS ( - SELECT 1 - FROM msdb.dbo.restorehistory r - WHERE r.destination_database_name = rw.database_name - AND r.restore_type = 'D' - ); - - - END; --End check for wayward databases + RAISERROR('Setting job name', 0, 1) WITH NOWAIT; - /* - - Wait 1 minute between runs, we don't need to be checking this constantly - - */ + SET @job_name_backups = N'sp_AllNightLog_Backup_' + CASE WHEN @counter < 10 THEN N'0' + CONVERT(NVARCHAR(10), @counter) + WHEN @counter >= 10 THEN CONVERT(NVARCHAR(10), @counter) + END; + + + RAISERROR('Setting @job_sql', 0, 1) WITH NOWAIT; - /* Check to make sure job is still enabled */ - IF NOT EXISTS ( - SELECT * - FROM msdb.dbo.sysjobs - WHERE name = 'sp_AllNightLog_PollDiskForNewDatabases' - AND enabled = 1 - ) - BEGIN - RAISERROR('sp_AllNightLog_PollDiskForNewDatabases job is disabled, so gracefully exiting. It feels graceful to me, anyway.', 0, 1) WITH NOWAIT; - RETURN; - END - - IF @Debug = 1 RAISERROR('Waiting for 1 minute', 0, 1) WITH NOWAIT; - - WAITFOR DELAY '00:01:00.000'; + + SET @job_sql = N' + + EXEC msdb.dbo.sp_add_job @job_name = ' + @job_name_backups + ', + @description = ' + @job_description_backups + ', + @category_name = ' + @job_category + ', + @owner_login_name = ' + @job_owner + ','; + IF @EnableBackupJobs = 1 + BEGIN + SET @job_sql = @job_sql + ' @enabled = 1; '; + END + ELSE + BEGIN + SET @job_sql = @job_sql + ' @enabled = 0; '; + END + + + SET @job_sql = @job_sql + ' + EXEC msdb.dbo.sp_add_jobstep @job_name = ' + @job_name_backups + ', + @step_name = ' + @job_name_backups + ', + @subsystem = ''TSQL'', + @command = ' + @job_command_backups + '; + + + EXEC msdb.dbo.sp_add_jobserver @job_name = ' + @job_name_backups + '; + + + EXEC msdb.dbo.sp_attach_schedule @job_name = ' + @job_name_backups + ', + @schedule_name = ten_seconds; + + '; + + + SET @counter += 1; - END TRY + + IF @Debug = 1 + BEGIN + RAISERROR(@job_sql, 0, 1) WITH NOWAIT; + END; - BEGIN CATCH + + IF @job_sql IS NULL + BEGIN + RAISERROR('@job_sql is NULL for some reason', 0, 1) WITH NOWAIT; + END; - SELECT @msg = N'Error inserting databases to msdb.dbo.restore_worker, error number is ' + CONVERT(NVARCHAR(10), ERROR_NUMBER()) + ', error message is ' + ERROR_MESSAGE(), - @error_severity = ERROR_SEVERITY(), - @error_state = ERROR_STATE(); - - RAISERROR(@msg, @error_severity, @error_state) WITH NOWAIT; + EXEC sp_executesql @job_sql; - - WHILE @@TRANCOUNT > 0 - ROLLBACK; + + END; - END CATCH; - - - END; - - END;-- End Pollster loop - - ELSE - - BEGIN - - RAISERROR('msdb.dbo.restore_worker does not exist, please create it.', 0, 1) WITH NOWAIT; - RETURN; - - END; - RETURN; + /* + + This section creates @Jobs (quantity) of worker jobs to restore logs with + They too work in a queue -/* + Like a queue-t 3.14 + + */ -Begin LogShamer -*/ + RAISERROR('Checking for sp_AllNightLog Restore jobs', 0, 1) WITH NOWAIT; + + + SELECT @counter = COUNT(*) + 1 + FROM msdb.dbo.sysjobs + WHERE name LIKE 'sp[_]AllNightLog[_]Restore[_]%'; -LogShamer: + SET @msg = 'Found ' + CONVERT(NVARCHAR(10), (@counter - 1)) + ' restore jobs -- ' + CASE WHEN @counter < @Jobs THEN + 'starting loop!' + WHEN @counter >= @Jobs THEN 'skipping loop!' + ELSE 'Oh woah something weird happened!' + END; + + RAISERROR(@msg, 0, 1) WITH NOWAIT; + + + WHILE @counter <= @Jobs - IF @Debug = 1 RAISERROR('Beginning Backups', 0, 1) WITH NOWAIT; - - IF OBJECT_ID('msdbCentral.dbo.backup_worker') IS NOT NULL - - BEGIN - - /* - - Make sure configuration table exists... - - */ - - IF OBJECT_ID('msdbCentral.dbo.backup_configuration') IS NOT NULL - - BEGIN - - IF @Debug = 1 RAISERROR('Checking variables', 0, 1) WITH NOWAIT; - - /* - - These settings are configurable - - I haven't found a good way to find the default backup path that doesn't involve xp_regread - - */ - - SELECT @rpo = CONVERT(INT, configuration_setting) - FROM msdbCentral.dbo.backup_configuration c - WHERE configuration_name = N'log backup frequency' - AND database_name = N'all'; - - - IF @rpo IS NULL - BEGIN - RAISERROR('@rpo cannot be NULL. Please check the msdbCentral.dbo.backup_configuration table', 0, 1) WITH NOWAIT; - RETURN; - END; - - - SELECT @backup_path = CONVERT(NVARCHAR(512), configuration_setting) - FROM msdbCentral.dbo.backup_configuration c - WHERE configuration_name = N'log backup path' - AND database_name = N'all'; - - IF @backup_path IS NULL BEGIN - RAISERROR('@backup_path cannot be NULL. Please check the msdbCentral.dbo.backup_configuration table', 0, 1) WITH NOWAIT; - RETURN; - END; - SELECT @changebackuptype = configuration_setting - FROM msdbCentral.dbo.backup_configuration c - WHERE configuration_name = N'change backup type' - AND database_name = N'all'; + + RAISERROR('Setting job name', 0, 1) WITH NOWAIT; - SELECT @encrypt = configuration_setting - FROM msdbCentral.dbo.backup_configuration c - WHERE configuration_name = N'encrypt' - AND database_name = N'all'; + SET @job_name_restores = N'sp_AllNightLog_Restore_' + CASE WHEN @counter < 10 THEN N'0' + CONVERT(NVARCHAR(10), @counter) + WHEN @counter >= 10 THEN CONVERT(NVARCHAR(10), @counter) + END; + + + RAISERROR('Setting @job_sql', 0, 1) WITH NOWAIT; - SELECT @encryptionalgorithm = configuration_setting - FROM msdbCentral.dbo.backup_configuration c - WHERE configuration_name = N'encryptionalgorithm' - AND database_name = N'all'; + + SET @job_sql = N' + + EXEC msdb.dbo.sp_add_job @job_name = ' + @job_name_restores + ', + @description = ' + @job_description_restores + ', + @category_name = ' + @job_category + ', + @owner_login_name = ' + @job_owner + ','; + IF @EnableRestoreJobs = 1 + BEGIN + SET @job_sql = @job_sql + ' @enabled = 1; '; + END + ELSE + BEGIN + SET @job_sql = @job_sql + ' @enabled = 0; '; + END + + + SET @job_sql = @job_sql + ' + + EXEC msdb.dbo.sp_add_jobstep @job_name = ' + @job_name_restores + ', + @step_name = ' + @job_name_restores + ', + @subsystem = ''TSQL'', + @command = ' + @job_command_restores + '; + + + EXEC msdb.dbo.sp_add_jobserver @job_name = ' + @job_name_restores + '; + + + EXEC msdb.dbo.sp_attach_schedule @job_name = ' + @job_name_restores + ', + @schedule_name = ten_seconds; + + '; + + + SET @counter += 1; - SELECT @servercertificate = configuration_setting - FROM msdbCentral.dbo.backup_configuration c - WHERE configuration_name = N'servercertificate' - AND database_name = N'all'; + + IF @Debug = 1 + BEGIN + RAISERROR(@job_sql, 0, 1) WITH NOWAIT; + END; - IF @encrypt = N'Y' AND (@encryptionalgorithm IS NULL OR @servercertificate IS NULL) - BEGIN - RAISERROR('If encryption is Y, then both the encryptionalgorithm and servercertificate must be set. Please check the msdbCentral.dbo.backup_configuration table', 0, 1) WITH NOWAIT; - RETURN; - END; - - END; - - ELSE - - BEGIN - - RAISERROR('msdbCentral.dbo.backup_configuration does not exist, please run setup script', 0, 1) WITH NOWAIT; - RETURN; - - END; - - - WHILE @Backup = 1 + + IF @job_sql IS NULL + BEGIN + RAISERROR('@job_sql is NULL for some reason', 0, 1) WITH NOWAIT; + END; - /* - - Start loop to take log backups - */ + EXEC sp_executesql @job_sql; - - BEGIN - - BEGIN TRY - BEGIN TRAN; - - IF @Debug = 1 RAISERROR('Begin tran to grab a database to back up', 0, 1) WITH NOWAIT; + END; - /* - - This grabs a database for a worker to work on + RAISERROR('Setup complete!', 0, 1) WITH NOWAIT; + + END; --End for the Agent job creation - The locking hints hope to provide some isolation when 10+ workers are in action - - */ - - - SELECT TOP (1) - @database = bw.database_name - FROM msdbCentral.dbo.backup_worker bw WITH (UPDLOCK, HOLDLOCK, ROWLOCK) - WHERE - ( /*This section works on databases already part of the backup cycle*/ - bw.is_started = 0 - AND bw.is_completed = 1 - AND bw.last_log_backup_start_time < DATEADD(SECOND, (@rpo * -1), GETDATE()) - AND (bw.error_number IS NULL OR bw.error_number > 0) /* negative numbers indicate human attention required */ - AND bw.ignore_database = 0 - ) - OR - ( /*This section picks up newly added databases by Pollster*/ - bw.is_started = 0 - AND bw.is_completed = 0 - AND bw.last_log_backup_start_time = '1900-01-01 00:00:00.000' - AND bw.last_log_backup_finish_time = '9999-12-31 00:00:00.000' - AND (bw.error_number IS NULL OR bw.error_number > 0) /* negative numbers indicate human attention required */ - AND bw.ignore_database = 0 - ) - ORDER BY bw.last_log_backup_start_time ASC, bw.last_log_backup_finish_time ASC, bw.database_name ASC; - - - IF @database IS NOT NULL - BEGIN - SET @msg = N'Updating backup_worker for database ' + ISNULL(@database, 'UH OH NULL @database'); - IF @Debug = 1 RAISERROR(@msg, 0, 1) WITH NOWAIT; - - /* - - Update the worker table so other workers know a database is being backed up - - */ + END;--End for Database and Table creation - - UPDATE bw - SET bw.is_started = 1, - bw.is_completed = 0, - bw.last_log_backup_start_time = GETDATE() - FROM msdbCentral.dbo.backup_worker bw - WHERE bw.database_name = @database; - END - - COMMIT; - - END TRY - - BEGIN CATCH - - /* - - Do I need to build retry logic in here? Try to catch deadlocks? I don't know yet! - - */ + END TRY - SELECT @msg = N'Error securing a database to backup, error number is ' + CONVERT(NVARCHAR(10), ERROR_NUMBER()) + ', error message is ' + ERROR_MESSAGE(), - @error_severity = ERROR_SEVERITY(), - @error_state = ERROR_STATE(); - RAISERROR(@msg, @error_severity, @error_state) WITH NOWAIT; + BEGIN CATCH - SET @database = NULL; - - WHILE @@TRANCOUNT > 0 - ROLLBACK; - - END CATCH; + SELECT @msg = N'Error occurred during setup: ' + CONVERT(NVARCHAR(10), ERROR_NUMBER()) + ', error message is ' + ERROR_MESSAGE(), + @error_severity = ERROR_SEVERITY(), + @error_state = ERROR_STATE(); + + RAISERROR(@msg, @error_severity, @error_state) WITH NOWAIT; - /* If we don't find a database to work on, wait for a few seconds */ - IF @database IS NULL - BEGIN - IF @Debug = 1 RAISERROR('No databases to back up right now, starting 3 second throttle', 0, 1) WITH NOWAIT; - WAITFOR DELAY '00:00:03.000'; + WHILE @@TRANCOUNT > 0 + ROLLBACK; - /* Check to make sure job is still enabled */ - IF NOT EXISTS ( - SELECT * - FROM msdb.dbo.sysjobs - WHERE name LIKE 'sp_AllNightLog_Backup%' - AND enabled = 1 - ) - BEGIN - RAISERROR('sp_AllNightLog_Backup jobs are disabled, so gracefully exiting. It feels graceful to me, anyway.', 0, 1) WITH NOWAIT; - RETURN; - END + END CATCH; +END; /* IF @RunSetup = 1 */ - END - +RETURN; + + +UpdateConfigs: + +IF @UpdateSetup = 1 - BEGIN TRY + BEGIN + + /* If we're enabling backup jobs, we may need to run restore with recovery on msdbCentral to bring it online: */ + IF @EnableBackupJobs = 1 AND EXISTS (SELECT * FROM sys.databases WHERE name = 'msdbCentral' AND state = 1) + BEGIN + RAISERROR('msdbCentral exists, but is in restoring state. Running restore with recovery...', 0, 1) WITH NOWAIT; + + BEGIN TRY + RESTORE DATABASE [msdbCentral] WITH RECOVERY; + END TRY + + BEGIN CATCH + + SELECT @error_number = ERROR_NUMBER(), + @error_severity = ERROR_SEVERITY(), + @error_state = ERROR_STATE(); + + SELECT @msg = N'Error running restore with recovery on msdbCentral, error number is ' + CONVERT(NVARCHAR(10), ERROR_NUMBER()) + ', error message is ' + ERROR_MESSAGE(), + @error_severity = ERROR_SEVERITY(), + @error_state = ERROR_STATE(); - BEGIN - - IF @database IS NOT NULL + RAISERROR(@msg, @error_severity, @error_state) WITH NOWAIT; - /* - - Make sure we have a database to work on -- I should make this more robust so we do something if it is NULL, maybe - - */ + END CATCH; - - BEGIN - - SET @msg = N'Taking backup of ' + ISNULL(@database, 'UH OH NULL @database'); - IF @Debug = 1 RAISERROR(@msg, 0, 1) WITH NOWAIT; + END - /* - - Call Ola's proc to backup the database - - */ + /* Only check for this after trying to restore msdbCentral: */ + IF @EnableBackupJobs = 1 AND NOT EXISTS (SELECT * FROM sys.databases WHERE name = 'msdbCentral' AND state = 0) + BEGIN + RAISERROR('msdbCentral is not online. Repair that first, then try to enable backup jobs.', 0, 1) WITH NOWAIT; + RETURN + END - IF @encrypt = 'Y' - EXEC dbo.DatabaseBackup @Databases = @database, --Database we're working on - @BackupType = 'LOG', --Going for the LOGs - @Directory = @backup_path, --The path we need to back up to - @Verify = 'N', --We don't want to verify these, it eats into job time - @ChangeBackupType = @changebackuptype, --If we need to switch to a FULL because one hasn't been taken - @CheckSum = 'Y', --These are a good idea - @Compress = 'Y', --This is usually a good idea - @LogToTable = 'Y', --We should do this for posterity - @Encrypt = @encrypt, - @EncryptionAlgorithm = @encryptionalgorithm, - @ServerCertificate = @servercertificate; - ELSE - EXEC dbo.DatabaseBackup @Databases = @database, --Database we're working on - @BackupType = 'LOG', --Going for the LOGs - @Directory = @backup_path, --The path we need to back up to - @Verify = 'N', --We don't want to verify these, it eats into job time - @ChangeBackupType = @changebackuptype, --If we need to switch to a FULL because one hasn't been taken - @CheckSum = 'Y', --These are a good idea - @Compress = 'Y', --This is usually a good idea - @LogToTable = 'Y'; --We should do this for posterity - - - /* - - Catch any erroneous zones - - */ - - SELECT @error_number = ERROR_NUMBER(), - @error_severity = ERROR_SEVERITY(), - @error_state = ERROR_STATE(); - - END; --End call to dbo.DatabaseBackup - - END; --End successful check of @database (not NULL) - - END TRY - - BEGIN CATCH + IF OBJECT_ID('msdbCentral.dbo.backup_configuration') IS NOT NULL + + RAISERROR('Found backup config, checking variables...', 0, 1) WITH NOWAIT; - IF @error_number IS NOT NULL + BEGIN + + BEGIN TRY - /* - If the ERROR() function returns a number, update the table with it and the last error date. + IF @RPOSeconds IS NOT NULL - Also update the last start time to 1900-01-01 so it gets picked back up immediately -- the query to find a log backup to take sorts by start time - */ - BEGIN - - SET @msg = N'Error number is ' + CONVERT(NVARCHAR(10), ERROR_NUMBER()); - RAISERROR(@msg, @error_severity, @error_state) WITH NOWAIT; - - SET @msg = N'Updating backup_worker for database ' + ISNULL(@database, 'UH OH NULL @database') + ' for unsuccessful backup'; - RAISERROR(@msg, 0, 1) WITH NOWAIT; - - - UPDATE bw - SET bw.is_started = 0, - bw.is_completed = 1, - bw.last_log_backup_start_time = '19000101', - bw.error_number = @error_number, - bw.last_error_date = GETDATE() - FROM msdbCentral.dbo.backup_worker bw - WHERE bw.database_name = @database; + RAISERROR('Attempting to update RPO setting', 0, 1) WITH NOWAIT; - /* - - Set @database back to NULL to avoid variable assignment weirdness - - */ + UPDATE c + SET c.configuration_setting = CONVERT(NVARCHAR(10), @RPOSeconds) + FROM msdbCentral.dbo.backup_configuration AS c + WHERE c.configuration_name = N'log backup frequency'; - SET @database = NULL; + END; - - /* - - Wait around for a second so we're not just spinning wheels -- this only runs if the BEGIN CATCH is triggered by an error + + IF @BackupPath IS NOT NULL - */ - - IF @Debug = 1 RAISERROR('Starting 1 second throttle', 0, 1) WITH NOWAIT; - - WAITFOR DELAY '00:00:01.000'; + BEGIN + + RAISERROR('Attempting to update Backup Path setting', 0, 1) WITH NOWAIT; - END; -- End update of unsuccessful backup - - END CATCH; - - IF @database IS NOT NULL AND @error_number IS NULL - - /* - - If no error, update everything normally - - */ - - - BEGIN - - IF @Debug = 1 RAISERROR('Error number IS NULL', 0, 1) WITH NOWAIT; - - SET @msg = N'Updating backup_worker for database ' + ISNULL(@database, 'UH OH NULL @database') + ' for successful backup'; - IF @Debug = 1 RAISERROR(@msg, 0, 1) WITH NOWAIT; - - - UPDATE bw - SET bw.is_started = 0, - bw.is_completed = 1, - bw.last_log_backup_finish_time = GETDATE() - FROM msdbCentral.dbo.backup_worker bw - WHERE bw.database_name = @database; - - - /* - - Set @database back to NULL to avoid variable assignment weirdness - - */ + UPDATE c + SET c.configuration_setting = @BackupPath + FROM msdbCentral.dbo.backup_configuration AS c + WHERE c.configuration_name = N'log backup path'; - SET @database = NULL; + END; - END; -- End update for successful backup + END TRY - - END; -- End @Backup WHILE loop - - END; -- End successful check for backup_worker and subsequent code + BEGIN CATCH - - ELSE - - BEGIN - - RAISERROR('msdbCentral.dbo.backup_worker does not exist, please run setup script', 0, 1) WITH NOWAIT; - - RETURN; - - END; -RETURN; + SELECT @error_number = ERROR_NUMBER(), + @error_severity = ERROR_SEVERITY(), + @error_state = ERROR_STATE(); -/* + SELECT @msg = N'Error updating backup configuration setting, error number is ' + CONVERT(NVARCHAR(10), ERROR_NUMBER()) + ', error message is ' + ERROR_MESSAGE(), + @error_severity = ERROR_SEVERITY(), + @error_state = ERROR_STATE(); + + RAISERROR(@msg, @error_severity, @error_state) WITH NOWAIT; -Begin Restoregasm_Addict section -*/ + END CATCH; -Restoregasm_Addict: + END; -IF @Restore = 1 - IF @Debug = 1 RAISERROR('Beginning Restores', 0, 1) WITH NOWAIT; - - /* Check to make sure backup jobs aren't enabled */ - IF EXISTS ( - SELECT * - FROM msdb.dbo.sysjobs - WHERE name LIKE 'sp_AllNightLog_Backup%' - AND enabled = 1 - ) - BEGIN - RAISERROR('sp_AllNightLog_Backup jobs are enabled, so gracefully exiting. You do not want to accidentally do restores over top of the databases you are backing up.', 0, 1) WITH NOWAIT; - RETURN; - END - IF OBJECT_ID('msdb.dbo.restore_worker') IS NOT NULL - - BEGIN - - /* - - Make sure configuration table exists... - - */ - IF OBJECT_ID('msdb.dbo.restore_configuration') IS NOT NULL - - BEGIN - - IF @Debug = 1 RAISERROR('Checking variables', 0, 1) WITH NOWAIT; - - /* - - These settings are configurable - - */ - - SELECT @rto = CONVERT(INT, configuration_setting) - FROM msdb.dbo.restore_configuration c - WHERE configuration_name = N'log restore frequency'; - - - IF @rto IS NULL - BEGIN - RAISERROR('@rto cannot be NULL. Please check the msdb.dbo.restore_configuration table', 0, 1) WITH NOWAIT; - RETURN; - END; - - - END; - - ELSE - - BEGIN - - RAISERROR('msdb.dbo.restore_configuration does not exist, please run setup script', 0, 1) WITH NOWAIT; - - RETURN; - - END; - - - WHILE @Restore = 1 - - /* - - Start loop to restore log backups - */ + RAISERROR('Found restore config, checking variables...', 0, 1) WITH NOWAIT; - BEGIN - - BEGIN TRY - - BEGIN TRAN; - - IF @Debug = 1 RAISERROR('Begin tran to grab a database to restore', 0, 1) WITH NOWAIT; - - - /* - - This grabs a database for a worker to work on - - The locking hints hope to provide some isolation when 10+ workers are in action - - */ - - - SELECT TOP (1) - @database = rw.database_name, - @only_logs_after = REPLACE(REPLACE(REPLACE(CONVERT(NVARCHAR(30), rw.last_log_restore_start_time, 120), ' ', ''), '-', ''), ':', ''), - @restore_full = CASE WHEN rw.is_started = 0 - AND rw.is_completed = 0 - AND rw.last_log_restore_start_time = '1900-01-01 00:00:00.000' - AND rw.last_log_restore_finish_time = '9999-12-31 00:00:00.000' - THEN 1 - ELSE 0 - END - FROM msdb.dbo.restore_worker rw WITH (UPDLOCK, HOLDLOCK, ROWLOCK) - WHERE ( - ( /*This section works on databases already part of the backup cycle*/ - rw.is_started = 0 - AND rw.is_completed = 1 - AND rw.last_log_restore_start_time < DATEADD(SECOND, (@rto * -1), GETDATE()) - AND (rw.error_number IS NULL OR rw.error_number > 0) /* negative numbers indicate human attention required */ - ) - OR - ( /*This section picks up newly added databases by DiskPollster*/ - rw.is_started = 0 - AND rw.is_completed = 0 - AND rw.last_log_restore_start_time = '1900-01-01 00:00:00.000' - AND rw.last_log_restore_finish_time = '9999-12-31 00:00:00.000' - AND (rw.error_number IS NULL OR rw.error_number > 0) /* negative numbers indicate human attention required */ - ) - ) - AND rw.ignore_database = 0 - AND NOT EXISTS ( - /* Validation check to ensure the database either doesn't exist or is in a restoring/standby state */ - SELECT 1 - FROM sys.databases d - WHERE d.name = rw.database_name - AND state <> 1 /* Restoring */ - AND NOT (state=0 AND d.is_in_standby=1) /* standby mode */ - ) - ORDER BY rw.last_log_restore_start_time ASC, rw.last_log_restore_finish_time ASC, rw.database_name ASC; - - - IF @database IS NOT NULL - BEGIN - SET @msg = N'Updating restore_worker for database ' + ISNULL(@database, 'UH OH NULL @database'); - IF @Debug = 1 RAISERROR(@msg, 0, 1) WITH NOWAIT; - - /* - - Update the worker table so other workers know a database is being restored - - */ - - UPDATE rw - SET rw.is_started = 1, - rw.is_completed = 0, - rw.last_log_restore_start_time = GETDATE() - FROM msdb.dbo.restore_worker rw - WHERE rw.database_name = @database; - END - - COMMIT; - - END TRY - - BEGIN CATCH - - /* - - Do I need to build retry logic in here? Try to catch deadlocks? I don't know yet! - - */ + BEGIN TRY - SELECT @msg = N'Error securing a database to restore, error number is ' + CONVERT(NVARCHAR(10), ERROR_NUMBER()) + ', error message is ' + ERROR_MESSAGE(), - @error_severity = ERROR_SEVERITY(), - @error_state = ERROR_STATE(); - RAISERROR(@msg, @error_severity, @error_state) WITH NOWAIT; + EXEC msdb.dbo.sp_update_schedule @name = ten_seconds, @active_start_date = @active_start_date, @active_start_time = 000000; - SET @database = NULL; - - WHILE @@TRANCOUNT > 0 - ROLLBACK; - - END CATCH; + IF @EnableRestoreJobs IS NOT NULL + BEGIN + RAISERROR('Changing restore job status based on @EnableBackupJobs parameter...', 0, 1) WITH NOWAIT; + INSERT INTO @jobs_to_change(name) + SELECT name + FROM msdb.dbo.sysjobs + WHERE name LIKE 'sp_AllNightLog_Restore%' OR name = 'sp_AllNightLog_PollDiskForNewDatabases'; + DECLARE jobs_cursor CURSOR FOR + SELECT name + FROM @jobs_to_change + OPEN jobs_cursor + FETCH NEXT FROM jobs_cursor INTO @current_job_name - /* If we don't find a database to work on, wait for a few seconds */ - IF @database IS NULL + WHILE @@FETCH_STATUS = 0 + BEGIN + RAISERROR(@current_job_name, 0, 1) WITH NOWAIT; + EXEC msdb.dbo.sp_update_job @job_name=@current_job_name,@enabled = @EnableRestoreJobs; + FETCH NEXT FROM jobs_cursor INTO @current_job_name + END - BEGIN - IF @Debug = 1 RAISERROR('No databases to restore up right now, starting 3 second throttle', 0, 1) WITH NOWAIT; - WAITFOR DELAY '00:00:03.000'; + CLOSE jobs_cursor + DEALLOCATE jobs_cursor + DELETE @jobs_to_change; + END; - /* Check to make sure backup jobs aren't enabled */ - IF EXISTS ( - SELECT * - FROM msdb.dbo.sysjobs - WHERE name LIKE 'sp_AllNightLog_Backup%' - AND enabled = 1 - ) - BEGIN - RAISERROR('sp_AllNightLog_Backup jobs are enabled, so gracefully exiting. You do not want to accidentally do restores over top of the databases you are backing up.', 0, 1) WITH NOWAIT; - RETURN; - END + /* If they wanted to turn off restore jobs, wait to make sure that finishes before we start enabling the backup jobs */ + IF @EnableRestoreJobs = 0 + BEGIN + SET @started_waiting_for_jobs = GETDATE(); + SELECT @counter = COUNT(*) + FROM [msdb].[dbo].[sysjobactivity] [ja] + INNER JOIN [msdb].[dbo].[sysjobs] [j] + ON [ja].[job_id] = [j].[job_id] + WHERE [ja].[session_id] = ( + SELECT TOP 1 [session_id] + FROM [msdb].[dbo].[syssessions] + ORDER BY [agent_start_date] DESC + ) + AND [start_execution_date] IS NOT NULL + AND [stop_execution_date] IS NULL + AND [j].[name] LIKE 'sp_AllNightLog_Restore%'; - /* Check to make sure job is still enabled */ - IF NOT EXISTS ( - SELECT * - FROM msdb.dbo.sysjobs - WHERE name LIKE 'sp_AllNightLog_Restore%' - AND enabled = 1 - ) + WHILE @counter > 0 BEGIN - RAISERROR('sp_AllNightLog_Restore jobs are disabled, so gracefully exiting. It feels graceful to me, anyway.', 0, 1) WITH NOWAIT; - RETURN; - END - - END - - - BEGIN TRY - - BEGIN + IF DATEADD(SS, 120, @started_waiting_for_jobs) < GETDATE() + BEGIN + RAISERROR('OH NOES! We waited 2 minutes and restore jobs are still running. We are stopping here - get a meatbag involved to figure out if restore jobs need to be killed, and the backup jobs will need to be enabled manually.', 16, 1) WITH NOWAIT; + RETURN + END + SET @msg = N'Waiting for ' + CAST(@counter AS NVARCHAR(100)) + N' sp_AllNightLog_Restore job(s) to finish.' + RAISERROR(@msg, 0, 1) WITH NOWAIT; + WAITFOR DELAY '0:00:01'; -- Wait until the restore jobs are fully stopped - IF @database IS NOT NULL + SELECT @counter = COUNT(*) + FROM [msdb].[dbo].[sysjobactivity] [ja] + INNER JOIN [msdb].[dbo].[sysjobs] [j] + ON [ja].[job_id] = [j].[job_id] + WHERE [ja].[session_id] = ( + SELECT TOP 1 [session_id] + FROM [msdb].[dbo].[syssessions] + ORDER BY [agent_start_date] DESC + ) + AND [start_execution_date] IS NOT NULL + AND [stop_execution_date] IS NULL + AND [j].[name] LIKE 'sp_AllNightLog_Restore%'; + END + END /* IF @EnableRestoreJobs = 0 */ - /* - - Make sure we have a database to work on -- I should make this more robust so we do something if it is NULL, maybe - - */ - - BEGIN - - SET @msg = CASE WHEN @restore_full = 0 - THEN N'Restoring logs for ' - ELSE N'Restoring full backup for ' - END - + ISNULL(@database, 'UH OH NULL @database'); + IF @EnableBackupJobs IS NOT NULL + BEGIN + RAISERROR('Changing backup job status based on @EnableBackupJobs parameter...', 0, 1) WITH NOWAIT; + INSERT INTO @jobs_to_change(name) + SELECT name + FROM msdb.dbo.sysjobs + WHERE name LIKE 'sp_AllNightLog_Backup%' OR name = 'sp_AllNightLog_PollForNewDatabases'; + DECLARE jobs_cursor CURSOR FOR + SELECT name + FROM @jobs_to_change - IF @Debug = 1 RAISERROR(@msg, 0, 1) WITH NOWAIT; + OPEN jobs_cursor + FETCH NEXT FROM jobs_cursor INTO @current_job_name - /* - - Call sp_DatabaseRestore to backup the database - - */ + WHILE @@FETCH_STATUS = 0 + BEGIN + RAISERROR(@current_job_name, 0, 1) WITH NOWAIT; + EXEC msdb.dbo.sp_update_job @job_name=@current_job_name,@enabled = @EnableBackupJobs; + FETCH NEXT FROM jobs_cursor INTO @current_job_name + END - SET @restore_path_full = @restore_path_base + N'\' + @database + N'\' + N'FULL\' - - SET @msg = N'Path for FULL backups for ' + @database + N' is ' + @restore_path_full - IF @Debug = 1 RAISERROR(@msg, 0, 1) WITH NOWAIT; + CLOSE jobs_cursor + DEALLOCATE jobs_cursor + DELETE @jobs_to_change; + END; - SET @restore_path_log = @restore_path_base + N'\' + @database + N'\' + N'LOG\' - SET @msg = N'Path for LOG backups for ' + @database + N' is ' + @restore_path_log - IF @Debug = 1 RAISERROR(@msg, 0, 1) WITH NOWAIT; + + IF @RTOSeconds IS NOT NULL - IF @restore_full = 0 + BEGIN - BEGIN + RAISERROR('Attempting to update RTO setting', 0, 1) WITH NOWAIT; - IF @Debug = 1 RAISERROR('Starting Log only restores', 0, 1) WITH NOWAIT; + UPDATE c + SET c.configuration_setting = CONVERT(NVARCHAR(10), @RTOSeconds) + FROM msdb.dbo.restore_configuration AS c + WHERE c.configuration_name = N'log restore frequency'; - EXEC dbo.sp_DatabaseRestore @Database = @database, - @BackupPathFull = @restore_path_full, - @BackupPathLog = @restore_path_log, - @ContinueLogs = 1, - @RunRecovery = 0, - @OnlyLogsAfter = @only_logs_after, - @MoveFiles = @restore_move_files, - @Debug = @Debug - - END + END; - IF @restore_full = 1 + + IF @RestorePath IS NOT NULL - BEGIN + BEGIN + + RAISERROR('Attempting to update Restore Path setting', 0, 1) WITH NOWAIT; - IF @Debug = 1 RAISERROR('Starting first Full restore from: ', 0, 1) WITH NOWAIT; - IF @Debug = 1 RAISERROR(@restore_path_full, 0, 1) WITH NOWAIT; + UPDATE c + SET c.configuration_setting = @RestorePath + FROM msdb.dbo.restore_configuration AS c + WHERE c.configuration_name = N'log restore path'; - EXEC dbo.sp_DatabaseRestore @Database = @database, - @BackupPathFull = @restore_path_full, - @BackupPathLog = @restore_path_log, - @ContinueLogs = 0, - @RunRecovery = 0, - @MoveFiles = @restore_move_files, - @Debug = @Debug - - END + END; - - /* - - Catch any erroneous zones - - */ - - SELECT @error_number = ERROR_NUMBER(), - @error_severity = ERROR_SEVERITY(), - @error_state = ERROR_STATE(); - - END; --End call to dbo.sp_DatabaseRestore - - END; --End successful check of @database (not NULL) - END TRY - - BEGIN CATCH - - IF @error_number IS NOT NULL - /* - - If the ERROR() function returns a number, update the table with it and the last error date. - Also update the last start time to 1900-01-01 so it gets picked back up immediately -- the query to find a log restore to take sorts by start time + BEGIN CATCH - */ - - BEGIN - - SET @msg = N'Error number is ' + CONVERT(NVARCHAR(10), ERROR_NUMBER()); - RAISERROR(@msg, @error_severity, @error_state) WITH NOWAIT; - - SET @msg = N'Updating restore_worker for database ' + ISNULL(@database, 'UH OH NULL @database') + ' for unsuccessful backup'; - RAISERROR(@msg, 0, 1) WITH NOWAIT; - - - UPDATE rw - SET rw.is_started = 0, - rw.is_completed = 1, - rw.last_log_restore_start_time = '19000101', - rw.error_number = @error_number, - rw.last_error_date = GETDATE() - FROM msdb.dbo.restore_worker rw - WHERE rw.database_name = @database; + SELECT @error_number = ERROR_NUMBER(), + @error_severity = ERROR_SEVERITY(), + @error_state = ERROR_STATE(); - /* - - Set @database back to NULL to avoid variable assignment weirdness - - */ + SELECT @msg = N'Error updating restore configuration setting, error number is ' + CONVERT(NVARCHAR(10), ERROR_NUMBER()) + ', error message is ' + ERROR_MESSAGE(), + @error_severity = ERROR_SEVERITY(), + @error_state = ERROR_STATE(); + + RAISERROR(@msg, @error_severity, @error_state) WITH NOWAIT; - SET @database = NULL; - - /* - - Wait around for a second so we're not just spinning wheels -- this only runs if the BEGIN CATCH is triggered by an error + END CATCH; - */ - - IF @Debug = 1 RAISERROR('Starting 1 second throttle', 0, 1) WITH NOWAIT; - - WAITFOR DELAY '00:00:01.000'; + END; - END; -- End update of unsuccessful restore - - END CATCH; + RAISERROR('Update complete!', 0, 1) WITH NOWAIT; + RETURN; - IF @database IS NOT NULL AND @error_number IS NULL + END; --End updates to configuration table - /* - - If no error, update everything normally - - */ - - BEGIN - - IF @Debug = 1 RAISERROR('Error number IS NULL', 0, 1) WITH NOWAIT; +END; -- Final END for stored proc +GO - /* Make sure database actually exists and is in the restoring state */ - IF EXISTS (SELECT * FROM sys.databases WHERE name = @database AND state = 1) /* Restoring */ - BEGIN - SET @msg = N'Updating backup_worker for database ' + ISNULL(@database, 'UH OH NULL @database') + ' for successful backup'; - IF @Debug = 1 RAISERROR(@msg, 0, 1) WITH NOWAIT; - - UPDATE rw - SET rw.is_started = 0, - rw.is_completed = 1, - rw.last_log_restore_finish_time = GETDATE() - FROM msdb.dbo.restore_worker rw - WHERE rw.database_name = @database; - - END - ELSE /* The database doesn't exist, or it's not in the restoring state */ - BEGIN - SET @msg = N'Updating backup_worker for database ' + ISNULL(@database, 'UH OH NULL @database') + ' for UNsuccessful backup'; - IF @Debug = 1 RAISERROR(@msg, 0, 1) WITH NOWAIT; - - UPDATE rw - SET rw.is_started = 0, - rw.is_completed = 1, - rw.error_number = -1, /* unknown, human attention required */ - rw.last_error_date = GETDATE() - /* rw.last_log_restore_finish_time = GETDATE() don't change this - the last log may still be successful */ - FROM msdb.dbo.restore_worker rw - WHERE rw.database_name = @database; - END - - - - /* - - Set @database back to NULL to avoid variable assignment weirdness - - */ - - SET @database = NULL; - - - END; -- End update for successful backup - - END; -- End @Restore WHILE loop - - - END; -- End successful check for restore_worker and subsequent code - - - ELSE - - BEGIN - - RAISERROR('msdb.dbo.restore_worker does not exist, please run setup script', 0, 1) WITH NOWAIT; - - RETURN; - - END; -RETURN; - - - -END; -- Final END for stored proc - -GO SET ANSI_NULLS ON; SET ANSI_PADDING ON; SET ANSI_WARNINGS ON; @@ -1526,29 +1352,21 @@ SET STATISTICS IO OFF; SET STATISTICS TIME OFF; GO -IF OBJECT_ID('dbo.sp_AllNightLog_Setup') IS NULL - EXEC ('CREATE PROCEDURE dbo.sp_AllNightLog_Setup AS RETURN 0;'); +IF OBJECT_ID('dbo.sp_AllNightLog') IS NULL + EXEC ('CREATE PROCEDURE dbo.sp_AllNightLog AS RETURN 0;') GO -ALTER PROCEDURE dbo.sp_AllNightLog_Setup - @RPOSeconds BIGINT = 30, - @RTOSeconds BIGINT = 30, - @BackupPath NVARCHAR(MAX) = NULL, - @RestorePath NVARCHAR(MAX) = NULL, - @Jobs TINYINT = 10, - @RunSetup BIT = 0, - @UpdateSetup BIT = 0, - @EnableBackupJobs INT = NULL, - @EnableRestoreJobs INT = NULL, - @Debug BIT = 0, - @FirstFullBackup BIT = 0, - @FirstDiffBackup BIT = 0, - @MoveFiles BIT = 1, - @Help BIT = 0, - @Version VARCHAR(30) = NULL OUTPUT, - @VersionDate DATETIME = NULL OUTPUT, - @VersionCheckMode BIT = 0 +ALTER PROCEDURE dbo.sp_AllNightLog + @PollForNewDatabases BIT = 0, /* Formerly Pollster */ + @Backup BIT = 0, /* Formerly LogShaming */ + @PollDiskForNewDatabases BIT = 0, + @Restore BIT = 0, + @Debug BIT = 0, + @Help BIT = 0, + @Version VARCHAR(30) = NULL OUTPUT, + @VersionDate DATETIME = NULL OUTPUT, + @VersionCheckMode BIT = 0 WITH RECOMPILE AS SET NOCOUNT ON; @@ -1556,7 +1374,8 @@ SET STATISTICS XML OFF; BEGIN; -SELECT @Version = '8.12', @VersionDate = '20221213'; + +SELECT @Version = '8.13', @VersionDate = '20230215'; IF(@VersionCheckMode = 1) BEGIN @@ -1571,35 +1390,15 @@ BEGIN /* - sp_AllNightLog_Setup from http://FirstResponderKit.org + sp_AllNightLog from http://FirstResponderKit.org - This script sets up a database, tables, rows, and jobs for sp_AllNightLog, including: - - * Creates a database - * Right now it''s hard-coded to use msdbCentral, that might change later + * @PollForNewDatabases = 1 polls sys.databases for new entries + * Unfortunately no other way currently to automate new database additions when restored from backups + * No triggers or extended events that easily do this - * Creates tables in that database! - * dbo.backup_configuration - * Hold variables used by stored proc to make runtime decisions - * RPO: Seconds, how often we look for databases that need log backups - * Backup Path: The path we feed to Ola H''s backup proc - * dbo.backup_worker - * Holds list of databases and some information that helps our Agent jobs figure out if they need to take another log backup - - * Creates tables in msdb - * dbo.restore_configuration - * Holds variables used by stored proc to make runtime decisions - * RTO: Seconds, how often to look for log backups to restore - * Restore Path: The path we feed to sp_DatabaseRestore - * Move Files: Whether to move files to default data/log directories. - * dbo.restore_worker - * Holds list of databases and some information that helps our Agent jobs figure out if they need to look for files to restore + * @Backup = 1 polls msdbCentral.dbo.backup_worker for databases not backed up in [RPO], takes LOG backups + * Will switch to a full backup if none exists - * Creates agent jobs - * 1 job that polls sys.databases for new entries - * 10 jobs that run to take log backups - * Based on a queue table - * Requires Ola Hallengren''s Database Backup stored proc To learn more, visit http://FirstResponderKit.org where you can download new versions for free, watch training videos on how it works, get more info on @@ -1607,7 +1406,7 @@ BEGIN Known limitations of this version: - Only Microsoft-supported versions of SQL Server. Sorry, 2005 and 2000! And really, maybe not even anything less than 2016. Heh. - - The repository database name is hard-coded to msdbCentral. + - When restoring encrypted backups, the encryption certificate must already be installed. Unknown limitations of this version: - None. (If we knew them, they would be known. Duh.) @@ -1618,26 +1417,17 @@ BEGIN Parameter explanations: - @RunSetup BIT, defaults to 0. When this is set to 1, it will run the setup portion to create database, tables, and worker jobs. - @UpdateSetup BIT, defaults to 0. When set to 1, will update existing configs for RPO/RTO and database backup/restore paths. - @RPOSeconds BIGINT, defaults to 30. Value in seconds you want to use to determine if a new log backup needs to be taken. - @BackupPath NVARCHAR(MAX), This is REQUIRED if @Runsetup=1. This tells Ola''s job where to put backups. - @MoveFiles BIT, defaults to 1. When this is set to 1, it will move files to default data/log directories + @PollForNewDatabases BIT, defaults to 0. When this is set to 1, runs in a perma-loop to find new entries in sys.databases + @Backup BIT, defaults to 0. When this is set to 1, runs in a perma-loop checking the backup_worker table for databases that need to be backed up @Debug BIT, defaults to 0. Whent this is set to 1, it prints out dynamic SQL commands + @RPOSeconds BIGINT, defaults to 30. Value in seconds you want to use to determine if a new log backup needs to be taken. + @BackupPath NVARCHAR(MAX), defaults to = ''D:\Backup''. You 99.99999% will need to change this path to something else. This tells Ola''s job where to put backups. - Sample call: - EXEC dbo.sp_AllNightLog_Setup - @RunSetup = 1, - @RPOSeconds = 30, - @BackupPath = N''M:\MSSQL\Backup'', - @Debug = 1 - - For more documentation: https://github.com/BrentOzarULTD/SQL-Server-First-Responder-Kit/ MIT License - Copyright (c) 2021 Brent Ozar Unlimited + Copyright (c) Brent Ozar Unlimited Permission is hereby granted, free of charge, to any person obtaining a copy of this software and associated documentation files (the "Software"), to deal @@ -1660,8 +1450,8 @@ BEGIN */'; -RETURN; -END; /* IF @Help = 1 */ +RETURN +END DECLARE @database NVARCHAR(128) = NULL; --Holds the database that's currently being processed DECLARE @error_number INT = NULL; --Used for TRY/CATCH @@ -1669,110 +1459,45 @@ DECLARE @error_severity INT; --Used for TRY/CATCH DECLARE @error_state INT; --Used for TRY/CATCH DECLARE @msg NVARCHAR(4000) = N''; --Used for RAISERROR DECLARE @rpo INT; --Used to hold the RPO value in our configuration table +DECLARE @rto INT; --Used to hold the RPO value in our configuration table DECLARE @backup_path NVARCHAR(MAX); --Used to hold the backup path in our configuration table +DECLARE @changebackuptype NVARCHAR(MAX); --Config table: Y = escalate to full backup, MSDB = escalate if MSDB history doesn't show a recent full. +DECLARE @encrypt NVARCHAR(MAX); --Config table: Y = encrypt the backup. N (default) = do not encrypt. +DECLARE @encryptionalgorithm NVARCHAR(MAX); --Config table: native 2014 choices include TRIPLE_DES_3KEY, AES_128, AES_192, AES_256 +DECLARE @servercertificate NVARCHAR(MAX); --Config table: server certificate that is used to encrypt the backup +DECLARE @restore_path_base NVARCHAR(MAX); --Used to hold the base backup path in our configuration table +DECLARE @restore_path_full NVARCHAR(MAX); --Used to hold the full backup path in our configuration table +DECLARE @restore_path_log NVARCHAR(MAX); --Used to hold the log backup path in our configuration table +DECLARE @restore_move_files INT; -- used to hold the move files bit in our configuration table DECLARE @db_sql NVARCHAR(MAX) = N''; --Used to hold the dynamic SQL to create msdbCentral DECLARE @tbl_sql NVARCHAR(MAX) = N''; --Used to hold the dynamic SQL that creates tables in msdbCentral DECLARE @database_name NVARCHAR(256) = N'msdbCentral'; --Used to hold the name of the database we create to centralize data --Right now it's hardcoded to msdbCentral, but I made it dynamic in case that changes down the line +DECLARE @cmd NVARCHAR(4000) = N'' --Holds dir cmd +DECLARE @FileList TABLE ( BackupFile NVARCHAR(255) ); --Where we dump @cmd +DECLARE @restore_full BIT = 0 --We use this one +DECLARE @only_logs_after NVARCHAR(30) = N'' -/*These variables control the loop to create/modify jobs*/ -DECLARE @job_sql NVARCHAR(MAX) = N''; --Used to hold the dynamic SQL that creates Agent jobs -DECLARE @counter INT = 0; --For looping to create 10 Agent jobs -DECLARE @job_category NVARCHAR(MAX) = N'''Database Maintenance'''; --Job category -DECLARE @job_owner NVARCHAR(128) = QUOTENAME(SUSER_SNAME(0x01), ''''); -- Admin user/owner -DECLARE @jobs_to_change TABLE(name SYSNAME); -- list of jobs we need to enable or disable -DECLARE @current_job_name SYSNAME; -- While looping through Agent jobs to enable or disable -DECLARE @active_start_date INT = (CONVERT(INT, CONVERT(VARCHAR(10), GETDATE(), 112))); -DECLARE @started_waiting_for_jobs DATETIME; --We need to wait for a while when disabling jobs - -/*Specifically for Backups*/ -DECLARE @job_name_backups NVARCHAR(MAX) = N'''sp_AllNightLog_Backup_Job_'''; --Name of log backup job -DECLARE @job_description_backups NVARCHAR(MAX) = N'''This is a worker for the purposes of taking log backups from msdbCentral.dbo.backup_worker queue table.'''; --Job description -DECLARE @job_command_backups NVARCHAR(MAX) = N'''EXEC sp_AllNightLog @Backup = 1'''; --Command the Agent job will run - -/*Specifically for Restores*/ -DECLARE @job_name_restores NVARCHAR(MAX) = N'''sp_AllNightLog_Restore_Job_'''; --Name of log backup job -DECLARE @job_description_restores NVARCHAR(MAX) = N'''This is a worker for the purposes of restoring log backups from msdb.dbo.restore_worker queue table.'''; --Job description -DECLARE @job_command_restores NVARCHAR(MAX) = N'''EXEC sp_AllNightLog @Restore = 1'''; --Command the Agent job will run - - -/* - -Sanity check some variables - -*/ - - - -IF ((@RunSetup = 0 OR @RunSetup IS NULL) AND (@UpdateSetup = 0 OR @UpdateSetup IS NULL)) - - BEGIN - - RAISERROR('You have to either run setup or update setup. You can''t not do neither nor, if you follow. Or not.', 0, 1) WITH NOWAIT; - - RETURN; - - END; - - -/* - -Should be a positive number - -*/ - -IF (@RPOSeconds < 0) - - BEGIN - RAISERROR('Please choose a positive number for @RPOSeconds', 0, 1) WITH NOWAIT; - - RETURN; - END; - - -/* - -Probably shouldn't be more than 20 - -*/ - -IF (@Jobs > 20) OR (@Jobs < 1) - - BEGIN - RAISERROR('We advise sticking with 1-20 jobs.', 0, 1) WITH NOWAIT; - - RETURN; - END; - -/* - -Probably shouldn't be more than 4 hours - -*/ - -IF (@RPOSeconds >= 14400) - BEGIN - - RAISERROR('If your RPO is really 4 hours, perhaps you''d be interested in a more modest recovery model, like SIMPLE?', 0, 1) WITH NOWAIT; - - RETURN; - END; - /* -Can't enable both the backup and restore jobs at the same time +Make sure we're doing something */ -IF @EnableBackupJobs = 1 AND @EnableRestoreJobs = 1 - BEGIN - - RAISERROR('You are not allowed to enable both the backup and restore jobs at the same time. Pick one, bucko.', 0, 1) WITH NOWAIT; - +IF ( + @PollForNewDatabases = 0 + AND @PollDiskForNewDatabases = 0 + AND @Backup = 0 + AND @Restore = 0 + AND @Help = 0 +) + BEGIN + RAISERROR('You don''t seem to have picked an action for this stored procedure to take.', 0, 1) WITH NOWAIT + RETURN; - END; + END /* Make sure xp_cmdshell is enabled @@ -1811,1055 +1536,1330 @@ IF NOT EXISTS (SELECT * FROM sys.procedures WHERE name = 'sp_DatabaseRestore') RETURN; END -/* -Basic path sanity checks +IF (@PollDiskForNewDatabases = 1 OR @Restore = 1) AND OBJECT_ID('msdb.dbo.restore_configuration') IS NOT NULL + BEGIN -*/ + IF @Debug = 1 RAISERROR('Checking restore path', 0, 1) WITH NOWAIT; -IF @RunSetup = 1 and @BackupPath is NULL - BEGIN - - RAISERROR('@BackupPath is required during setup', 0, 1) WITH NOWAIT; - - RETURN; - END + SELECT @restore_path_base = CONVERT(NVARCHAR(512), configuration_setting) + FROM msdb.dbo.restore_configuration c + WHERE configuration_name = N'log restore path'; -IF (@BackupPath NOT LIKE '[c-zC-Z]:\%') --Local path, don't think anyone has A or B drives -AND (@BackupPath NOT LIKE '\\[a-zA-Z0-9]%\%') --UNC path - - BEGIN - RAISERROR('Are you sure that''s a real path?', 0, 1) WITH NOWAIT; - + + IF @restore_path_base IS NULL + BEGIN + RAISERROR('@restore_path cannot be NULL. Please check the msdb.dbo.restore_configuration table', 0, 1) WITH NOWAIT; RETURN; - END; + END; -/* + IF CHARINDEX('**', @restore_path_base) <> 0 + BEGIN -If you want to update the table, one of these has to not be NULL + /* If they passed in a dynamic **DATABASENAME**, stop at that folder looking for databases. More info: https://github.com/BrentOzarULTD/SQL-Server-First-Responder-Kit/issues/993 */ + IF CHARINDEX('**DATABASENAME**', @restore_path_base) <> 0 + BEGIN + SET @restore_path_base = SUBSTRING(@restore_path_base, 1, CHARINDEX('**DATABASENAME**',@restore_path_base) - 2); + END; -*/ + SET @restore_path_base = REPLACE(@restore_path_base, '**AVAILABILITYGROUP**', ''); + SET @restore_path_base = REPLACE(@restore_path_base, '**BACKUPTYPE**', 'FULL'); + SET @restore_path_base = REPLACE(@restore_path_base, '**SERVERNAME**', REPLACE(CAST(SERVERPROPERTY('servername') AS nvarchar(max)),'\','$')); -IF @UpdateSetup = 1 - AND ( @RPOSeconds IS NULL - AND @BackupPath IS NULL - AND @RPOSeconds IS NULL - AND @RestorePath IS NULL - AND @EnableBackupJobs IS NULL - AND @EnableRestoreJobs IS NULL - ) + IF CHARINDEX('\',CAST(SERVERPROPERTY('servername') AS nvarchar(max))) > 0 + BEGIN + SET @restore_path_base = REPLACE(@restore_path_base, '**SERVERNAMEWITHOUTINSTANCE**', SUBSTRING(CAST(SERVERPROPERTY('servername') AS nvarchar(max)), 1, (CHARINDEX('\',CAST(SERVERPROPERTY('servername') AS nvarchar(max))) - 1))); + SET @restore_path_base = REPLACE(@restore_path_base, '**INSTANCENAME**', SUBSTRING(CAST(SERVERPROPERTY('servername') AS nvarchar(max)), CHARINDEX('\',CAST(SERVERPROPERTY('servername') AS nvarchar(max))), (LEN(CAST(SERVERPROPERTY('servername') AS nvarchar(max))) - CHARINDEX('\',CAST(SERVERPROPERTY('servername') AS nvarchar(max)))) + 1)); + END + ELSE /* No instance installed */ + BEGIN + SET @restore_path_base = REPLACE(@restore_path_base, '**SERVERNAMEWITHOUTINSTANCE**', CAST(SERVERPROPERTY('servername') AS nvarchar(max))); + SET @restore_path_base = REPLACE(@restore_path_base, '**INSTANCENAME**', 'DEFAULT'); + END + + IF CHARINDEX('**CLUSTER**', @restore_path_base) <> 0 + BEGIN + DECLARE @ClusterName NVARCHAR(128); + IF EXISTS(SELECT * FROM sys.all_objects WHERE name = 'dm_hadr_cluster') + BEGIN + SELECT @ClusterName = cluster_name FROM sys.dm_hadr_cluster; + END + SET @restore_path_base = REPLACE(@restore_path_base, '**CLUSTER**', COALESCE(@ClusterName,'')); + END; + END /* IF CHARINDEX('**', @restore_path_base) <> 0 */ + + SELECT @restore_move_files = CONVERT(BIT, configuration_setting) + FROM msdb.dbo.restore_configuration c + WHERE configuration_name = N'move files'; + + IF @restore_move_files is NULL BEGIN + -- Set to default value of 1 + SET @restore_move_files = 1 + END - RAISERROR('If you want to update configuration settings, they can''t be NULL. Please Make sure @RPOSeconds / @RTOSeconds or @BackupPath / @RestorePath has a value', 0, 1) WITH NOWAIT; + END /* IF @PollDiskForNewDatabases = 1 OR @Restore = 1 */ - RETURN; - END; +/* +Certain variables necessarily skip to parts of this script that are irrelevant +in both directions to each other. They are used for other stuff. -IF @UpdateSetup = 1 - GOTO UpdateConfigs; +*/ -IF @RunSetup = 1 -BEGIN - BEGIN TRY - BEGIN - +/* - /* - - First check to see if Agent is running -- we'll get errors if it's not - - */ - - - IF ( SELECT 1 - FROM sys.all_objects - WHERE name = 'dm_server_services' ) IS NOT NULL +Pollster use happens strictly to check for new databases in sys.databases to place them in a worker queue - BEGIN +*/ - IF EXISTS ( - SELECT 1 - FROM sys.dm_server_services - WHERE servicename LIKE 'SQL Server Agent%' - AND status_desc = 'Stopped' - ) - - BEGIN - - RAISERROR('SQL Server Agent is not currently running -- it needs to be enabled to add backup worker jobs and the new database polling job', 0, 1) WITH NOWAIT; - - RETURN; - - END; - - END - +IF @PollForNewDatabases = 1 + GOTO Pollster; - BEGIN +/* +LogShamer happens when we need to find and assign work to a worker job for backups - /* - - Check to see if the database exists +*/ - */ - - RAISERROR('Checking for msdbCentral', 0, 1) WITH NOWAIT; +IF @Backup = 1 + GOTO LogShamer; - SET @db_sql += N' +/* - IF DATABASEPROPERTYEX(' + QUOTENAME(@database_name, '''') + ', ''Status'') IS NULL +Pollster use happens strictly to check for new databases in sys.databases to place them in a worker queue - BEGIN +*/ - RAISERROR(''Creating msdbCentral'', 0, 1) WITH NOWAIT; +IF @PollDiskForNewDatabases = 1 + GOTO DiskPollster; - CREATE DATABASE ' + QUOTENAME(@database_name) + '; - - ALTER DATABASE ' + QUOTENAME(@database_name) + ' SET RECOVERY FULL; - - END - '; +/* +Restoregasm Addict happens when we need to find and assign work to a worker job for restores - IF @Debug = 1 - BEGIN - RAISERROR(@db_sql, 0, 1) WITH NOWAIT; - END; +*/ +IF @Restore = 1 + GOTO Restoregasm_Addict; - IF @db_sql IS NULL - BEGIN - RAISERROR('@db_sql is NULL for some reason', 0, 1) WITH NOWAIT; - END; - EXEC sp_executesql @db_sql; +/* +Begin Polling section - /* - - Check for tables and stuff +*/ - */ - - RAISERROR('Checking for tables in msdbCentral', 0, 1) WITH NOWAIT; - SET @tbl_sql += N' - - USE ' + QUOTENAME(@database_name) + ' - - - IF OBJECT_ID(''' + QUOTENAME(@database_name) + '.dbo.backup_configuration'') IS NULL - - BEGIN - - RAISERROR(''Creating table dbo.backup_configuration'', 0, 1) WITH NOWAIT; - - CREATE TABLE dbo.backup_configuration ( - database_name NVARCHAR(256), - configuration_name NVARCHAR(512), - configuration_description NVARCHAR(512), - configuration_setting NVARCHAR(MAX) - ); - - END - - ELSE - - BEGIN - - - RAISERROR(''Backup configuration table exists, truncating'', 0, 1) WITH NOWAIT; - - - TRUNCATE TABLE dbo.backup_configuration +/* - - END +This section runs in a loop checking for new databases added to the server, or broken backups +*/ - RAISERROR(''Inserting configuration values'', 0, 1) WITH NOWAIT; - - INSERT dbo.backup_configuration (database_name, configuration_name, configuration_description, configuration_setting) - VALUES (''all'', ''log backup frequency'', ''The length of time in second between Log Backups.'', ''' + CONVERT(NVARCHAR(10), @RPOSeconds) + '''); - - INSERT dbo.backup_configuration (database_name, configuration_name, configuration_description, configuration_setting) - VALUES (''all'', ''log backup path'', ''The path to which Log Backups should go.'', ''' + @BackupPath + '''); - - INSERT dbo.backup_configuration (database_name, configuration_name, configuration_description, configuration_setting) - VALUES (''all'', ''change backup type'', ''For Ola Hallengren DatabaseBackup @ChangeBackupType param: Y = escalate to fulls, MSDB = escalate by checking msdb backup history.'', ''MSDB''); - - INSERT dbo.backup_configuration (database_name, configuration_name, configuration_description, configuration_setting) - VALUES (''all'', ''encrypt'', ''For Ola Hallengren DatabaseBackup: Y = encrypt the backup. N (default) = do not encrypt.'', NULL); - - INSERT dbo.backup_configuration (database_name, configuration_name, configuration_description, configuration_setting) - VALUES (''all'', ''encryptionalgorithm'', ''For Ola Hallengren DatabaseBackup: native 2014 choices include TRIPLE_DES_3KEY, AES_128, AES_192, AES_256.'', NULL); - - INSERT dbo.backup_configuration (database_name, configuration_name, configuration_description, configuration_setting) - VALUES (''all'', ''servercertificate'', ''For Ola Hallengren DatabaseBackup: server certificate that is used to encrypt the backup.'', NULL); - - - IF OBJECT_ID(''' + QUOTENAME(@database_name) + '.dbo.backup_worker'') IS NULL - - BEGIN - - - RAISERROR(''Creating table dbo.backup_worker'', 0, 1) WITH NOWAIT; - - CREATE TABLE dbo.backup_worker ( - id INT IDENTITY(1, 1) PRIMARY KEY CLUSTERED, - database_name NVARCHAR(256), - last_log_backup_start_time DATETIME DEFAULT ''19000101'', - last_log_backup_finish_time DATETIME DEFAULT ''99991231'', - is_started BIT DEFAULT 0, - is_completed BIT DEFAULT 0, - error_number INT DEFAULT NULL, - last_error_date DATETIME DEFAULT NULL, - ignore_database BIT DEFAULT 0, - full_backup_required BIT DEFAULT ' + CASE WHEN @FirstFullBackup = 0 THEN N'0,' ELSE N'1,' END + CHAR(10) + - N'diff_backup_required BIT DEFAULT ' + CASE WHEN @FirstDiffBackup = 0 THEN N'0' ELSE N'1' END + CHAR(10) + - N'); - - END; - - ELSE +Pollster: - BEGIN + IF @Debug = 1 RAISERROR('Beginning Pollster', 0, 1) WITH NOWAIT; + + IF OBJECT_ID('msdbCentral.dbo.backup_worker') IS NOT NULL + + BEGIN + + WHILE @PollForNewDatabases = 1 + + BEGIN + + BEGIN TRY + + IF @Debug = 1 RAISERROR('Checking for new databases...', 0, 1) WITH NOWAIT; + /* + + Look for new non-system databases -- there should probably be additional filters here for accessibility, etc. - RAISERROR(''Backup worker table exists, truncating'', 0, 1) WITH NOWAIT; - - - TRUNCATE TABLE dbo.backup_worker + */ + + INSERT msdbCentral.dbo.backup_worker (database_name) + SELECT d.name + FROM sys.databases d + WHERE NOT EXISTS ( + SELECT 1 + FROM msdbCentral.dbo.backup_worker bw + WHERE bw.database_name = d.name + ) + AND d.database_id > 4; + IF @Debug = 1 RAISERROR('Checking for wayward databases', 0, 1) WITH NOWAIT; - END + /* + + This section aims to find databases that have + * Had a log backup ever (the default for finish time is 9999-12-31, so anything with a more recent finish time has had a log backup) + * Not had a log backup start in the last 5 minutes (this could be trouble! or a really big log backup) + * Also checks msdb.dbo.backupset to make sure the database has a full backup associated with it (otherwise it's the first full, and we don't need to start taking log backups yet) - - RAISERROR(''Inserting databases for backups'', 0, 1) WITH NOWAIT; - - INSERT ' + QUOTENAME(@database_name) + '.dbo.backup_worker (database_name) - SELECT d.name - FROM sys.databases d - WHERE NOT EXISTS ( - SELECT * - FROM msdbCentral.dbo.backup_worker bw - WHERE bw.database_name = d.name - ) - AND d.database_id > 4; + */ + + IF EXISTS ( + + SELECT 1 + FROM msdbCentral.dbo.backup_worker bw WITH (READPAST) + WHERE bw.last_log_backup_finish_time < '99991231' + AND bw.last_log_backup_start_time < DATEADD(SECOND, (@rpo * -1), GETDATE()) + AND EXISTS ( + SELECT 1 + FROM msdb.dbo.backupset b + WHERE b.database_name = bw.database_name + AND b.type = 'D' + ) + ) + + BEGIN - '; + IF @Debug = 1 RAISERROR('Resetting databases with a log backup and no log backup in the last 5 minutes', 0, 1) WITH NOWAIT; - - IF @Debug = 1 - BEGIN - SET @msg = SUBSTRING(@tbl_sql, 0, 2044) - RAISERROR(@msg, 0, 1) WITH NOWAIT; - SET @msg = SUBSTRING(@tbl_sql, 2044, 4088) - RAISERROR(@msg, 0, 1) WITH NOWAIT; - SET @msg = SUBSTRING(@tbl_sql, 4088, 6132) - RAISERROR(@msg, 0, 1) WITH NOWAIT; - SET @msg = SUBSTRING(@tbl_sql, 6132, 8176) - RAISERROR(@msg, 0, 1) WITH NOWAIT; - END; + + UPDATE bw + SET bw.is_started = 0, + bw.is_completed = 1, + bw.last_log_backup_start_time = '19000101' + FROM msdbCentral.dbo.backup_worker bw + WHERE bw.last_log_backup_finish_time < '99991231' + AND bw.last_log_backup_start_time < DATEADD(SECOND, (@rpo * -1), GETDATE()) + AND EXISTS ( + SELECT 1 + FROM msdb.dbo.backupset b + WHERE b.database_name = bw.database_name + AND b.type = 'D' + ); - - IF @tbl_sql IS NULL - BEGIN - RAISERROR('@tbl_sql is NULL for some reason', 0, 1) WITH NOWAIT; - END; + + END; --End check for wayward databases + + /* + + Wait 1 minute between runs, we don't need to be checking this constantly + + */ + + IF @Debug = 1 RAISERROR('Waiting for 1 minute', 0, 1) WITH NOWAIT; + + WAITFOR DELAY '00:01:00.000'; - EXEC sp_executesql @tbl_sql; + END TRY + BEGIN CATCH + + + SELECT @msg = N'Error inserting databases to msdbCentral.dbo.backup_worker, error number is ' + CONVERT(NVARCHAR(10), ERROR_NUMBER()) + ', error message is ' + ERROR_MESSAGE(), + @error_severity = ERROR_SEVERITY(), + @error_state = ERROR_STATE(); + + RAISERROR(@msg, @error_severity, @error_state) WITH NOWAIT; + + + WHILE @@TRANCOUNT > 0 + ROLLBACK; + + + END CATCH; + + + END; + + /* Check to make sure job is still enabled */ + IF NOT EXISTS ( + SELECT * + FROM msdb.dbo.sysjobs + WHERE name = 'sp_AllNightLog_PollForNewDatabases' + AND enabled = 1 + ) + BEGIN + RAISERROR('sp_AllNightLog_PollForNewDatabases job is disabled, so gracefully exiting. It feels graceful to me, anyway.', 0, 1) WITH NOWAIT; + RETURN; + END + + END;-- End Pollster loop + + ELSE + + BEGIN + + RAISERROR('msdbCentral.dbo.backup_worker does not exist, please create it.', 0, 1) WITH NOWAIT; + RETURN; + + END; + RETURN; + + +/* + +End of Pollster + +*/ + + +/* + +Begin DiskPollster + +*/ + + +/* + +This section runs in a loop checking restore path for new databases added to the server, or broken restores + +*/ + +DiskPollster: + + IF @Debug = 1 RAISERROR('Beginning DiskPollster', 0, 1) WITH NOWAIT; + + IF OBJECT_ID('msdb.dbo.restore_configuration') IS NOT NULL + + BEGIN + + WHILE @PollDiskForNewDatabases = 1 + + BEGIN + + BEGIN TRY + + IF @Debug = 1 RAISERROR('Checking for new databases in: ', 0, 1) WITH NOWAIT; + IF @Debug = 1 RAISERROR(@restore_path_base, 0, 1) WITH NOWAIT; + + /* + + Look for new non-system databases -- there should probably be additional filters here for accessibility, etc. + + */ /* - This section creates tables for restore workers to work off of + This setups up the @cmd variable to check the restore path for new folders + In our case, a new folder means a new database, because we assume a pristine path + */ + SET @cmd = N'DIR /b "' + @restore_path_base + N'"'; - /* - - In search of msdb + IF @Debug = 1 + BEGIN + PRINT @cmd; + END - */ - RAISERROR('Checking for msdb. Yeah, I know...', 0, 1) WITH NOWAIT; + DELETE @FileList; + INSERT INTO @FileList (BackupFile) + EXEC master.sys.xp_cmdshell @cmd; - IF DATABASEPROPERTYEX('msdb', 'Status') IS NULL + IF ( + SELECT COUNT(*) + FROM @FileList AS fl + WHERE fl.BackupFile = 'The system cannot find the path specified.' + OR fl.BackupFile = 'File Not Found' + ) = 1 BEGIN - - RAISERROR('YOU HAVE NO MSDB WHY?!', 0, 1) WITH NOWAIT; - - RETURN; + + RAISERROR('No rows were returned for that database\path', 0, 1) WITH NOWAIT; END; + IF ( + SELECT COUNT(*) + FROM @FileList AS fl + WHERE fl.BackupFile = 'Access is denied.' + ) = 1 + + BEGIN - /* In search of restore_configuration */ + RAISERROR('Access is denied to %s', 16, 1, @restore_path_base) WITH NOWAIT; - RAISERROR('Checking for Restore Worker tables in msdb', 0, 1) WITH NOWAIT; + END; - IF OBJECT_ID('msdb.dbo.restore_configuration') IS NULL + IF ( + SELECT COUNT(*) + FROM @FileList AS fl + ) = 1 + AND ( + SELECT COUNT(*) + FROM @FileList AS fl + WHERE fl.BackupFile IS NULL + ) = 1 BEGIN + + RAISERROR('That directory appears to be empty', 0, 1) WITH NOWAIT; + + RETURN; + + END - RAISERROR('Creating restore_configuration table in msdb', 0, 1) WITH NOWAIT; + IF ( + SELECT COUNT(*) + FROM @FileList AS fl + WHERE fl.BackupFile = 'The user name or password is incorrect.' + ) = 1 - CREATE TABLE msdb.dbo.restore_configuration ( - database_name NVARCHAR(256), - configuration_name NVARCHAR(512), - configuration_description NVARCHAR(512), - configuration_setting NVARCHAR(MAX) - ); + BEGIN + + RAISERROR('Incorrect user name or password for %s', 16, 1, @restore_path_base) WITH NOWAIT; END; + INSERT msdb.dbo.restore_worker (database_name) + SELECT fl.BackupFile + FROM @FileList AS fl + WHERE fl.BackupFile IS NOT NULL + AND fl.BackupFile COLLATE DATABASE_DEFAULT NOT IN (SELECT name from sys.databases where database_id < 5) + AND NOT EXISTS + ( + SELECT 1 + FROM msdb.dbo.restore_worker rw + WHERE rw.database_name = fl.BackupFile + ) - ELSE + IF @Debug = 1 RAISERROR('Checking for wayward databases', 0, 1) WITH NOWAIT; + /* + + This section aims to find databases that have + * Had a log restore ever (the default for finish time is 9999-12-31, so anything with a more recent finish time has had a log restore) + * Not had a log restore start in the last 5 minutes (this could be trouble! or a really big log restore) + * Also checks msdb.dbo.backupset to make sure the database has a full backup associated with it (otherwise it's the first full, and we don't need to start adding log restores yet) + */ + + IF EXISTS ( + + SELECT 1 + FROM msdb.dbo.restore_worker rw WITH (READPAST) + WHERE rw.last_log_restore_finish_time < '99991231' + AND rw.last_log_restore_start_time < DATEADD(SECOND, (@rto * -1), GETDATE()) + AND EXISTS ( + SELECT 1 + FROM msdb.dbo.restorehistory r + WHERE r.destination_database_name = rw.database_name + AND r.restore_type = 'D' + ) + ) + BEGIN + + IF @Debug = 1 RAISERROR('Resetting databases with a log restore and no log restore in the last 5 minutes', 0, 1) WITH NOWAIT; - RAISERROR('Restore configuration table exists, truncating', 0, 1) WITH NOWAIT; + + UPDATE rw + SET rw.is_started = 0, + rw.is_completed = 1, + rw.last_log_restore_start_time = '19000101' + FROM msdb.dbo.restore_worker rw + WHERE rw.last_log_restore_finish_time < '99991231' + AND rw.last_log_restore_start_time < DATEADD(SECOND, (@rto * -1), GETDATE()) + AND EXISTS ( + SELECT 1 + FROM msdb.dbo.restorehistory r + WHERE r.destination_database_name = rw.database_name + AND r.restore_type = 'D' + ); - TRUNCATE TABLE msdb.dbo.restore_configuration; + + END; --End check for wayward databases + + /* - END; + Wait 1 minute between runs, we don't need to be checking this constantly + + */ + /* Check to make sure job is still enabled */ + IF NOT EXISTS ( + SELECT * + FROM msdb.dbo.sysjobs + WHERE name = 'sp_AllNightLog_PollDiskForNewDatabases' + AND enabled = 1 + ) + BEGIN + RAISERROR('sp_AllNightLog_PollDiskForNewDatabases job is disabled, so gracefully exiting. It feels graceful to me, anyway.', 0, 1) WITH NOWAIT; + RETURN; + END + + IF @Debug = 1 RAISERROR('Waiting for 1 minute', 0, 1) WITH NOWAIT; + + WAITFOR DELAY '00:01:00.000'; - RAISERROR('Inserting configuration values to msdb.dbo.restore_configuration', 0, 1) WITH NOWAIT; - - INSERT msdb.dbo.restore_configuration (database_name, configuration_name, configuration_description, configuration_setting) - VALUES ('all', 'log restore frequency', 'The length of time in second between Log Restores.', @RTOSeconds); - - INSERT msdb.dbo.restore_configuration (database_name, configuration_name, configuration_description, configuration_setting) - VALUES ('all', 'log restore path', 'The path to which Log Restores come from.', @RestorePath); + END TRY - INSERT msdb.dbo.restore_configuration (database_name, configuration_name, configuration_description, configuration_setting) - VALUES ('all', 'move files', 'Determines if we move database files to default data/log directories.', @MoveFiles); + BEGIN CATCH - IF OBJECT_ID('msdb.dbo.restore_worker') IS NULL - - BEGIN - - - RAISERROR('Creating table msdb.dbo.restore_worker', 0, 1) WITH NOWAIT; - - CREATE TABLE msdb.dbo.restore_worker ( - id INT IDENTITY(1, 1) PRIMARY KEY CLUSTERED, - database_name NVARCHAR(256), - last_log_restore_start_time DATETIME DEFAULT '19000101', - last_log_restore_finish_time DATETIME DEFAULT '99991231', - is_started BIT DEFAULT 0, - is_completed BIT DEFAULT 0, - error_number INT DEFAULT NULL, - last_error_date DATETIME DEFAULT NULL, - ignore_database BIT DEFAULT 0, - full_backup_required BIT DEFAULT 0, - diff_backup_required BIT DEFAULT 0 - ); - - RAISERROR('Inserting databases for restores', 0, 1) WITH NOWAIT; + SELECT @msg = N'Error inserting databases to msdb.dbo.restore_worker, error number is ' + CONVERT(NVARCHAR(10), ERROR_NUMBER()) + ', error message is ' + ERROR_MESSAGE(), + @error_severity = ERROR_SEVERITY(), + @error_state = ERROR_STATE(); - INSERT msdb.dbo.restore_worker (database_name) - SELECT d.name - FROM sys.databases d - WHERE NOT EXISTS ( - SELECT * - FROM msdb.dbo.restore_worker bw - WHERE bw.database_name = d.name - ) - AND d.database_id > 4; - - - END; + RAISERROR(@msg, @error_severity, @error_state) WITH NOWAIT; + + WHILE @@TRANCOUNT > 0 + ROLLBACK; - - /* - - Add Jobs - - */ - + END CATCH; + + + END; - /* - - Look for our ten second schedule -- all jobs use this to restart themselves if they fail + END;-- End Pollster loop + + ELSE + + BEGIN + + RAISERROR('msdb.dbo.restore_worker does not exist, please create it.', 0, 1) WITH NOWAIT; + RETURN; + + END; + RETURN; - Fun fact: you can add the same schedule name multiple times, so we don't want to just stick it in there - - */ - RAISERROR('Checking for ten second schedule', 0, 1) WITH NOWAIT; +/* - IF NOT EXISTS ( - SELECT 1 - FROM msdb.dbo.sysschedules - WHERE name = 'ten_seconds' - ) - - BEGIN - - - RAISERROR('Creating ten second schedule', 0, 1) WITH NOWAIT; +Begin LogShamer - - EXEC msdb.dbo.sp_add_schedule @schedule_name= ten_seconds, - @enabled = 1, - @freq_type = 4, - @freq_interval = 1, - @freq_subday_type = 2, - @freq_subday_interval = 10, - @freq_relative_interval = 0, - @freq_recurrence_factor = 0, - @active_start_date = @active_start_date, - @active_end_date = 99991231, - @active_start_time = 0, - @active_end_time = 235959; - - END; +*/ + +LogShamer: + + IF @Debug = 1 RAISERROR('Beginning Backups', 0, 1) WITH NOWAIT; + + IF OBJECT_ID('msdbCentral.dbo.backup_worker') IS NOT NULL + + BEGIN - /* - Look for Backup Pollster job -- this job sets up our watcher for new databases to back up + Make sure configuration table exists... */ - + + IF OBJECT_ID('msdbCentral.dbo.backup_configuration') IS NOT NULL + + BEGIN + + IF @Debug = 1 RAISERROR('Checking variables', 0, 1) WITH NOWAIT; + + /* - RAISERROR('Checking for pollster job', 0, 1) WITH NOWAIT; - + These settings are configurable + + I haven't found a good way to find the default backup path that doesn't involve xp_regread - IF NOT EXISTS ( - SELECT 1 - FROM msdb.dbo.sysjobs - WHERE name = 'sp_AllNightLog_PollForNewDatabases' - ) - - - BEGIN - - - RAISERROR('Creating pollster job', 0, 1) WITH NOWAIT; - - IF @EnableBackupJobs = 1 - BEGIN - EXEC msdb.dbo.sp_add_job @job_name = sp_AllNightLog_PollForNewDatabases, - @description = 'This is a worker for the purposes of polling sys.databases for new entries to insert to the worker queue table.', - @category_name = 'Database Maintenance', - @owner_login_name = 'sa', - @enabled = 1; - END - ELSE - BEGIN - EXEC msdb.dbo.sp_add_job @job_name = sp_AllNightLog_PollForNewDatabases, - @description = 'This is a worker for the purposes of polling sys.databases for new entries to insert to the worker queue table.', - @category_name = 'Database Maintenance', - @owner_login_name = 'sa', - @enabled = 0; - END - - - RAISERROR('Adding job step', 0, 1) WITH NOWAIT; + */ + + SELECT @rpo = CONVERT(INT, configuration_setting) + FROM msdbCentral.dbo.backup_configuration c + WHERE configuration_name = N'log backup frequency' + AND database_name = N'all'; + + + IF @rpo IS NULL + BEGIN + RAISERROR('@rpo cannot be NULL. Please check the msdbCentral.dbo.backup_configuration table', 0, 1) WITH NOWAIT; + RETURN; + END; + + + SELECT @backup_path = CONVERT(NVARCHAR(512), configuration_setting) + FROM msdbCentral.dbo.backup_configuration c + WHERE configuration_name = N'log backup path' + AND database_name = N'all'; + + + IF @backup_path IS NULL + BEGIN + RAISERROR('@backup_path cannot be NULL. Please check the msdbCentral.dbo.backup_configuration table', 0, 1) WITH NOWAIT; + RETURN; + END; - - EXEC msdb.dbo.sp_add_jobstep @job_name = sp_AllNightLog_PollForNewDatabases, - @step_name = sp_AllNightLog_PollForNewDatabases, - @subsystem = 'TSQL', - @command = 'EXEC sp_AllNightLog @PollForNewDatabases = 1'; - - - - RAISERROR('Adding job server', 0, 1) WITH NOWAIT; + SELECT @changebackuptype = configuration_setting + FROM msdbCentral.dbo.backup_configuration c + WHERE configuration_name = N'change backup type' + AND database_name = N'all'; - - EXEC msdb.dbo.sp_add_jobserver @job_name = sp_AllNightLog_PollForNewDatabases; + SELECT @encrypt = configuration_setting + FROM msdbCentral.dbo.backup_configuration c + WHERE configuration_name = N'encrypt' + AND database_name = N'all'; - - - RAISERROR('Attaching schedule', 0, 1) WITH NOWAIT; - - - EXEC msdb.dbo.sp_attach_schedule @job_name = sp_AllNightLog_PollForNewDatabases, - @schedule_name = ten_seconds; - - - END; - + SELECT @encryptionalgorithm = configuration_setting + FROM msdbCentral.dbo.backup_configuration c + WHERE configuration_name = N'encryptionalgorithm' + AND database_name = N'all'; + SELECT @servercertificate = configuration_setting + FROM msdbCentral.dbo.backup_configuration c + WHERE configuration_name = N'servercertificate' + AND database_name = N'all'; + + IF @encrypt = N'Y' AND (@encryptionalgorithm IS NULL OR @servercertificate IS NULL) + BEGIN + RAISERROR('If encryption is Y, then both the encryptionalgorithm and servercertificate must be set. Please check the msdbCentral.dbo.backup_configuration table', 0, 1) WITH NOWAIT; + RETURN; + END; + + END; + + ELSE + + BEGIN + + RAISERROR('msdbCentral.dbo.backup_configuration does not exist, please run setup script', 0, 1) WITH NOWAIT; + RETURN; + + END; + + + WHILE @Backup = 1 /* - Look for Restore Pollster job -- this job sets up our watcher for new databases to back up - - */ + Start loop to take log backups - - RAISERROR('Checking for restore pollster job', 0, 1) WITH NOWAIT; + */ - IF NOT EXISTS ( - SELECT 1 - FROM msdb.dbo.sysjobs - WHERE name = 'sp_AllNightLog_PollDiskForNewDatabases' - ) - - BEGIN - - - RAISERROR('Creating restore pollster job', 0, 1) WITH NOWAIT; + + BEGIN TRY + + BEGIN TRAN; + + IF @Debug = 1 RAISERROR('Begin tran to grab a database to back up', 0, 1) WITH NOWAIT; - - IF @EnableRestoreJobs = 1 - BEGIN - EXEC msdb.dbo.sp_add_job @job_name = sp_AllNightLog_PollDiskForNewDatabases, - @description = 'This is a worker for the purposes of polling your restore path for new entries to insert to the worker queue table.', - @category_name = 'Database Maintenance', - @owner_login_name = 'sa', - @enabled = 1; - END - ELSE - BEGIN - EXEC msdb.dbo.sp_add_job @job_name = sp_AllNightLog_PollDiskForNewDatabases, - @description = 'This is a worker for the purposes of polling your restore path for new entries to insert to the worker queue table.', - @category_name = 'Database Maintenance', - @owner_login_name = 'sa', - @enabled = 0; - END - - - - RAISERROR('Adding restore job step', 0, 1) WITH NOWAIT; - - EXEC msdb.dbo.sp_add_jobstep @job_name = sp_AllNightLog_PollDiskForNewDatabases, - @step_name = sp_AllNightLog_PollDiskForNewDatabases, - @subsystem = 'TSQL', - @command = 'EXEC sp_AllNightLog @PollDiskForNewDatabases = 1'; - - - - RAISERROR('Adding restore job server', 0, 1) WITH NOWAIT; + /* + + This grabs a database for a worker to work on - - EXEC msdb.dbo.sp_add_jobserver @job_name = sp_AllNightLog_PollDiskForNewDatabases; + The locking hints hope to provide some isolation when 10+ workers are in action + + */ + + + SELECT TOP (1) + @database = bw.database_name + FROM msdbCentral.dbo.backup_worker bw WITH (UPDLOCK, HOLDLOCK, ROWLOCK) + WHERE + ( /*This section works on databases already part of the backup cycle*/ + bw.is_started = 0 + AND bw.is_completed = 1 + AND bw.last_log_backup_start_time < DATEADD(SECOND, (@rpo * -1), GETDATE()) + AND (bw.error_number IS NULL OR bw.error_number > 0) /* negative numbers indicate human attention required */ + AND bw.ignore_database = 0 + ) + OR + ( /*This section picks up newly added databases by Pollster*/ + bw.is_started = 0 + AND bw.is_completed = 0 + AND bw.last_log_backup_start_time = '1900-01-01 00:00:00.000' + AND bw.last_log_backup_finish_time = '9999-12-31 00:00:00.000' + AND (bw.error_number IS NULL OR bw.error_number > 0) /* negative numbers indicate human attention required */ + AND bw.ignore_database = 0 + ) + ORDER BY bw.last_log_backup_start_time ASC, bw.last_log_backup_finish_time ASC, bw.database_name ASC; + + + IF @database IS NOT NULL + BEGIN + SET @msg = N'Updating backup_worker for database ' + ISNULL(@database, 'UH OH NULL @database'); + IF @Debug = 1 RAISERROR(@msg, 0, 1) WITH NOWAIT; + + /* + + Update the worker table so other workers know a database is being backed up + + */ - - - RAISERROR('Attaching schedule', 0, 1) WITH NOWAIT; - + + UPDATE bw + SET bw.is_started = 1, + bw.is_completed = 0, + bw.last_log_backup_start_time = GETDATE() + FROM msdbCentral.dbo.backup_worker bw + WHERE bw.database_name = @database; + END + + COMMIT; + + END TRY + + BEGIN CATCH - EXEC msdb.dbo.sp_attach_schedule @job_name = sp_AllNightLog_PollDiskForNewDatabases, - @schedule_name = ten_seconds; - - - END; - - + /* + + Do I need to build retry logic in here? Try to catch deadlocks? I don't know yet! + + */ - /* - - This section creates @Jobs (quantity) of worker jobs to take log backups with + SELECT @msg = N'Error securing a database to backup, error number is ' + CONVERT(NVARCHAR(10), ERROR_NUMBER()) + ', error message is ' + ERROR_MESSAGE(), + @error_severity = ERROR_SEVERITY(), + @error_state = ERROR_STATE(); + RAISERROR(@msg, @error_severity, @error_state) WITH NOWAIT; - They work in a queue + SET @database = NULL; + + WHILE @@TRANCOUNT > 0 + ROLLBACK; + + END CATCH; - It's queuete - - */ + /* If we don't find a database to work on, wait for a few seconds */ + IF @database IS NULL - RAISERROR('Checking for sp_AllNightLog backup jobs', 0, 1) WITH NOWAIT; - - - SELECT @counter = COUNT(*) + 1 - FROM msdb.dbo.sysjobs - WHERE name LIKE 'sp[_]AllNightLog[_]Backup[_]%'; + BEGIN + IF @Debug = 1 RAISERROR('No databases to back up right now, starting 3 second throttle', 0, 1) WITH NOWAIT; + WAITFOR DELAY '00:00:03.000'; - SET @msg = 'Found ' + CONVERT(NVARCHAR(10), (@counter - 1)) + ' backup jobs -- ' + CASE WHEN @counter < @Jobs THEN + 'starting loop!' - WHEN @counter >= @Jobs THEN 'skipping loop!' - ELSE 'Oh woah something weird happened!' - END; + /* Check to make sure job is still enabled */ + IF NOT EXISTS ( + SELECT * + FROM msdb.dbo.sysjobs + WHERE name LIKE 'sp_AllNightLog_Backup%' + AND enabled = 1 + ) + BEGIN + RAISERROR('sp_AllNightLog_Backup jobs are disabled, so gracefully exiting. It feels graceful to me, anyway.', 0, 1) WITH NOWAIT; + RETURN; + END - RAISERROR(@msg, 0, 1) WITH NOWAIT; - - WHILE @counter <= @Jobs + END + + + BEGIN TRY + + BEGIN + + IF @database IS NOT NULL + /* - BEGIN + Make sure we have a database to work on -- I should make this more robust so we do something if it is NULL, maybe + + */ - - RAISERROR('Setting job name', 0, 1) WITH NOWAIT; + + BEGIN + + SET @msg = N'Taking backup of ' + ISNULL(@database, 'UH OH NULL @database'); + IF @Debug = 1 RAISERROR(@msg, 0, 1) WITH NOWAIT; - SET @job_name_backups = N'sp_AllNightLog_Backup_' + CASE WHEN @counter < 10 THEN N'0' + CONVERT(NVARCHAR(10), @counter) - WHEN @counter >= 10 THEN CONVERT(NVARCHAR(10), @counter) - END; - + /* - RAISERROR('Setting @job_sql', 0, 1) WITH NOWAIT; + Call Ola's proc to backup the database + + */ + + IF @encrypt = 'Y' + EXEC dbo.DatabaseBackup @Databases = @database, --Database we're working on + @BackupType = 'LOG', --Going for the LOGs + @Directory = @backup_path, --The path we need to back up to + @Verify = 'N', --We don't want to verify these, it eats into job time + @ChangeBackupType = @changebackuptype, --If we need to switch to a FULL because one hasn't been taken + @CheckSum = 'Y', --These are a good idea + @Compress = 'Y', --This is usually a good idea + @LogToTable = 'Y', --We should do this for posterity + @Encrypt = @encrypt, + @EncryptionAlgorithm = @encryptionalgorithm, + @ServerCertificate = @servercertificate; + ELSE + EXEC dbo.DatabaseBackup @Databases = @database, --Database we're working on + @BackupType = 'LOG', --Going for the LOGs + @Directory = @backup_path, --The path we need to back up to + @Verify = 'N', --We don't want to verify these, it eats into job time + @ChangeBackupType = @changebackuptype, --If we need to switch to a FULL because one hasn't been taken + @CheckSum = 'Y', --These are a good idea + @Compress = 'Y', --This is usually a good idea + @LogToTable = 'Y'; --We should do this for posterity + - SET @job_sql = N' - - EXEC msdb.dbo.sp_add_job @job_name = ' + @job_name_backups + ', - @description = ' + @job_description_backups + ', - @category_name = ' + @job_category + ', - @owner_login_name = ' + @job_owner + ','; - IF @EnableBackupJobs = 1 - BEGIN - SET @job_sql = @job_sql + ' @enabled = 1; '; - END - ELSE - BEGIN - SET @job_sql = @job_sql + ' @enabled = 0; '; - END - - - SET @job_sql = @job_sql + ' - EXEC msdb.dbo.sp_add_jobstep @job_name = ' + @job_name_backups + ', - @step_name = ' + @job_name_backups + ', - @subsystem = ''TSQL'', - @command = ' + @job_command_backups + '; - - - EXEC msdb.dbo.sp_add_jobserver @job_name = ' + @job_name_backups + '; - - - EXEC msdb.dbo.sp_attach_schedule @job_name = ' + @job_name_backups + ', - @schedule_name = ten_seconds; - - '; - + /* - SET @counter += 1; - + Catch any erroneous zones - IF @Debug = 1 - BEGIN - RAISERROR(@job_sql, 0, 1) WITH NOWAIT; - END; - - - IF @job_sql IS NULL - BEGIN - RAISERROR('@job_sql is NULL for some reason', 0, 1) WITH NOWAIT; - END; - - - EXEC sp_executesql @job_sql; - - - END; - - - - /* - - This section creates @Jobs (quantity) of worker jobs to restore logs with - - They too work in a queue - - Like a queue-t 3.14 - - */ - - - RAISERROR('Checking for sp_AllNightLog Restore jobs', 0, 1) WITH NOWAIT; - + */ + + SELECT @error_number = ERROR_NUMBER(), + @error_severity = ERROR_SEVERITY(), + @error_state = ERROR_STATE(); + + END; --End call to dbo.DatabaseBackup + + END; --End successful check of @database (not NULL) - SELECT @counter = COUNT(*) + 1 - FROM msdb.dbo.sysjobs - WHERE name LIKE 'sp[_]AllNightLog[_]Restore[_]%'; + END TRY + + BEGIN CATCH + + IF @error_number IS NOT NULL - SET @msg = 'Found ' + CONVERT(NVARCHAR(10), (@counter - 1)) + ' restore jobs -- ' + CASE WHEN @counter < @Jobs THEN + 'starting loop!' - WHEN @counter >= @Jobs THEN 'skipping loop!' - ELSE 'Oh woah something weird happened!' - END; + /* + + If the ERROR() function returns a number, update the table with it and the last error date. - RAISERROR(@msg, 0, 1) WITH NOWAIT; + Also update the last start time to 1900-01-01 so it gets picked back up immediately -- the query to find a log backup to take sorts by start time - - WHILE @counter <= @Jobs + */ + + BEGIN + + SET @msg = N'Error number is ' + CONVERT(NVARCHAR(10), ERROR_NUMBER()); + RAISERROR(@msg, @error_severity, @error_state) WITH NOWAIT; + + SET @msg = N'Updating backup_worker for database ' + ISNULL(@database, 'UH OH NULL @database') + ' for unsuccessful backup'; + RAISERROR(@msg, 0, 1) WITH NOWAIT; + + + UPDATE bw + SET bw.is_started = 0, + bw.is_completed = 1, + bw.last_log_backup_start_time = '19000101', + bw.error_number = @error_number, + bw.last_error_date = GETDATE() + FROM msdbCentral.dbo.backup_worker bw + WHERE bw.database_name = @database; - - BEGIN - - RAISERROR('Setting job name', 0, 1) WITH NOWAIT; + /* + + Set @database back to NULL to avoid variable assignment weirdness + + */ - SET @job_name_restores = N'sp_AllNightLog_Restore_' + CASE WHEN @counter < 10 THEN N'0' + CONVERT(NVARCHAR(10), @counter) - WHEN @counter >= 10 THEN CONVERT(NVARCHAR(10), @counter) - END; - - - RAISERROR('Setting @job_sql', 0, 1) WITH NOWAIT; + SET @database = NULL; - SET @job_sql = N' - - EXEC msdb.dbo.sp_add_job @job_name = ' + @job_name_restores + ', - @description = ' + @job_description_restores + ', - @category_name = ' + @job_category + ', - @owner_login_name = ' + @job_owner + ','; - IF @EnableRestoreJobs = 1 - BEGIN - SET @job_sql = @job_sql + ' @enabled = 1; '; - END - ELSE - BEGIN - SET @job_sql = @job_sql + ' @enabled = 0; '; - END - - - SET @job_sql = @job_sql + ' - - EXEC msdb.dbo.sp_add_jobstep @job_name = ' + @job_name_restores + ', - @step_name = ' + @job_name_restores + ', - @subsystem = ''TSQL'', - @command = ' + @job_command_restores + '; - - - EXEC msdb.dbo.sp_add_jobserver @job_name = ' + @job_name_restores + '; - - - EXEC msdb.dbo.sp_attach_schedule @job_name = ' + @job_name_restores + ', - @schedule_name = ten_seconds; - - '; - + /* - SET @counter += 1; + Wait around for a second so we're not just spinning wheels -- this only runs if the BEGIN CATCH is triggered by an error + */ - IF @Debug = 1 - BEGIN - RAISERROR(@job_sql, 0, 1) WITH NOWAIT; - END; - - - IF @job_sql IS NULL - BEGIN - RAISERROR('@job_sql is NULL for some reason', 0, 1) WITH NOWAIT; - END; + IF @Debug = 1 RAISERROR('Starting 1 second throttle', 0, 1) WITH NOWAIT; + + WAITFOR DELAY '00:00:01.000'; + END; -- End update of unsuccessful backup + + END CATCH; + + IF @database IS NOT NULL AND @error_number IS NULL - EXEC sp_executesql @job_sql; + /* + + If no error, update everything normally + + */ - END; + BEGIN + + IF @Debug = 1 RAISERROR('Error number IS NULL', 0, 1) WITH NOWAIT; + + SET @msg = N'Updating backup_worker for database ' + ISNULL(@database, 'UH OH NULL @database') + ' for successful backup'; + IF @Debug = 1 RAISERROR(@msg, 0, 1) WITH NOWAIT; + + + UPDATE bw + SET bw.is_started = 0, + bw.is_completed = 1, + bw.last_log_backup_finish_time = GETDATE() + FROM msdbCentral.dbo.backup_worker bw + WHERE bw.database_name = @database; + + /* + + Set @database back to NULL to avoid variable assignment weirdness + + */ - RAISERROR('Setup complete!', 0, 1) WITH NOWAIT; - - END; --End for the Agent job creation + SET @database = NULL; - END;--End for Database and Table creation - END TRY + END; -- End update for successful backup - BEGIN CATCH + + END; -- End @Backup WHILE loop + + END; -- End successful check for backup_worker and subsequent code - SELECT @msg = N'Error occurred during setup: ' + CONVERT(NVARCHAR(10), ERROR_NUMBER()) + ', error message is ' + ERROR_MESSAGE(), - @error_severity = ERROR_SEVERITY(), - @error_state = ERROR_STATE(); + + ELSE + + BEGIN + + RAISERROR('msdbCentral.dbo.backup_worker does not exist, please run setup script', 0, 1) WITH NOWAIT; + + RETURN; - RAISERROR(@msg, @error_severity, @error_state) WITH NOWAIT; - - - WHILE @@TRANCOUNT > 0 - ROLLBACK; - - END CATCH; - -END; /* IF @RunSetup = 1 */ - + END; RETURN; -UpdateConfigs: - -IF @UpdateSetup = 1 - - BEGIN - - /* If we're enabling backup jobs, we may need to run restore with recovery on msdbCentral to bring it online: */ - IF @EnableBackupJobs = 1 AND EXISTS (SELECT * FROM sys.databases WHERE name = 'msdbCentral' AND state = 1) - BEGIN - RAISERROR('msdbCentral exists, but is in restoring state. Running restore with recovery...', 0, 1) WITH NOWAIT; - - BEGIN TRY - RESTORE DATABASE [msdbCentral] WITH RECOVERY; - END TRY - - BEGIN CATCH +/* - SELECT @error_number = ERROR_NUMBER(), - @error_severity = ERROR_SEVERITY(), - @error_state = ERROR_STATE(); +Begin Restoregasm_Addict section - SELECT @msg = N'Error running restore with recovery on msdbCentral, error number is ' + CONVERT(NVARCHAR(10), ERROR_NUMBER()) + ', error message is ' + ERROR_MESSAGE(), - @error_severity = ERROR_SEVERITY(), - @error_state = ERROR_STATE(); - - RAISERROR(@msg, @error_severity, @error_state) WITH NOWAIT; +*/ - END CATCH; +Restoregasm_Addict: - END +IF @Restore = 1 + IF @Debug = 1 RAISERROR('Beginning Restores', 0, 1) WITH NOWAIT; + + /* Check to make sure backup jobs aren't enabled */ + IF EXISTS ( + SELECT * + FROM msdb.dbo.sysjobs + WHERE name LIKE 'sp_AllNightLog_Backup%' + AND enabled = 1 + ) + BEGIN + RAISERROR('sp_AllNightLog_Backup jobs are enabled, so gracefully exiting. You do not want to accidentally do restores over top of the databases you are backing up.', 0, 1) WITH NOWAIT; + RETURN; + END - /* Only check for this after trying to restore msdbCentral: */ - IF @EnableBackupJobs = 1 AND NOT EXISTS (SELECT * FROM sys.databases WHERE name = 'msdbCentral' AND state = 0) - BEGIN - RAISERROR('msdbCentral is not online. Repair that first, then try to enable backup jobs.', 0, 1) WITH NOWAIT; - RETURN - END + IF OBJECT_ID('msdb.dbo.restore_worker') IS NOT NULL + + BEGIN + + /* + + Make sure configuration table exists... + + */ + + IF OBJECT_ID('msdb.dbo.restore_configuration') IS NOT NULL + + BEGIN + + IF @Debug = 1 RAISERROR('Checking variables', 0, 1) WITH NOWAIT; + + /* + + These settings are configurable + + */ + + SELECT @rto = CONVERT(INT, configuration_setting) + FROM msdb.dbo.restore_configuration c + WHERE configuration_name = N'log restore frequency'; + + + IF @rto IS NULL + BEGIN + RAISERROR('@rto cannot be NULL. Please check the msdb.dbo.restore_configuration table', 0, 1) WITH NOWAIT; + RETURN; + END; + + + END; + + ELSE + + BEGIN + + RAISERROR('msdb.dbo.restore_configuration does not exist, please run setup script', 0, 1) WITH NOWAIT; + + RETURN; + + END; + + + WHILE @Restore = 1 + /* + + Start loop to restore log backups - IF OBJECT_ID('msdbCentral.dbo.backup_configuration') IS NOT NULL + */ - RAISERROR('Found backup config, checking variables...', 0, 1) WITH NOWAIT; - + BEGIN - + BEGIN TRY + + BEGIN TRAN; + + IF @Debug = 1 RAISERROR('Begin tran to grab a database to restore', 0, 1) WITH NOWAIT; - - IF @RPOSeconds IS NOT NULL - - - BEGIN - - RAISERROR('Attempting to update RPO setting', 0, 1) WITH NOWAIT; - - UPDATE c - SET c.configuration_setting = CONVERT(NVARCHAR(10), @RPOSeconds) - FROM msdbCentral.dbo.backup_configuration AS c - WHERE c.configuration_name = N'log backup frequency'; - - END; - - - IF @BackupPath IS NOT NULL - BEGIN + /* - RAISERROR('Attempting to update Backup Path setting', 0, 1) WITH NOWAIT; - - UPDATE c - SET c.configuration_setting = @BackupPath - FROM msdbCentral.dbo.backup_configuration AS c - WHERE c.configuration_name = N'log backup path'; - + This grabs a database for a worker to work on - END; + The locking hints hope to provide some isolation when 10+ workers are in action + + */ + + + SELECT TOP (1) + @database = rw.database_name, + @only_logs_after = REPLACE(REPLACE(REPLACE(CONVERT(NVARCHAR(30), rw.last_log_restore_start_time, 120), ' ', ''), '-', ''), ':', ''), + @restore_full = CASE WHEN rw.is_started = 0 + AND rw.is_completed = 0 + AND rw.last_log_restore_start_time = '1900-01-01 00:00:00.000' + AND rw.last_log_restore_finish_time = '9999-12-31 00:00:00.000' + THEN 1 + ELSE 0 + END + FROM msdb.dbo.restore_worker rw WITH (UPDLOCK, HOLDLOCK, ROWLOCK) + WHERE ( + ( /*This section works on databases already part of the backup cycle*/ + rw.is_started = 0 + AND rw.is_completed = 1 + AND rw.last_log_restore_start_time < DATEADD(SECOND, (@rto * -1), GETDATE()) + AND (rw.error_number IS NULL OR rw.error_number > 0) /* negative numbers indicate human attention required */ + ) + OR + ( /*This section picks up newly added databases by DiskPollster*/ + rw.is_started = 0 + AND rw.is_completed = 0 + AND rw.last_log_restore_start_time = '1900-01-01 00:00:00.000' + AND rw.last_log_restore_finish_time = '9999-12-31 00:00:00.000' + AND (rw.error_number IS NULL OR rw.error_number > 0) /* negative numbers indicate human attention required */ + ) + ) + AND rw.ignore_database = 0 + AND NOT EXISTS ( + /* Validation check to ensure the database either doesn't exist or is in a restoring/standby state */ + SELECT 1 + FROM sys.databases d + WHERE d.name = rw.database_name + AND state <> 1 /* Restoring */ + AND NOT (state=0 AND d.is_in_standby=1) /* standby mode */ + ) + ORDER BY rw.last_log_restore_start_time ASC, rw.last_log_restore_finish_time ASC, rw.database_name ASC; + + + IF @database IS NOT NULL + BEGIN + SET @msg = N'Updating restore_worker for database ' + ISNULL(@database, 'UH OH NULL @database'); + IF @Debug = 1 RAISERROR(@msg, 0, 1) WITH NOWAIT; + + /* + + Update the worker table so other workers know a database is being restored + + */ + + UPDATE rw + SET rw.is_started = 1, + rw.is_completed = 0, + rw.last_log_restore_start_time = GETDATE() + FROM msdb.dbo.restore_worker rw + WHERE rw.database_name = @database; + END + + COMMIT; + END TRY - - + BEGIN CATCH + + /* + + Do I need to build retry logic in here? Try to catch deadlocks? I don't know yet! + + */ - - SELECT @error_number = ERROR_NUMBER(), - @error_severity = ERROR_SEVERITY(), - @error_state = ERROR_STATE(); - - SELECT @msg = N'Error updating backup configuration setting, error number is ' + CONVERT(NVARCHAR(10), ERROR_NUMBER()) + ', error message is ' + ERROR_MESSAGE(), + SELECT @msg = N'Error securing a database to restore, error number is ' + CONVERT(NVARCHAR(10), ERROR_NUMBER()) + ', error message is ' + ERROR_MESSAGE(), @error_severity = ERROR_SEVERITY(), @error_state = ERROR_STATE(); - RAISERROR(@msg, @error_severity, @error_state) WITH NOWAIT; - + SET @database = NULL; + + WHILE @@TRANCOUNT > 0 + ROLLBACK; + END CATCH; - END; + /* If we don't find a database to work on, wait for a few seconds */ + IF @database IS NULL - IF OBJECT_ID('msdb.dbo.restore_configuration') IS NOT NULL + BEGIN + IF @Debug = 1 RAISERROR('No databases to restore up right now, starting 3 second throttle', 0, 1) WITH NOWAIT; + WAITFOR DELAY '00:00:03.000'; - RAISERROR('Found restore config, checking variables...', 0, 1) WITH NOWAIT; + /* Check to make sure backup jobs aren't enabled */ + IF EXISTS ( + SELECT * + FROM msdb.dbo.sysjobs + WHERE name LIKE 'sp_AllNightLog_Backup%' + AND enabled = 1 + ) + BEGIN + RAISERROR('sp_AllNightLog_Backup jobs are enabled, so gracefully exiting. You do not want to accidentally do restores over top of the databases you are backing up.', 0, 1) WITH NOWAIT; + RETURN; + END - BEGIN + /* Check to make sure job is still enabled */ + IF NOT EXISTS ( + SELECT * + FROM msdb.dbo.sysjobs + WHERE name LIKE 'sp_AllNightLog_Restore%' + AND enabled = 1 + ) + BEGIN + RAISERROR('sp_AllNightLog_Restore jobs are disabled, so gracefully exiting. It feels graceful to me, anyway.', 0, 1) WITH NOWAIT; + RETURN; + END + END + + BEGIN TRY + + BEGIN + + IF @database IS NOT NULL - EXEC msdb.dbo.sp_update_schedule @name = ten_seconds, @active_start_date = @active_start_date, @active_start_time = 000000; - - IF @EnableRestoreJobs IS NOT NULL - BEGIN - RAISERROR('Changing restore job status based on @EnableBackupJobs parameter...', 0, 1) WITH NOWAIT; - INSERT INTO @jobs_to_change(name) - SELECT name - FROM msdb.dbo.sysjobs - WHERE name LIKE 'sp_AllNightLog_Restore%' OR name = 'sp_AllNightLog_PollDiskForNewDatabases'; - DECLARE jobs_cursor CURSOR FOR - SELECT name - FROM @jobs_to_change + /* + + Make sure we have a database to work on -- I should make this more robust so we do something if it is NULL, maybe + + */ - OPEN jobs_cursor - FETCH NEXT FROM jobs_cursor INTO @current_job_name + + BEGIN + + SET @msg = CASE WHEN @restore_full = 0 + THEN N'Restoring logs for ' + ELSE N'Restoring full backup for ' + END + + ISNULL(@database, 'UH OH NULL @database'); - WHILE @@FETCH_STATUS = 0 - BEGIN - RAISERROR(@current_job_name, 0, 1) WITH NOWAIT; - EXEC msdb.dbo.sp_update_job @job_name=@current_job_name,@enabled = @EnableRestoreJobs; - FETCH NEXT FROM jobs_cursor INTO @current_job_name - END + IF @Debug = 1 RAISERROR(@msg, 0, 1) WITH NOWAIT; - CLOSE jobs_cursor - DEALLOCATE jobs_cursor - DELETE @jobs_to_change; - END; + /* + + Call sp_DatabaseRestore to backup the database + + */ - /* If they wanted to turn off restore jobs, wait to make sure that finishes before we start enabling the backup jobs */ - IF @EnableRestoreJobs = 0 - BEGIN - SET @started_waiting_for_jobs = GETDATE(); - SELECT @counter = COUNT(*) - FROM [msdb].[dbo].[sysjobactivity] [ja] - INNER JOIN [msdb].[dbo].[sysjobs] [j] - ON [ja].[job_id] = [j].[job_id] - WHERE [ja].[session_id] = ( - SELECT TOP 1 [session_id] - FROM [msdb].[dbo].[syssessions] - ORDER BY [agent_start_date] DESC - ) - AND [start_execution_date] IS NOT NULL - AND [stop_execution_date] IS NULL - AND [j].[name] LIKE 'sp_AllNightLog_Restore%'; + SET @restore_path_full = @restore_path_base + N'\' + @database + N'\' + N'FULL\' + + SET @msg = N'Path for FULL backups for ' + @database + N' is ' + @restore_path_full + IF @Debug = 1 RAISERROR(@msg, 0, 1) WITH NOWAIT; - WHILE @counter > 0 - BEGIN - IF DATEADD(SS, 120, @started_waiting_for_jobs) < GETDATE() - BEGIN - RAISERROR('OH NOES! We waited 2 minutes and restore jobs are still running. We are stopping here - get a meatbag involved to figure out if restore jobs need to be killed, and the backup jobs will need to be enabled manually.', 16, 1) WITH NOWAIT; - RETURN - END - SET @msg = N'Waiting for ' + CAST(@counter AS NVARCHAR(100)) + N' sp_AllNightLog_Restore job(s) to finish.' - RAISERROR(@msg, 0, 1) WITH NOWAIT; - WAITFOR DELAY '0:00:01'; -- Wait until the restore jobs are fully stopped - - SELECT @counter = COUNT(*) - FROM [msdb].[dbo].[sysjobactivity] [ja] - INNER JOIN [msdb].[dbo].[sysjobs] [j] - ON [ja].[job_id] = [j].[job_id] - WHERE [ja].[session_id] = ( - SELECT TOP 1 [session_id] - FROM [msdb].[dbo].[syssessions] - ORDER BY [agent_start_date] DESC - ) - AND [start_execution_date] IS NOT NULL - AND [stop_execution_date] IS NULL - AND [j].[name] LIKE 'sp_AllNightLog_Restore%'; - END - END /* IF @EnableRestoreJobs = 0 */ + SET @restore_path_log = @restore_path_base + N'\' + @database + N'\' + N'LOG\' + SET @msg = N'Path for LOG backups for ' + @database + N' is ' + @restore_path_log + IF @Debug = 1 RAISERROR(@msg, 0, 1) WITH NOWAIT; - IF @EnableBackupJobs IS NOT NULL - BEGIN - RAISERROR('Changing backup job status based on @EnableBackupJobs parameter...', 0, 1) WITH NOWAIT; - INSERT INTO @jobs_to_change(name) - SELECT name - FROM msdb.dbo.sysjobs - WHERE name LIKE 'sp_AllNightLog_Backup%' OR name = 'sp_AllNightLog_PollForNewDatabases'; - DECLARE jobs_cursor CURSOR FOR - SELECT name - FROM @jobs_to_change + IF @restore_full = 0 - OPEN jobs_cursor - FETCH NEXT FROM jobs_cursor INTO @current_job_name + BEGIN - WHILE @@FETCH_STATUS = 0 - BEGIN - RAISERROR(@current_job_name, 0, 1) WITH NOWAIT; - EXEC msdb.dbo.sp_update_job @job_name=@current_job_name,@enabled = @EnableBackupJobs; - FETCH NEXT FROM jobs_cursor INTO @current_job_name - END + IF @Debug = 1 RAISERROR('Starting Log only restores', 0, 1) WITH NOWAIT; - CLOSE jobs_cursor - DEALLOCATE jobs_cursor - DELETE @jobs_to_change; - END; + EXEC dbo.sp_DatabaseRestore @Database = @database, + @BackupPathFull = @restore_path_full, + @BackupPathLog = @restore_path_log, + @ContinueLogs = 1, + @RunRecovery = 0, + @OnlyLogsAfter = @only_logs_after, + @MoveFiles = @restore_move_files, + @Debug = @Debug + + END + IF @restore_full = 1 - - IF @RTOSeconds IS NOT NULL + BEGIN - BEGIN + IF @Debug = 1 RAISERROR('Starting first Full restore from: ', 0, 1) WITH NOWAIT; + IF @Debug = 1 RAISERROR(@restore_path_full, 0, 1) WITH NOWAIT; - RAISERROR('Attempting to update RTO setting', 0, 1) WITH NOWAIT; + EXEC dbo.sp_DatabaseRestore @Database = @database, + @BackupPathFull = @restore_path_full, + @BackupPathLog = @restore_path_log, + @ContinueLogs = 0, + @RunRecovery = 0, + @MoveFiles = @restore_move_files, + @Debug = @Debug + + END - UPDATE c - SET c.configuration_setting = CONVERT(NVARCHAR(10), @RTOSeconds) - FROM msdb.dbo.restore_configuration AS c - WHERE c.configuration_name = N'log restore frequency'; - END; + + /* + + Catch any erroneous zones + + */ + + SELECT @error_number = ERROR_NUMBER(), + @error_severity = ERROR_SEVERITY(), + @error_state = ERROR_STATE(); + + END; --End call to dbo.sp_DatabaseRestore + + END; --End successful check of @database (not NULL) + + END TRY + + BEGIN CATCH + + IF @error_number IS NOT NULL + /* - IF @RestorePath IS NOT NULL + If the ERROR() function returns a number, update the table with it and the last error date. + + Also update the last start time to 1900-01-01 so it gets picked back up immediately -- the query to find a log restore to take sorts by start time + */ + BEGIN + + SET @msg = N'Error number is ' + CONVERT(NVARCHAR(10), ERROR_NUMBER()); + RAISERROR(@msg, @error_severity, @error_state) WITH NOWAIT; - RAISERROR('Attempting to update Restore Path setting', 0, 1) WITH NOWAIT; + SET @msg = N'Updating restore_worker for database ' + ISNULL(@database, 'UH OH NULL @database') + ' for unsuccessful backup'; + RAISERROR(@msg, 0, 1) WITH NOWAIT; + + + UPDATE rw + SET rw.is_started = 0, + rw.is_completed = 1, + rw.last_log_restore_start_time = '19000101', + rw.error_number = @error_number, + rw.last_error_date = GETDATE() + FROM msdb.dbo.restore_worker rw + WHERE rw.database_name = @database; - UPDATE c - SET c.configuration_setting = @RestorePath - FROM msdb.dbo.restore_configuration AS c - WHERE c.configuration_name = N'log restore path'; + /* + + Set @database back to NULL to avoid variable assignment weirdness + + */ - END; + SET @database = NULL; - END TRY + + /* + + Wait around for a second so we're not just spinning wheels -- this only runs if the BEGIN CATCH is triggered by an error + */ + + IF @Debug = 1 RAISERROR('Starting 1 second throttle', 0, 1) WITH NOWAIT; + + WAITFOR DELAY '00:00:01.000'; - BEGIN CATCH + END; -- End update of unsuccessful restore + + END CATCH; - SELECT @error_number = ERROR_NUMBER(), - @error_severity = ERROR_SEVERITY(), - @error_state = ERROR_STATE(); + IF @database IS NOT NULL AND @error_number IS NULL - SELECT @msg = N'Error updating restore configuration setting, error number is ' + CONVERT(NVARCHAR(10), ERROR_NUMBER()) + ', error message is ' + ERROR_MESSAGE(), - @error_severity = ERROR_SEVERITY(), - @error_state = ERROR_STATE(); + /* - RAISERROR(@msg, @error_severity, @error_state) WITH NOWAIT; + If no error, update everything normally + + */ + + BEGIN + + IF @Debug = 1 RAISERROR('Error number IS NULL', 0, 1) WITH NOWAIT; - END CATCH; + /* Make sure database actually exists and is in the restoring state */ + IF EXISTS (SELECT * FROM sys.databases WHERE name = @database AND state = 1) /* Restoring */ + BEGIN + SET @msg = N'Updating backup_worker for database ' + ISNULL(@database, 'UH OH NULL @database') + ' for successful backup'; + IF @Debug = 1 RAISERROR(@msg, 0, 1) WITH NOWAIT; + + UPDATE rw + SET rw.is_started = 0, + rw.is_completed = 1, + rw.last_log_restore_finish_time = GETDATE() + FROM msdb.dbo.restore_worker rw + WHERE rw.database_name = @database; - END; + END + ELSE /* The database doesn't exist, or it's not in the restoring state */ + BEGIN + SET @msg = N'Updating backup_worker for database ' + ISNULL(@database, 'UH OH NULL @database') + ' for UNsuccessful backup'; + IF @Debug = 1 RAISERROR(@msg, 0, 1) WITH NOWAIT; + + UPDATE rw + SET rw.is_started = 0, + rw.is_completed = 1, + rw.error_number = -1, /* unknown, human attention required */ + rw.last_error_date = GETDATE() + /* rw.last_log_restore_finish_time = GETDATE() don't change this - the last log may still be successful */ + FROM msdb.dbo.restore_worker rw + WHERE rw.database_name = @database; + END + + + + /* + + Set @database back to NULL to avoid variable assignment weirdness + + */ + + SET @database = NULL; - RAISERROR('Update complete!', 0, 1) WITH NOWAIT; + END; -- End update for successful backup + + END; -- End @Restore WHILE loop + + + END; -- End successful check for restore_worker and subsequent code + + + ELSE + + BEGIN + + RAISERROR('msdb.dbo.restore_worker does not exist, please run setup script', 0, 1) WITH NOWAIT; + RETURN; + + END; +RETURN; - END; --End updates to configuration table END; -- Final END for stored proc -GO +GO IF OBJECT_ID('dbo.sp_Blitz') IS NULL EXEC ('CREATE PROCEDURE dbo.sp_Blitz AS RETURN 0;'); GO @@ -2900,7 +2900,7 @@ AS SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED; - SELECT @Version = '8.12', @VersionDate = '20221213'; + SELECT @Version = '8.13', @VersionDate = '20230215'; SET @OutputType = UPPER(@OutputType); IF(@VersionCheckMode = 1) @@ -2955,9 +2955,9 @@ AS tigertoolbox and are provided under the MIT license: https://github.com/Microsoft/tigertoolbox - All other copyrights for sp_Blitz are held by Brent Ozar Unlimited, 2021. + All other copyrights for sp_Blitz are held by Brent Ozar Unlimited. - Copyright (c) 2021 Brent Ozar Unlimited + Copyright (c) Brent Ozar Unlimited Permission is hereby granted, free of charge, to any person obtaining a copy of this software and associated documentation files (the "Software"), to deal @@ -12599,7 +12599,7 @@ AS SET NOCOUNT ON; SET STATISTICS XML OFF; -SELECT @Version = '8.12', @VersionDate = '20221213'; +SELECT @Version = '8.13', @VersionDate = '20230215'; IF(@VersionCheckMode = 1) BEGIN @@ -13477,7 +13477,7 @@ AS SET STATISTICS XML OFF; SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED; - SELECT @Version = '8.12', @VersionDate = '20221213'; + SELECT @Version = '8.13', @VersionDate = '20230215'; IF(@VersionCheckMode = 1) BEGIN @@ -13524,7 +13524,7 @@ AS MIT License - Copyright (c) 2021 Brent Ozar Unlimited + Copyright (c) Brent Ozar Unlimited Permission is hereby granted, free of charge, to any person obtaining a copy of this software and associated documentation files (the "Software"), to deal @@ -15211,7 +15211,8 @@ CREATE TABLE ##BlitzCacheProcs ( cached_execution_parameters XML, missing_indexes XML, SetOptions VARCHAR(MAX), - Warnings VARCHAR(MAX) + Warnings VARCHAR(MAX), + Pattern NVARCHAR(20) ); GO @@ -15258,7 +15259,7 @@ SET NOCOUNT ON; SET STATISTICS XML OFF; SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED; -SELECT @Version = '8.12', @VersionDate = '20221213'; +SELECT @Version = '8.13', @VersionDate = '20230215'; SET @OutputType = UPPER(@OutputType); IF(@VersionCheckMode = 1) @@ -15282,7 +15283,6 @@ IF @Help = 1 the findings, contribute your own code, and more. Known limitations of this version: - - This query will not run on SQL Server 2005. - SQL Server 2008 and 2008R2 have a bug in trigger stats, so that output is excluded by default. - @IgnoreQueryHashes and @OnlyQueryHashes require a CSV list of hashes @@ -15298,7 +15298,7 @@ IF @Help = 1 MIT License - Copyright (c) 2021 Brent Ozar Unlimited + Copyright (c) Brent Ozar Unlimited Permission is hereby granted, free of charge, to any person obtaining a copy of this software and associated documentation files (the "Software"), to deal @@ -16034,7 +16034,8 @@ BEGIN cached_execution_parameters XML, missing_indexes XML, SetOptions VARCHAR(MAX), - Warnings VARCHAR(MAX) + Warnings VARCHAR(MAX), + Pattern NVARCHAR(20) ); END; @@ -16135,18 +16136,18 @@ IF @SkipAnalysis = 1 DECLARE @AllSortSql NVARCHAR(MAX) = N''; DECLARE @VersionShowsMemoryGrants BIT; -IF EXISTS(SELECT * FROM sys.all_columns WHERE OBJECT_ID = OBJECT_ID('sys.dm_exec_query_stats') AND name = 'max_grant_kb') +IF EXISTS(SELECT * FROM sys.all_columns WHERE object_id = OBJECT_ID('sys.dm_exec_query_stats') AND name = 'max_grant_kb') SET @VersionShowsMemoryGrants = 1; ELSE SET @VersionShowsMemoryGrants = 0; DECLARE @VersionShowsSpills BIT; -IF EXISTS(SELECT * FROM sys.all_columns WHERE OBJECT_ID = OBJECT_ID('sys.dm_exec_query_stats') AND name = 'max_spills') +IF EXISTS(SELECT * FROM sys.all_columns WHERE object_id = OBJECT_ID('sys.dm_exec_query_stats') AND name = 'max_spills') SET @VersionShowsSpills = 1; ELSE SET @VersionShowsSpills = 0; -IF EXISTS(SELECT * FROM sys.all_columns WHERE OBJECT_ID = OBJECT_ID('sys.dm_exec_query_plan_stats') AND name = 'query_plan') +IF EXISTS(SELECT * FROM sys.all_columns WHERE object_id = OBJECT_ID('sys.dm_exec_query_plan_stats') AND name = 'query_plan') SET @VersionShowsAirQuoteActualPlans = 1; ELSE SET @VersionShowsAirQuoteActualPlans = 0; @@ -16953,7 +16954,7 @@ INSERT INTO ##BlitzCacheProcs (SPID, QueryType, DatabaseName, AverageCPU, TotalC LastReturnedRows, MinGrantKB, MaxGrantKB, MinUsedGrantKB, MaxUsedGrantKB, PercentMemoryGrantUsed, AvgMaxMemoryGrant, MinSpills, MaxSpills, TotalSpills, AvgSpills, QueryText, QueryPlan, TotalWorkerTimeForType, TotalElapsedTimeForType, TotalReadsForType, TotalExecutionCountForType, TotalWritesForType, SqlHandle, PlanHandle, QueryHash, QueryPlanHash, - min_worker_time, max_worker_time, is_parallel, min_elapsed_time, max_elapsed_time, age_minutes, age_minutes_lifetime) ' ; + min_worker_time, max_worker_time, is_parallel, min_elapsed_time, max_elapsed_time, age_minutes, age_minutes_lifetime, Pattern) ' ; SET @body += N' FROM (SELECT TOP (@Top) x.*, xpa.*, @@ -17217,7 +17218,8 @@ SELECT TOP (@Top) qs.min_elapsed_time / 1000.0, qs.max_elapsed_time / 1000.0, age_minutes, - age_minutes_lifetime '; + age_minutes_lifetime, + @SortOrder '; IF LEFT(@QueryFilter, 3) IN ('all', 'sta') @@ -17365,7 +17367,8 @@ BEGIN qs.min_elapsed_time / 1000.0, qs.max_worker_time / 1000.0, age_minutes, - age_minutes_lifetime '; + age_minutes_lifetime, + @SortOrder '; SET @sql += REPLACE(REPLACE(@body, '#view#', 'dm_exec_query_stats'), 'cached_time', 'creation_time') ; @@ -17600,7 +17603,7 @@ IF @Reanalyze = 0 BEGIN RAISERROR('Collecting execution plan information.', 0, 1) WITH NOWAIT; - EXEC sp_executesql @sql, N'@Top INT, @min_duration INT, @min_back INT', @Top, @DurationFilter_i, @MinutesBack; + EXEC sp_executesql @sql, N'@Top INT, @min_duration INT, @min_back INT, @SortOrder NVARCHAR(20)', @Top, @DurationFilter_i, @MinutesBack, @SortOrder; END; IF @SkipAnalysis = 1 @@ -22093,6 +22096,7 @@ ELSE TotalSpills BIGINT, AvgSpills MONEY, QueryPlanCost FLOAT, + Pattern NVARCHAR(20), JoinKey AS ServerName + Cast(CheckDate AS NVARCHAR(50)), CONSTRAINT [PK_' + REPLACE(REPLACE(@OutputTableName,N'[',N''),N']',N'') + N'] PRIMARY KEY CLUSTERED(ID ASC));' ); @@ -22194,6 +22198,22 @@ END '; EXEC(@StringToExecute); END; + /* If the table doesn't have the new Pattern column, add it */ + SET @ObjectFullName = @OutputDatabaseName + N'.' + @OutputSchemaName + N'.' + @OutputTableName; + SET @StringToExecute = N'IF NOT EXISTS (SELECT * FROM ' + @OutputDatabaseName + N'.sys.all_columns + WHERE object_id = (OBJECT_ID(''' + @ObjectFullName + N''')) AND name = ''Pattern'') + ALTER TABLE ' + @ObjectFullName + N' ADD Pattern NVARCHAR(20) NULL;'; + IF @ValidOutputServer = 1 + BEGIN + SET @StringToExecute = REPLACE(@StringToExecute,'''Pattern''','''''Pattern'''''); + SET @StringToExecute = REPLACE(@StringToExecute,'''' + @ObjectFullName + '''','''''' + @ObjectFullName + ''''''); + EXEC('EXEC('''+@StringToExecute+''') AT ' + @OutputServerName); + END; + ELSE + BEGIN + EXEC(@StringToExecute); + END + IF @CheckDateOverride IS NULL BEGIN SET @CheckDateOverride = SYSDATETIMEOFFSET(); @@ -22213,14 +22233,14 @@ END '; + ' (ServerName, CheckDate, Version, QueryType, DatabaseName, AverageCPU, TotalCPU, PercentCPUByType, CPUWeight, AverageDuration, TotalDuration, DurationWeight, PercentDurationByType, AverageReads, TotalReads, ReadWeight, PercentReadsByType, ' + ' AverageWrites, TotalWrites, WriteWeight, PercentWritesByType, ExecutionCount, ExecutionWeight, PercentExecutionsByType, ' + ' ExecutionsPerMinute, PlanCreationTime, LastExecutionTime, LastCompletionTime, PlanHandle, SqlHandle, QueryHash, QueryPlanHash, StatementStartOffset, StatementEndOffset, PlanGenerationNum, MinReturnedRows, MaxReturnedRows, AverageReturnedRows, TotalReturnedRows, QueryText, QueryPlan, NumberOfPlans, NumberOfDistinctPlans, Warnings, ' - + ' SerialRequiredMemory, SerialDesiredMemory, MinGrantKB, MaxGrantKB, MinUsedGrantKB, MaxUsedGrantKB, PercentMemoryGrantUsed, AvgMaxMemoryGrant, MinSpills, MaxSpills, TotalSpills, AvgSpills, QueryPlanCost ) ' + + ' SerialRequiredMemory, SerialDesiredMemory, MinGrantKB, MaxGrantKB, MinUsedGrantKB, MaxUsedGrantKB, PercentMemoryGrantUsed, AvgMaxMemoryGrant, MinSpills, MaxSpills, TotalSpills, AvgSpills, QueryPlanCost, Pattern ) ' + 'SELECT TOP (@Top) ' + QUOTENAME(CAST(SERVERPROPERTY('ServerName') AS NVARCHAR(128)), '''') + ', @CheckDateOverride, ' + QUOTENAME(CAST(SERVERPROPERTY('ProductVersion') AS NVARCHAR(128)), '''') + ', ' + ' QueryType, DatabaseName, AverageCPU, TotalCPU, PercentCPUByType, PercentCPU, AverageDuration, TotalDuration, PercentDuration, PercentDurationByType, AverageReads, TotalReads, PercentReads, PercentReadsByType, ' + ' AverageWrites, TotalWrites, PercentWrites, PercentWritesByType, ExecutionCount, PercentExecutions, PercentExecutionsByType, ' + ' ExecutionsPerMinute, PlanCreationTime, LastExecutionTime, LastCompletionTime, PlanHandle, SqlHandle, QueryHash, QueryPlanHash, StatementStartOffset, StatementEndOffset, PlanGenerationNum, MinReturnedRows, MaxReturnedRows, AverageReturnedRows, TotalReturnedRows, QueryText, CAST(QueryPlan AS NVARCHAR(MAX)), NumberOfPlans, NumberOfDistinctPlans, Warnings, ' - + ' SerialRequiredMemory, SerialDesiredMemory, MinGrantKB, MaxGrantKB, MinUsedGrantKB, MaxUsedGrantKB, PercentMemoryGrantUsed, AvgMaxMemoryGrant, MinSpills, MaxSpills, TotalSpills, AvgSpills, QueryPlanCost ' + + ' SerialRequiredMemory, SerialDesiredMemory, MinGrantKB, MaxGrantKB, MinUsedGrantKB, MaxUsedGrantKB, PercentMemoryGrantUsed, AvgMaxMemoryGrant, MinSpills, MaxSpills, TotalSpills, AvgSpills, QueryPlanCost, Pattern ' + ' FROM ##BlitzCacheProcs ' + ' WHERE 1=1 '; @@ -22281,14 +22301,14 @@ END '; + ' (ServerName, CheckDate, Version, QueryType, DatabaseName, AverageCPU, TotalCPU, PercentCPUByType, CPUWeight, AverageDuration, TotalDuration, DurationWeight, PercentDurationByType, AverageReads, TotalReads, ReadWeight, PercentReadsByType, ' + ' AverageWrites, TotalWrites, WriteWeight, PercentWritesByType, ExecutionCount, ExecutionWeight, PercentExecutionsByType, ' + ' ExecutionsPerMinute, PlanCreationTime, LastExecutionTime, LastCompletionTime, PlanHandle, SqlHandle, QueryHash, QueryPlanHash, StatementStartOffset, StatementEndOffset, PlanGenerationNum, MinReturnedRows, MaxReturnedRows, AverageReturnedRows, TotalReturnedRows, QueryText, QueryPlan, NumberOfPlans, NumberOfDistinctPlans, Warnings, ' - + ' SerialRequiredMemory, SerialDesiredMemory, MinGrantKB, MaxGrantKB, MinUsedGrantKB, MaxUsedGrantKB, PercentMemoryGrantUsed, AvgMaxMemoryGrant, MinSpills, MaxSpills, TotalSpills, AvgSpills, QueryPlanCost ) ' + + ' SerialRequiredMemory, SerialDesiredMemory, MinGrantKB, MaxGrantKB, MinUsedGrantKB, MaxUsedGrantKB, PercentMemoryGrantUsed, AvgMaxMemoryGrant, MinSpills, MaxSpills, TotalSpills, AvgSpills, QueryPlanCost, Pattern ) ' + 'SELECT TOP (@Top) ' + QUOTENAME(CAST(SERVERPROPERTY('ServerName') AS NVARCHAR(128)), '''') + ', @CheckDateOverride, ' + QUOTENAME(CAST(SERVERPROPERTY('ProductVersion') AS NVARCHAR(128)), '''') + ', ' + ' QueryType, DatabaseName, AverageCPU, TotalCPU, PercentCPUByType, PercentCPU, AverageDuration, TotalDuration, PercentDuration, PercentDurationByType, AverageReads, TotalReads, PercentReads, PercentReadsByType, ' + ' AverageWrites, TotalWrites, PercentWrites, PercentWritesByType, ExecutionCount, PercentExecutions, PercentExecutionsByType, ' + ' ExecutionsPerMinute, PlanCreationTime, LastExecutionTime, LastCompletionTime, PlanHandle, SqlHandle, QueryHash, QueryPlanHash, StatementStartOffset, StatementEndOffset, PlanGenerationNum, MinReturnedRows, MaxReturnedRows, AverageReturnedRows, TotalReturnedRows, QueryText, QueryPlan, NumberOfPlans, NumberOfDistinctPlans, Warnings, ' - + ' SerialRequiredMemory, SerialDesiredMemory, MinGrantKB, MaxGrantKB, MinUsedGrantKB, MaxUsedGrantKB, PercentMemoryGrantUsed, AvgMaxMemoryGrant, MinSpills, MaxSpills, TotalSpills, AvgSpills, QueryPlanCost ' + + ' SerialRequiredMemory, SerialDesiredMemory, MinGrantKB, MaxGrantKB, MinUsedGrantKB, MaxUsedGrantKB, PercentMemoryGrantUsed, AvgMaxMemoryGrant, MinSpills, MaxSpills, TotalSpills, AvgSpills, QueryPlanCost, Pattern ' + ' FROM ##BlitzCacheProcs ' + ' WHERE 1=1 '; @@ -22430,6 +22450,7 @@ END '; TotalSpills BIGINT, AvgSpills MONEY, QueryPlanCost FLOAT, + Pattern NVARCHAR(20), JoinKey AS ServerName + Cast(CheckDate AS NVARCHAR(50)), CONSTRAINT [PK_' + REPLACE(REPLACE(@OutputTableName,'[',''),']','') + '] PRIMARY KEY CLUSTERED(ID ASC));'; SET @StringToExecute += N' INSERT ' @@ -22437,14 +22458,14 @@ END '; + ' (ServerName, CheckDate, Version, QueryType, DatabaseName, AverageCPU, TotalCPU, PercentCPUByType, CPUWeight, AverageDuration, TotalDuration, DurationWeight, PercentDurationByType, AverageReads, TotalReads, ReadWeight, PercentReadsByType, ' + ' AverageWrites, TotalWrites, WriteWeight, PercentWritesByType, ExecutionCount, ExecutionWeight, PercentExecutionsByType, ' + ' ExecutionsPerMinute, PlanCreationTime, LastExecutionTime, LastCompletionTime, PlanHandle, SqlHandle, QueryHash, QueryPlanHash, StatementStartOffset, StatementEndOffset, PlanGenerationNum, MinReturnedRows, MaxReturnedRows, AverageReturnedRows, TotalReturnedRows, QueryText, QueryPlan, NumberOfPlans, NumberOfDistinctPlans, Warnings, ' - + ' SerialRequiredMemory, SerialDesiredMemory, MinGrantKB, MaxGrantKB, MinUsedGrantKB, MaxUsedGrantKB, PercentMemoryGrantUsed, AvgMaxMemoryGrant, MinSpills, MaxSpills, TotalSpills, AvgSpills, QueryPlanCost ) ' + + ' SerialRequiredMemory, SerialDesiredMemory, MinGrantKB, MaxGrantKB, MinUsedGrantKB, MaxUsedGrantKB, PercentMemoryGrantUsed, AvgMaxMemoryGrant, MinSpills, MaxSpills, TotalSpills, AvgSpills, QueryPlanCost, Pattern ) ' + 'SELECT TOP (@Top) ' + QUOTENAME(CAST(SERVERPROPERTY('ServerName') AS NVARCHAR(128)), '''') + ', @CheckDateOverride, ' + QUOTENAME(CAST(SERVERPROPERTY('ProductVersion') AS NVARCHAR(128)), '''') + ', ' + ' QueryType, DatabaseName, AverageCPU, TotalCPU, PercentCPUByType, PercentCPU, AverageDuration, TotalDuration, PercentDuration, PercentDurationByType, AverageReads, TotalReads, PercentReads, PercentReadsByType, ' + ' AverageWrites, TotalWrites, PercentWrites, PercentWritesByType, ExecutionCount, PercentExecutions, PercentExecutionsByType, ' + ' ExecutionsPerMinute, PlanCreationTime, LastExecutionTime, LastCompletionTime, PlanHandle, SqlHandle, QueryHash, QueryPlanHash, StatementStartOffset, StatementEndOffset, PlanGenerationNum, MinReturnedRows, MaxReturnedRows, AverageReturnedRows, TotalReturnedRows, QueryText, QueryPlan, NumberOfPlans, NumberOfDistinctPlans, Warnings, ' - + ' SerialRequiredMemory, SerialDesiredMemory, MinGrantKB, MaxGrantKB, MinUsedGrantKB, MaxUsedGrantKB, PercentMemoryGrantUsed, AvgMaxMemoryGrant, MinSpills, MaxSpills, TotalSpills, AvgSpills, QueryPlanCost ' + + ' SerialRequiredMemory, SerialDesiredMemory, MinGrantKB, MaxGrantKB, MinUsedGrantKB, MaxUsedGrantKB, PercentMemoryGrantUsed, AvgMaxMemoryGrant, MinSpills, MaxSpills, TotalSpills, AvgSpills, QueryPlanCost, Pattern ' + ' FROM ##BlitzCacheProcs ' + ' WHERE 1=1 '; @@ -22556,7 +22577,7 @@ SET NOCOUNT ON; SET STATISTICS XML OFF; SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED; -SELECT @Version = '8.12', @VersionDate = '20221213'; +SELECT @Version = '8.13', @VersionDate = '20230215'; SET @OutputType = UPPER(@OutputType); IF(@VersionCheckMode = 1) @@ -22593,7 +22614,7 @@ Unknown limitations of this version: MIT License -Copyright (c) 2021 Brent Ozar Unlimited +Copyright (c) Brent Ozar Unlimited Permission is hereby granted, free of charge, to any person obtaining a copy of this software and associated documentation files (the "Software"), to deal @@ -28733,7 +28754,7 @@ BEGIN SET NOCOUNT, XACT_ABORT ON; SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED; - SELECT @Version = '8.12', @VersionDate = '20221213'; + SELECT @Version = '8.13', @VersionDate = '20230215'; IF @VersionCheckMode = 1 BEGIN @@ -28794,7 +28815,7 @@ BEGIN MIT License - Copyright (c) 2022 Brent Ozar Unlimited + Copyright (c) Brent Ozar Unlimited Permission is hereby granted, free of charge, to any person obtaining a copy of this software and associated documentation files (the "Software"), to deal @@ -29867,7 +29888,7 @@ BEGIN waiter_mode = w.l.value('@mode', 'nvarchar(256)'), owner_id = o.l.value('@id', 'nvarchar(256)'), owner_mode = o.l.value('@mode', 'nvarchar(256)'), - lock_type = N'OBJECT' + lock_type = CAST(N'OBJECT' AS NVARCHAR(100)) INTO #deadlock_owner_waiter FROM ( @@ -30492,7 +30513,7 @@ BEGIN N'S', N'IS' ) - AND (dow.database_id = @DatabaseName OR @DatabaseName IS NULL) + AND (dow.database_id = @DatabaseId OR @DatabaseName IS NULL) AND (dow.event_date >= @StartDate OR @StartDate IS NULL) AND (dow.event_date < @EndDate OR @EndDate IS NULL) AND (dow.object_name = @ObjectName OR @ObjectName IS NULL) @@ -30535,7 +30556,7 @@ BEGIN N' deadlock(s).' FROM #deadlock_owner_waiter AS dow WHERE 1 = 1 - AND (dow.database_id = @DatabaseName OR @DatabaseName IS NULL) + AND (dow.database_id = @DatabaseId OR @DatabaseName IS NULL) AND (dow.event_date >= @StartDate OR @StartDate IS NULL) AND (dow.event_date < @EndDate OR @EndDate IS NULL) AND (dow.object_name = @ObjectName OR @ObjectName IS NULL) @@ -30574,7 +30595,7 @@ BEGIN N' deadlock(s).' FROM #deadlock_owner_waiter AS dow WHERE 1 = 1 - AND (dow.database_id = @DatabaseName OR @DatabaseName IS NULL) + AND (dow.database_id = @DatabaseId OR @DatabaseName IS NULL) AND (dow.event_date >= @StartDate OR @StartDate IS NULL) AND (dow.event_date < @EndDate OR @EndDate IS NULL) AND (dow.object_name = @ObjectName OR @ObjectName IS NULL) @@ -30619,7 +30640,7 @@ BEGIN N' deadlock(s).' FROM #deadlock_owner_waiter AS dow WHERE 1 = 1 - AND (dow.database_id = @DatabaseName OR @DatabaseName IS NULL) + AND (dow.database_id = @DatabaseId OR @DatabaseName IS NULL) AND (dow.event_date >= @StartDate OR @StartDate IS NULL) AND (dow.event_date < @EndDate OR @EndDate IS NULL) AND (dow.object_name = @ObjectName OR @ObjectName IS NULL) @@ -30945,7 +30966,7 @@ BEGIN ON dow.owner_id = ds.id AND dow.event_date = ds.event_date WHERE 1 = 1 - AND (dow.database_id = @DatabaseName OR @DatabaseName IS NULL) + AND (dow.database_id = @DatabaseId OR @DatabaseName IS NULL) AND (dow.event_date >= @StartDate OR @StartDate IS NULL) AND (dow.event_date < @EndDate OR @EndDate IS NULL) AND (dow.object_name = @StoredProcName OR @StoredProcName IS NULL) @@ -31001,7 +31022,7 @@ BEGIN ON dow.owner_id = ds.id AND dow.event_date = ds.event_date WHERE ds.proc_name <> N'adhoc' - AND (dow.database_id = @DatabaseName OR @DatabaseName IS NULL) + AND (dow.database_id = @DatabaseId OR @DatabaseName IS NULL) AND (dow.event_date >= @StartDate OR @StartDate IS NULL) AND (dow.event_date < @EndDate OR @EndDate IS NULL) AND (dow.object_name = @StoredProcName OR @StoredProcName IS NULL) @@ -31077,7 +31098,7 @@ BEGIN ON s.database_id = dow.database_id AND s.partition_id = dow.associatedObjectId WHERE 1 = 1 - AND (dow.database_id = @DatabaseName OR @DatabaseName IS NULL) + AND (dow.database_id = @DatabaseId OR @DatabaseName IS NULL) AND (dow.event_date >= @StartDate OR @StartDate IS NULL) AND (dow.event_date < @EndDate OR @EndDate IS NULL) AND (dow.object_name = @ObjectName OR @ObjectName IS NULL) @@ -31139,6 +31160,76 @@ BEGIN ) ), wait_time_hms = + /*the more wait time you rack up the less accurate this gets, + it's either that or erroring out*/ + CASE + WHEN + SUM + ( + CONVERT + ( + bigint, + dp.wait_time + ) + )/1000 > 2147483647 + THEN + CONVERT + ( + nvarchar(30), + DATEADD + ( + MINUTE, + ( + ( + SUM + ( + CONVERT + ( + bigint, + dp.wait_time + ) + ) + )/ + 60000 + ), + 0 + ), + 14 + ) + WHEN + SUM + ( + CONVERT + ( + bigint, + dp.wait_time + ) + ) BETWEEN 2147483648 AND 2147483647000 + THEN + CONVERT + ( + nvarchar(30), + DATEADD + ( + SECOND, + ( + ( + SUM + ( + CONVERT + ( + bigint, + dp.wait_time + ) + ) + )/ + 1000 + ), + 0 + ), + 14 + ) + ELSE CONVERT ( nvarchar(30), @@ -31159,6 +31250,7 @@ BEGIN ), 14 ) + END FROM #deadlock_owner_waiter AS dow JOIN #deadlock_process AS dp ON (dp.id = dow.owner_id @@ -31275,6 +31367,76 @@ BEGIN ) ) + N' ' + + /*the more wait time you rack up the less accurate this gets, + it's either that or erroring out*/ + CASE + WHEN + SUM + ( + CONVERT + ( + bigint, + wt.total_wait_time_ms + ) + )/1000 > 2147483647 + THEN + CONVERT + ( + nvarchar(30), + DATEADD + ( + MINUTE, + ( + ( + SUM + ( + CONVERT + ( + bigint, + wt.total_wait_time_ms + ) + ) + )/ + 60000 + ), + 0 + ), + 14 + ) + WHEN + SUM + ( + CONVERT + ( + bigint, + wt.total_wait_time_ms + ) + ) BETWEEN 2147483648 AND 2147483647000 + THEN + CONVERT + ( + nvarchar(30), + DATEADD + ( + SECOND, + ( + ( + SUM + ( + CONVERT + ( + bigint, + wt.total_wait_time_ms + ) + ) + )/ + 1000 + ), + 0 + ), + 14 + ) + ELSE CONVERT ( nvarchar(30), @@ -31294,7 +31456,7 @@ BEGIN 0 ), 14 - ) + + ) END + N' [dd hh:mm:ss:ms] of deadlock wait time.' FROM wait_time AS wt GROUP BY @@ -32240,7 +32402,7 @@ SET NOCOUNT ON; SET STATISTICS XML OFF; SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED; -SELECT @Version = '8.12', @VersionDate = '20221213'; +SELECT @Version = '8.13', @VersionDate = '20230215'; IF(@VersionCheckMode = 1) BEGIN RETURN; @@ -32326,7 +32488,7 @@ IF @Help = 1 MIT License - Copyright (c) 2021 Brent Ozar Unlimited + Copyright (c) Brent Ozar Unlimited Permission is hereby granted, free of charge, to any person obtaining a copy of this software and associated documentation files (the "Software"), to deal @@ -37971,7 +38133,7 @@ BEGIN SET STATISTICS XML OFF; SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED; - SELECT @Version = '8.12', @VersionDate = '20221213'; + SELECT @Version = '8.13', @VersionDate = '20230215'; IF(@VersionCheckMode = 1) BEGIN @@ -37999,7 +38161,7 @@ Known limitations of this version: MIT License -Copyright (c) 2021 Brent Ozar Unlimited +Copyright (c) Brent Ozar Unlimited Permission is hereby granted, free of charge, to any person obtaining a copy of this software and associated documentation files (the "Software"), to deal @@ -38628,11 +38790,11 @@ BEGIN END AS blocking_session_id, COALESCE(DB_NAME(r.database_id), DB_NAME(blocked.dbid), ''N/A'') AS database_name, ISNULL(SUBSTRING(dest.text, - ( query_stats.statement_start_offset / 2 ) + 1, - ( ( CASE query_stats.statement_end_offset + ( r.statement_start_offset / 2 ) + 1, + ( ( CASE r.statement_end_offset WHEN -1 THEN DATALENGTH(dest.text) - ELSE query_stats.statement_end_offset - END - query_stats.statement_start_offset ) + ELSE r.statement_end_offset + END - r.statement_start_offset ) / 2 ) + 1), dest.text) AS query_text , '+CASE WHEN @GetOuterCommand = 1 THEN N'CAST(event_info AS NVARCHAR(4000)) AS outer_command,' @@ -38797,7 +38959,7 @@ BEGIN OUTER APPLY sys.dm_exec_sql_text(COALESCE(r.sql_handle, blocked.sql_handle)) AS dest OUTER APPLY sys.dm_exec_query_plan(r.plan_handle) AS derp OUTER APPLY ( - SELECT CONVERT(DECIMAL(38,2), SUM( (((tsu.user_objects_alloc_page_count - user_objects_dealloc_page_count) * 8) / 1024.)) ) AS tempdb_allocations_mb + SELECT CONVERT(DECIMAL(38,2), SUM( ((((tsu.user_objects_alloc_page_count - user_objects_dealloc_page_count) + (tsu.internal_objects_alloc_page_count - internal_objects_dealloc_page_count)) * 8) / 1024.)) ) AS tempdb_allocations_mb FROM sys.dm_db_task_space_usage tsu WHERE tsu.request_id = r.request_id AND tsu.session_id = r.session_id @@ -38846,11 +39008,11 @@ IF @ProductVersionMajor >= 11 END AS blocking_session_id, COALESCE(DB_NAME(r.database_id), DB_NAME(blocked.dbid), ''N/A'') AS database_name, ISNULL(SUBSTRING(dest.text, - ( query_stats.statement_start_offset / 2 ) + 1, - ( ( CASE query_stats.statement_end_offset + ( r.statement_start_offset / 2 ) + 1, + ( ( CASE r.statement_end_offset WHEN -1 THEN DATALENGTH(dest.text) - ELSE query_stats.statement_end_offset - END - query_stats.statement_start_offset ) + ELSE r.statement_end_offset + END - r.statement_start_offset ) / 2 ) + 1), dest.text) AS query_text , '+CASE WHEN @GetOuterCommand = 1 THEN N'CAST(event_info AS NVARCHAR(4000)) AS outer_command,' @@ -39090,7 +39252,7 @@ IF @ProductVersionMajor >= 11 OUTER APPLY sys.dm_exec_sql_text(COALESCE(r.sql_handle, blocked.sql_handle)) AS dest OUTER APPLY sys.dm_exec_query_plan(r.plan_handle) AS derp OUTER APPLY ( - SELECT CONVERT(DECIMAL(38,2), SUM( (((tsu.user_objects_alloc_page_count - user_objects_dealloc_page_count) * 8) / 1024.)) ) AS tempdb_allocations_mb + SELECT CONVERT(DECIMAL(38,2), SUM( ((((tsu.user_objects_alloc_page_count - user_objects_dealloc_page_count) + (tsu.internal_objects_alloc_page_count - internal_objects_dealloc_page_count)) * 8) / 1024.)) ) AS tempdb_allocations_mb FROM sys.dm_db_task_space_usage tsu WHERE tsu.request_id = r.request_id AND tsu.session_id = r.session_id @@ -39368,7 +39530,7 @@ SET STATISTICS XML OFF; /*Versioning details*/ -SELECT @Version = '8.12', @VersionDate = '20221213'; +SELECT @Version = '8.13', @VersionDate = '20230215'; IF(@VersionCheckMode = 1) BEGIN @@ -39400,7 +39562,7 @@ BEGIN MIT License - Copyright (c) 2021 Brent Ozar Unlimited + Copyright (c) Brent Ozar Unlimited Permission is hereby granted, free of charge, to any person obtaining a copy of this software and associated documentation files (the "Software"), to deal @@ -40944,7 +41106,7 @@ BEGIN SET NOCOUNT ON; SET STATISTICS XML OFF; - SELECT @Version = '8.12', @VersionDate = '20221213'; + SELECT @Version = '8.13', @VersionDate = '20230215'; IF(@VersionCheckMode = 1) BEGIN @@ -40977,7 +41139,7 @@ BEGIN MIT License - Copyright (c) 2021 Brent Ozar Unlimited + Copyright (c) Brent Ozar Unlimited Permission is hereby granted, free of charge, to any person obtaining a copy of this software and associated documentation files (the "Software"), to deal @@ -41290,7 +41452,9 @@ DELETE FROM dbo.SqlServerVersions; INSERT INTO dbo.SqlServerVersions (MajorVersionNumber, MinorVersionNumber, Branch, [Url], ReleaseDate, MainstreamSupportEndDate, ExtendedSupportEndDate, MajorVersionName, MinorVersionName) VALUES + (16, 1050, 'RTM GDR', 'https://support.microsoft.com/kb/5021522', '2023-02-14', '2028-01-11', '2033-01-11', 'SQL Server 2022 GDR', 'RTM'), (16, 1000, 'RTM', '', '2022-11-15', '2028-01-11', '2033-01-11', 'SQL Server 2022', 'RTM'), + (15, 4280, 'CU18 GDR', 'https://support.microsoft.com/kb/5021124', '2023-02-14', '2025-01-07', '2030-01-08', 'SQL Server 2019', 'Cumulative Update 18 GDR'), (15, 4261, 'CU18', 'https://support.microsoft.com/en-us/help/5017593', '2022-09-28', '2025-01-07', '2030-01-08', 'SQL Server 2019', 'Cumulative Update 18'), (15, 4249, 'CU17', 'https://support.microsoft.com/en-us/help/5016394', '2022-08-11', '2025-01-07', '2030-01-08', 'SQL Server 2019', 'Cumulative Update 17'), (15, 4236, 'CU16 GDR', 'https://support.microsoft.com/en-us/help/5014353', '2022-06-14', '2025-01-07', '2030-01-08', 'SQL Server 2019', 'Cumulative Update 16 GDR'), @@ -41313,6 +41477,7 @@ VALUES (15, 4003, 'CU1', 'https://support.microsoft.com/en-us/help/4527376', '2020-01-07', '2025-01-07', '2030-01-08', 'SQL Server 2019', 'Cumulative Update 1 '), (15, 2070, 'GDR', 'https://support.microsoft.com/en-us/help/4517790', '2019-11-04', '2025-01-07', '2030-01-08', 'SQL Server 2019', 'RTM GDR '), (15, 2000, 'RTM ', '', '2019-11-04', '2025-01-07', '2030-01-08', 'SQL Server 2019', 'RTM '), + (14, 3460, 'RTM CU31 GDR', 'https://support.microsoft.com/kb/5021126', '2023-02-14', '2022-10-11', '2027-10-12', 'SQL Server 2017', 'RTM Cumulative Update 31 GDR'), (14, 3456, 'RTM CU31', 'https://support.microsoft.com/en-us/help/5016884', '2022-09-20', '2022-10-11', '2027-10-12', 'SQL Server 2017', 'RTM Cumulative Update 31'), (14, 3451, 'RTM CU30', 'https://support.microsoft.com/en-us/help/5013756', '2022-07-13', '2022-10-11', '2027-10-12', 'SQL Server 2017', 'RTM Cumulative Update 30'), (14, 3445, 'RTM CU29 GDR', 'https://support.microsoft.com/en-us/help/5014553', '2022-06-14', '2022-10-11', '2027-10-12', 'SQL Server 2017', 'RTM Cumulative Update 29 GDR'), @@ -41349,6 +41514,7 @@ VALUES (14, 1000, 'RTM ', '', '2017-10-02', '2022-10-11', '2027-10-12', 'SQL Server 2017', 'RTM '), (13, 7016, 'SP3 Azure Feature Pack GDR', 'https://support.microsoft.com/en-us/help/5015371', '2022-06-14', '2021-07-13', '2026-07-14', 'SQL Server 2016', 'Service Pack 3 Azure Feature Pack GDR'), (13, 7000, 'SP3 Azure Feature Pack', 'https://support.microsoft.com/en-us/help/5014242', '2022-05-19', '2021-07-13', '2026-07-14', 'SQL Server 2016', 'Service Pack 3 Azure Feature Pack'), + (13, 6430, 'SP3 GDR', 'https://support.microsoft.com/kb/5021129', '2023-02-14', '2021-07-13', '2026-07-14', 'SQL Server 2016', 'Service Pack 3 GDR'), (13, 6419, 'SP3 GDR', 'https://support.microsoft.com/en-us/help/5014355', '2022-06-14', '2021-07-13', '2026-07-14', 'SQL Server 2016', 'Service Pack 3 GDR'), (13, 6404, 'SP3 GDR', 'https://support.microsoft.com/en-us/help/5006943', '2021-10-27', '2021-07-13', '2026-07-14', 'SQL Server 2016', 'Service Pack 3 GDR'), (13, 6300, 'SP3 ', 'https://support.microsoft.com/en-us/help/5003279', '2021-09-15', '2021-07-13', '2026-07-14', 'SQL Server 2016', 'Service Pack 3'), @@ -41400,6 +41566,7 @@ VALUES (13, 2164, 'RTM CU2', 'https://support.microsoft.com/en-us/help/3182270 ', '2016-09-22', '2018-01-09', '2018-01-09', 'SQL Server 2016', 'RTM Cumulative Update 2'), (13, 2149, 'RTM CU1', 'https://support.microsoft.com/en-us/help/3164674 ', '2016-07-25', '2018-01-09', '2018-01-09', 'SQL Server 2016', 'RTM Cumulative Update 1'), (13, 1601, 'RTM ', '', '2016-06-01', '2019-01-09', '2019-01-09', 'SQL Server 2016', 'RTM '), + (12, 6444, 'SP3 CU4 GDR', 'https://support.microsoft.com/kb/5021045', '2023-02-14', '2019-07-09', '2024-07-09', 'SQL Server 2014', 'Service Pack 3 Cumulative Update 4 GDR'), (12, 6439, 'SP3 CU4 GDR', 'https://support.microsoft.com/en-us/help/5014164', '2022-06-14', '2019-07-09', '2024-07-09', 'SQL Server 2014', 'Service Pack 3 Cumulative Update 4 GDR'), (12, 6433, 'SP3 CU4 GDR', 'https://support.microsoft.com/en-us/help/4583462', '2021-01-12', '2019-07-09', '2024-07-09', 'SQL Server 2014', 'Service Pack 3 Cumulative Update 4 GDR'), (12, 6372, 'SP3 CU4 GDR', 'https://support.microsoft.com/en-us/help/4535288', '2020-02-11', '2019-07-09', '2024-07-09', 'SQL Server 2014', 'Service Pack 3 Cumulative Update 4 GDR'), @@ -41706,7 +41873,7 @@ SET NOCOUNT ON; SET STATISTICS XML OFF; SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED; -SELECT @Version = '8.12', @VersionDate = '20221213'; +SELECT @Version = '8.13', @VersionDate = '20230215'; IF(@VersionCheckMode = 1) BEGIN @@ -41746,7 +41913,7 @@ https://github.com/BrentOzarULTD/SQL-Server-First-Responder-Kit/ MIT License -Copyright (c) 2021 Brent Ozar Unlimited +Copyright (c) Brent Ozar Unlimited Permission is hereby granted, free of charge, to any person obtaining a copy of this software and associated documentation files (the "Software"), to deal @@ -43953,8 +44120,9 @@ If one of them is a lead blocker, consider killing that query.'' AS HowToStopit, CROSS APPLY sys.dm_exec_query_plan(r.plan_handle) AS qp '; IF EXISTS (SELECT * FROM sys.all_objects WHERE name = 'dm_exec_query_statistics_xml') - SET @StringToExecute = @StringToExecute + N' OUTER APPLY sys.dm_exec_query_statistics_xml(s.session_id) qs_live '; - + /* GitHub #3210 */ + SET @StringToExecute = N' + SET LOCK_TIMEOUT 1000 ' + @StringToExecute + N' OUTER APPLY sys.dm_exec_query_statistics_xml(s.session_id) qs_live '; SET @StringToExecute = @StringToExecute + N'; diff --git a/Install-Core-Blitz-No-Query-Store.sql b/Install-Core-Blitz-No-Query-Store.sql index 9529b2a4..448bde00 100644 --- a/Install-Core-Blitz-No-Query-Store.sql +++ b/Install-Core-Blitz-No-Query-Store.sql @@ -38,7 +38,7 @@ AS SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED; - SELECT @Version = '8.12', @VersionDate = '20221213'; + SELECT @Version = '8.13', @VersionDate = '20230215'; SET @OutputType = UPPER(@OutputType); IF(@VersionCheckMode = 1) @@ -93,9 +93,9 @@ AS tigertoolbox and are provided under the MIT license: https://github.com/Microsoft/tigertoolbox - All other copyrights for sp_Blitz are held by Brent Ozar Unlimited, 2021. + All other copyrights for sp_Blitz are held by Brent Ozar Unlimited. - Copyright (c) 2021 Brent Ozar Unlimited + Copyright (c) Brent Ozar Unlimited Permission is hereby granted, free of charge, to any person obtaining a copy of this software and associated documentation files (the "Software"), to deal @@ -9737,7 +9737,7 @@ AS SET NOCOUNT ON; SET STATISTICS XML OFF; -SELECT @Version = '8.12', @VersionDate = '20221213'; +SELECT @Version = '8.13', @VersionDate = '20230215'; IF(@VersionCheckMode = 1) BEGIN @@ -10615,7 +10615,7 @@ AS SET STATISTICS XML OFF; SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED; - SELECT @Version = '8.12', @VersionDate = '20221213'; + SELECT @Version = '8.13', @VersionDate = '20230215'; IF(@VersionCheckMode = 1) BEGIN @@ -10662,7 +10662,7 @@ AS MIT License - Copyright (c) 2021 Brent Ozar Unlimited + Copyright (c) Brent Ozar Unlimited Permission is hereby granted, free of charge, to any person obtaining a copy of this software and associated documentation files (the "Software"), to deal @@ -12349,7 +12349,8 @@ CREATE TABLE ##BlitzCacheProcs ( cached_execution_parameters XML, missing_indexes XML, SetOptions VARCHAR(MAX), - Warnings VARCHAR(MAX) + Warnings VARCHAR(MAX), + Pattern NVARCHAR(20) ); GO @@ -12396,7 +12397,7 @@ SET NOCOUNT ON; SET STATISTICS XML OFF; SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED; -SELECT @Version = '8.12', @VersionDate = '20221213'; +SELECT @Version = '8.13', @VersionDate = '20230215'; SET @OutputType = UPPER(@OutputType); IF(@VersionCheckMode = 1) @@ -12420,7 +12421,6 @@ IF @Help = 1 the findings, contribute your own code, and more. Known limitations of this version: - - This query will not run on SQL Server 2005. - SQL Server 2008 and 2008R2 have a bug in trigger stats, so that output is excluded by default. - @IgnoreQueryHashes and @OnlyQueryHashes require a CSV list of hashes @@ -12436,7 +12436,7 @@ IF @Help = 1 MIT License - Copyright (c) 2021 Brent Ozar Unlimited + Copyright (c) Brent Ozar Unlimited Permission is hereby granted, free of charge, to any person obtaining a copy of this software and associated documentation files (the "Software"), to deal @@ -13172,7 +13172,8 @@ BEGIN cached_execution_parameters XML, missing_indexes XML, SetOptions VARCHAR(MAX), - Warnings VARCHAR(MAX) + Warnings VARCHAR(MAX), + Pattern NVARCHAR(20) ); END; @@ -13273,18 +13274,18 @@ IF @SkipAnalysis = 1 DECLARE @AllSortSql NVARCHAR(MAX) = N''; DECLARE @VersionShowsMemoryGrants BIT; -IF EXISTS(SELECT * FROM sys.all_columns WHERE OBJECT_ID = OBJECT_ID('sys.dm_exec_query_stats') AND name = 'max_grant_kb') +IF EXISTS(SELECT * FROM sys.all_columns WHERE object_id = OBJECT_ID('sys.dm_exec_query_stats') AND name = 'max_grant_kb') SET @VersionShowsMemoryGrants = 1; ELSE SET @VersionShowsMemoryGrants = 0; DECLARE @VersionShowsSpills BIT; -IF EXISTS(SELECT * FROM sys.all_columns WHERE OBJECT_ID = OBJECT_ID('sys.dm_exec_query_stats') AND name = 'max_spills') +IF EXISTS(SELECT * FROM sys.all_columns WHERE object_id = OBJECT_ID('sys.dm_exec_query_stats') AND name = 'max_spills') SET @VersionShowsSpills = 1; ELSE SET @VersionShowsSpills = 0; -IF EXISTS(SELECT * FROM sys.all_columns WHERE OBJECT_ID = OBJECT_ID('sys.dm_exec_query_plan_stats') AND name = 'query_plan') +IF EXISTS(SELECT * FROM sys.all_columns WHERE object_id = OBJECT_ID('sys.dm_exec_query_plan_stats') AND name = 'query_plan') SET @VersionShowsAirQuoteActualPlans = 1; ELSE SET @VersionShowsAirQuoteActualPlans = 0; @@ -14091,7 +14092,7 @@ INSERT INTO ##BlitzCacheProcs (SPID, QueryType, DatabaseName, AverageCPU, TotalC LastReturnedRows, MinGrantKB, MaxGrantKB, MinUsedGrantKB, MaxUsedGrantKB, PercentMemoryGrantUsed, AvgMaxMemoryGrant, MinSpills, MaxSpills, TotalSpills, AvgSpills, QueryText, QueryPlan, TotalWorkerTimeForType, TotalElapsedTimeForType, TotalReadsForType, TotalExecutionCountForType, TotalWritesForType, SqlHandle, PlanHandle, QueryHash, QueryPlanHash, - min_worker_time, max_worker_time, is_parallel, min_elapsed_time, max_elapsed_time, age_minutes, age_minutes_lifetime) ' ; + min_worker_time, max_worker_time, is_parallel, min_elapsed_time, max_elapsed_time, age_minutes, age_minutes_lifetime, Pattern) ' ; SET @body += N' FROM (SELECT TOP (@Top) x.*, xpa.*, @@ -14355,7 +14356,8 @@ SELECT TOP (@Top) qs.min_elapsed_time / 1000.0, qs.max_elapsed_time / 1000.0, age_minutes, - age_minutes_lifetime '; + age_minutes_lifetime, + @SortOrder '; IF LEFT(@QueryFilter, 3) IN ('all', 'sta') @@ -14503,7 +14505,8 @@ BEGIN qs.min_elapsed_time / 1000.0, qs.max_worker_time / 1000.0, age_minutes, - age_minutes_lifetime '; + age_minutes_lifetime, + @SortOrder '; SET @sql += REPLACE(REPLACE(@body, '#view#', 'dm_exec_query_stats'), 'cached_time', 'creation_time') ; @@ -14738,7 +14741,7 @@ IF @Reanalyze = 0 BEGIN RAISERROR('Collecting execution plan information.', 0, 1) WITH NOWAIT; - EXEC sp_executesql @sql, N'@Top INT, @min_duration INT, @min_back INT', @Top, @DurationFilter_i, @MinutesBack; + EXEC sp_executesql @sql, N'@Top INT, @min_duration INT, @min_back INT, @SortOrder NVARCHAR(20)', @Top, @DurationFilter_i, @MinutesBack, @SortOrder; END; IF @SkipAnalysis = 1 @@ -19231,6 +19234,7 @@ ELSE TotalSpills BIGINT, AvgSpills MONEY, QueryPlanCost FLOAT, + Pattern NVARCHAR(20), JoinKey AS ServerName + Cast(CheckDate AS NVARCHAR(50)), CONSTRAINT [PK_' + REPLACE(REPLACE(@OutputTableName,N'[',N''),N']',N'') + N'] PRIMARY KEY CLUSTERED(ID ASC));' ); @@ -19332,6 +19336,22 @@ END '; EXEC(@StringToExecute); END; + /* If the table doesn't have the new Pattern column, add it */ + SET @ObjectFullName = @OutputDatabaseName + N'.' + @OutputSchemaName + N'.' + @OutputTableName; + SET @StringToExecute = N'IF NOT EXISTS (SELECT * FROM ' + @OutputDatabaseName + N'.sys.all_columns + WHERE object_id = (OBJECT_ID(''' + @ObjectFullName + N''')) AND name = ''Pattern'') + ALTER TABLE ' + @ObjectFullName + N' ADD Pattern NVARCHAR(20) NULL;'; + IF @ValidOutputServer = 1 + BEGIN + SET @StringToExecute = REPLACE(@StringToExecute,'''Pattern''','''''Pattern'''''); + SET @StringToExecute = REPLACE(@StringToExecute,'''' + @ObjectFullName + '''','''''' + @ObjectFullName + ''''''); + EXEC('EXEC('''+@StringToExecute+''') AT ' + @OutputServerName); + END; + ELSE + BEGIN + EXEC(@StringToExecute); + END + IF @CheckDateOverride IS NULL BEGIN SET @CheckDateOverride = SYSDATETIMEOFFSET(); @@ -19351,14 +19371,14 @@ END '; + ' (ServerName, CheckDate, Version, QueryType, DatabaseName, AverageCPU, TotalCPU, PercentCPUByType, CPUWeight, AverageDuration, TotalDuration, DurationWeight, PercentDurationByType, AverageReads, TotalReads, ReadWeight, PercentReadsByType, ' + ' AverageWrites, TotalWrites, WriteWeight, PercentWritesByType, ExecutionCount, ExecutionWeight, PercentExecutionsByType, ' + ' ExecutionsPerMinute, PlanCreationTime, LastExecutionTime, LastCompletionTime, PlanHandle, SqlHandle, QueryHash, QueryPlanHash, StatementStartOffset, StatementEndOffset, PlanGenerationNum, MinReturnedRows, MaxReturnedRows, AverageReturnedRows, TotalReturnedRows, QueryText, QueryPlan, NumberOfPlans, NumberOfDistinctPlans, Warnings, ' - + ' SerialRequiredMemory, SerialDesiredMemory, MinGrantKB, MaxGrantKB, MinUsedGrantKB, MaxUsedGrantKB, PercentMemoryGrantUsed, AvgMaxMemoryGrant, MinSpills, MaxSpills, TotalSpills, AvgSpills, QueryPlanCost ) ' + + ' SerialRequiredMemory, SerialDesiredMemory, MinGrantKB, MaxGrantKB, MinUsedGrantKB, MaxUsedGrantKB, PercentMemoryGrantUsed, AvgMaxMemoryGrant, MinSpills, MaxSpills, TotalSpills, AvgSpills, QueryPlanCost, Pattern ) ' + 'SELECT TOP (@Top) ' + QUOTENAME(CAST(SERVERPROPERTY('ServerName') AS NVARCHAR(128)), '''') + ', @CheckDateOverride, ' + QUOTENAME(CAST(SERVERPROPERTY('ProductVersion') AS NVARCHAR(128)), '''') + ', ' + ' QueryType, DatabaseName, AverageCPU, TotalCPU, PercentCPUByType, PercentCPU, AverageDuration, TotalDuration, PercentDuration, PercentDurationByType, AverageReads, TotalReads, PercentReads, PercentReadsByType, ' + ' AverageWrites, TotalWrites, PercentWrites, PercentWritesByType, ExecutionCount, PercentExecutions, PercentExecutionsByType, ' + ' ExecutionsPerMinute, PlanCreationTime, LastExecutionTime, LastCompletionTime, PlanHandle, SqlHandle, QueryHash, QueryPlanHash, StatementStartOffset, StatementEndOffset, PlanGenerationNum, MinReturnedRows, MaxReturnedRows, AverageReturnedRows, TotalReturnedRows, QueryText, CAST(QueryPlan AS NVARCHAR(MAX)), NumberOfPlans, NumberOfDistinctPlans, Warnings, ' - + ' SerialRequiredMemory, SerialDesiredMemory, MinGrantKB, MaxGrantKB, MinUsedGrantKB, MaxUsedGrantKB, PercentMemoryGrantUsed, AvgMaxMemoryGrant, MinSpills, MaxSpills, TotalSpills, AvgSpills, QueryPlanCost ' + + ' SerialRequiredMemory, SerialDesiredMemory, MinGrantKB, MaxGrantKB, MinUsedGrantKB, MaxUsedGrantKB, PercentMemoryGrantUsed, AvgMaxMemoryGrant, MinSpills, MaxSpills, TotalSpills, AvgSpills, QueryPlanCost, Pattern ' + ' FROM ##BlitzCacheProcs ' + ' WHERE 1=1 '; @@ -19419,14 +19439,14 @@ END '; + ' (ServerName, CheckDate, Version, QueryType, DatabaseName, AverageCPU, TotalCPU, PercentCPUByType, CPUWeight, AverageDuration, TotalDuration, DurationWeight, PercentDurationByType, AverageReads, TotalReads, ReadWeight, PercentReadsByType, ' + ' AverageWrites, TotalWrites, WriteWeight, PercentWritesByType, ExecutionCount, ExecutionWeight, PercentExecutionsByType, ' + ' ExecutionsPerMinute, PlanCreationTime, LastExecutionTime, LastCompletionTime, PlanHandle, SqlHandle, QueryHash, QueryPlanHash, StatementStartOffset, StatementEndOffset, PlanGenerationNum, MinReturnedRows, MaxReturnedRows, AverageReturnedRows, TotalReturnedRows, QueryText, QueryPlan, NumberOfPlans, NumberOfDistinctPlans, Warnings, ' - + ' SerialRequiredMemory, SerialDesiredMemory, MinGrantKB, MaxGrantKB, MinUsedGrantKB, MaxUsedGrantKB, PercentMemoryGrantUsed, AvgMaxMemoryGrant, MinSpills, MaxSpills, TotalSpills, AvgSpills, QueryPlanCost ) ' + + ' SerialRequiredMemory, SerialDesiredMemory, MinGrantKB, MaxGrantKB, MinUsedGrantKB, MaxUsedGrantKB, PercentMemoryGrantUsed, AvgMaxMemoryGrant, MinSpills, MaxSpills, TotalSpills, AvgSpills, QueryPlanCost, Pattern ) ' + 'SELECT TOP (@Top) ' + QUOTENAME(CAST(SERVERPROPERTY('ServerName') AS NVARCHAR(128)), '''') + ', @CheckDateOverride, ' + QUOTENAME(CAST(SERVERPROPERTY('ProductVersion') AS NVARCHAR(128)), '''') + ', ' + ' QueryType, DatabaseName, AverageCPU, TotalCPU, PercentCPUByType, PercentCPU, AverageDuration, TotalDuration, PercentDuration, PercentDurationByType, AverageReads, TotalReads, PercentReads, PercentReadsByType, ' + ' AverageWrites, TotalWrites, PercentWrites, PercentWritesByType, ExecutionCount, PercentExecutions, PercentExecutionsByType, ' + ' ExecutionsPerMinute, PlanCreationTime, LastExecutionTime, LastCompletionTime, PlanHandle, SqlHandle, QueryHash, QueryPlanHash, StatementStartOffset, StatementEndOffset, PlanGenerationNum, MinReturnedRows, MaxReturnedRows, AverageReturnedRows, TotalReturnedRows, QueryText, QueryPlan, NumberOfPlans, NumberOfDistinctPlans, Warnings, ' - + ' SerialRequiredMemory, SerialDesiredMemory, MinGrantKB, MaxGrantKB, MinUsedGrantKB, MaxUsedGrantKB, PercentMemoryGrantUsed, AvgMaxMemoryGrant, MinSpills, MaxSpills, TotalSpills, AvgSpills, QueryPlanCost ' + + ' SerialRequiredMemory, SerialDesiredMemory, MinGrantKB, MaxGrantKB, MinUsedGrantKB, MaxUsedGrantKB, PercentMemoryGrantUsed, AvgMaxMemoryGrant, MinSpills, MaxSpills, TotalSpills, AvgSpills, QueryPlanCost, Pattern ' + ' FROM ##BlitzCacheProcs ' + ' WHERE 1=1 '; @@ -19568,6 +19588,7 @@ END '; TotalSpills BIGINT, AvgSpills MONEY, QueryPlanCost FLOAT, + Pattern NVARCHAR(20), JoinKey AS ServerName + Cast(CheckDate AS NVARCHAR(50)), CONSTRAINT [PK_' + REPLACE(REPLACE(@OutputTableName,'[',''),']','') + '] PRIMARY KEY CLUSTERED(ID ASC));'; SET @StringToExecute += N' INSERT ' @@ -19575,14 +19596,14 @@ END '; + ' (ServerName, CheckDate, Version, QueryType, DatabaseName, AverageCPU, TotalCPU, PercentCPUByType, CPUWeight, AverageDuration, TotalDuration, DurationWeight, PercentDurationByType, AverageReads, TotalReads, ReadWeight, PercentReadsByType, ' + ' AverageWrites, TotalWrites, WriteWeight, PercentWritesByType, ExecutionCount, ExecutionWeight, PercentExecutionsByType, ' + ' ExecutionsPerMinute, PlanCreationTime, LastExecutionTime, LastCompletionTime, PlanHandle, SqlHandle, QueryHash, QueryPlanHash, StatementStartOffset, StatementEndOffset, PlanGenerationNum, MinReturnedRows, MaxReturnedRows, AverageReturnedRows, TotalReturnedRows, QueryText, QueryPlan, NumberOfPlans, NumberOfDistinctPlans, Warnings, ' - + ' SerialRequiredMemory, SerialDesiredMemory, MinGrantKB, MaxGrantKB, MinUsedGrantKB, MaxUsedGrantKB, PercentMemoryGrantUsed, AvgMaxMemoryGrant, MinSpills, MaxSpills, TotalSpills, AvgSpills, QueryPlanCost ) ' + + ' SerialRequiredMemory, SerialDesiredMemory, MinGrantKB, MaxGrantKB, MinUsedGrantKB, MaxUsedGrantKB, PercentMemoryGrantUsed, AvgMaxMemoryGrant, MinSpills, MaxSpills, TotalSpills, AvgSpills, QueryPlanCost, Pattern ) ' + 'SELECT TOP (@Top) ' + QUOTENAME(CAST(SERVERPROPERTY('ServerName') AS NVARCHAR(128)), '''') + ', @CheckDateOverride, ' + QUOTENAME(CAST(SERVERPROPERTY('ProductVersion') AS NVARCHAR(128)), '''') + ', ' + ' QueryType, DatabaseName, AverageCPU, TotalCPU, PercentCPUByType, PercentCPU, AverageDuration, TotalDuration, PercentDuration, PercentDurationByType, AverageReads, TotalReads, PercentReads, PercentReadsByType, ' + ' AverageWrites, TotalWrites, PercentWrites, PercentWritesByType, ExecutionCount, PercentExecutions, PercentExecutionsByType, ' + ' ExecutionsPerMinute, PlanCreationTime, LastExecutionTime, LastCompletionTime, PlanHandle, SqlHandle, QueryHash, QueryPlanHash, StatementStartOffset, StatementEndOffset, PlanGenerationNum, MinReturnedRows, MaxReturnedRows, AverageReturnedRows, TotalReturnedRows, QueryText, QueryPlan, NumberOfPlans, NumberOfDistinctPlans, Warnings, ' - + ' SerialRequiredMemory, SerialDesiredMemory, MinGrantKB, MaxGrantKB, MinUsedGrantKB, MaxUsedGrantKB, PercentMemoryGrantUsed, AvgMaxMemoryGrant, MinSpills, MaxSpills, TotalSpills, AvgSpills, QueryPlanCost ' + + ' SerialRequiredMemory, SerialDesiredMemory, MinGrantKB, MaxGrantKB, MinUsedGrantKB, MaxUsedGrantKB, PercentMemoryGrantUsed, AvgMaxMemoryGrant, MinSpills, MaxSpills, TotalSpills, AvgSpills, QueryPlanCost, Pattern ' + ' FROM ##BlitzCacheProcs ' + ' WHERE 1=1 '; @@ -19694,7 +19715,7 @@ SET NOCOUNT ON; SET STATISTICS XML OFF; SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED; -SELECT @Version = '8.12', @VersionDate = '20221213'; +SELECT @Version = '8.13', @VersionDate = '20230215'; SET @OutputType = UPPER(@OutputType); IF(@VersionCheckMode = 1) @@ -19731,7 +19752,7 @@ Unknown limitations of this version: MIT License -Copyright (c) 2021 Brent Ozar Unlimited +Copyright (c) Brent Ozar Unlimited Permission is hereby granted, free of charge, to any person obtaining a copy of this software and associated documentation files (the "Software"), to deal @@ -25871,7 +25892,7 @@ BEGIN SET NOCOUNT, XACT_ABORT ON; SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED; - SELECT @Version = '8.12', @VersionDate = '20221213'; + SELECT @Version = '8.13', @VersionDate = '20230215'; IF @VersionCheckMode = 1 BEGIN @@ -25932,7 +25953,7 @@ BEGIN MIT License - Copyright (c) 2022 Brent Ozar Unlimited + Copyright (c) Brent Ozar Unlimited Permission is hereby granted, free of charge, to any person obtaining a copy of this software and associated documentation files (the "Software"), to deal @@ -27005,7 +27026,7 @@ BEGIN waiter_mode = w.l.value('@mode', 'nvarchar(256)'), owner_id = o.l.value('@id', 'nvarchar(256)'), owner_mode = o.l.value('@mode', 'nvarchar(256)'), - lock_type = N'OBJECT' + lock_type = CAST(N'OBJECT' AS NVARCHAR(100)) INTO #deadlock_owner_waiter FROM ( @@ -27630,7 +27651,7 @@ BEGIN N'S', N'IS' ) - AND (dow.database_id = @DatabaseName OR @DatabaseName IS NULL) + AND (dow.database_id = @DatabaseId OR @DatabaseName IS NULL) AND (dow.event_date >= @StartDate OR @StartDate IS NULL) AND (dow.event_date < @EndDate OR @EndDate IS NULL) AND (dow.object_name = @ObjectName OR @ObjectName IS NULL) @@ -27673,7 +27694,7 @@ BEGIN N' deadlock(s).' FROM #deadlock_owner_waiter AS dow WHERE 1 = 1 - AND (dow.database_id = @DatabaseName OR @DatabaseName IS NULL) + AND (dow.database_id = @DatabaseId OR @DatabaseName IS NULL) AND (dow.event_date >= @StartDate OR @StartDate IS NULL) AND (dow.event_date < @EndDate OR @EndDate IS NULL) AND (dow.object_name = @ObjectName OR @ObjectName IS NULL) @@ -27712,7 +27733,7 @@ BEGIN N' deadlock(s).' FROM #deadlock_owner_waiter AS dow WHERE 1 = 1 - AND (dow.database_id = @DatabaseName OR @DatabaseName IS NULL) + AND (dow.database_id = @DatabaseId OR @DatabaseName IS NULL) AND (dow.event_date >= @StartDate OR @StartDate IS NULL) AND (dow.event_date < @EndDate OR @EndDate IS NULL) AND (dow.object_name = @ObjectName OR @ObjectName IS NULL) @@ -27757,7 +27778,7 @@ BEGIN N' deadlock(s).' FROM #deadlock_owner_waiter AS dow WHERE 1 = 1 - AND (dow.database_id = @DatabaseName OR @DatabaseName IS NULL) + AND (dow.database_id = @DatabaseId OR @DatabaseName IS NULL) AND (dow.event_date >= @StartDate OR @StartDate IS NULL) AND (dow.event_date < @EndDate OR @EndDate IS NULL) AND (dow.object_name = @ObjectName OR @ObjectName IS NULL) @@ -28083,7 +28104,7 @@ BEGIN ON dow.owner_id = ds.id AND dow.event_date = ds.event_date WHERE 1 = 1 - AND (dow.database_id = @DatabaseName OR @DatabaseName IS NULL) + AND (dow.database_id = @DatabaseId OR @DatabaseName IS NULL) AND (dow.event_date >= @StartDate OR @StartDate IS NULL) AND (dow.event_date < @EndDate OR @EndDate IS NULL) AND (dow.object_name = @StoredProcName OR @StoredProcName IS NULL) @@ -28139,7 +28160,7 @@ BEGIN ON dow.owner_id = ds.id AND dow.event_date = ds.event_date WHERE ds.proc_name <> N'adhoc' - AND (dow.database_id = @DatabaseName OR @DatabaseName IS NULL) + AND (dow.database_id = @DatabaseId OR @DatabaseName IS NULL) AND (dow.event_date >= @StartDate OR @StartDate IS NULL) AND (dow.event_date < @EndDate OR @EndDate IS NULL) AND (dow.object_name = @StoredProcName OR @StoredProcName IS NULL) @@ -28215,7 +28236,7 @@ BEGIN ON s.database_id = dow.database_id AND s.partition_id = dow.associatedObjectId WHERE 1 = 1 - AND (dow.database_id = @DatabaseName OR @DatabaseName IS NULL) + AND (dow.database_id = @DatabaseId OR @DatabaseName IS NULL) AND (dow.event_date >= @StartDate OR @StartDate IS NULL) AND (dow.event_date < @EndDate OR @EndDate IS NULL) AND (dow.object_name = @ObjectName OR @ObjectName IS NULL) @@ -28277,6 +28298,76 @@ BEGIN ) ), wait_time_hms = + /*the more wait time you rack up the less accurate this gets, + it's either that or erroring out*/ + CASE + WHEN + SUM + ( + CONVERT + ( + bigint, + dp.wait_time + ) + )/1000 > 2147483647 + THEN + CONVERT + ( + nvarchar(30), + DATEADD + ( + MINUTE, + ( + ( + SUM + ( + CONVERT + ( + bigint, + dp.wait_time + ) + ) + )/ + 60000 + ), + 0 + ), + 14 + ) + WHEN + SUM + ( + CONVERT + ( + bigint, + dp.wait_time + ) + ) BETWEEN 2147483648 AND 2147483647000 + THEN + CONVERT + ( + nvarchar(30), + DATEADD + ( + SECOND, + ( + ( + SUM + ( + CONVERT + ( + bigint, + dp.wait_time + ) + ) + )/ + 1000 + ), + 0 + ), + 14 + ) + ELSE CONVERT ( nvarchar(30), @@ -28297,6 +28388,7 @@ BEGIN ), 14 ) + END FROM #deadlock_owner_waiter AS dow JOIN #deadlock_process AS dp ON (dp.id = dow.owner_id @@ -28413,6 +28505,76 @@ BEGIN ) ) + N' ' + + /*the more wait time you rack up the less accurate this gets, + it's either that or erroring out*/ + CASE + WHEN + SUM + ( + CONVERT + ( + bigint, + wt.total_wait_time_ms + ) + )/1000 > 2147483647 + THEN + CONVERT + ( + nvarchar(30), + DATEADD + ( + MINUTE, + ( + ( + SUM + ( + CONVERT + ( + bigint, + wt.total_wait_time_ms + ) + ) + )/ + 60000 + ), + 0 + ), + 14 + ) + WHEN + SUM + ( + CONVERT + ( + bigint, + wt.total_wait_time_ms + ) + ) BETWEEN 2147483648 AND 2147483647000 + THEN + CONVERT + ( + nvarchar(30), + DATEADD + ( + SECOND, + ( + ( + SUM + ( + CONVERT + ( + bigint, + wt.total_wait_time_ms + ) + ) + )/ + 1000 + ), + 0 + ), + 14 + ) + ELSE CONVERT ( nvarchar(30), @@ -28432,7 +28594,7 @@ BEGIN 0 ), 14 - ) + + ) END + N' [dd hh:mm:ss:ms] of deadlock wait time.' FROM wait_time AS wt GROUP BY @@ -29354,7 +29516,7 @@ BEGIN SET STATISTICS XML OFF; SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED; - SELECT @Version = '8.12', @VersionDate = '20221213'; + SELECT @Version = '8.13', @VersionDate = '20230215'; IF(@VersionCheckMode = 1) BEGIN @@ -29382,7 +29544,7 @@ Known limitations of this version: MIT License -Copyright (c) 2021 Brent Ozar Unlimited +Copyright (c) Brent Ozar Unlimited Permission is hereby granted, free of charge, to any person obtaining a copy of this software and associated documentation files (the "Software"), to deal @@ -30011,11 +30173,11 @@ BEGIN END AS blocking_session_id, COALESCE(DB_NAME(r.database_id), DB_NAME(blocked.dbid), ''N/A'') AS database_name, ISNULL(SUBSTRING(dest.text, - ( query_stats.statement_start_offset / 2 ) + 1, - ( ( CASE query_stats.statement_end_offset + ( r.statement_start_offset / 2 ) + 1, + ( ( CASE r.statement_end_offset WHEN -1 THEN DATALENGTH(dest.text) - ELSE query_stats.statement_end_offset - END - query_stats.statement_start_offset ) + ELSE r.statement_end_offset + END - r.statement_start_offset ) / 2 ) + 1), dest.text) AS query_text , '+CASE WHEN @GetOuterCommand = 1 THEN N'CAST(event_info AS NVARCHAR(4000)) AS outer_command,' @@ -30180,7 +30342,7 @@ BEGIN OUTER APPLY sys.dm_exec_sql_text(COALESCE(r.sql_handle, blocked.sql_handle)) AS dest OUTER APPLY sys.dm_exec_query_plan(r.plan_handle) AS derp OUTER APPLY ( - SELECT CONVERT(DECIMAL(38,2), SUM( (((tsu.user_objects_alloc_page_count - user_objects_dealloc_page_count) * 8) / 1024.)) ) AS tempdb_allocations_mb + SELECT CONVERT(DECIMAL(38,2), SUM( ((((tsu.user_objects_alloc_page_count - user_objects_dealloc_page_count) + (tsu.internal_objects_alloc_page_count - internal_objects_dealloc_page_count)) * 8) / 1024.)) ) AS tempdb_allocations_mb FROM sys.dm_db_task_space_usage tsu WHERE tsu.request_id = r.request_id AND tsu.session_id = r.session_id @@ -30229,11 +30391,11 @@ IF @ProductVersionMajor >= 11 END AS blocking_session_id, COALESCE(DB_NAME(r.database_id), DB_NAME(blocked.dbid), ''N/A'') AS database_name, ISNULL(SUBSTRING(dest.text, - ( query_stats.statement_start_offset / 2 ) + 1, - ( ( CASE query_stats.statement_end_offset + ( r.statement_start_offset / 2 ) + 1, + ( ( CASE r.statement_end_offset WHEN -1 THEN DATALENGTH(dest.text) - ELSE query_stats.statement_end_offset - END - query_stats.statement_start_offset ) + ELSE r.statement_end_offset + END - r.statement_start_offset ) / 2 ) + 1), dest.text) AS query_text , '+CASE WHEN @GetOuterCommand = 1 THEN N'CAST(event_info AS NVARCHAR(4000)) AS outer_command,' @@ -30473,7 +30635,7 @@ IF @ProductVersionMajor >= 11 OUTER APPLY sys.dm_exec_sql_text(COALESCE(r.sql_handle, blocked.sql_handle)) AS dest OUTER APPLY sys.dm_exec_query_plan(r.plan_handle) AS derp OUTER APPLY ( - SELECT CONVERT(DECIMAL(38,2), SUM( (((tsu.user_objects_alloc_page_count - user_objects_dealloc_page_count) * 8) / 1024.)) ) AS tempdb_allocations_mb + SELECT CONVERT(DECIMAL(38,2), SUM( ((((tsu.user_objects_alloc_page_count - user_objects_dealloc_page_count) + (tsu.internal_objects_alloc_page_count - internal_objects_dealloc_page_count)) * 8) / 1024.)) ) AS tempdb_allocations_mb FROM sys.dm_db_task_space_usage tsu WHERE tsu.request_id = r.request_id AND tsu.session_id = r.session_id @@ -30750,7 +30912,9 @@ DELETE FROM dbo.SqlServerVersions; INSERT INTO dbo.SqlServerVersions (MajorVersionNumber, MinorVersionNumber, Branch, [Url], ReleaseDate, MainstreamSupportEndDate, ExtendedSupportEndDate, MajorVersionName, MinorVersionName) VALUES + (16, 1050, 'RTM GDR', 'https://support.microsoft.com/kb/5021522', '2023-02-14', '2028-01-11', '2033-01-11', 'SQL Server 2022 GDR', 'RTM'), (16, 1000, 'RTM', '', '2022-11-15', '2028-01-11', '2033-01-11', 'SQL Server 2022', 'RTM'), + (15, 4280, 'CU18 GDR', 'https://support.microsoft.com/kb/5021124', '2023-02-14', '2025-01-07', '2030-01-08', 'SQL Server 2019', 'Cumulative Update 18 GDR'), (15, 4261, 'CU18', 'https://support.microsoft.com/en-us/help/5017593', '2022-09-28', '2025-01-07', '2030-01-08', 'SQL Server 2019', 'Cumulative Update 18'), (15, 4249, 'CU17', 'https://support.microsoft.com/en-us/help/5016394', '2022-08-11', '2025-01-07', '2030-01-08', 'SQL Server 2019', 'Cumulative Update 17'), (15, 4236, 'CU16 GDR', 'https://support.microsoft.com/en-us/help/5014353', '2022-06-14', '2025-01-07', '2030-01-08', 'SQL Server 2019', 'Cumulative Update 16 GDR'), @@ -30773,6 +30937,7 @@ VALUES (15, 4003, 'CU1', 'https://support.microsoft.com/en-us/help/4527376', '2020-01-07', '2025-01-07', '2030-01-08', 'SQL Server 2019', 'Cumulative Update 1 '), (15, 2070, 'GDR', 'https://support.microsoft.com/en-us/help/4517790', '2019-11-04', '2025-01-07', '2030-01-08', 'SQL Server 2019', 'RTM GDR '), (15, 2000, 'RTM ', '', '2019-11-04', '2025-01-07', '2030-01-08', 'SQL Server 2019', 'RTM '), + (14, 3460, 'RTM CU31 GDR', 'https://support.microsoft.com/kb/5021126', '2023-02-14', '2022-10-11', '2027-10-12', 'SQL Server 2017', 'RTM Cumulative Update 31 GDR'), (14, 3456, 'RTM CU31', 'https://support.microsoft.com/en-us/help/5016884', '2022-09-20', '2022-10-11', '2027-10-12', 'SQL Server 2017', 'RTM Cumulative Update 31'), (14, 3451, 'RTM CU30', 'https://support.microsoft.com/en-us/help/5013756', '2022-07-13', '2022-10-11', '2027-10-12', 'SQL Server 2017', 'RTM Cumulative Update 30'), (14, 3445, 'RTM CU29 GDR', 'https://support.microsoft.com/en-us/help/5014553', '2022-06-14', '2022-10-11', '2027-10-12', 'SQL Server 2017', 'RTM Cumulative Update 29 GDR'), @@ -30809,6 +30974,7 @@ VALUES (14, 1000, 'RTM ', '', '2017-10-02', '2022-10-11', '2027-10-12', 'SQL Server 2017', 'RTM '), (13, 7016, 'SP3 Azure Feature Pack GDR', 'https://support.microsoft.com/en-us/help/5015371', '2022-06-14', '2021-07-13', '2026-07-14', 'SQL Server 2016', 'Service Pack 3 Azure Feature Pack GDR'), (13, 7000, 'SP3 Azure Feature Pack', 'https://support.microsoft.com/en-us/help/5014242', '2022-05-19', '2021-07-13', '2026-07-14', 'SQL Server 2016', 'Service Pack 3 Azure Feature Pack'), + (13, 6430, 'SP3 GDR', 'https://support.microsoft.com/kb/5021129', '2023-02-14', '2021-07-13', '2026-07-14', 'SQL Server 2016', 'Service Pack 3 GDR'), (13, 6419, 'SP3 GDR', 'https://support.microsoft.com/en-us/help/5014355', '2022-06-14', '2021-07-13', '2026-07-14', 'SQL Server 2016', 'Service Pack 3 GDR'), (13, 6404, 'SP3 GDR', 'https://support.microsoft.com/en-us/help/5006943', '2021-10-27', '2021-07-13', '2026-07-14', 'SQL Server 2016', 'Service Pack 3 GDR'), (13, 6300, 'SP3 ', 'https://support.microsoft.com/en-us/help/5003279', '2021-09-15', '2021-07-13', '2026-07-14', 'SQL Server 2016', 'Service Pack 3'), @@ -30860,6 +31026,7 @@ VALUES (13, 2164, 'RTM CU2', 'https://support.microsoft.com/en-us/help/3182270 ', '2016-09-22', '2018-01-09', '2018-01-09', 'SQL Server 2016', 'RTM Cumulative Update 2'), (13, 2149, 'RTM CU1', 'https://support.microsoft.com/en-us/help/3164674 ', '2016-07-25', '2018-01-09', '2018-01-09', 'SQL Server 2016', 'RTM Cumulative Update 1'), (13, 1601, 'RTM ', '', '2016-06-01', '2019-01-09', '2019-01-09', 'SQL Server 2016', 'RTM '), + (12, 6444, 'SP3 CU4 GDR', 'https://support.microsoft.com/kb/5021045', '2023-02-14', '2019-07-09', '2024-07-09', 'SQL Server 2014', 'Service Pack 3 Cumulative Update 4 GDR'), (12, 6439, 'SP3 CU4 GDR', 'https://support.microsoft.com/en-us/help/5014164', '2022-06-14', '2019-07-09', '2024-07-09', 'SQL Server 2014', 'Service Pack 3 Cumulative Update 4 GDR'), (12, 6433, 'SP3 CU4 GDR', 'https://support.microsoft.com/en-us/help/4583462', '2021-01-12', '2019-07-09', '2024-07-09', 'SQL Server 2014', 'Service Pack 3 Cumulative Update 4 GDR'), (12, 6372, 'SP3 CU4 GDR', 'https://support.microsoft.com/en-us/help/4535288', '2020-02-11', '2019-07-09', '2024-07-09', 'SQL Server 2014', 'Service Pack 3 Cumulative Update 4 GDR'), @@ -31166,7 +31333,7 @@ SET NOCOUNT ON; SET STATISTICS XML OFF; SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED; -SELECT @Version = '8.12', @VersionDate = '20221213'; +SELECT @Version = '8.13', @VersionDate = '20230215'; IF(@VersionCheckMode = 1) BEGIN @@ -31206,7 +31373,7 @@ https://github.com/BrentOzarULTD/SQL-Server-First-Responder-Kit/ MIT License -Copyright (c) 2021 Brent Ozar Unlimited +Copyright (c) Brent Ozar Unlimited Permission is hereby granted, free of charge, to any person obtaining a copy of this software and associated documentation files (the "Software"), to deal @@ -33413,8 +33580,9 @@ If one of them is a lead blocker, consider killing that query.'' AS HowToStopit, CROSS APPLY sys.dm_exec_query_plan(r.plan_handle) AS qp '; IF EXISTS (SELECT * FROM sys.all_objects WHERE name = 'dm_exec_query_statistics_xml') - SET @StringToExecute = @StringToExecute + N' OUTER APPLY sys.dm_exec_query_statistics_xml(s.session_id) qs_live '; - + /* GitHub #3210 */ + SET @StringToExecute = N' + SET LOCK_TIMEOUT 1000 ' + @StringToExecute + N' OUTER APPLY sys.dm_exec_query_statistics_xml(s.session_id) qs_live '; SET @StringToExecute = @StringToExecute + N'; diff --git a/Install-Core-Blitz-With-Query-Store.sql b/Install-Core-Blitz-With-Query-Store.sql index 84ff5684..03b39864 100644 --- a/Install-Core-Blitz-With-Query-Store.sql +++ b/Install-Core-Blitz-With-Query-Store.sql @@ -38,7 +38,7 @@ AS SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED; - SELECT @Version = '8.12', @VersionDate = '20221213'; + SELECT @Version = '8.13', @VersionDate = '20230215'; SET @OutputType = UPPER(@OutputType); IF(@VersionCheckMode = 1) @@ -93,9 +93,9 @@ AS tigertoolbox and are provided under the MIT license: https://github.com/Microsoft/tigertoolbox - All other copyrights for sp_Blitz are held by Brent Ozar Unlimited, 2021. + All other copyrights for sp_Blitz are held by Brent Ozar Unlimited. - Copyright (c) 2021 Brent Ozar Unlimited + Copyright (c) Brent Ozar Unlimited Permission is hereby granted, free of charge, to any person obtaining a copy of this software and associated documentation files (the "Software"), to deal @@ -9737,7 +9737,7 @@ AS SET NOCOUNT ON; SET STATISTICS XML OFF; -SELECT @Version = '8.12', @VersionDate = '20221213'; +SELECT @Version = '8.13', @VersionDate = '20230215'; IF(@VersionCheckMode = 1) BEGIN @@ -10615,7 +10615,7 @@ AS SET STATISTICS XML OFF; SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED; - SELECT @Version = '8.12', @VersionDate = '20221213'; + SELECT @Version = '8.13', @VersionDate = '20230215'; IF(@VersionCheckMode = 1) BEGIN @@ -10662,7 +10662,7 @@ AS MIT License - Copyright (c) 2021 Brent Ozar Unlimited + Copyright (c) Brent Ozar Unlimited Permission is hereby granted, free of charge, to any person obtaining a copy of this software and associated documentation files (the "Software"), to deal @@ -12349,7 +12349,8 @@ CREATE TABLE ##BlitzCacheProcs ( cached_execution_parameters XML, missing_indexes XML, SetOptions VARCHAR(MAX), - Warnings VARCHAR(MAX) + Warnings VARCHAR(MAX), + Pattern NVARCHAR(20) ); GO @@ -12396,7 +12397,7 @@ SET NOCOUNT ON; SET STATISTICS XML OFF; SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED; -SELECT @Version = '8.12', @VersionDate = '20221213'; +SELECT @Version = '8.13', @VersionDate = '20230215'; SET @OutputType = UPPER(@OutputType); IF(@VersionCheckMode = 1) @@ -12420,7 +12421,6 @@ IF @Help = 1 the findings, contribute your own code, and more. Known limitations of this version: - - This query will not run on SQL Server 2005. - SQL Server 2008 and 2008R2 have a bug in trigger stats, so that output is excluded by default. - @IgnoreQueryHashes and @OnlyQueryHashes require a CSV list of hashes @@ -12436,7 +12436,7 @@ IF @Help = 1 MIT License - Copyright (c) 2021 Brent Ozar Unlimited + Copyright (c) Brent Ozar Unlimited Permission is hereby granted, free of charge, to any person obtaining a copy of this software and associated documentation files (the "Software"), to deal @@ -13172,7 +13172,8 @@ BEGIN cached_execution_parameters XML, missing_indexes XML, SetOptions VARCHAR(MAX), - Warnings VARCHAR(MAX) + Warnings VARCHAR(MAX), + Pattern NVARCHAR(20) ); END; @@ -13273,18 +13274,18 @@ IF @SkipAnalysis = 1 DECLARE @AllSortSql NVARCHAR(MAX) = N''; DECLARE @VersionShowsMemoryGrants BIT; -IF EXISTS(SELECT * FROM sys.all_columns WHERE OBJECT_ID = OBJECT_ID('sys.dm_exec_query_stats') AND name = 'max_grant_kb') +IF EXISTS(SELECT * FROM sys.all_columns WHERE object_id = OBJECT_ID('sys.dm_exec_query_stats') AND name = 'max_grant_kb') SET @VersionShowsMemoryGrants = 1; ELSE SET @VersionShowsMemoryGrants = 0; DECLARE @VersionShowsSpills BIT; -IF EXISTS(SELECT * FROM sys.all_columns WHERE OBJECT_ID = OBJECT_ID('sys.dm_exec_query_stats') AND name = 'max_spills') +IF EXISTS(SELECT * FROM sys.all_columns WHERE object_id = OBJECT_ID('sys.dm_exec_query_stats') AND name = 'max_spills') SET @VersionShowsSpills = 1; ELSE SET @VersionShowsSpills = 0; -IF EXISTS(SELECT * FROM sys.all_columns WHERE OBJECT_ID = OBJECT_ID('sys.dm_exec_query_plan_stats') AND name = 'query_plan') +IF EXISTS(SELECT * FROM sys.all_columns WHERE object_id = OBJECT_ID('sys.dm_exec_query_plan_stats') AND name = 'query_plan') SET @VersionShowsAirQuoteActualPlans = 1; ELSE SET @VersionShowsAirQuoteActualPlans = 0; @@ -14091,7 +14092,7 @@ INSERT INTO ##BlitzCacheProcs (SPID, QueryType, DatabaseName, AverageCPU, TotalC LastReturnedRows, MinGrantKB, MaxGrantKB, MinUsedGrantKB, MaxUsedGrantKB, PercentMemoryGrantUsed, AvgMaxMemoryGrant, MinSpills, MaxSpills, TotalSpills, AvgSpills, QueryText, QueryPlan, TotalWorkerTimeForType, TotalElapsedTimeForType, TotalReadsForType, TotalExecutionCountForType, TotalWritesForType, SqlHandle, PlanHandle, QueryHash, QueryPlanHash, - min_worker_time, max_worker_time, is_parallel, min_elapsed_time, max_elapsed_time, age_minutes, age_minutes_lifetime) ' ; + min_worker_time, max_worker_time, is_parallel, min_elapsed_time, max_elapsed_time, age_minutes, age_minutes_lifetime, Pattern) ' ; SET @body += N' FROM (SELECT TOP (@Top) x.*, xpa.*, @@ -14355,7 +14356,8 @@ SELECT TOP (@Top) qs.min_elapsed_time / 1000.0, qs.max_elapsed_time / 1000.0, age_minutes, - age_minutes_lifetime '; + age_minutes_lifetime, + @SortOrder '; IF LEFT(@QueryFilter, 3) IN ('all', 'sta') @@ -14503,7 +14505,8 @@ BEGIN qs.min_elapsed_time / 1000.0, qs.max_worker_time / 1000.0, age_minutes, - age_minutes_lifetime '; + age_minutes_lifetime, + @SortOrder '; SET @sql += REPLACE(REPLACE(@body, '#view#', 'dm_exec_query_stats'), 'cached_time', 'creation_time') ; @@ -14738,7 +14741,7 @@ IF @Reanalyze = 0 BEGIN RAISERROR('Collecting execution plan information.', 0, 1) WITH NOWAIT; - EXEC sp_executesql @sql, N'@Top INT, @min_duration INT, @min_back INT', @Top, @DurationFilter_i, @MinutesBack; + EXEC sp_executesql @sql, N'@Top INT, @min_duration INT, @min_back INT, @SortOrder NVARCHAR(20)', @Top, @DurationFilter_i, @MinutesBack, @SortOrder; END; IF @SkipAnalysis = 1 @@ -19231,6 +19234,7 @@ ELSE TotalSpills BIGINT, AvgSpills MONEY, QueryPlanCost FLOAT, + Pattern NVARCHAR(20), JoinKey AS ServerName + Cast(CheckDate AS NVARCHAR(50)), CONSTRAINT [PK_' + REPLACE(REPLACE(@OutputTableName,N'[',N''),N']',N'') + N'] PRIMARY KEY CLUSTERED(ID ASC));' ); @@ -19332,6 +19336,22 @@ END '; EXEC(@StringToExecute); END; + /* If the table doesn't have the new Pattern column, add it */ + SET @ObjectFullName = @OutputDatabaseName + N'.' + @OutputSchemaName + N'.' + @OutputTableName; + SET @StringToExecute = N'IF NOT EXISTS (SELECT * FROM ' + @OutputDatabaseName + N'.sys.all_columns + WHERE object_id = (OBJECT_ID(''' + @ObjectFullName + N''')) AND name = ''Pattern'') + ALTER TABLE ' + @ObjectFullName + N' ADD Pattern NVARCHAR(20) NULL;'; + IF @ValidOutputServer = 1 + BEGIN + SET @StringToExecute = REPLACE(@StringToExecute,'''Pattern''','''''Pattern'''''); + SET @StringToExecute = REPLACE(@StringToExecute,'''' + @ObjectFullName + '''','''''' + @ObjectFullName + ''''''); + EXEC('EXEC('''+@StringToExecute+''') AT ' + @OutputServerName); + END; + ELSE + BEGIN + EXEC(@StringToExecute); + END + IF @CheckDateOverride IS NULL BEGIN SET @CheckDateOverride = SYSDATETIMEOFFSET(); @@ -19351,14 +19371,14 @@ END '; + ' (ServerName, CheckDate, Version, QueryType, DatabaseName, AverageCPU, TotalCPU, PercentCPUByType, CPUWeight, AverageDuration, TotalDuration, DurationWeight, PercentDurationByType, AverageReads, TotalReads, ReadWeight, PercentReadsByType, ' + ' AverageWrites, TotalWrites, WriteWeight, PercentWritesByType, ExecutionCount, ExecutionWeight, PercentExecutionsByType, ' + ' ExecutionsPerMinute, PlanCreationTime, LastExecutionTime, LastCompletionTime, PlanHandle, SqlHandle, QueryHash, QueryPlanHash, StatementStartOffset, StatementEndOffset, PlanGenerationNum, MinReturnedRows, MaxReturnedRows, AverageReturnedRows, TotalReturnedRows, QueryText, QueryPlan, NumberOfPlans, NumberOfDistinctPlans, Warnings, ' - + ' SerialRequiredMemory, SerialDesiredMemory, MinGrantKB, MaxGrantKB, MinUsedGrantKB, MaxUsedGrantKB, PercentMemoryGrantUsed, AvgMaxMemoryGrant, MinSpills, MaxSpills, TotalSpills, AvgSpills, QueryPlanCost ) ' + + ' SerialRequiredMemory, SerialDesiredMemory, MinGrantKB, MaxGrantKB, MinUsedGrantKB, MaxUsedGrantKB, PercentMemoryGrantUsed, AvgMaxMemoryGrant, MinSpills, MaxSpills, TotalSpills, AvgSpills, QueryPlanCost, Pattern ) ' + 'SELECT TOP (@Top) ' + QUOTENAME(CAST(SERVERPROPERTY('ServerName') AS NVARCHAR(128)), '''') + ', @CheckDateOverride, ' + QUOTENAME(CAST(SERVERPROPERTY('ProductVersion') AS NVARCHAR(128)), '''') + ', ' + ' QueryType, DatabaseName, AverageCPU, TotalCPU, PercentCPUByType, PercentCPU, AverageDuration, TotalDuration, PercentDuration, PercentDurationByType, AverageReads, TotalReads, PercentReads, PercentReadsByType, ' + ' AverageWrites, TotalWrites, PercentWrites, PercentWritesByType, ExecutionCount, PercentExecutions, PercentExecutionsByType, ' + ' ExecutionsPerMinute, PlanCreationTime, LastExecutionTime, LastCompletionTime, PlanHandle, SqlHandle, QueryHash, QueryPlanHash, StatementStartOffset, StatementEndOffset, PlanGenerationNum, MinReturnedRows, MaxReturnedRows, AverageReturnedRows, TotalReturnedRows, QueryText, CAST(QueryPlan AS NVARCHAR(MAX)), NumberOfPlans, NumberOfDistinctPlans, Warnings, ' - + ' SerialRequiredMemory, SerialDesiredMemory, MinGrantKB, MaxGrantKB, MinUsedGrantKB, MaxUsedGrantKB, PercentMemoryGrantUsed, AvgMaxMemoryGrant, MinSpills, MaxSpills, TotalSpills, AvgSpills, QueryPlanCost ' + + ' SerialRequiredMemory, SerialDesiredMemory, MinGrantKB, MaxGrantKB, MinUsedGrantKB, MaxUsedGrantKB, PercentMemoryGrantUsed, AvgMaxMemoryGrant, MinSpills, MaxSpills, TotalSpills, AvgSpills, QueryPlanCost, Pattern ' + ' FROM ##BlitzCacheProcs ' + ' WHERE 1=1 '; @@ -19419,14 +19439,14 @@ END '; + ' (ServerName, CheckDate, Version, QueryType, DatabaseName, AverageCPU, TotalCPU, PercentCPUByType, CPUWeight, AverageDuration, TotalDuration, DurationWeight, PercentDurationByType, AverageReads, TotalReads, ReadWeight, PercentReadsByType, ' + ' AverageWrites, TotalWrites, WriteWeight, PercentWritesByType, ExecutionCount, ExecutionWeight, PercentExecutionsByType, ' + ' ExecutionsPerMinute, PlanCreationTime, LastExecutionTime, LastCompletionTime, PlanHandle, SqlHandle, QueryHash, QueryPlanHash, StatementStartOffset, StatementEndOffset, PlanGenerationNum, MinReturnedRows, MaxReturnedRows, AverageReturnedRows, TotalReturnedRows, QueryText, QueryPlan, NumberOfPlans, NumberOfDistinctPlans, Warnings, ' - + ' SerialRequiredMemory, SerialDesiredMemory, MinGrantKB, MaxGrantKB, MinUsedGrantKB, MaxUsedGrantKB, PercentMemoryGrantUsed, AvgMaxMemoryGrant, MinSpills, MaxSpills, TotalSpills, AvgSpills, QueryPlanCost ) ' + + ' SerialRequiredMemory, SerialDesiredMemory, MinGrantKB, MaxGrantKB, MinUsedGrantKB, MaxUsedGrantKB, PercentMemoryGrantUsed, AvgMaxMemoryGrant, MinSpills, MaxSpills, TotalSpills, AvgSpills, QueryPlanCost, Pattern ) ' + 'SELECT TOP (@Top) ' + QUOTENAME(CAST(SERVERPROPERTY('ServerName') AS NVARCHAR(128)), '''') + ', @CheckDateOverride, ' + QUOTENAME(CAST(SERVERPROPERTY('ProductVersion') AS NVARCHAR(128)), '''') + ', ' + ' QueryType, DatabaseName, AverageCPU, TotalCPU, PercentCPUByType, PercentCPU, AverageDuration, TotalDuration, PercentDuration, PercentDurationByType, AverageReads, TotalReads, PercentReads, PercentReadsByType, ' + ' AverageWrites, TotalWrites, PercentWrites, PercentWritesByType, ExecutionCount, PercentExecutions, PercentExecutionsByType, ' + ' ExecutionsPerMinute, PlanCreationTime, LastExecutionTime, LastCompletionTime, PlanHandle, SqlHandle, QueryHash, QueryPlanHash, StatementStartOffset, StatementEndOffset, PlanGenerationNum, MinReturnedRows, MaxReturnedRows, AverageReturnedRows, TotalReturnedRows, QueryText, QueryPlan, NumberOfPlans, NumberOfDistinctPlans, Warnings, ' - + ' SerialRequiredMemory, SerialDesiredMemory, MinGrantKB, MaxGrantKB, MinUsedGrantKB, MaxUsedGrantKB, PercentMemoryGrantUsed, AvgMaxMemoryGrant, MinSpills, MaxSpills, TotalSpills, AvgSpills, QueryPlanCost ' + + ' SerialRequiredMemory, SerialDesiredMemory, MinGrantKB, MaxGrantKB, MinUsedGrantKB, MaxUsedGrantKB, PercentMemoryGrantUsed, AvgMaxMemoryGrant, MinSpills, MaxSpills, TotalSpills, AvgSpills, QueryPlanCost, Pattern ' + ' FROM ##BlitzCacheProcs ' + ' WHERE 1=1 '; @@ -19568,6 +19588,7 @@ END '; TotalSpills BIGINT, AvgSpills MONEY, QueryPlanCost FLOAT, + Pattern NVARCHAR(20), JoinKey AS ServerName + Cast(CheckDate AS NVARCHAR(50)), CONSTRAINT [PK_' + REPLACE(REPLACE(@OutputTableName,'[',''),']','') + '] PRIMARY KEY CLUSTERED(ID ASC));'; SET @StringToExecute += N' INSERT ' @@ -19575,14 +19596,14 @@ END '; + ' (ServerName, CheckDate, Version, QueryType, DatabaseName, AverageCPU, TotalCPU, PercentCPUByType, CPUWeight, AverageDuration, TotalDuration, DurationWeight, PercentDurationByType, AverageReads, TotalReads, ReadWeight, PercentReadsByType, ' + ' AverageWrites, TotalWrites, WriteWeight, PercentWritesByType, ExecutionCount, ExecutionWeight, PercentExecutionsByType, ' + ' ExecutionsPerMinute, PlanCreationTime, LastExecutionTime, LastCompletionTime, PlanHandle, SqlHandle, QueryHash, QueryPlanHash, StatementStartOffset, StatementEndOffset, PlanGenerationNum, MinReturnedRows, MaxReturnedRows, AverageReturnedRows, TotalReturnedRows, QueryText, QueryPlan, NumberOfPlans, NumberOfDistinctPlans, Warnings, ' - + ' SerialRequiredMemory, SerialDesiredMemory, MinGrantKB, MaxGrantKB, MinUsedGrantKB, MaxUsedGrantKB, PercentMemoryGrantUsed, AvgMaxMemoryGrant, MinSpills, MaxSpills, TotalSpills, AvgSpills, QueryPlanCost ) ' + + ' SerialRequiredMemory, SerialDesiredMemory, MinGrantKB, MaxGrantKB, MinUsedGrantKB, MaxUsedGrantKB, PercentMemoryGrantUsed, AvgMaxMemoryGrant, MinSpills, MaxSpills, TotalSpills, AvgSpills, QueryPlanCost, Pattern ) ' + 'SELECT TOP (@Top) ' + QUOTENAME(CAST(SERVERPROPERTY('ServerName') AS NVARCHAR(128)), '''') + ', @CheckDateOverride, ' + QUOTENAME(CAST(SERVERPROPERTY('ProductVersion') AS NVARCHAR(128)), '''') + ', ' + ' QueryType, DatabaseName, AverageCPU, TotalCPU, PercentCPUByType, PercentCPU, AverageDuration, TotalDuration, PercentDuration, PercentDurationByType, AverageReads, TotalReads, PercentReads, PercentReadsByType, ' + ' AverageWrites, TotalWrites, PercentWrites, PercentWritesByType, ExecutionCount, PercentExecutions, PercentExecutionsByType, ' + ' ExecutionsPerMinute, PlanCreationTime, LastExecutionTime, LastCompletionTime, PlanHandle, SqlHandle, QueryHash, QueryPlanHash, StatementStartOffset, StatementEndOffset, PlanGenerationNum, MinReturnedRows, MaxReturnedRows, AverageReturnedRows, TotalReturnedRows, QueryText, QueryPlan, NumberOfPlans, NumberOfDistinctPlans, Warnings, ' - + ' SerialRequiredMemory, SerialDesiredMemory, MinGrantKB, MaxGrantKB, MinUsedGrantKB, MaxUsedGrantKB, PercentMemoryGrantUsed, AvgMaxMemoryGrant, MinSpills, MaxSpills, TotalSpills, AvgSpills, QueryPlanCost ' + + ' SerialRequiredMemory, SerialDesiredMemory, MinGrantKB, MaxGrantKB, MinUsedGrantKB, MaxUsedGrantKB, PercentMemoryGrantUsed, AvgMaxMemoryGrant, MinSpills, MaxSpills, TotalSpills, AvgSpills, QueryPlanCost, Pattern ' + ' FROM ##BlitzCacheProcs ' + ' WHERE 1=1 '; @@ -19694,7 +19715,7 @@ SET NOCOUNT ON; SET STATISTICS XML OFF; SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED; -SELECT @Version = '8.12', @VersionDate = '20221213'; +SELECT @Version = '8.13', @VersionDate = '20230215'; SET @OutputType = UPPER(@OutputType); IF(@VersionCheckMode = 1) @@ -19731,7 +19752,7 @@ Unknown limitations of this version: MIT License -Copyright (c) 2021 Brent Ozar Unlimited +Copyright (c) Brent Ozar Unlimited Permission is hereby granted, free of charge, to any person obtaining a copy of this software and associated documentation files (the "Software"), to deal @@ -25871,7 +25892,7 @@ BEGIN SET NOCOUNT, XACT_ABORT ON; SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED; - SELECT @Version = '8.12', @VersionDate = '20221213'; + SELECT @Version = '8.13', @VersionDate = '20230215'; IF @VersionCheckMode = 1 BEGIN @@ -25932,7 +25953,7 @@ BEGIN MIT License - Copyright (c) 2022 Brent Ozar Unlimited + Copyright (c) Brent Ozar Unlimited Permission is hereby granted, free of charge, to any person obtaining a copy of this software and associated documentation files (the "Software"), to deal @@ -27005,7 +27026,7 @@ BEGIN waiter_mode = w.l.value('@mode', 'nvarchar(256)'), owner_id = o.l.value('@id', 'nvarchar(256)'), owner_mode = o.l.value('@mode', 'nvarchar(256)'), - lock_type = N'OBJECT' + lock_type = CAST(N'OBJECT' AS NVARCHAR(100)) INTO #deadlock_owner_waiter FROM ( @@ -27630,7 +27651,7 @@ BEGIN N'S', N'IS' ) - AND (dow.database_id = @DatabaseName OR @DatabaseName IS NULL) + AND (dow.database_id = @DatabaseId OR @DatabaseName IS NULL) AND (dow.event_date >= @StartDate OR @StartDate IS NULL) AND (dow.event_date < @EndDate OR @EndDate IS NULL) AND (dow.object_name = @ObjectName OR @ObjectName IS NULL) @@ -27673,7 +27694,7 @@ BEGIN N' deadlock(s).' FROM #deadlock_owner_waiter AS dow WHERE 1 = 1 - AND (dow.database_id = @DatabaseName OR @DatabaseName IS NULL) + AND (dow.database_id = @DatabaseId OR @DatabaseName IS NULL) AND (dow.event_date >= @StartDate OR @StartDate IS NULL) AND (dow.event_date < @EndDate OR @EndDate IS NULL) AND (dow.object_name = @ObjectName OR @ObjectName IS NULL) @@ -27712,7 +27733,7 @@ BEGIN N' deadlock(s).' FROM #deadlock_owner_waiter AS dow WHERE 1 = 1 - AND (dow.database_id = @DatabaseName OR @DatabaseName IS NULL) + AND (dow.database_id = @DatabaseId OR @DatabaseName IS NULL) AND (dow.event_date >= @StartDate OR @StartDate IS NULL) AND (dow.event_date < @EndDate OR @EndDate IS NULL) AND (dow.object_name = @ObjectName OR @ObjectName IS NULL) @@ -27757,7 +27778,7 @@ BEGIN N' deadlock(s).' FROM #deadlock_owner_waiter AS dow WHERE 1 = 1 - AND (dow.database_id = @DatabaseName OR @DatabaseName IS NULL) + AND (dow.database_id = @DatabaseId OR @DatabaseName IS NULL) AND (dow.event_date >= @StartDate OR @StartDate IS NULL) AND (dow.event_date < @EndDate OR @EndDate IS NULL) AND (dow.object_name = @ObjectName OR @ObjectName IS NULL) @@ -28083,7 +28104,7 @@ BEGIN ON dow.owner_id = ds.id AND dow.event_date = ds.event_date WHERE 1 = 1 - AND (dow.database_id = @DatabaseName OR @DatabaseName IS NULL) + AND (dow.database_id = @DatabaseId OR @DatabaseName IS NULL) AND (dow.event_date >= @StartDate OR @StartDate IS NULL) AND (dow.event_date < @EndDate OR @EndDate IS NULL) AND (dow.object_name = @StoredProcName OR @StoredProcName IS NULL) @@ -28139,7 +28160,7 @@ BEGIN ON dow.owner_id = ds.id AND dow.event_date = ds.event_date WHERE ds.proc_name <> N'adhoc' - AND (dow.database_id = @DatabaseName OR @DatabaseName IS NULL) + AND (dow.database_id = @DatabaseId OR @DatabaseName IS NULL) AND (dow.event_date >= @StartDate OR @StartDate IS NULL) AND (dow.event_date < @EndDate OR @EndDate IS NULL) AND (dow.object_name = @StoredProcName OR @StoredProcName IS NULL) @@ -28215,7 +28236,7 @@ BEGIN ON s.database_id = dow.database_id AND s.partition_id = dow.associatedObjectId WHERE 1 = 1 - AND (dow.database_id = @DatabaseName OR @DatabaseName IS NULL) + AND (dow.database_id = @DatabaseId OR @DatabaseName IS NULL) AND (dow.event_date >= @StartDate OR @StartDate IS NULL) AND (dow.event_date < @EndDate OR @EndDate IS NULL) AND (dow.object_name = @ObjectName OR @ObjectName IS NULL) @@ -28277,6 +28298,76 @@ BEGIN ) ), wait_time_hms = + /*the more wait time you rack up the less accurate this gets, + it's either that or erroring out*/ + CASE + WHEN + SUM + ( + CONVERT + ( + bigint, + dp.wait_time + ) + )/1000 > 2147483647 + THEN + CONVERT + ( + nvarchar(30), + DATEADD + ( + MINUTE, + ( + ( + SUM + ( + CONVERT + ( + bigint, + dp.wait_time + ) + ) + )/ + 60000 + ), + 0 + ), + 14 + ) + WHEN + SUM + ( + CONVERT + ( + bigint, + dp.wait_time + ) + ) BETWEEN 2147483648 AND 2147483647000 + THEN + CONVERT + ( + nvarchar(30), + DATEADD + ( + SECOND, + ( + ( + SUM + ( + CONVERT + ( + bigint, + dp.wait_time + ) + ) + )/ + 1000 + ), + 0 + ), + 14 + ) + ELSE CONVERT ( nvarchar(30), @@ -28297,6 +28388,7 @@ BEGIN ), 14 ) + END FROM #deadlock_owner_waiter AS dow JOIN #deadlock_process AS dp ON (dp.id = dow.owner_id @@ -28413,6 +28505,76 @@ BEGIN ) ) + N' ' + + /*the more wait time you rack up the less accurate this gets, + it's either that or erroring out*/ + CASE + WHEN + SUM + ( + CONVERT + ( + bigint, + wt.total_wait_time_ms + ) + )/1000 > 2147483647 + THEN + CONVERT + ( + nvarchar(30), + DATEADD + ( + MINUTE, + ( + ( + SUM + ( + CONVERT + ( + bigint, + wt.total_wait_time_ms + ) + ) + )/ + 60000 + ), + 0 + ), + 14 + ) + WHEN + SUM + ( + CONVERT + ( + bigint, + wt.total_wait_time_ms + ) + ) BETWEEN 2147483648 AND 2147483647000 + THEN + CONVERT + ( + nvarchar(30), + DATEADD + ( + SECOND, + ( + ( + SUM + ( + CONVERT + ( + bigint, + wt.total_wait_time_ms + ) + ) + )/ + 1000 + ), + 0 + ), + 14 + ) + ELSE CONVERT ( nvarchar(30), @@ -28432,7 +28594,7 @@ BEGIN 0 ), 14 - ) + + ) END + N' [dd hh:mm:ss:ms] of deadlock wait time.' FROM wait_time AS wt GROUP BY @@ -29378,7 +29540,7 @@ SET NOCOUNT ON; SET STATISTICS XML OFF; SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED; -SELECT @Version = '8.12', @VersionDate = '20221213'; +SELECT @Version = '8.13', @VersionDate = '20230215'; IF(@VersionCheckMode = 1) BEGIN RETURN; @@ -29464,7 +29626,7 @@ IF @Help = 1 MIT License - Copyright (c) 2021 Brent Ozar Unlimited + Copyright (c) Brent Ozar Unlimited Permission is hereby granted, free of charge, to any person obtaining a copy of this software and associated documentation files (the "Software"), to deal @@ -35109,7 +35271,7 @@ BEGIN SET STATISTICS XML OFF; SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED; - SELECT @Version = '8.12', @VersionDate = '20221213'; + SELECT @Version = '8.13', @VersionDate = '20230215'; IF(@VersionCheckMode = 1) BEGIN @@ -35137,7 +35299,7 @@ Known limitations of this version: MIT License -Copyright (c) 2021 Brent Ozar Unlimited +Copyright (c) Brent Ozar Unlimited Permission is hereby granted, free of charge, to any person obtaining a copy of this software and associated documentation files (the "Software"), to deal @@ -35766,11 +35928,11 @@ BEGIN END AS blocking_session_id, COALESCE(DB_NAME(r.database_id), DB_NAME(blocked.dbid), ''N/A'') AS database_name, ISNULL(SUBSTRING(dest.text, - ( query_stats.statement_start_offset / 2 ) + 1, - ( ( CASE query_stats.statement_end_offset + ( r.statement_start_offset / 2 ) + 1, + ( ( CASE r.statement_end_offset WHEN -1 THEN DATALENGTH(dest.text) - ELSE query_stats.statement_end_offset - END - query_stats.statement_start_offset ) + ELSE r.statement_end_offset + END - r.statement_start_offset ) / 2 ) + 1), dest.text) AS query_text , '+CASE WHEN @GetOuterCommand = 1 THEN N'CAST(event_info AS NVARCHAR(4000)) AS outer_command,' @@ -35935,7 +36097,7 @@ BEGIN OUTER APPLY sys.dm_exec_sql_text(COALESCE(r.sql_handle, blocked.sql_handle)) AS dest OUTER APPLY sys.dm_exec_query_plan(r.plan_handle) AS derp OUTER APPLY ( - SELECT CONVERT(DECIMAL(38,2), SUM( (((tsu.user_objects_alloc_page_count - user_objects_dealloc_page_count) * 8) / 1024.)) ) AS tempdb_allocations_mb + SELECT CONVERT(DECIMAL(38,2), SUM( ((((tsu.user_objects_alloc_page_count - user_objects_dealloc_page_count) + (tsu.internal_objects_alloc_page_count - internal_objects_dealloc_page_count)) * 8) / 1024.)) ) AS tempdb_allocations_mb FROM sys.dm_db_task_space_usage tsu WHERE tsu.request_id = r.request_id AND tsu.session_id = r.session_id @@ -35984,11 +36146,11 @@ IF @ProductVersionMajor >= 11 END AS blocking_session_id, COALESCE(DB_NAME(r.database_id), DB_NAME(blocked.dbid), ''N/A'') AS database_name, ISNULL(SUBSTRING(dest.text, - ( query_stats.statement_start_offset / 2 ) + 1, - ( ( CASE query_stats.statement_end_offset + ( r.statement_start_offset / 2 ) + 1, + ( ( CASE r.statement_end_offset WHEN -1 THEN DATALENGTH(dest.text) - ELSE query_stats.statement_end_offset - END - query_stats.statement_start_offset ) + ELSE r.statement_end_offset + END - r.statement_start_offset ) / 2 ) + 1), dest.text) AS query_text , '+CASE WHEN @GetOuterCommand = 1 THEN N'CAST(event_info AS NVARCHAR(4000)) AS outer_command,' @@ -36228,7 +36390,7 @@ IF @ProductVersionMajor >= 11 OUTER APPLY sys.dm_exec_sql_text(COALESCE(r.sql_handle, blocked.sql_handle)) AS dest OUTER APPLY sys.dm_exec_query_plan(r.plan_handle) AS derp OUTER APPLY ( - SELECT CONVERT(DECIMAL(38,2), SUM( (((tsu.user_objects_alloc_page_count - user_objects_dealloc_page_count) * 8) / 1024.)) ) AS tempdb_allocations_mb + SELECT CONVERT(DECIMAL(38,2), SUM( ((((tsu.user_objects_alloc_page_count - user_objects_dealloc_page_count) + (tsu.internal_objects_alloc_page_count - internal_objects_dealloc_page_count)) * 8) / 1024.)) ) AS tempdb_allocations_mb FROM sys.dm_db_task_space_usage tsu WHERE tsu.request_id = r.request_id AND tsu.session_id = r.session_id @@ -36505,7 +36667,9 @@ DELETE FROM dbo.SqlServerVersions; INSERT INTO dbo.SqlServerVersions (MajorVersionNumber, MinorVersionNumber, Branch, [Url], ReleaseDate, MainstreamSupportEndDate, ExtendedSupportEndDate, MajorVersionName, MinorVersionName) VALUES + (16, 1050, 'RTM GDR', 'https://support.microsoft.com/kb/5021522', '2023-02-14', '2028-01-11', '2033-01-11', 'SQL Server 2022 GDR', 'RTM'), (16, 1000, 'RTM', '', '2022-11-15', '2028-01-11', '2033-01-11', 'SQL Server 2022', 'RTM'), + (15, 4280, 'CU18 GDR', 'https://support.microsoft.com/kb/5021124', '2023-02-14', '2025-01-07', '2030-01-08', 'SQL Server 2019', 'Cumulative Update 18 GDR'), (15, 4261, 'CU18', 'https://support.microsoft.com/en-us/help/5017593', '2022-09-28', '2025-01-07', '2030-01-08', 'SQL Server 2019', 'Cumulative Update 18'), (15, 4249, 'CU17', 'https://support.microsoft.com/en-us/help/5016394', '2022-08-11', '2025-01-07', '2030-01-08', 'SQL Server 2019', 'Cumulative Update 17'), (15, 4236, 'CU16 GDR', 'https://support.microsoft.com/en-us/help/5014353', '2022-06-14', '2025-01-07', '2030-01-08', 'SQL Server 2019', 'Cumulative Update 16 GDR'), @@ -36528,6 +36692,7 @@ VALUES (15, 4003, 'CU1', 'https://support.microsoft.com/en-us/help/4527376', '2020-01-07', '2025-01-07', '2030-01-08', 'SQL Server 2019', 'Cumulative Update 1 '), (15, 2070, 'GDR', 'https://support.microsoft.com/en-us/help/4517790', '2019-11-04', '2025-01-07', '2030-01-08', 'SQL Server 2019', 'RTM GDR '), (15, 2000, 'RTM ', '', '2019-11-04', '2025-01-07', '2030-01-08', 'SQL Server 2019', 'RTM '), + (14, 3460, 'RTM CU31 GDR', 'https://support.microsoft.com/kb/5021126', '2023-02-14', '2022-10-11', '2027-10-12', 'SQL Server 2017', 'RTM Cumulative Update 31 GDR'), (14, 3456, 'RTM CU31', 'https://support.microsoft.com/en-us/help/5016884', '2022-09-20', '2022-10-11', '2027-10-12', 'SQL Server 2017', 'RTM Cumulative Update 31'), (14, 3451, 'RTM CU30', 'https://support.microsoft.com/en-us/help/5013756', '2022-07-13', '2022-10-11', '2027-10-12', 'SQL Server 2017', 'RTM Cumulative Update 30'), (14, 3445, 'RTM CU29 GDR', 'https://support.microsoft.com/en-us/help/5014553', '2022-06-14', '2022-10-11', '2027-10-12', 'SQL Server 2017', 'RTM Cumulative Update 29 GDR'), @@ -36564,6 +36729,7 @@ VALUES (14, 1000, 'RTM ', '', '2017-10-02', '2022-10-11', '2027-10-12', 'SQL Server 2017', 'RTM '), (13, 7016, 'SP3 Azure Feature Pack GDR', 'https://support.microsoft.com/en-us/help/5015371', '2022-06-14', '2021-07-13', '2026-07-14', 'SQL Server 2016', 'Service Pack 3 Azure Feature Pack GDR'), (13, 7000, 'SP3 Azure Feature Pack', 'https://support.microsoft.com/en-us/help/5014242', '2022-05-19', '2021-07-13', '2026-07-14', 'SQL Server 2016', 'Service Pack 3 Azure Feature Pack'), + (13, 6430, 'SP3 GDR', 'https://support.microsoft.com/kb/5021129', '2023-02-14', '2021-07-13', '2026-07-14', 'SQL Server 2016', 'Service Pack 3 GDR'), (13, 6419, 'SP3 GDR', 'https://support.microsoft.com/en-us/help/5014355', '2022-06-14', '2021-07-13', '2026-07-14', 'SQL Server 2016', 'Service Pack 3 GDR'), (13, 6404, 'SP3 GDR', 'https://support.microsoft.com/en-us/help/5006943', '2021-10-27', '2021-07-13', '2026-07-14', 'SQL Server 2016', 'Service Pack 3 GDR'), (13, 6300, 'SP3 ', 'https://support.microsoft.com/en-us/help/5003279', '2021-09-15', '2021-07-13', '2026-07-14', 'SQL Server 2016', 'Service Pack 3'), @@ -36615,6 +36781,7 @@ VALUES (13, 2164, 'RTM CU2', 'https://support.microsoft.com/en-us/help/3182270 ', '2016-09-22', '2018-01-09', '2018-01-09', 'SQL Server 2016', 'RTM Cumulative Update 2'), (13, 2149, 'RTM CU1', 'https://support.microsoft.com/en-us/help/3164674 ', '2016-07-25', '2018-01-09', '2018-01-09', 'SQL Server 2016', 'RTM Cumulative Update 1'), (13, 1601, 'RTM ', '', '2016-06-01', '2019-01-09', '2019-01-09', 'SQL Server 2016', 'RTM '), + (12, 6444, 'SP3 CU4 GDR', 'https://support.microsoft.com/kb/5021045', '2023-02-14', '2019-07-09', '2024-07-09', 'SQL Server 2014', 'Service Pack 3 Cumulative Update 4 GDR'), (12, 6439, 'SP3 CU4 GDR', 'https://support.microsoft.com/en-us/help/5014164', '2022-06-14', '2019-07-09', '2024-07-09', 'SQL Server 2014', 'Service Pack 3 Cumulative Update 4 GDR'), (12, 6433, 'SP3 CU4 GDR', 'https://support.microsoft.com/en-us/help/4583462', '2021-01-12', '2019-07-09', '2024-07-09', 'SQL Server 2014', 'Service Pack 3 Cumulative Update 4 GDR'), (12, 6372, 'SP3 CU4 GDR', 'https://support.microsoft.com/en-us/help/4535288', '2020-02-11', '2019-07-09', '2024-07-09', 'SQL Server 2014', 'Service Pack 3 Cumulative Update 4 GDR'), @@ -36921,7 +37088,7 @@ SET NOCOUNT ON; SET STATISTICS XML OFF; SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED; -SELECT @Version = '8.12', @VersionDate = '20221213'; +SELECT @Version = '8.13', @VersionDate = '20230215'; IF(@VersionCheckMode = 1) BEGIN @@ -36961,7 +37128,7 @@ https://github.com/BrentOzarULTD/SQL-Server-First-Responder-Kit/ MIT License -Copyright (c) 2021 Brent Ozar Unlimited +Copyright (c) Brent Ozar Unlimited Permission is hereby granted, free of charge, to any person obtaining a copy of this software and associated documentation files (the "Software"), to deal @@ -39168,8 +39335,9 @@ If one of them is a lead blocker, consider killing that query.'' AS HowToStopit, CROSS APPLY sys.dm_exec_query_plan(r.plan_handle) AS qp '; IF EXISTS (SELECT * FROM sys.all_objects WHERE name = 'dm_exec_query_statistics_xml') - SET @StringToExecute = @StringToExecute + N' OUTER APPLY sys.dm_exec_query_statistics_xml(s.session_id) qs_live '; - + /* GitHub #3210 */ + SET @StringToExecute = N' + SET LOCK_TIMEOUT 1000 ' + @StringToExecute + N' OUTER APPLY sys.dm_exec_query_statistics_xml(s.session_id) qs_live '; SET @StringToExecute = @StringToExecute + N'; diff --git a/sp_AllNightLog.sql b/sp_AllNightLog.sql index 9e5df6eb..77a410ae 100644 --- a/sp_AllNightLog.sql +++ b/sp_AllNightLog.sql @@ -31,7 +31,7 @@ SET STATISTICS XML OFF; BEGIN; -SELECT @Version = '8.12', @VersionDate = '20221213'; +SELECT @Version = '8.13', @VersionDate = '20230215'; IF(@VersionCheckMode = 1) BEGIN @@ -83,7 +83,7 @@ BEGIN MIT License - Copyright (c) 2021 Brent Ozar Unlimited + Copyright (c) Brent Ozar Unlimited Permission is hereby granted, free of charge, to any person obtaining a copy of this software and associated documentation files (the "Software"), to deal diff --git a/sp_AllNightLog_Setup.sql b/sp_AllNightLog_Setup.sql index ba77dbfc..cbcd2924 100644 --- a/sp_AllNightLog_Setup.sql +++ b/sp_AllNightLog_Setup.sql @@ -38,7 +38,7 @@ SET STATISTICS XML OFF; BEGIN; -SELECT @Version = '8.12', @VersionDate = '20221213'; +SELECT @Version = '8.13', @VersionDate = '20230215'; IF(@VersionCheckMode = 1) BEGIN @@ -119,7 +119,7 @@ BEGIN MIT License - Copyright (c) 2021 Brent Ozar Unlimited + Copyright (c) Brent Ozar Unlimited Permission is hereby granted, free of charge, to any person obtaining a copy of this software and associated documentation files (the "Software"), to deal diff --git a/sp_Blitz.sql b/sp_Blitz.sql index ab74b6ac..d0f77cc3 100644 --- a/sp_Blitz.sql +++ b/sp_Blitz.sql @@ -38,7 +38,7 @@ AS SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED; - SELECT @Version = '8.12', @VersionDate = '20221213'; + SELECT @Version = '8.13', @VersionDate = '20230215'; SET @OutputType = UPPER(@OutputType); IF(@VersionCheckMode = 1) @@ -93,9 +93,9 @@ AS tigertoolbox and are provided under the MIT license: https://github.com/Microsoft/tigertoolbox - All other copyrights for sp_Blitz are held by Brent Ozar Unlimited, 2021. + All other copyrights for sp_Blitz are held by Brent Ozar Unlimited. - Copyright (c) 2021 Brent Ozar Unlimited + Copyright (c) Brent Ozar Unlimited Permission is hereby granted, free of charge, to any person obtaining a copy of this software and associated documentation files (the "Software"), to deal diff --git a/sp_BlitzAnalysis.sql b/sp_BlitzAnalysis.sql index e11f351c..8a944734 100644 --- a/sp_BlitzAnalysis.sql +++ b/sp_BlitzAnalysis.sql @@ -37,7 +37,7 @@ AS SET NOCOUNT ON; SET STATISTICS XML OFF; -SELECT @Version = '8.12', @VersionDate = '20221213'; +SELECT @Version = '8.13', @VersionDate = '20230215'; IF(@VersionCheckMode = 1) BEGIN diff --git a/sp_BlitzBackups.sql b/sp_BlitzBackups.sql index a2d353e4..15d47a7f 100755 --- a/sp_BlitzBackups.sql +++ b/sp_BlitzBackups.sql @@ -24,7 +24,7 @@ AS SET STATISTICS XML OFF; SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED; - SELECT @Version = '8.12', @VersionDate = '20221213'; + SELECT @Version = '8.13', @VersionDate = '20230215'; IF(@VersionCheckMode = 1) BEGIN @@ -71,7 +71,7 @@ AS MIT License - Copyright (c) 2021 Brent Ozar Unlimited + Copyright (c) Brent Ozar Unlimited Permission is hereby granted, free of charge, to any person obtaining a copy of this software and associated documentation files (the "Software"), to deal diff --git a/sp_BlitzCache.sql b/sp_BlitzCache.sql index ad39383b..974dec39 100644 --- a/sp_BlitzCache.sql +++ b/sp_BlitzCache.sql @@ -281,7 +281,7 @@ SET NOCOUNT ON; SET STATISTICS XML OFF; SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED; -SELECT @Version = '8.12', @VersionDate = '20221213'; +SELECT @Version = '8.13', @VersionDate = '20230215'; SET @OutputType = UPPER(@OutputType); IF(@VersionCheckMode = 1) @@ -305,7 +305,6 @@ IF @Help = 1 the findings, contribute your own code, and more. Known limitations of this version: - - This query will not run on SQL Server 2005. - SQL Server 2008 and 2008R2 have a bug in trigger stats, so that output is excluded by default. - @IgnoreQueryHashes and @OnlyQueryHashes require a CSV list of hashes @@ -321,7 +320,7 @@ IF @Help = 1 MIT License - Copyright (c) 2021 Brent Ozar Unlimited + Copyright (c) Brent Ozar Unlimited Permission is hereby granted, free of charge, to any person obtaining a copy of this software and associated documentation files (the "Software"), to deal diff --git a/sp_BlitzFirst.sql b/sp_BlitzFirst.sql index 7dbcfd5d..5ce7ad5d 100644 --- a/sp_BlitzFirst.sql +++ b/sp_BlitzFirst.sql @@ -46,7 +46,7 @@ SET NOCOUNT ON; SET STATISTICS XML OFF; SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED; -SELECT @Version = '8.12', @VersionDate = '20221213'; +SELECT @Version = '8.13', @VersionDate = '20230215'; IF(@VersionCheckMode = 1) BEGIN @@ -86,7 +86,7 @@ https://github.com/BrentOzarULTD/SQL-Server-First-Responder-Kit/ MIT License -Copyright (c) 2021 Brent Ozar Unlimited +Copyright (c) Brent Ozar Unlimited Permission is hereby granted, free of charge, to any person obtaining a copy of this software and associated documentation files (the "Software"), to deal diff --git a/sp_BlitzInMemoryOLTP.sql b/sp_BlitzInMemoryOLTP.sql index 07d0a10a..1dda6aba 100644 --- a/sp_BlitzInMemoryOLTP.sql +++ b/sp_BlitzInMemoryOLTP.sql @@ -82,7 +82,7 @@ THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR IMPLI */ AS DECLARE @ScriptVersion VARCHAR(30); -SELECT @ScriptVersion = '1.8', @VersionDate = '20221213'; +SELECT @ScriptVersion = '1.8', @VersionDate = '20230215'; IF(@VersionCheckMode = 1) BEGIN diff --git a/sp_BlitzIndex.sql b/sp_BlitzIndex.sql index 7d0d71f9..0c6dd6b0 100644 --- a/sp_BlitzIndex.sql +++ b/sp_BlitzIndex.sql @@ -48,7 +48,7 @@ SET NOCOUNT ON; SET STATISTICS XML OFF; SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED; -SELECT @Version = '8.12', @VersionDate = '20221213'; +SELECT @Version = '8.13', @VersionDate = '20230215'; SET @OutputType = UPPER(@OutputType); IF(@VersionCheckMode = 1) @@ -85,7 +85,7 @@ Unknown limitations of this version: MIT License -Copyright (c) 2021 Brent Ozar Unlimited +Copyright (c) Brent Ozar Unlimited Permission is hereby granted, free of charge, to any person obtaining a copy of this software and associated documentation files (the "Software"), to deal diff --git a/sp_BlitzLock.sql b/sp_BlitzLock.sql index 2d5f3b35..26e78185 100644 --- a/sp_BlitzLock.sql +++ b/sp_BlitzLock.sql @@ -35,7 +35,7 @@ BEGIN SET NOCOUNT, XACT_ABORT ON; SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED; - SELECT @Version = '8.12', @VersionDate = '20221213'; + SELECT @Version = '8.13', @VersionDate = '20230215'; IF @VersionCheckMode = 1 BEGIN @@ -96,7 +96,7 @@ BEGIN MIT License - Copyright (c) 2022 Brent Ozar Unlimited + Copyright (c) Brent Ozar Unlimited Permission is hereby granted, free of charge, to any person obtaining a copy of this software and associated documentation files (the "Software"), to deal diff --git a/sp_BlitzQueryStore.sql b/sp_BlitzQueryStore.sql index 6a8ddd11..3d8dd5cf 100644 --- a/sp_BlitzQueryStore.sql +++ b/sp_BlitzQueryStore.sql @@ -57,7 +57,7 @@ SET NOCOUNT ON; SET STATISTICS XML OFF; SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED; -SELECT @Version = '8.12', @VersionDate = '20221213'; +SELECT @Version = '8.13', @VersionDate = '20230215'; IF(@VersionCheckMode = 1) BEGIN RETURN; @@ -143,7 +143,7 @@ IF @Help = 1 MIT License - Copyright (c) 2021 Brent Ozar Unlimited + Copyright (c) Brent Ozar Unlimited Permission is hereby granted, free of charge, to any person obtaining a copy of this software and associated documentation files (the "Software"), to deal diff --git a/sp_BlitzWho.sql b/sp_BlitzWho.sql index 429ec5a4..da7565ec 100644 --- a/sp_BlitzWho.sql +++ b/sp_BlitzWho.sql @@ -33,7 +33,7 @@ BEGIN SET STATISTICS XML OFF; SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED; - SELECT @Version = '8.12', @VersionDate = '20221213'; + SELECT @Version = '8.13', @VersionDate = '20230215'; IF(@VersionCheckMode = 1) BEGIN @@ -61,7 +61,7 @@ Known limitations of this version: MIT License -Copyright (c) 2021 Brent Ozar Unlimited +Copyright (c) Brent Ozar Unlimited Permission is hereby granted, free of charge, to any person obtaining a copy of this software and associated documentation files (the "Software"), to deal diff --git a/sp_DatabaseRestore.sql b/sp_DatabaseRestore.sql index 8e5df506..36109fbc 100755 --- a/sp_DatabaseRestore.sql +++ b/sp_DatabaseRestore.sql @@ -42,7 +42,7 @@ SET STATISTICS XML OFF; /*Versioning details*/ -SELECT @Version = '8.12', @VersionDate = '20221213'; +SELECT @Version = '8.13', @VersionDate = '20230215'; IF(@VersionCheckMode = 1) BEGIN @@ -74,7 +74,7 @@ BEGIN MIT License - Copyright (c) 2021 Brent Ozar Unlimited + Copyright (c) Brent Ozar Unlimited Permission is hereby granted, free of charge, to any person obtaining a copy of this software and associated documentation files (the "Software"), to deal diff --git a/sp_ineachdb.sql b/sp_ineachdb.sql index 2b5c8fe4..6ec373ba 100644 --- a/sp_ineachdb.sql +++ b/sp_ineachdb.sql @@ -35,7 +35,7 @@ BEGIN SET NOCOUNT ON; SET STATISTICS XML OFF; - SELECT @Version = '8.12', @VersionDate = '20221213'; + SELECT @Version = '8.13', @VersionDate = '20230215'; IF(@VersionCheckMode = 1) BEGIN @@ -68,7 +68,7 @@ BEGIN MIT License - Copyright (c) 2021 Brent Ozar Unlimited + Copyright (c) Brent Ozar Unlimited Permission is hereby granted, free of charge, to any person obtaining a copy of this software and associated documentation files (the "Software"), to deal