USE [DD_SYS] GO SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO -- [PRDD_MAINTAIN_DATABASE] -- ================================================================= -- Checks database health, shrinks all database and log files -- and recreates indizes in a maintanance run. -- Minimum requirement: MS SQL Server 2016 -- -- Returns: INT Value - 0 = Everything worked well -- ================================================================= -- Copyright (c) 2025 by Digital Data GmbH -- -- Digital Data GmbH • Ludwig-Rinn-Strasse 16 • D-35452 Heuchelheim -- Tel.: 0641/202360 • E-Mail: info-flow@digitaldata.works -- ================================================================= -- Creation Date / Author: 29.11.2024 / MK -- Version Date / Editor: 23.12.2025 / MK -- Version Number: 1.6.0.0 -- ================================================================= -- History: -- 29.11.2024 / MK - First Version -- 06.12.2024 / MK - Added "SET ONLINE" after forced SINGLE_USER Mode, Added repair parameter for DBCHECK, added @pRECOMPILEPROCEDURES, some minor error fixes -- 13.12.2024 / MK - New way the get the procedure name, failsafe for parameters implemented -- 20.03.2025 / MK - Improved safty checks -- 01.12.2025 / MK - Improved text formating, Improve Index recreation, SINGLE_USER replaced with RESTRICTED_USER -- 06.12.2025 / MK - Improved access mode while repair db -- 08.12.2025 / MK - Extended PRINT commands and checking recovery modell of db extended -- 13.12.2025 / MK - Improved dbshrink action, Improved logshrink action -- 15.12.2025 / MK - Fixed issue with "user_access_desc FROM [sys].[databases]" -- 21.12.2025 / MK - Added heap rebuild, columnstore maintenance, statistics update, file growth checks, log cleanup and error log cycling -- 23.12.2025 / MK - Added optional system/session cache clearing and database scoped procedure cache clearing CREATE OR ALTER PROCEDURE [dbo].[PRDD_MAINTAIN_DATABASE] ( @pCHECKDB BIT = 0, -- Set to 1 to make a check of the database before shrinking incl. soft repair function. Otherwise set to 0. @pSHRINKLOG BIT = 0, -- Set to 1 to shrink the log file. Otherwise set to 0. @pSHRINKDB BIT = 0, -- Set to 1 to shrink the database file as well. Otherwise set to 0. (Dont use on FILESTREAM databases!) @pSHRINKTEMPDB BIT = 0, -- Set to 1 to shrink tempdb data and log files. Otherwise set to 0. @pREBUILDINDEX BIT = 0, -- Set to 1 to rebuild or recreate all database indexes. Otherwise set to 0. @pRECOMPILEPROCEDURES BIT = 0, -- Set to 1 to recompile all database procedures. Otherwise set to 0. @pCLEARQUERYCACHE BIT = 0, -- Set to 1 to clear the QL query cache via DROPCLEANBUFFERS. Otherwise set to 0. @pFREESYSTEMCACHE BIT = 0, -- Set to 1 to clear the system cache via DBCC FREESYSTEMCACHE. Otherwise set to 0. @pFREESESSIONCACHE BIT = 0, -- Set to 1 to clear the session cache via DBCC FREESESSIONCACHE. Otherwise set to 0. @pCLEARDBPROCCACHE BIT = 0, -- Set to 1 to clear the database scoped procedure cache. Otherwise set to 0. @pUPDATESTATISTICS BIT = 1, -- Set to 1 to update statistics for all tables. Otherwise set to 0. @pREBUILDHEAPS BIT = 0, -- Set to 1 to rebuild heaps with forwarded records. Otherwise set to 0. @pMAINTAINCOLUMNSTORE BIT = 0, -- Set to 1 to maintain columnstore indexes. Otherwise set to 0. @pCHECKFILEGROWTH BIT = 1, -- Set to 1 to check database file growth settings. Otherwise set to 0. @pCLEANLOGS BIT = 0, -- Set to 1 to cleanup maintenance log entries. Otherwise set to 0. @pLOGRETENTIONDAYS INT = 90, -- Set the log retention days for cleanup. Otherwise set to 0 to keep all. @pCYCLEERRORLOGS BIT = 0, -- Set to 1 to cycle SQL Server and Agent error logs. Otherwise set to 0. @pFORCE BIT = 0, -- Set to 1 to force the shrinking, it will cut all current sessens. In combination with @pCHECKDB it trys the soft reapair dbs. Otherwise set to 0. @pINCLUDEDB NVARCHAR(1000) = 'DD_ECM', -- Set a list of included databases. IF <> NULL, it will override the @pEXCLUDEDB Parameter @pEXCLUDEDB NVARCHAR(1000) = 'master,model,msdb,tempdb', -- Set a list of exluded databases. Default exclusen are the system databases. @pLOGLEVEL NVARCHAR(25) = 'ERROR' -- Set to 'INFO','WARN' OR 'ERROR' (or NULL to disable), logging to table: [TBDD_MAINTAIN_DATABASE_LOG] ) -- 'INFO' includes Infos, Warnings and Errors, 'WARN' only warnings and Errors and 'ERROR' only Errors AS BEGIN SET NOCOUNT ON; -- declare new vars because of parameter sniffing DECLARE @CHECKDB BIT = ISNULL(@pCHECKDB,0), @SHRINKLOG BIT = ISNULL(@pSHRINKLOG,0), @SHRINKDB BIT = ISNULL(@pSHRINKDB,0), @SHRINKTEMPDB BIT = ISNULL(@pSHRINKTEMPDB,0), @REBUILDINDEX BIT = ISNULL(@pREBUILDINDEX,0), @RECOMPILEPROCEDURES BIT = ISNULL(@pRECOMPILEPROCEDURES,0), @CLEARQUERYCACHE BIT = ISNULL(@pCLEARQUERYCACHE,0), @FREESYSTEMCACHE BIT = ISNULL(@pFREESYSTEMCACHE,0), @FREESESSIONCACHE BIT = ISNULL(@pFREESESSIONCACHE,0), @CLEARDBPROCCACHE BIT = ISNULL(@pCLEARDBPROCCACHE,0), @UPDATESTATISTICS BIT = ISNULL(@pUPDATESTATISTICS,1), @REBUILDHEAPS BIT = ISNULL(@pREBUILDHEAPS,0), @MAINTAINCOLUMNSTORE BIT = ISNULL(@pMAINTAINCOLUMNSTORE,0), @CHECKFILEGROWTH BIT = ISNULL(@pCHECKFILEGROWTH,1), @CLEANLOGS BIT = ISNULL(@pCLEANLOGS,0), @LOGRETENTIONDAYS INT = ISNULL(@pLOGRETENTIONDAYS,90), @CYCLEERRORLOGS BIT = ISNULL(@pCYCLEERRORLOGS,0), @FORCE BIT = ISNULL(@pFORCE,0), @INCLUDEDB NVARCHAR(1000) = NULLIF(LTRIM(RTRIM(@pINCLUDEDB)),''), @EXCLUDEDB NVARCHAR(1000) = LTRIM(RTRIM(ISNULL(@pEXCLUDEDB,'master,model,msdb,tempdb'))), @LOGLEVEL NVARCHAR(25) = UPPER(LTRIM(RTRIM(ISNULL(@pLOGLEVEL,'ERROR')))); -- declare runtime vars DECLARE @MY_PROCEDURE_NAME NVARCHAR(128) = OBJECT_NAME(@@PROCID); DECLARE @ProcedureName NVARCHAR(128) = NULL, @DBName NVARCHAR(100) = NULL, @DBNameCount INT = 0, @RecoveryModelActual NVARCHAR(20) = NULL, @RecoveryModelTarget NVARCHAR(20) = 'SIMPLE', @UserAccessActual NVARCHAR(20) = NULL, @UserAccessTarget NVARCHAR(20) = 'RESTRICTED_USER', @LogFileStatus NVARCHAR(100) = NULL, @LogFileName NVARCHAR(100) = NULL, @CurrentLogFileSizeInMB INT = 0, @MinimumLogFileSizeInMB INT = 0, @MaximumLogFileSizeInMB INT = 0, @LogIsPercentGrowth BIT = 0, @LogGrowthValue INT = 0, @TargetLogFileSizeInMB INT = 0, @ProductVersion sql_variant, @ProductMainVersion INT, @ProductLevel sql_variant, @ProductEdition sql_variant, @SchemaName NVARCHAR(50), @TableName NVARCHAR(256), @IndexName NVARCHAR(256), @Fragmentation FLOAT, @IndexAction NVARCHAR(15), @DataFileName NVARCHAR(128), @DataFileCount INT = 0, @TempdbFileName NVARCHAR(128), @TempdbFileCount INT = 0, @HeapSchemaName NVARCHAR(50), @HeapTableName NVARCHAR(256), @HeapListCount INT = 0, @ColumnstoreSchemaName NVARCHAR(50), @ColumnstoreTableName NVARCHAR(256), @ColumnstoreIndexName NVARCHAR(256), @ColumnstoreDeletedPercent FLOAT, @ColumnstoreAction NVARCHAR(15), @ColumnstoreListCount INT = 0, @FileName NVARCHAR(128), @FileType NVARCHAR(10), @FileSizeInMB INT = 0, @FileGrowthDesc NVARCHAR(50), @FileMaxSizeInMB INT = 0, @FileMaxSizeText NVARCHAR(20), @FileIsPercentGrowth BIT = 0, @FileGrowthCount INT = 0, @LoginName NVARCHAR(50), @HostName NVARCHAR(50), @SessionID NVARCHAR(50) = NULL, @MySessionID NVARCHAR(50) = @@SPID, @SQLCommand NVARCHAR(MAX) = NULL, @RunStart DATETIME2(0) = SYSDATETIME(), @RunHasErrors BIT = 0, @HasMemoryOptimizedTables BIT = 0, @TableListCount INT = 0, @IndexListCount INT = 0, @ProcedureListCount INT = 0, @RETURN_STATUS INT = 0, @RETURN_STATUS_TEXT NVARCHAR(MAX) = 'START PROCEDURE [' + @MY_PROCEDURE_NAME + '] @ ' + CONVERT(varchar(50),GETDATE(),120), @RETURN_ERROR_TEXT NVARCHAR(MAX) = ''; ---------------------------------------------------------------------------------------------------------------------------- IF (@LOGRETENTIONDAYS < 0) BEGIN SET @LOGRETENTIONDAYS = 0; END; --=================================================-- Output parameters --================================================-- PRINT '===================================================================================================='; PRINT @return_status_text; PRINT ''; PRINT 'PARAMETER01 - @CHECKDB: ' + CONVERT(NVARCHAR(1),@CHECKDB); PRINT 'PARAMETER02 - @SHRINKLOG: ' + CONVERT(NVARCHAR(1),@SHRINKLOG); PRINT 'PARAMETER03 - @SHRINKDB: ' + CONVERT(NVARCHAR(1),@SHRINKDB); PRINT 'PARAMETER04 - @SHRINKTEMPDB: ' + CONVERT(NVARCHAR(1),@SHRINKTEMPDB); PRINT 'PARAMETER05 - @REBUILDINDEX: ' + CONVERT(NVARCHAR(1),@REBUILDINDEX); PRINT 'PARAMETER06 - @RECOMPILEPROCEDURES: ' + CONVERT(NVARCHAR(1),@RECOMPILEPROCEDURES); PRINT 'PARAMETER07 - @CLEARQUERYCACHE: ' + CONVERT(NVARCHAR(1),@CLEARQUERYCACHE); PRINT 'PARAMETER08 - @FREESYSTEMCACHE: ' + CONVERT(NVARCHAR(1),@FREESYSTEMCACHE); PRINT 'PARAMETER09 - @FREESESSIONCACHE: ' + CONVERT(NVARCHAR(1),@FREESESSIONCACHE); PRINT 'PARAMETER10 - @CLEARDBPROCCACHE: ' + CONVERT(NVARCHAR(1),@CLEARDBPROCCACHE); PRINT 'PARAMETER11 - @UPDATESTATISTICS: ' + CONVERT(NVARCHAR(1),@UPDATESTATISTICS); PRINT 'PARAMETER12 - @REBUILDHEAPS: ' + CONVERT(NVARCHAR(1),@REBUILDHEAPS); PRINT 'PARAMETER13 - @MAINTAINCOLUMNSTORE: ' + CONVERT(NVARCHAR(1),@MAINTAINCOLUMNSTORE); PRINT 'PARAMETER14 - @CHECKFILEGROWTH: ' + CONVERT(NVARCHAR(1),@CHECKFILEGROWTH); PRINT 'PARAMETER15 - @CLEANLOGS: ' + CONVERT(NVARCHAR(1),@CLEANLOGS); PRINT 'PARAMETER16 - @LOGRETENTIONDAYS: ' + CONVERT(NVARCHAR(10),@LOGRETENTIONDAYS); PRINT 'PARAMETER17 - @CYCLEERRORLOGS: ' + CONVERT(NVARCHAR(1),@CYCLEERRORLOGS); PRINT 'PARAMETER18 - @FORCE: ' + CONVERT(NVARCHAR(1),@FORCE); PRINT 'PARAMETER19 - @INCLUDEDB: ' + CONVERT(NVARCHAR(1000),@INCLUDEDB); PRINT 'PARAMETER20 - @EXCLUDEDB: ' + CONVERT(NVARCHAR(1000),@EXCLUDEDB); PRINT 'PARAMETER21 - @LOGLEVEL: ' + CONVERT(NVARCHAR(25),@LOGLEVEL); PRINT ''; ---------------------------------------------------------------------------------------------------------------------------- --=================================================-- Get server infos --==================================================-- SELECT @ProductVersion = SERVERPROPERTY('productversion'), @ProductLevel = SERVERPROPERTY ('productlevel'), @ProductEdition = SERVERPROPERTY ('edition'); SET @ProductMainVersion = ISNULL(LEFT(convert(NVARCHAR(100),@ProductVersion), CHARINDEX('.', convert(NVARCHAR(100),@ProductVersion)) - 1),0); PRINT 'Informations about this Server:'; PRINT '@MySessionID: ' + CONVERT(NVARCHAR(100),@MySessionID); PRINT '@ProductVersion: ' + CONVERT(NVARCHAR(100),@ProductVersion); PRINT '@ProductMainVersion: ' + CONVERT(NVARCHAR(100),@ProductMainVersion); PRINT '@ProductLevel: ' + CONVERT(NVARCHAR(100),@ProductLevel); PRINT '@ProductEdition: ' + CONVERT(NVARCHAR(100),@ProductEdition); ----------------------------------------------------------------------------------------------------------------------------- --==============================================-- Prepare the log table --================================================-- IF (@LOGLEVEL is not NULL) BEGIN PRINT ''; IF EXISTS (SELECT * FROM [INFORMATION_SCHEMA].[TABLES] WHERE [TABLE_NAME] = N'TBDD_MAINTAIN_DATABASE_LOG') BEGIN PRINT 'INFO: Log table already exists'; END ELSE BEGIN PRINT 'INFO: Log table does not exists, trying to create...'; CREATE TABLE [dbo].[TBDD_MAINTAIN_DATABASE_LOG]( [GUID] [bigint] IDENTITY(1,1) NOT NULL, [LOG_LEVEL] [nvarchar](25) NOT NULL, [MESSAGE1] [nvarchar](max) NOT NULL, [MESSAGE2] [nvarchar](max) NULL, [MESSAGE3] [nvarchar](max) NULL, [MESSAGE4] [nvarchar](max) NULL, [MESSAGE5] [nvarchar](max) NULL, [COMMENT] [nvarchar](max) NULL, [ADDED_WHO] [nvarchar](50) NOT NULL, [ADDED_WHEN] [datetime] NOT NULL, CONSTRAINT [PK_TBDD_MAINTAIN_DATABASE_LOG_GUID] PRIMARY KEY CLUSTERED ( [GUID] ASC ) WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, DATA_COMPRESSION = PAGE) ON [PRIMARY] ) ON [PRIMARY] TEXTIMAGE_ON [PRIMARY]; ALTER TABLE [dbo].[TBDD_MAINTAIN_DATABASE_LOG] ADD CONSTRAINT [DF_TBDD_MAINTAIN_DATABASE_LOG_ADDED_WHO] DEFAULT (SUSER_SNAME()) FOR [ADDED_WHO]; ALTER TABLE [dbo].[TBDD_MAINTAIN_DATABASE_LOG] ADD CONSTRAINT [DF_TBDD_MAINTAIN_DATABASE_LOG_ADDED_WHEN] DEFAULT (SYSDATETIME()) FOR [ADDED_WHEN]; END; END; ELSE BEGIN PRINT ''; PRINT 'WARN: Skipping Logging to log table!'; END; ----------------------------------------------------------------------------------------------------------------------------- --===============================================-- Check for log table --================================================-- IF NOT EXISTS (SELECT * FROM [INFORMATION_SCHEMA].[TABLES] WHERE [TABLE_NAME] = N'TBDD_MAINTAIN_DATABASE_LOG') BEGIN SET @LOGLEVEL = 'NONE'; PRINT 'ERROR: Because the log table [TBDD_MAINTAIN_DATABASE_LOG] does not exists, logging is disabled for this run!'; END; ----------------------------------------------------------------------------------------------------------------------------- --===============================================-- Log start to table --=================================================-- IF ((@LOGLEVEL in ('INFO')) and (@return_status is not null) and (@return_status_text is not null)) BEGIN INSERT INTO [TBDD_MAINTAIN_DATABASE_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN]) VALUES (@LOGLEVEL,'preparing', 'procedure', @return_status, @return_status_text, @MY_PROCEDURE_NAME, GetDate()); END; ----------------------------------------------------------------------------------------------------------------------------- --=============================================-- Get the dbs for the loop --==============================================-- -- Create a temporary table to hold the table names CREATE TABLE #DBList (DBName NVARCHAR(256)); IF (@ProductMainVersion >= 13) BEGIN IF (@INCLUDEDB is not NULL) BEGIN INSERT INTO #DBList(DBName) SELECT [name] as 'DBName' FROM [master].[sys].[databases] WHERE [name] IN (SELECT LTRIM(RTRIM([value])) FROM STRING_SPLIT(@INCLUDEDB, ',') WHERE LTRIM(RTRIM([value])) <> '') -- include these databases AND [state] = 0 -- database is online AND [is_in_standby] = 0; -- database is not read only for log shipping END; ELSE BEGIN INSERT INTO #DBList(DBName) SELECT [name] as 'DBName' FROM [master].[sys].[databases] WHERE [name] NOT IN (SELECT LTRIM(RTRIM([value])) FROM STRING_SPLIT(@EXCLUDEDB, ',') WHERE LTRIM(RTRIM([value])) <> '') -- exclude these databases AND [state] = 0 -- database is online AND [is_in_standby] = 0; -- database is not read only for log shipping END; END; ELSE BEGIN PRINT 'WARN: Because of the SQL Version only one DB can be processed!' INSERT INTO #DBList(DBName) SELECT [name] as 'DBName' FROM [master].[sys].[databases] WHERE [name] = ISNULL(@INCLUDEDB,DB_NAME()) -- use only this database AND [state] = 0 -- database is online AND [is_in_standby] = 0; -- database is not read only for log shipping END; SELECT @DBNameCount = COUNT(*) FROM #DBList; ----------------------------------------------------------------------------------------------------------------------------- SET @return_status_text = 'INFO: Found ' + convert(VARCHAR,@DBNameCount) + ' database(s) to process!'; PRINT @return_status_text; --===============================================-- Log result to table --=================================================-- IF (@LOGLEVEL in ('INFO','WARN')) BEGIN INSERT INTO [TBDD_MAINTAIN_DATABASE_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN]) VALUES (@LOGLEVEL, 'db_list', 'count', @return_status, @return_status_text, @MY_PROCEDURE_NAME, GetDate()); END; ----------------------------------------------------------------------------------------------------------------------------- --==========================================-- Create the main loop (cursor) --============================================-- IF (@DBNameCount > 0) BEGIN DECLARE db_cursor CURSOR STATIC LOCAL FOR SELECT [DBName] as 'DBName' FROM #DBList; OPEN db_cursor FETCH NEXT FROM db_cursor INTO @DBName WHILE @@FETCH_STATUS = 0 BEGIN PRINT ' '; PRINT '-------------------------------'; PRINT 'INFO: Now processing: ' + CONVERT(varchar(100),@DBName); SET @return_status = 0; SET @HasMemoryOptimizedTables = 0; --=====================================-- Detect memory-optimized tables --===========================================-- BEGIN TRY SET @SQLCommand = N'SELECT @HasMemoryOptimizedTablesOUT = CASE WHEN EXISTS (SELECT 1 FROM [' + @DBName + '].[sys].[tables] WHERE [is_memory_optimized] = 1) THEN 1 ELSE 0 END;'; EXEC sp_executesql @SQLCommand, N'@HasMemoryOptimizedTablesOUT BIT OUTPUT', @HasMemoryOptimizedTables OUTPUT; IF (@HasMemoryOptimizedTables = 1) BEGIN SET @return_status_text = 'WARN: Memory-optimized tables detected in database [' + @DBName + ']. For safety, the following actions are skipped: SHRINKDB, REBUILDHEAPS, REBUILDINDEX, MAINTAINCOLUMNSTORE.'; PRINT @return_status_text; END; ELSE IF (@LOGLEVEL in ('INFO')) BEGIN SET @return_status_text = 'INFO: No memory-optimized tables detected in database [' + @DBName + '].'; PRINT @return_status_text; END; END TRY BEGIN CATCH SELECT ERROR_MESSAGE() AS ErrorMessage; SET @RunHasErrors = 1; SET @return_status = -1; SET @HasMemoryOptimizedTables = 1; SET @return_status_text = 'WARN: Detection of memory-optimized tables failed for database [' + @DBName + ']. Safety mode enabled: SHRINKDB, REBUILDHEAPS, REBUILDINDEX, MAINTAINCOLUMNSTORE are skipped.'; PRINT @return_status_text; END CATCH; IF ((@LOGLEVEL in ('INFO','WARN')) and (@return_status is not null) and (@return_status_text is not null)) BEGIN INSERT INTO [TBDD_MAINTAIN_DATABASE_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN]) VALUES (@LOGLEVEL, 'memory_optimized', @DBName, @return_status, @return_status_text, @MY_PROCEDURE_NAME, GetDate()); END; ----------------------------------------------------------------------------------------------------------------------------- --==============================================-- Change db working mode --===============================================-- IF (@FORCE = 1) and (@return_status = 0) BEGIN PRINT 'INFO: Closing active database connections... first time'; DECLARE kill_cursor CURSOR STATIC LOCAL FOR SELECT CONVERT(NVARCHAR(5), [session_id]) as 'SessionID', CONVERT(NVARCHAR(50), [login_name]) as 'LoginName', CONVERT(NVARCHAR(50), [host_name]) as 'HostName' FROM [master].[sys].[dm_exec_sessions] WHERE [is_user_process] = 1 AND [database_id] = db_id(@DBName) AND [session_id] <> @MySessionID; OPEN kill_cursor; FETCH NEXT FROM kill_cursor INTO @SessionID, @LoginName, @HostName; WHILE @@FETCH_STATUS = 0 BEGIN BEGIN TRY SET @SQLCommand = 'KILL ' + @SessionID + ';'; PRINT 'INFO: Killing @SessionID: ' + @SessionID + ', @LoginName: ' + @LoginName + ', @HostName: ' + @HostName; EXEC sp_executesql @SQLCommand; SET @SQLCommand = NULL; IF ((@LOGLEVEL in ('INFO')) and (@return_status = 0)) BEGIN SET @return_status_text = 'INFO: Closing connections to database was successfully completed!'; PRINT @return_status_text; END; ELSE IF ((@LOGLEVEL in ('WARN')) and (@return_status <> 0)) BEGIN SET @return_status_text = 'WARN: Closing connections to database returns warnings or has failed, check the ID!'; PRINT @return_status_text; END; --===============================================-- Log result to table --=================================================-- IF ((@LOGLEVEL in ('INFO','WARN')) and (@return_status is not null) and (@return_status_text is not null)) BEGIN INSERT INTO [TBDD_MAINTAIN_DATABASE_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN]) VALUES (@LOGLEVEL, 'kill_cursor', @DBName, @return_status, @return_status_text, @MY_PROCEDURE_NAME, GetDate()); END; ----------------------------------------------------------------------------------------------------------------------------- END TRY BEGIN CATCH -- Handle any errors that occur during the process. SELECT ERROR_MESSAGE() AS ErrorMessage; SET @RunHasErrors = 1; SET @return_status = -1; SET @SQLCommand = NULL; --===============================================-- Log result to table --=================================================-- IF ((@LOGLEVEL in ('INFO','WARN','ERROR')) and (@return_status is not null) and (@return_status_text is not null)) BEGIN INSERT INTO [TBDD_MAINTAIN_DATABASE_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [ADDED_WHO], [ADDED_WHEN]) VALUES ('ERROR', 'kill_cursor', @DBName, ERROR_MESSAGE(),@MY_PROCEDURE_NAME, GetDate()); END; ----------------------------------------------------------------------------------------------------------------------------- END CATCH; FETCH NEXT FROM kill_cursor INTO @SessionID, @LoginName, @HostName; END; CLOSE kill_cursor; DEALLOCATE kill_cursor; ----------------------------------------------------------------------------------------------------------------------------- --=========================================-- Get current user access level --=============================================-- SET @UserAccessActual = (SELECT [user_access_desc] FROM [sys].[databases] WHERE NAME = @DBName); IF ((@LOGLEVEL in ('INFO')) and (@return_status = 0)) BEGIN SET @return_status_text = 'INFO: Currently the user access level is set to: ' + @UserAccessActual; PRINT @return_status_text; END ELSE IF ((@LOGLEVEL in ('WARN')) and (@return_status <> 0)) BEGIN SET @return_status_text = 'WARN: Currently the user access level is set to: ' + @UserAccessActual; PRINT @return_status_text; END; ----------------------------------------------------------------------------------------------------------------------------- --===============================================-- Log result to table --=================================================-- IF ((@LOGLEVEL in ('INFO','WARN')) and (@return_status is not null) and (@return_status_text is not null)) BEGIN INSERT INTO [TBDD_MAINTAIN_DATABASE_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN]) VALUES (@LOGLEVEL,'db_cursor', @DBName, @return_status, @return_status_text, @MY_PROCEDURE_NAME, GetDate()); END; ----------------------------------------------------------------------------------------------------------------------------- --==============================================-- Switch db operation mode --=============================================-- IF (@CHECKDB = 1) BEGIN PRINT 'INFO: Set the database to SINGLE_USER mode to avoid multiple active sessions.'; SET @SQLCommand = N'ALTER DATABASE [' + @DBName + '] SET SINGLE_USER WITH ROLLBACK IMMEDIATE;'; EXEC @return_status = sp_executesql @SQLCommand; IF ((@LOGLEVEL in ('INFO')) and (@return_status = 0)) BEGIN SET @return_status_text = 'INFO: Setting the database to SINGLE_USER mode was successfully completed!'; PRINT @return_status_text; END; ELSE IF ((@LOGLEVEL in ('WARN')) and (@return_status <> 0)) BEGIN SET @return_status_text = 'WARN: Setting the database to SINGLE_USER mode returns warnings or has failed, check the ID!'; PRINT @return_status_text; END; END; ELSE BEGIN PRINT 'INFO: Set the database to ' + @UserAccessTarget + ' mode to avoid multiple active sessions.'; SET @SQLCommand = N'ALTER DATABASE [' + @DBName + '] SET ' + @UserAccessTarget + ' WITH ROLLBACK IMMEDIATE;'; EXEC @return_status = sp_executesql @SQLCommand; IF ((@LOGLEVEL in ('INFO')) and (@return_status = 0)) BEGIN SET @return_status_text = 'INFO: Setting the database to ' + @UserAccessTarget + ' mode was successfully completed!'; PRINT @return_status_text; END; ELSE IF ((@LOGLEVEL in ('WARN')) and (@return_status <> 0)) BEGIN SET @return_status_text = 'WARN: Setting the database to ' + @UserAccessTarget + ' mode returns warnings or has failed, check the ID!'; PRINT @return_status_text; END; END; ----------------------------------------------------------------------------------------------------------------------------- --===============================================-- Log result to table --=================================================-- IF ((@LOGLEVEL in ('INFO','WARN')) and (@return_status is not null) and (@return_status_text is not null)) BEGIN INSERT INTO [TBDD_MAINTAIN_DATABASE_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN]) VALUES (@LOGLEVEL, 'db_cursor', @DBName, @return_status, @return_status_text, @MY_PROCEDURE_NAME, GetDate()); END; ----------------------------------------------------------------------------------------------------------------------------- END; ELSE BEGIN IF (@LOGLEVEL in ('INFO')) BEGIN SET @return_status_text = 'INFO: Skipping to change the database mode (FORCE = OFF)!'; PRINT @return_status_text; END; --===============================================-- Log result to table --=================================================-- IF ((@LOGLEVEL in ('INFO','WARN')) and (@return_status is not null) and (@return_status_text is not null)) BEGIN INSERT INTO [TBDD_MAINTAIN_DATABASE_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN]) VALUES (@LOGLEVEL, 'db_cursor', @DBName, @return_status, @return_status_text, @MY_PROCEDURE_NAME, GetDate()); END; ----------------------------------------------------------------------------------------------------------------------------- END; ----------------------------------------------------------------------------------------------------------------------------- --===============================================-- Check db consistency --================================================-- IF (@CHECKDB = 1) and (@return_status = 0) BEGIN --==========================================-- Get current recovery modell --==============================================-- SET @RecoveryModelActual = (SELECT [recovery_model_desc] FROM [sys].[databases] WHERE NAME = @DBName); IF ((@LOGLEVEL in ('INFO')) and (@return_status = 0)) BEGIN SET @return_status_text = 'INFO: Currently the recovery mode is set to: ' + @RecoveryModelActual; PRINT @return_status_text; END; ELSE IF ((@LOGLEVEL in ('WARN')) and (@return_status <> 0)) BEGIN SET @return_status_text = 'WARN: Currently the recovery mode is set to: ' + @RecoveryModelActual; PRINT @return_status_text; END; ----------------------------------------------------------------------------------------------------------------------------- --===============================================-- Log result to table --=================================================-- IF ((@LOGLEVEL in ('INFO','WARN')) and (@return_status is not null) and (@return_status_text is not null)) BEGIN INSERT INTO [TBDD_MAINTAIN_DATABASE_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN]) VALUES (@LOGLEVEL,'db_cursor', @DBName, @return_status, @return_status_text, @MY_PROCEDURE_NAME, GetDate()); END; ----------------------------------------------------------------------------------------------------------------------------- IF (@FORCE = 1) BEGIN PRINT 'INFO: Check the database for consistency and health and try soft repair.'; SET @SQLCommand = N'USE [' + @DBName + ']; ALTER DATABASE [' + @DBName + '] SET RECOVERY ' + @RecoveryModelTarget + '; DBCC CHECKDB ([' + @DBName + '],REPAIR_REBUILD) WITH NO_INFOMSGS, ALL_ERRORMSGS; ALTER DATABASE [' + @DBName + '] SET RECOVERY ' + @RecoveryModelActual + ';'; END; ELSE BEGIN PRINT 'INFO: Check the database for consistency and health.'; SET @SQLCommand = N'USE [' + @DBName + ']; ALTER DATABASE [' + @DBName + '] SET RECOVERY ' + @RecoveryModelTarget + '; DBCC CHECKDB ([' + @DBName + ']) WITH NO_INFOMSGS, ALL_ERRORMSGS; ALTER DATABASE [' + @DBName + '] SET RECOVERY ' + @RecoveryModelActual + ';'; END; EXEC @return_status = sp_executesql @SQLCommand; IF ((@LOGLEVEL in ('INFO')) and (@return_status = 0)) BEGIN SET @return_status_text = 'INFO: Check the database for consistency and health was successfully completed!'; PRINT @return_status_text; END; ELSE IF ((@LOGLEVEL in ('WARN')) and (@return_status <> 0)) BEGIN SET @return_status_text = 'WARN: Check the database for consistency and health returns warnings or has failed, check the ID!'; PRINT @return_status_text; END; END; ELSE BEGIN IF (@LOGLEVEL in ('INFO')) BEGIN SET @return_status_text = 'INFO: Skipping the database check for consistency and health!'; PRINT @return_status_text; END; END; ----------------------------------------------------------------------------------------------------------------------------- --===============================================-- Log result to table --=================================================-- IF ((@LOGLEVEL in ('INFO','WARN')) and (@return_status is not null) and (@return_status_text is not null)) BEGIN INSERT INTO [TBDD_MAINTAIN_DATABASE_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN]) VALUES (@LOGLEVEL, 'db_cursor', @DBName, @return_status, @return_status_text, @MY_PROCEDURE_NAME, GetDate()); END; ----------------------------------------------------------------------------------------------------------------------------- --=========================================-- Get current user access level --=============================================-- SET @UserAccessActual = (SELECT [user_access_desc] FROM [sys].[databases] WHERE NAME = @DBName); IF ((@LOGLEVEL in ('INFO')) and (@return_status = 0)) BEGIN SET @return_status_text = 'INFO: Currently the user access level is set to: ' + @UserAccessActual; PRINT @return_status_text; END; ELSE IF ((@LOGLEVEL in ('WARN')) and (@return_status <> 0)) BEGIN SET @return_status_text = 'WARN: Currently the user access level is set to: ' + @UserAccessActual; PRINT @return_status_text; END; ----------------------------------------------------------------------------------------------------------------------------- --===============================================-- Log result to table --=================================================-- IF ((@LOGLEVEL in ('INFO','WARN')) and (@return_status is not null) and (@return_status_text is not null)) BEGIN INSERT INTO [TBDD_MAINTAIN_DATABASE_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN]) VALUES (@LOGLEVEL,'db_cursor', @DBName, @return_status, @return_status_text, @MY_PROCEDURE_NAME, GetDate()); END; ----------------------------------------------------------------------------------------------------------------------------- --===========================================-- Switch db operation mode back --===========================================-- IF ((@CHECKDB <> 1) AND (@UserAccessActual = @UserAccessTarget)) BEGIN PRINT 'INFO: Set the database back to MULTI_USER mode to allow multiple active sessions.'; SET @SQLCommand = N'ALTER DATABASE [' + @DBName + '] SET MULTI_USER WITH ROLLBACK IMMEDIATE;'; EXEC @return_status = sp_executesql @SQLCommand; IF ((@LOGLEVEL in ('INFO')) and (@return_status = 0)) BEGIN SET @return_status_text = 'INFO: Setting the database to MULTI_USER mode was successfully completed!'; PRINT @return_status_text; END; ELSE IF ((@LOGLEVEL in ('WARN')) and (@return_status <> 0)) BEGIN SET @return_status_text = 'WARN: Setting the database to MULTI_USER mode returns warnings or has failed, check the ID!'; PRINT @return_status_text; END; END; ----------------------------------------------------------------------------------------------------------------------------- --===============================================-- Log result to table --=================================================-- IF ((@LOGLEVEL in ('INFO','WARN')) and (@return_status is not null) and (@return_status_text is not null)) BEGIN INSERT INTO [TBDD_MAINTAIN_DATABASE_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN]) VALUES (@LOGLEVEL, 'db_cursor', @DBName, @return_status, @return_status_text, @MY_PROCEDURE_NAME, GetDate()); END; ----------------------------------------------------------------------------------------------------------------------------- --==========================================-- Rebuild heaps with forwarded records --========================================-- IF ((@REBUILDHEAPS = 1) and (@return_status = 0) and (@HasMemoryOptimizedTables = 0)) BEGIN PRINT 'INFO: Prepare to rebuild heaps with forwarded records.'; BEGIN TRY DROP TABLE #HeapList; END TRY BEGIN CATCH PRINT 'INFO: #HeapList Temp table is already gone... (1)'; END CATCH; -- Create a temporary table to hold heap tables CREATE TABLE #HeapList (SchemaName NVARCHAR(50), TableName NVARCHAR(256)); -- Set the context to the specified database and fill the temporary table SET @SQLCommand = 'INSERT INTO #HeapList (SchemaName, TableName) SELECT DISTINCT s.[name], t.[name] FROM [' + @DBName + '].[sys].[tables] t INNER JOIN [' + @DBName + '].[sys].[schemas] s ON t.[schema_id] = s.[schema_id] INNER JOIN [' + @DBName + '].[sys].[indexes] i ON t.[object_id] = i.[object_id] INNER JOIN sys.dm_db_index_physical_stats(DB_ID(''' + @DBName + '''), NULL, NULL, NULL, ''LIMITED'') ips ON i.[object_id] = ips.[object_id] AND i.[index_id] = ips.[index_id] WHERE i.[type] = 0 AND ips.[index_id] = 0 AND ips.forwarded_record_count > 0;'; EXEC @return_status = sp_executesql @SQLCommand; IF ((@LOGLEVEL in ('INFO')) and (@return_status = 0)) BEGIN SET @return_status_text = 'INFO: Getting the heaps was successfully done!'; PRINT @return_status_text; END; ELSE IF ((@LOGLEVEL in ('WARN')) and (@return_status <> 0)) BEGIN SET @return_status_text = 'WARN: Getting the heaps returns warnings or has failed, check the ID!'; PRINT @return_status_text; END; IF (@return_status = 0) BEGIN SELECT @HeapListCount = COUNT(*) FROM #HeapList; PRINT 'INFO: Found: ' + convert(VARCHAR,@HeapListCount) + ' heaps to rebuild'; END; ELSE BEGIN SET @HeapListCount = 0; PRINT 'WARN: Found: no heaps to rebuild'; END; END; ELSE BEGIN IF ((@REBUILDHEAPS = 1) and (@HasMemoryOptimizedTables = 1)) BEGIN SET @return_status_text = 'WARN: Skipping rebuilding heaps because memory-optimized tables were detected in database [' + @DBName + '].'; PRINT @return_status_text; END; ELSE IF (@LOGLEVEL in ('INFO')) BEGIN SET @return_status_text = 'INFO: Skipping rebuilding heaps!'; PRINT @return_status_text; END; END; --===============================================-- Log result to table --=================================================-- IF ((@LOGLEVEL in ('INFO','WARN')) and (@return_status is not null) and (@return_status_text is not null)) BEGIN INSERT INTO [TBDD_MAINTAIN_DATABASE_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN]) VALUES (@LOGLEVEL, 'db_cursor', @DBName, @return_status, @return_status_text, @MY_PROCEDURE_NAME, GetDate()); END; ------------------------------------------------------------------------------------------------------------------------------ IF ((@REBUILDHEAPS = 1) and (@return_status = 0) and (@HeapListCount > 0) and (@HasMemoryOptimizedTables = 0)) BEGIN DECLARE heap_cursor CURSOR STATIC LOCAL FOR SELECT SchemaName, TableName FROM #HeapList; OPEN heap_cursor; FETCH NEXT FROM heap_cursor INTO @HeapSchemaName, @HeapTableName; WHILE @@FETCH_STATUS = 0 BEGIN BEGIN TRY PRINT 'INFO: Rebuild heap table: ' + CONVERT(VARCHAR(1000),@HeapSchemaName + '.' + @HeapTableName); SET @SQLCommand = 'USE [' + @DBName + ']; ALTER TABLE [' + @HeapSchemaName + '].[' + @HeapTableName + '] REBUILD;'; EXEC @return_status = sp_executesql @SQLCommand; IF ((@LOGLEVEL in ('INFO')) and (@return_status = 0)) BEGIN SET @return_status_text = 'INFO: Heap table [' + @HeapSchemaName + '].[' + @HeapTableName + '] successfully rebuilt!'; PRINT @return_status_text; END; ELSE IF ((@LOGLEVEL in ('WARN')) and (@return_status <> 0)) BEGIN SET @return_status_text = 'WARN: Heap table [' + @HeapSchemaName + '].[' + @HeapTableName + '] returns warnings or has failed, check the ID!'; PRINT @return_status_text; END; --===============================================-- Log result to table --=================================================-- IF ((@LOGLEVEL in ('INFO','WARN')) and (@return_status is not null) and (@return_status_text is not null)) BEGIN INSERT INTO [TBDD_MAINTAIN_DATABASE_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN]) VALUES (@LOGLEVEL, 'heap_cursor', @DBName, @return_status, @return_status_text, @MY_PROCEDURE_NAME, GetDate()); END; ------------------------------------------------------------------------------------------------------------------------------ END TRY BEGIN CATCH -- Handle any errors that occur during the process. SELECT ERROR_MESSAGE() AS ErrorMessage; SET @RunHasErrors = 1; SET @return_status = -1; --================================================-- Log error to table --=================================================-- IF (@LOGLEVEL in ('INFO','WARN','ERROR')) BEGIN INSERT INTO [TBDD_MAINTAIN_DATABASE_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [ADDED_WHO], [ADDED_WHEN]) VALUES ('ERROR', 'heap_cursor', @DBName, ERROR_MESSAGE(),@MY_PROCEDURE_NAME, GetDate()); END; ------------------------------------------------------------------------------------------------------------------------------ END CATCH; FETCH NEXT FROM heap_cursor INTO @HeapSchemaName, @HeapTableName; END; CLOSE heap_cursor; DEALLOCATE heap_cursor; -- Drop the temporary table DROP TABLE #HeapList; SET @return_status_text = 'INFO: Rebuilding heaps successfully completed!'; PRINT @return_status_text; END; ELSE BEGIN IF ((@REBUILDHEAPS = 1) and (@HasMemoryOptimizedTables = 1)) BEGIN SET @return_status_text = 'WARN: Skipping heap rebuild execution because memory-optimized tables were detected in database [' + @DBName + '].'; PRINT @return_status_text; END; ELSE IF (@LOGLEVEL in ('INFO')) BEGIN SET @return_status_text = 'INFO: Skipping the heap rebuild execution!'; PRINT @return_status_text; END; END; ------------------------------------------------------------------------------------------------------------------------------ --=============================================-- Rebuild database indexes --==============================================-- IF ((@REBUILDINDEX = 1) and (@return_status = 0) and (@HasMemoryOptimizedTables = 0)) BEGIN PRINT 'INFO: Prepare to maintain database indexes (reorganize/rebuild by fragmentation).'; BEGIN TRY DROP TABLE #TableList; END TRY BEGIN CATCH PRINT 'INFO: #TableList Temp table is already gone... (1)'; END CATCH; BEGIN TRY DROP TABLE #IndexList; END TRY BEGIN CATCH PRINT 'INFO: #IndexList Temp table is already gone... (1)'; END CATCH; -- Create a temporary table to hold the table names CREATE TABLE #TableList (SchemaName NVARCHAR(50), TableName NVARCHAR(256)); -- Set the context to the specified database and fill the temporary table SET @SQLCommand = ' INSERT INTO #TableList (SchemaName, TableName) SELECT DISTINCT (SCHEMA_NAME([schema_id])), t.[name] FROM [' + @DBName + '].[sys].[tables] t INNER JOIN [' + @DBName + '].[sys].[indexes] i ON t.[object_id] = i.[object_id] WHERE i.[type] IN (1, 2) -- Clustered and Non-Clustered indexes;'; EXEC @return_status = sp_executesql @SQLCommand; IF ((@LOGLEVEL in ('INFO')) and (@return_status = 0)) BEGIN SET @return_status_text = 'INFO: Getting the tables was successfully done!'; PRINT @return_status_text; END; ELSE IF ((@LOGLEVEL in ('WARN')) and (@return_status <> 0)) BEGIN SET @return_status_text = 'WARN: Getting the tables returns warnings or has failed, check the ID!'; PRINT @return_status_text; END; IF (@return_status = 0) BEGIN SELECT @TableListCount = COUNT(*) FROM #TableList; PRINT 'INFO: Found: ' + convert(VARCHAR,@TableListCount) + ' tables to reindex'; END; ELSE BEGIN SET @TableListCount = 0; PRINT 'WARN: Found: no tables to reindex'; END; END; ELSE BEGIN IF ((@REBUILDINDEX = 1) and (@HasMemoryOptimizedTables = 1)) BEGIN SET @return_status_text = 'WARN: Skipping rebuilding database indexes because memory-optimized tables were detected in database [' + @DBName + '].'; PRINT @return_status_text; END; ELSE IF (@LOGLEVEL in ('INFO')) BEGIN SET @return_status_text = 'INFO: Skipping rebuilding database indexes!'; PRINT @return_status_text; END; END; --===============================================-- Log result to table --=================================================-- IF ((@LOGLEVEL in ('INFO','WARN')) and (@return_status is not null) and (@return_status_text is not null)) BEGIN INSERT INTO [TBDD_MAINTAIN_DATABASE_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN]) VALUES (@LOGLEVEL, 'db_cursor', @DBName, @return_status, @return_status_text, @MY_PROCEDURE_NAME, GetDate()); END; ----------------------------------------------------------------------------------------------------------------------------- IF ((@REBUILDINDEX = 1) and (@return_status = 0) and (@TableListCount > 0) and (@HasMemoryOptimizedTables = 0)) BEGIN DECLARE table_cursor CURSOR STATIC LOCAL FOR SELECT SchemaName, TableName FROM #TableList; OPEN table_cursor; FETCH NEXT FROM table_cursor INTO @SchemaName, @TableName; WHILE @@FETCH_STATUS = 0 BEGIN BEGIN TRY PRINT 'INFO: Maintain indexes for table: ' + CONVERT(VARCHAR(1000),@TableName); SET @IndexListCount = 0; --======================================-- Prepare index list with fragmentation --=======================================-- BEGIN TRY DROP TABLE #IndexList; END TRY BEGIN CATCH PRINT 'INFO: #IndexList Temp table is already gone... (2)'; END CATCH; CREATE TABLE #IndexList (IndexName NVARCHAR(256), Fragmentation FLOAT); SET @SQLCommand = 'INSERT INTO #IndexList (IndexName, Fragmentation) SELECT i.[name], ips.avg_fragmentation_in_percent FROM sys.dm_db_index_physical_stats(DB_ID(''' + @DBName + '''), OBJECT_ID(''' + QUOTENAME(@DBName) + '.' + QUOTENAME(@SchemaName) + '.' + QUOTENAME(@TableName) + '''), NULL, NULL, ''LIMITED'') ips INNER JOIN [' + @DBName + '].sys.indexes i ON ips.[object_id] = i.[object_id] AND ips.[index_id] = i.[index_id] WHERE i.[type] IN (1,2) AND ips.[index_id] > 0 AND ips.avg_fragmentation_in_percent IS NOT NULL;'; EXEC @return_status = sp_executesql @SQLCommand; IF ((@LOGLEVEL in ('INFO')) and (@return_status = 0)) BEGIN SET @return_status_text = 'INFO: Collected index fragmentation data for table [' + @TableName + ']'; PRINT @return_status_text; END; ELSE IF ((@LOGLEVEL in ('WARN')) and (@return_status <> 0)) BEGIN SET @return_status_text = 'WARN: Collecting index fragmentation data for table [' + @TableName + '] returned warnings or failed, check the ID!'; PRINT @return_status_text; END; SELECT @IndexListCount = COUNT(*) FROM #IndexList; PRINT 'INFO: Found: ' + CONVERT(VARCHAR,@IndexListCount) + ' indexes to process'; --======================================-- Process indexes per fragmentation --=======================================-- IF (@IndexListCount > 0) BEGIN DECLARE index_cursor CURSOR STATIC LOCAL FOR SELECT IndexName, Fragmentation FROM #IndexList; OPEN index_cursor; FETCH NEXT FROM index_cursor INTO @IndexName, @Fragmentation; WHILE @@FETCH_STATUS = 0 BEGIN BEGIN TRY SET @IndexAction = CASE WHEN @Fragmentation < 5 THEN 'NOTHING' WHEN @Fragmentation >= 5 AND @Fragmentation < 30 THEN 'REORGANIZE' ELSE 'REBUILD' END; PRINT 'INFO: Maintain index: ' + CONVERT(VARCHAR(1000),@IndexName) + ' (Fragmentation: ' + CONVERT(VARCHAR(20),@Fragmentation) + '%) -> Do: ' + @IndexAction; IF (@IndexAction = 'REORGANIZE') BEGIN SET @SQLCommand = 'ALTER INDEX [' + @IndexName + '] ON [' + @DBName + '].[' + @SchemaName + '].[' + @TableName + '] REORGANIZE;'; END; ELSE IF (@IndexAction = 'REBUILD') BEGIN SET @SQLCommand = 'ALTER INDEX [' + @IndexName + '] ON [' + @DBName + '].[' + @SchemaName + '].[' + @TableName + '] REBUILD WITH (FILLFACTOR = 80, SORT_IN_TEMPDB = ON, STATISTICS_NORECOMPUTE = ON);'; END; ELSE BEGIN SET @SQLCommand = NULL; PRINT 'INFO: Skipping index maintenance for index [' + @IndexName + '] because fragmentation is below threshold.'; END; IF (@SQLCommand is not NULL) BEGIN EXEC @return_status = sp_executesql @SQLCommand; END; ELSE BEGIN SET @return_status = 0; END; IF ((@LOGLEVEL in ('INFO')) and (@return_status = 0)) BEGIN SET @return_status_text = 'INFO: Index [' + @IndexName + ']; "Do: ' + LOWER(@IndexAction) + '" successfully completed!'; PRINT @return_status_text; END; ELSE IF ((@LOGLEVEL in ('WARN')) and (@return_status <> 0)) BEGIN SET @return_status_text = 'WARN: Index [' + @IndexName + ']; "Do: ' + LOWER(@IndexAction) + '" returns warnings or has failed, check the ID!'; PRINT @return_status_text; END; --===============================================-- Log result to table --=================================================-- IF ((@LOGLEVEL in ('INFO','WARN')) and (@return_status is not null) and (@return_status_text is not null)) BEGIN INSERT INTO [TBDD_MAINTAIN_DATABASE_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN]) VALUES (@LOGLEVEL, 'index_cursor', @DBName, @return_status, @return_status_text, @MY_PROCEDURE_NAME, GetDate()); END; ----------------------------------------------------------------------------------------------------------------------------- END TRY BEGIN CATCH -- Handle any errors that occur during the process. SELECT ERROR_MESSAGE() AS ErrorMessage; SET @RunHasErrors = 1; SET @return_status = -1; --================================================-- Log error to table --=================================================-- IF (@LOGLEVEL in ('INFO','WARN','ERROR')) BEGIN INSERT INTO [TBDD_MAINTAIN_DATABASE_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [ADDED_WHO], [ADDED_WHEN]) VALUES ('ERROR', 'index_cursor', @DBName, ERROR_MESSAGE(),@MY_PROCEDURE_NAME, GetDate()); END; ----------------------------------------------------------------------------------------------------------------------------- END CATCH; FETCH NEXT FROM index_cursor INTO @IndexName, @Fragmentation; END; CLOSE index_cursor; DEALLOCATE index_cursor; END; ELSE BEGIN PRINT 'WARN: No indexes found to reorganize or rebuild on table [' + @TableName + ']'; END; -- Drop the temporary table DROP TABLE #IndexList; SET @return_status_text = 'INFO: Index maintenance for table [' + @TableName + '] successfully completed!'; PRINT @return_status_text; --===============================================-- Log result to table --=================================================-- IF ((@LOGLEVEL in ('INFO','WARN')) and (@return_status is not null) and (@return_status_text is not null)) BEGIN INSERT INTO [TBDD_MAINTAIN_DATABASE_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN]) VALUES (@LOGLEVEL, 'table_cursor', @DBName, @return_status, @return_status_text, @MY_PROCEDURE_NAME, GetDate()); END; ----------------------------------------------------------------------------------------------------------------------------- -- Short break to avoid access violations WAITFOR DELAY '00:00:03'; ----------------------------------------------------------------------------------------------------------------------------- IF (@FORCE = 1) BEGIN PRINT 'INFO: Closing active database connections... again'; DECLARE kill_cursor CURSOR STATIC LOCAL FOR SELECT CONVERT(NVARCHAR(5), [session_id]) as 'SessionID', CONVERT(NVARCHAR(50), [login_name]) as 'LoginName', CONVERT(NVARCHAR(50), [host_name]) as 'HostName' FROM [master].[sys].[dm_exec_sessions] WHERE [is_user_process] = 1 AND [database_id] = db_id(@DBName) AND [session_id] <> @MySessionID; OPEN kill_cursor; FETCH NEXT FROM kill_cursor INTO @SessionID, @LoginName, @HostName; WHILE @@FETCH_STATUS = 0 BEGIN BEGIN TRY SET @SQLCommand = 'KILL ' + @SessionID + ';'; PRINT 'INFO: Killing @SessionID: ' + @SessionID + ', @LoginName: ' + @LoginName + ', @HostName: ' + @HostName; EXEC sp_executesql @SQLCommand; SET @SQLCommand = NULL; IF ((@LOGLEVEL in ('INFO')) and (@return_status = 0)) BEGIN SET @return_status_text = 'INFO: Closing connections to database was successfully completed!'; PRINT @return_status_text; END; ELSE IF ((@LOGLEVEL in ('WARN')) and (@return_status <> 0)) BEGIN SET @return_status_text = 'WARN: Closing connections to database returns warnings or has failed, check the ID!'; PRINT @return_status_text; END; --===============================================-- Log result to table --=================================================-- IF ((@LOGLEVEL in ('INFO','WARN')) and (@return_status is not null) and (@return_status_text is not null)) BEGIN INSERT INTO [TBDD_MAINTAIN_DATABASE_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN]) VALUES (@LOGLEVEL, 'kill_cursor', @DBName, @return_status, @return_status_text, @MY_PROCEDURE_NAME, GetDate()); END; ----------------------------------------------------------------------------------------------------------------------------- END TRY BEGIN CATCH -- Handle any errors that occur during the process. SELECT ERROR_MESSAGE() AS ErrorMessage; SET @RunHasErrors = 1; SET @return_status = -1; SET @SQLCommand = NULL; --===============================================-- Log result to table --=================================================-- IF ((@LOGLEVEL in ('INFO','WARN','ERROR')) and (@return_status is not null) and (@return_status_text is not null)) BEGIN INSERT INTO [TBDD_MAINTAIN_DATABASE_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [ADDED_WHO], [ADDED_WHEN]) VALUES ('ERROR', 'kill_cursor', @DBName, ERROR_MESSAGE(),@MY_PROCEDURE_NAME, GetDate()); END; ----------------------------------------------------------------------------------------------------------------------------- END CATCH; FETCH NEXT FROM kill_cursor INTO @SessionID, @LoginName, @HostName; END; CLOSE kill_cursor; DEALLOCATE kill_cursor; ----------------------------------------------------------------------------------------------------------------------------- END; FETCH NEXT FROM table_cursor INTO @SchemaName, @TableName; END TRY BEGIN CATCH -- Handle any errors that occur during the process. SELECT ERROR_MESSAGE() AS ErrorMessage; SET @RunHasErrors = 1; SET @return_status = -1; --================================================-- Log error to table --=================================================-- IF (@LOGLEVEL in ('INFO','WARN','ERROR')) BEGIN INSERT INTO [TBDD_MAINTAIN_DATABASE_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [ADDED_WHO], [ADDED_WHEN]) VALUES ('ERROR', 'table_cursor', @DBName, ERROR_MESSAGE(),@MY_PROCEDURE_NAME, GetDate()); END; ----------------------------------------------------------------------------------------------------------------------------- FETCH NEXT FROM table_cursor INTO @SchemaName, @TableName; END CATCH; END; CLOSE table_cursor; DEALLOCATE table_cursor; -- Drop the temporary table DROP TABLE #TableList; SET @return_status_text = 'INFO: Recreation of the database indexes successfully completed!'; PRINT @return_status_text; END; ELSE BEGIN IF ((@REBUILDINDEX = 1) and (@HasMemoryOptimizedTables = 1)) BEGIN SET @return_status_text = 'WARN: Skipping index maintenance execution because memory-optimized tables were detected in database [' + @DBName + '].'; PRINT @return_status_text; END; ELSE IF (@LOGLEVEL in ('INFO')) BEGIN SET @return_status_text = 'INFO: Skipping the recreation of the database indexes!'; PRINT @return_status_text; END; END; ----------------------------------------------------------------------------------------------------------------------------- --===============================================-- Log result to table --=================================================-- IF ((@LOGLEVEL in ('INFO','WARN')) and (@return_status is not null) and (@return_status_text is not null)) BEGIN INSERT INTO [TBDD_MAINTAIN_DATABASE_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN]) VALUES (@LOGLEVEL, 'db_cursor', @DBName, @return_status, @return_status_text, @MY_PROCEDURE_NAME, GetDate()); END; ----------------------------------------------------------------------------------------------------------------------------- --========================================-- Maintain columnstore indexes --===========================================-- IF ((@MAINTAINCOLUMNSTORE = 1) and (@return_status = 0) and (@HasMemoryOptimizedTables = 0)) BEGIN PRINT 'INFO: Prepare to maintain columnstore indexes.'; BEGIN TRY DROP TABLE #ColumnstoreList; END TRY BEGIN CATCH PRINT 'INFO: #ColumnstoreList Temp table is already gone... (1)'; END CATCH; CREATE TABLE #ColumnstoreList (SchemaName NVARCHAR(50), TableName NVARCHAR(256), IndexName NVARCHAR(256), DeletedPercent FLOAT); SET @SQLCommand = 'USE [' + @DBName + ']; INSERT INTO #ColumnstoreList (SchemaName, TableName, IndexName, DeletedPercent) SELECT s.[name], t.[name], i.[name], CASE WHEN SUM(rg.total_rows) = 0 THEN 0 ELSE (SUM(rg.deleted_rows) * 100.0 / SUM(rg.total_rows)) END FROM sys.[tables] t INNER JOIN sys.[schemas] s ON t.[schema_id] = s.[schema_id] INNER JOIN sys.[indexes] i ON t.[object_id] = i.[object_id] INNER JOIN sys.dm_db_column_store_row_group_physical_stats rg ON i.[object_id] = rg.[object_id] AND i.[index_id] = rg.[index_id] WHERE i.[type] IN (5,6) GROUP BY s.[name], t.[name], i.[name];'; EXEC @return_status = sp_executesql @SQLCommand; IF ((@LOGLEVEL in ('INFO')) and (@return_status = 0)) BEGIN SET @return_status_text = 'INFO: Getting the columnstore indexes was successfully done!'; PRINT @return_status_text; END; ELSE IF ((@LOGLEVEL in ('WARN')) and (@return_status <> 0)) BEGIN SET @return_status_text = 'WARN: Getting the columnstore indexes returns warnings or has failed, check the ID!'; PRINT @return_status_text; END; IF (@return_status = 0) BEGIN SELECT @ColumnstoreListCount = COUNT(*) FROM #ColumnstoreList; PRINT 'INFO: Found: ' + convert(VARCHAR,@ColumnstoreListCount) + ' columnstore index(es) to maintain'; END; ELSE BEGIN SET @ColumnstoreListCount = 0; PRINT 'WARN: Found: no columnstore indexes to maintain'; END; END; ELSE BEGIN IF ((@MAINTAINCOLUMNSTORE = 1) and (@HasMemoryOptimizedTables = 1)) BEGIN SET @return_status_text = 'WARN: Skipping columnstore maintenance because memory-optimized tables were detected in database [' + @DBName + '].'; PRINT @return_status_text; END; ELSE IF (@LOGLEVEL in ('INFO')) BEGIN SET @return_status_text = 'INFO: Skipping columnstore maintenance!'; PRINT @return_status_text; END; END; --===============================================-- Log result to table --=================================================-- IF ((@LOGLEVEL in ('INFO','WARN')) and (@return_status is not null) and (@return_status_text is not null)) BEGIN INSERT INTO [TBDD_MAINTAIN_DATABASE_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN]) VALUES (@LOGLEVEL, 'db_cursor', @DBName, @return_status, @return_status_text, @MY_PROCEDURE_NAME, GetDate()); END; ------------------------------------------------------------------------------------------------------------------------------ IF ((@MAINTAINCOLUMNSTORE = 1) and (@return_status = 0) and (@ColumnstoreListCount > 0) and (@HasMemoryOptimizedTables = 0)) BEGIN DECLARE columnstore_cursor CURSOR STATIC LOCAL FOR SELECT SchemaName, TableName, IndexName, DeletedPercent FROM #ColumnstoreList; OPEN columnstore_cursor; FETCH NEXT FROM columnstore_cursor INTO @ColumnstoreSchemaName, @ColumnstoreTableName, @ColumnstoreIndexName, @ColumnstoreDeletedPercent; WHILE @@FETCH_STATUS = 0 BEGIN BEGIN TRY SET @ColumnstoreAction = CASE WHEN @ColumnstoreDeletedPercent >= 20 THEN 'REBUILD' WHEN @ColumnstoreDeletedPercent >= 10 THEN 'REORGANIZE' ELSE 'NOTHING' END; PRINT 'INFO: Maintain columnstore index: ' + CONVERT(VARCHAR(1000),@ColumnstoreIndexName) + ' (Deleted: ' + CONVERT(VARCHAR(20),@ColumnstoreDeletedPercent) + '%) -> Do: ' + @ColumnstoreAction; IF (@ColumnstoreAction = 'REORGANIZE') BEGIN SET @SQLCommand = 'USE [' + @DBName + ']; ALTER INDEX [' + @ColumnstoreIndexName + '] ON [' + @ColumnstoreSchemaName + '].[' + @ColumnstoreTableName + '] REORGANIZE WITH (COMPRESS_ALL_ROW_GROUPS = ON);'; END; ELSE IF (@ColumnstoreAction = 'REBUILD') BEGIN SET @SQLCommand = 'USE [' + @DBName + ']; ALTER INDEX [' + @ColumnstoreIndexName + '] ON [' + @ColumnstoreSchemaName + '].[' + @ColumnstoreTableName + '] REBUILD;'; END; ELSE BEGIN SET @SQLCommand = NULL; PRINT 'INFO: Skipping columnstore maintenance for index [' + @ColumnstoreIndexName + '] because deleted rows are below threshold.'; END; IF (@SQLCommand is not NULL) BEGIN EXEC @return_status = sp_executesql @SQLCommand; END; ELSE BEGIN SET @return_status = 0; END; IF ((@LOGLEVEL in ('INFO')) and (@return_status = 0)) BEGIN SET @return_status_text = 'INFO: Columnstore index [' + @ColumnstoreIndexName + ']; "Do: ' + LOWER(@ColumnstoreAction) + '" successfully completed!'; PRINT @return_status_text; END; ELSE IF ((@LOGLEVEL in ('WARN')) and (@return_status <> 0)) BEGIN SET @return_status_text = 'WARN: Columnstore index [' + @ColumnstoreIndexName + ']; "Do: ' + LOWER(@ColumnstoreAction) + '" returns warnings or has failed, check the ID!'; PRINT @return_status_text; END; --===============================================-- Log result to table --=================================================-- IF ((@LOGLEVEL in ('INFO','WARN')) and (@return_status is not null) and (@return_status_text is not null)) BEGIN INSERT INTO [TBDD_MAINTAIN_DATABASE_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN]) VALUES (@LOGLEVEL, 'columnstore_cursor', @DBName, @return_status, @return_status_text, @MY_PROCEDURE_NAME, GetDate()); END; ------------------------------------------------------------------------------------------------------------------------------ END TRY BEGIN CATCH -- Handle any errors that occur during the process. SELECT ERROR_MESSAGE() AS ErrorMessage; SET @RunHasErrors = 1; SET @return_status = -1; --================================================-- Log error to table --=================================================-- IF (@LOGLEVEL in ('INFO','WARN','ERROR')) BEGIN INSERT INTO [TBDD_MAINTAIN_DATABASE_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [ADDED_WHO], [ADDED_WHEN]) VALUES ('ERROR', 'columnstore_cursor', @DBName, ERROR_MESSAGE(),@MY_PROCEDURE_NAME, GetDate()); END; ------------------------------------------------------------------------------------------------------------------------------ END CATCH; FETCH NEXT FROM columnstore_cursor INTO @ColumnstoreSchemaName, @ColumnstoreTableName, @ColumnstoreIndexName, @ColumnstoreDeletedPercent; END; CLOSE columnstore_cursor; DEALLOCATE columnstore_cursor; -- Drop the temporary table DROP TABLE #ColumnstoreList; SET @return_status_text = 'INFO: Columnstore maintenance successfully completed!'; PRINT @return_status_text; END; ELSE BEGIN IF ((@MAINTAINCOLUMNSTORE = 1) and (@HasMemoryOptimizedTables = 1)) BEGIN SET @return_status_text = 'WARN: Skipping columnstore maintenance execution because memory-optimized tables were detected in database [' + @DBName + '].'; PRINT @return_status_text; END; ELSE IF (@LOGLEVEL in ('INFO')) BEGIN SET @return_status_text = 'INFO: Skipping the columnstore maintenance execution!'; PRINT @return_status_text; END; END; ------------------------------------------------------------------------------------------------------------------------------ --==============================================-- Update statistics --==============================================-- IF ((@UPDATESTATISTICS = 1) and (@return_status = 0)) BEGIN PRINT 'INFO: Update statistics for database tables.'; SET @SQLCommand = N'USE [' + @DBName + ']; EXEC sp_updatestats;'; EXEC @return_status = sp_executesql @SQLCommand; IF ((@LOGLEVEL in ('INFO')) and (@return_status = 0)) BEGIN SET @return_status_text = 'INFO: Updating statistics was successfully completed!'; PRINT @return_status_text; END; ELSE IF ((@LOGLEVEL in ('WARN')) and (@return_status <> 0)) BEGIN SET @return_status_text = 'WARN: Updating statistics returns warnings or has failed, check the ID!'; PRINT @return_status_text; END; END; ELSE BEGIN IF (@LOGLEVEL in ('INFO')) BEGIN SET @return_status_text = 'INFO: Skipping updating statistics!'; PRINT @return_status_text; END; END; ------------------------------------------------------------------------------------------------------------------------------ --===============================================-- Log result to table --=================================================-- IF ((@LOGLEVEL in ('INFO','WARN')) and (@return_status is not null) and (@return_status_text is not null)) BEGIN INSERT INTO [TBDD_MAINTAIN_DATABASE_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN]) VALUES (@LOGLEVEL, 'db_cursor', @DBName, @return_status, @return_status_text, @MY_PROCEDURE_NAME, GetDate()); END; ------------------------------------------------------------------------------------------------------------------------------ --=========================================-- Prepare to recompile Procedures --===========================================-- IF ((@RECOMPILEPROCEDURES = 1) and (@return_status = 0)) BEGIN PRINT 'INFO: Prepare to recompile database procedures.'; BEGIN TRY DROP TABLE #ProcedureList; END TRY BEGIN CATCH PRINT 'INFO: #ProcedureList Temp table is already gone... (1)'; END CATCH; -- Create a temporary table to hold the procedure names CREATE TABLE #ProcedureList (SchemaName NVARCHAR(50), ProcedureName NVARCHAR(256)); -- Set the context to the specified database and fill the temporary table SET @SQLCommand = ' INSERT INTO #ProcedureList (SchemaName, ProcedureName) SELECT SPECIFIC_SCHEMA, SPECIFIC_NAME FROM [' + @DBName + '].INFORMATION_SCHEMA.ROUTINES WHERE ROUTINE_TYPE = ''PROCEDURE'' AND SPECIFIC_NAME <> ''' + @MY_PROCEDURE_NAME + ''' ORDER BY SPECIFIC_NAME;'; EXEC @return_status = sp_executesql @SQLCommand; IF ((@LOGLEVEL in ('INFO')) and (@return_status = 0)) BEGIN SET @return_status_text = 'INFO: Getting the procedures was successfully done!'; PRINT @return_status_text; END; ELSE IF ((@LOGLEVEL in ('WARN')) and (@return_status <> 0)) BEGIN SET @return_status_text = 'WARN: Getting the procedures returns warnings or has failed, check the ID!'; PRINT @return_status_text; END; IF (@return_status = 0) BEGIN SELECT @ProcedureListCount = COUNT(*) FROM #ProcedureList; PRINT 'INFO: Found: ' + convert(VARCHAR,@ProcedureListCount) + ' procedures to recompile'; END; ELSE BEGIN SET @ProcedureListCount = 0; PRINT 'WARN: Found: no procedures to recompile'; END; END; ELSE BEGIN IF (@LOGLEVEL in ('INFO')) BEGIN SET @return_status_text = 'INFO: Skipping recompiling procedures!'; PRINT @return_status_text; END; END; ----------------------------------------------------------------------------------------------------------------------------- --===============================================-- Log result to table --=================================================-- IF ((@LOGLEVEL in ('INFO','WARN')) and (@return_status is not null) and (@return_status_text is not null)) BEGIN INSERT INTO [TBDD_MAINTAIN_DATABASE_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN]) VALUES (@LOGLEVEL, 'db_cursor', @DBName, @return_status, @return_status_text, @MY_PROCEDURE_NAME, GetDate()); END; ----------------------------------------------------------------------------------------------------------------------------- --===============================================-- Recompile Procedures --================================================-- IF ((@RECOMPILEPROCEDURES = 1) and (@return_status = 0) and (@ProcedureListCount > 0)) BEGIN PRINT 'INFO: Removing all procedure elements from the query plan cache.'; SET @SQLCommand = N'USE [' + @DBName + ']; DBCC FREEPROCCACHE;'; EXEC @return_status = sp_executesql @SQLCommand; IF ((@LOGLEVEL in ('INFO')) and (@return_status = 0)) BEGIN SET @return_status_text = 'INFO: Removing all procedure elements was successfully completed!'; PRINT @return_status_text; END; ELSE IF ((@LOGLEVEL in ('WARN')) and (@return_status <> 0)) BEGIN SET @return_status_text = 'WARN: Removing all procedure elements returns warnings or has failed, check the ID!'; PRINT @return_status_text; END; --===============================================-- Log result to table --=================================================-- IF ((@LOGLEVEL in ('INFO','WARN')) and (@return_status is not null) and (@return_status_text is not null)) BEGIN INSERT INTO [TBDD_MAINTAIN_DATABASE_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN]) VALUES (@LOGLEVEL, 'procedure_cursor', @DBName, @return_status, @return_status_text, @MY_PROCEDURE_NAME, GetDate()); END; ----------------------------------------------------------------------------------------------------------------------------- DECLARE procedure_cursor CURSOR STATIC LOCAL FOR SELECT SchemaName, ProcedureName FROM #ProcedureList; OPEN procedure_cursor; FETCH NEXT FROM procedure_cursor INTO @SchemaName, @ProcedureName; WHILE @@FETCH_STATUS = 0 BEGIN BEGIN TRY PRINT 'INFO: Recompile procedure: ' + CONVERT(VARCHAR(1000),@SchemaName + '.' + @ProcedureName); SET @SQLCommand = 'USE [' + @DBName + ']; EXEC sp_recompile ''' + @SchemaName + '.' + @ProcedureName + '''; '; EXEC @return_status = sp_executesql @SQLCommand; IF ((@LOGLEVEL in ('INFO')) and (@return_status = 0)) BEGIN SET @return_status_text = 'INFO: Recompiling the procedure ' + @SchemaName + '.' + @ProcedureName + ' successfully completed!'; PRINT @return_status_text; END; ELSE IF ((@LOGLEVEL in ('WARN')) and (@return_status <> 0)) BEGIN SET @return_status_text = 'WARN: Recompiling the procedure ' + @SchemaName + '.' + @ProcedureName + ' returns warnings or has failed, check the ID!'; PRINT @return_status_text; END; --===============================================-- Log result to table --=================================================-- IF ((@LOGLEVEL in ('INFO','WARN')) and (@return_status is not null) and (@return_status_text is not null)) BEGIN INSERT INTO [TBDD_MAINTAIN_DATABASE_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN]) VALUES (@LOGLEVEL, 'procedure_cursor', @DBName, @return_status, @return_status_text, @MY_PROCEDURE_NAME, GetDate()); END; ----------------------------------------------------------------------------------------------------------------------------- FETCH NEXT FROM procedure_cursor INTO @SchemaName, @ProcedureName; END TRY BEGIN CATCH -- Handle any errors that occur during the process. SELECT ERROR_MESSAGE() AS ErrorMessage; SET @RunHasErrors = 1; SET @return_status = -1; --================================================-- Log error to table --=================================================-- IF (@LOGLEVEL in ('INFO','WARN','ERROR')) BEGIN INSERT INTO [TBDD_MAINTAIN_DATABASE_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [ADDED_WHO], [ADDED_WHEN]) VALUES ('ERROR', 'procedure_cursor', @DBName, ERROR_MESSAGE(),@MY_PROCEDURE_NAME, GetDate()); END; ----------------------------------------------------------------------------------------------------------------------------- FETCH NEXT FROM procedure_cursor INTO @SchemaName, @ProcedureName; END CATCH; END; CLOSE procedure_cursor; DEALLOCATE procedure_cursor; -- Drop the temporary table DROP TABLE #ProcedureList; SET @return_status_text = 'INFO: Recompiling of procedures successfully completed!'; PRINT @return_status_text; END; ELSE BEGIN IF (@LOGLEVEL in ('INFO')) BEGIN SET @return_status_text = 'INFO: Skipping the recompiling of the procedures!'; PRINT @return_status_text; END; END; ----------------------------------------------------------------------------------------------------------------------------- --===============================================-- Log result to table --=================================================-- IF ((@LOGLEVEL in ('INFO','WARN')) and (@return_status is not null) and (@return_status_text is not null)) BEGIN INSERT INTO [TBDD_MAINTAIN_DATABASE_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN]) VALUES (@LOGLEVEL, 'procedure_cursor', @DBName, @return_status, @return_status_text, @MY_PROCEDURE_NAME, GetDate()); END; ----------------------------------------------------------------------------------------------------------------------------- --=========================================-- Clear database scoped procedure cache --===========================================-- IF ((@CLEARDBPROCCACHE = 1) and (@return_status = 0)) BEGIN IF (@ProductMainVersion >= 13) BEGIN PRINT 'INFO: Clearing database scoped procedure cache.'; SET @SQLCommand = N'USE [' + @DBName + ']; ALTER DATABASE SCOPED CONFIGURATION CLEAR PROCEDURE CACHE;'; EXEC @return_status = sp_executesql @SQLCommand; IF ((@LOGLEVEL in ('INFO')) and (@return_status = 0)) BEGIN SET @return_status_text = 'INFO: Clearing database scoped procedure cache was successfully completed!'; PRINT @return_status_text; END; ELSE IF ((@LOGLEVEL in ('WARN')) and (@return_status <> 0)) BEGIN SET @return_status_text = 'WARN: Clearing database scoped procedure cache returns warnings or has failed, check the ID!'; PRINT @return_status_text; END; END; ELSE BEGIN IF (@LOGLEVEL in ('WARN')) BEGIN SET @return_status_text = 'WARN: Skipping database scoped procedure cache clearing, requires SQL Server 2016 or newer!'; PRINT @return_status_text; END; END; END; ELSE BEGIN IF (@LOGLEVEL in ('INFO')) BEGIN SET @return_status_text = 'INFO: Skipping database scoped procedure cache clearing!'; PRINT @return_status_text; END; END; ----------------------------------------------------------------------------------------------------------------------------- --===============================================-- Log result to table --=================================================-- IF ((@LOGLEVEL in ('INFO','WARN')) and (@return_status is not null) and (@return_status_text is not null)) BEGIN INSERT INTO [TBDD_MAINTAIN_DATABASE_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN]) VALUES (@LOGLEVEL, 'db_cursor', @DBName, @return_status, @return_status_text, @MY_PROCEDURE_NAME, GetDate()); END; ----------------------------------------------------------------------------------------------------------------------------- --================================================-- Clear Query Cache --==================================================-- IF ((@CLEARQUERYCACHE = 1) and (@return_status = 0)) BEGIN PRINT 'INFO: Removing the sql query cache.'; SET @SQLCommand = N'USE [' + @DBName + ']; DBCC DROPCLEANBUFFERS;'; EXEC @return_status = sp_executesql @SQLCommand; IF ((@LOGLEVEL in ('INFO')) and (@return_status = 0)) BEGIN SET @return_status_text = 'INFO: Removing sql query cache was successfully completed!'; PRINT @return_status_text; END; ELSE IF ((@LOGLEVEL in ('WARN')) and (@return_status <> 0)) BEGIN SET @return_status_text = 'WARN: Removing sql query cache returns warnings or has failed, check the ID!'; PRINT @return_status_text; END; END; ELSE BEGIN IF (@LOGLEVEL in ('INFO')) BEGIN SET @return_status_text = 'INFO: Skipping the query cache clearing!'; PRINT @return_status_text; END; END; ----------------------------------------------------------------------------------------------------------------------------- --===============================================-- Log result to table --=================================================-- IF ((@LOGLEVEL in ('INFO','WARN')) and (@return_status is not null) and (@return_status_text is not null)) BEGIN INSERT INTO [TBDD_MAINTAIN_DATABASE_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN]) VALUES (@LOGLEVEL, 'db_cursor', @DBName, @return_status, @return_status_text, @MY_PROCEDURE_NAME, GetDate()); END; ----------------------------------------------------------------------------------------------------------------------------- --================================================-- Shrink db as well --==================================================-- IF ((@SHRINKDB = 1) and (@return_status = 0) and (@HasMemoryOptimizedTables = 0)) BEGIN PRINT 'INFO: Shrink data files to reclaim unused space.'; -- do this after indexes are rebuilt BEGIN TRY DROP TABLE #DataFileList; END TRY BEGIN CATCH PRINT 'INFO: #DataFileList Temp table is already gone...'; END CATCH; CREATE TABLE #DataFileList (FileName NVARCHAR(128)); INSERT INTO #DataFileList(FileName) SELECT [name] FROM [master].[sys].[master_files] WHERE [database_id] = DB_ID(@DBName) AND [type_desc] = 'ROWS'; SELECT @DataFileCount = COUNT(*) FROM #DataFileList; PRINT 'INFO: Found: ' + CONVERT(VARCHAR,@DataFileCount) + ' data file(s) to shrink.'; IF (@DataFileCount > 0) BEGIN DECLARE datafile_cursor CURSOR STATIC LOCAL FOR SELECT FileName FROM #DataFileList; OPEN datafile_cursor; FETCH NEXT FROM datafile_cursor INTO @DataFileName; WHILE @@FETCH_STATUS = 0 BEGIN BEGIN TRY -- Shrink each data file to minimum size (target 0 lets SQL decide). SET @SQLCommand = N'USE [' + @DBName + ']; DBCC SHRINKFILE (N''' + @DataFileName + ''', 0) WITH NO_INFOMSGS;'; EXEC @return_status = sp_executesql @SQLCommand; IF ((@LOGLEVEL in ('INFO')) and (@return_status = 0)) BEGIN SET @return_status_text = 'INFO: Shrinking data file [' + @DataFileName + '] was successfully completed!'; PRINT @return_status_text; END; ELSE IF ((@LOGLEVEL in ('WARN')) and (@return_status <> 0)) BEGIN SET @return_status_text = 'WARN: Shrinking data file [' + @DataFileName + '] returns warnings or has failed, check the ID!'; PRINT @return_status_text; END; --===============================================-- Log result to table --=================================================-- IF ((@LOGLEVEL in ('INFO','WARN')) and (@return_status is not null) and (@return_status_text is not null)) BEGIN INSERT INTO [TBDD_MAINTAIN_DATABASE_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN]) VALUES (@LOGLEVEL, 'datafile_cursor', @DBName, @return_status, @return_status_text, @MY_PROCEDURE_NAME, GetDate()); END; ----------------------------------------------------------------------------------------------------------------------------- END TRY BEGIN CATCH -- Handle any errors that occur during the process. SELECT ERROR_MESSAGE() AS ErrorMessage; SET @RunHasErrors = 1; SET @return_status = -1; --================================================-- Log error to table --=================================================-- IF (@LOGLEVEL in ('INFO','WARN','ERROR')) BEGIN INSERT INTO [TBDD_MAINTAIN_DATABASE_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [ADDED_WHO], [ADDED_WHEN]) VALUES ('ERROR', 'datafile_cursor', @DBName, ERROR_MESSAGE(),@MY_PROCEDURE_NAME, GetDate()); END; ----------------------------------------------------------------------------------------------------------------------------- END CATCH; FETCH NEXT FROM datafile_cursor INTO @DataFileName; END; CLOSE datafile_cursor; DEALLOCATE datafile_cursor; END; ELSE BEGIN PRINT 'INFO: No data files found to shrink.'; END; BEGIN TRY DROP TABLE #DataFileList; END TRY BEGIN CATCH PRINT 'INFO: #DataFileList Temp table is already gone...'; END CATCH; END; ELSE BEGIN IF ((@SHRINKDB = 1) and (@HasMemoryOptimizedTables = 1)) BEGIN SET @return_status_text = 'WARN: Skipping shrinking database files because memory-optimized tables were detected in database [' + @DBName + '].'; PRINT @return_status_text; END; ELSE IF (@LOGLEVEL in ('INFO')) BEGIN SET @return_status_text = 'INFO: Skipping shrinking the database!'; PRINT @return_status_text; END; END; ----------------------------------------------------------------------------------------------------------------------------- --===============================================-- Log result to table --=================================================-- IF ((@LOGLEVEL in ('INFO','WARN')) and (@return_status is not null) and (@return_status_text is not null)) BEGIN INSERT INTO [TBDD_MAINTAIN_DATABASE_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN]) VALUES (@LOGLEVEL, 'db_cursor', @DBName, @return_status, @return_status_text, @MY_PROCEDURE_NAME, GetDate()); END; ----------------------------------------------------------------------------------------------------------------------------- --======================================-- Check if shrinking the log is possible --=======================================-- IF (@SHRINKLOG = 1) BEGIN --==========================================-- Get current recovery modell --==============================================-- SET @RecoveryModelActual = (SELECT [recovery_model_desc] FROM [sys].[databases] WHERE NAME = @DBName); IF ((@LOGLEVEL in ('INFO')) and (@return_status = 0)) BEGIN SET @return_status_text = 'INFO: Currently the recovery mode is set to: ' + @RecoveryModelActual; PRINT @return_status_text; END; ELSE IF ((@LOGLEVEL in ('WARN')) and (@return_status <> 0)) BEGIN SET @return_status_text = 'WARN: Currently the recovery mode is set to: ' + @RecoveryModelActual; PRINT @return_status_text; END; ----------------------------------------------------------------------------------------------------------------------------- --===============================================-- Log result to table --=================================================-- IF ((@LOGLEVEL in ('INFO','WARN')) and (@return_status is not null) and (@return_status_text is not null)) BEGIN INSERT INTO [TBDD_MAINTAIN_DATABASE_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN]) VALUES (@LOGLEVEL,'db_cursor', @DBName, @return_status, @return_status_text, @MY_PROCEDURE_NAME, GetDate()); END; ----------------------------------------------------------------------------------------------------------------------------- --===========================================-- Get infos about the log file --============================================-- PRINT 'INFO: Get the current and minimum size of the log file in MB.'; SET @SQLCommand = N'SELECT TOP 1 @LogFileName = [name], @CurrentLogFileSizeInMB = ([size] / 128), @LogGrowthValue = [growth], @LogIsPercentGrowth = [is_percent_growth], @MinimumLogFileSizeInMB = CASE WHEN [is_percent_growth] = 1 THEN 0 ELSE ([growth] / 128) END, @MaximumLogFileSizeInMB = CASE WHEN [max_size] = -1 THEN 0 ELSE ([max_size] / 128) END FROM [master].[sys].[master_files] WHERE [database_id] = DB_ID(''' + @DBName + ''') AND [STATE_DESC] = ''ONLINE'' AND [type_desc] = ''LOG'''; EXEC @return_status = sp_executesql @SQLCommand, N'@LogFileName VARCHAR(100) OUTPUT, @CurrentLogFileSizeInMB INT OUTPUT, @LogGrowthValue INT OUTPUT, @LogIsPercentGrowth BIT OUTPUT, @MinimumLogFileSizeInMB INT OUTPUT, @MaximumLogFileSizeInMB INT OUTPUT', @LogFileName OUTPUT, @CurrentLogFileSizeInMB OUTPUT, @LogGrowthValue OUTPUT, @LogIsPercentGrowth OUTPUT, @MinimumLogFileSizeInMB OUTPUT, @MaximumLogFileSizeInMB OUTPUT; IF ((@LOGLEVEL in ('INFO')) and (@return_status = 0)) BEGIN SET @return_status_text = 'INFO: Getting log file settings was successfully completed!'; PRINT @return_status_text; END; ELSE IF ((@LOGLEVEL in ('WARN')) and (@return_status <> 0)) BEGIN SET @return_status_text = 'WARN: Getting log file settings returns warnings or has failed, check the ID!'; PRINT @return_status_text; END; ----------------------------------------------------------------------------------------------------------------------------- --===========================================-- Calculate target file size --==============================================-- PRINT 'INFO: The @CurrentLogFileSizeInMB is: ' + CONVERT(VARCHAR(1000),@CurrentLogFileSizeInMB); PRINT 'INFO: The @LogGrowthValue is: ' + CONVERT(VARCHAR(1000),@LogGrowthValue); PRINT 'INFO: The @LogIsPercentGrowth is: ' + CONVERT(VARCHAR(10),@LogIsPercentGrowth); PRINT 'INFO: The @MinimumLogFileSizeInMB is: ' + CONVERT(VARCHAR(1000),@MinimumLogFileSizeInMB); PRINT 'INFO: The @MaximumLogFileSizeInMB is: ' + CONVERT(VARCHAR(1000),@MaximumLogFileSizeInMB); SET @TargetLogFileSizeInMB = CASE WHEN (@CurrentLogFileSizeInMB <= 0) THEN 0 WHEN (@MinimumLogFileSizeInMB > 0) AND (CEILING(@CurrentLogFileSizeInMB * 0.1) < @MinimumLogFileSizeInMB) THEN @MinimumLogFileSizeInMB ELSE CEILING(@CurrentLogFileSizeInMB * 0.1) END; PRINT 'INFO: The @TargetLogFileSizeInMB is: ' + CONVERT(VARCHAR(1000),@TargetLogFileSizeInMB); ----------------------------------------------------------------------------------------------------------------------------- --===============================================-- Log result to table --=================================================-- IF ((@LOGLEVEL in ('INFO','WARN')) and (@return_status is not null) and (@return_status_text is not null)) BEGIN INSERT INTO [TBDD_MAINTAIN_DATABASE_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN]) VALUES (@LOGLEVEL, 'db_cursor', @DBName, @return_status, @return_status_text, @MY_PROCEDURE_NAME, GetDate()); END; ----------------------------------------------------------------------------------------------------------------------------- --=======================================-- Needs the recovery modell to be reset? --======================================-- IF ((@CurrentLogFileSizeInMB > @TargetLogFileSizeInMB) AND (@RecoveryModelActual <> @RecoveryModelTarget)) BEGIN --=============================================-- Change db recovery mode --===============================================-- PRINT 'INFO: Truncating the log needs to change the database recovery model to: ' + @RecoveryModelTarget + '.'; SET @SQLCommand = N'ALTER DATABASE [' + @DBName + '] SET RECOVERY ' + @RecoveryModelTarget + ''; EXEC @return_status = sp_executesql @SQLCommand; IF ((@LOGLEVEL in ('INFO')) and (@return_status = 0)) BEGIN SET @return_status_text = 'INFO: Setting database to the ' + @RecoveryModelTarget + ' recovery model was successfully completed!'; PRINT @return_status_text; END; ELSE IF ((@LOGLEVEL in ('WARN')) and (@return_status <> 0)) BEGIN SET @return_status_text = 'WARN: Setting database to the ' + @RecoveryModelTarget + ' recovery model returns warnings or has failed, check the ID!'; PRINT @return_status_text; END; ----------------------------------------------------------------------------------------------------------------------------- --===============================================-- Log result to table --=================================================-- IF ((@LOGLEVEL in ('INFO','WARN')) and (@return_status is not null) and (@return_status_text is not null)) BEGIN INSERT INTO [TBDD_MAINTAIN_DATABASE_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN]) VALUES (@LOGLEVEL,'db_cursor', @DBName, @return_status, @return_status_text, @MY_PROCEDURE_NAME, GetDate()); END; ----------------------------------------------------------------------------------------------------------------------------- END; ----------------------------------------------------------------------------------------------------------------------------- --================================================-- Get LogFile Status --=================================================-- SET @LogFileStatus = (SELECT TOP 1 [log_reuse_wait_desc] FROM [sys].[databases] WHERE [NAME] = @DBName); IF (@LogFileStatus <> 'NOTHING') BEGIN --===================================================-- Output result --===================================================-- SET @return_status = -1; SET @RunHasErrors = 1; SET @return_status_text = 'WARN: The log file cannot be shrunk because of the following reason: ' + @LogFileStatus; PRINT @return_status_text; --===============================================-- Log result to table --=================================================-- IF ((@LOGLEVEL in ('INFO','WARN')) and (@return_status is not null) and (@return_status_text is not null)) BEGIN INSERT INTO [TBDD_MAINTAIN_DATABASE_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN]) VALUES (@LOGLEVEL, 'db_cursor', @DBName, @return_status, @return_status_text, @MY_PROCEDURE_NAME, GetDate()); END; ----------------------------------------------------------------------------------------------------------------------------- --===========================================-- Get infos about the log file --============================================-- PRINT 'INFO: Trying to force DB....'; SET @SQLCommand = N'USE [' + @DBName + ']; CHECKPOINT;'; EXEC @return_status = sp_executesql @SQLCommand; IF ((@LOGLEVEL in ('INFO')) and (@return_status = 0)) BEGIN SET @return_status_text = 'INFO: Setting CHECKPOINT was successfully completed!'; PRINT @return_status_text; END; ELSE IF ((@LOGLEVEL in ('WARN')) and (@return_status <> 0)) BEGIN SET @return_status_text = 'WARN: Setting CHECKPOINT returns warnings or has failed, check the ID!'; PRINT @return_status_text; END; ----------------------------------------------------------------------------------------------------------------------------- --===============================================-- Log result to table --=================================================-- IF ((@LOGLEVEL in ('INFO','WARN')) and (@return_status is not null) and (@return_status_text is not null)) BEGIN INSERT INTO [TBDD_MAINTAIN_DATABASE_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN]) VALUES (@LOGLEVEL, 'db_cursor', @DBName, @return_status, @return_status_text, @MY_PROCEDURE_NAME, GetDate()); END; ----------------------------------------------------------------------------------------------------------------------------- --===================================-- Check again if shrinking the log is possible --====================================-- PRINT 'Waiting for 30 seconds... and retrieving Status again'; WAITFOR DELAY '00:00:30'; -- Short break for the sync process SET @LogFileStatus = (SELECT TOP 1 [log_reuse_wait_desc] FROM [sys].[databases] WHERE [NAME] = @DBName); IF ((@LOGLEVEL in ('INFO')) and (@return_status = 0)) BEGIN SET @return_status_text = 'INFO: New status of db is: ' + @LogFileStatus; PRINT @return_status_text; END; ELSE IF ((@LOGLEVEL in ('WARN')) and (@return_status <> 0)) BEGIN SET @return_status_text = 'WARN: New status of db is: ' + @LogFileStatus; PRINT @return_status_text; END; ----------------------------------------------------------------------------------------------------------------------------- --===============================================-- Log result to table --=================================================-- IF ((@LOGLEVEL in ('INFO','WARN')) and (@return_status is not null) and (@return_status_text is not null)) BEGIN INSERT INTO [TBDD_MAINTAIN_DATABASE_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN]) VALUES (@LOGLEVEL, 'db_cursor', @DBName, @return_status, @return_status_text, @MY_PROCEDURE_NAME, GetDate()); END; ----------------------------------------------------------------------------------------------------------------------------- END; END; ----------------------------------------------------------------------------------------------------------------------------- --============================================-- Prepare shrinking the log--===============================================-- IF ((@SHRINKLOG = 1) AND (@LogFileStatus = 'NOTHING')) BEGIN --=================================================-- Schrink db logs --===================================================-- IF ((@CurrentLogFileSizeInMB > @TargetLogFileSizeInMB) AND (@return_status = 0)) BEGIN --===================================================-- Now, do it! --=====================================================-- IF (@return_status = 0) BEGIN PRINT 'INFO: Shrink the truncated log file to 10% of its current size or the fixed growth increment, whichever is larger.'; IF (@ProductMainVersion >= 16) BEGIN IF (@FORCE = 1) BEGIN SET @SQLCommand = N'USE [' + @DBName + ']; DBCC SHRINKFILE (''' + @LogFileName + ''', ' + CAST(@TargetLogFileSizeInMB AS VARCHAR) + ') WITH WAIT_AT_LOW_PRIORITY (ABORT_AFTER_WAIT = BLOCKERS), NO_INFOMSGS;'; END; ELSE BEGIN SET @SQLCommand = N'USE [' + @DBName + ']; DBCC SHRINKFILE (''' + @LogFileName + ''', ' + CAST(@TargetLogFileSizeInMB AS VARCHAR) + ') WITH WAIT_AT_LOW_PRIORITY (ABORT_AFTER_WAIT = SELF), NO_INFOMSGS;'; END; END; ELSE BEGIN PRINT 'WARN: Because of the sql server version, DBCC SHRINKFILE is not applicable with the FORCE parameter!'; SET @SQLCommand = N'USE [' + @DBName + ']; DBCC SHRINKFILE (''' + @LogFileName + ''', ' + CAST(@TargetLogFileSizeInMB AS VARCHAR) + ') WITH NO_INFOMSGS;'; END; EXEC @return_status = sp_executesql @SQLCommand; IF ((@LOGLEVEL in ('INFO')) and (@return_status = 0)) BEGIN SET @return_status_text = 'INFO: Shrinking the database log file was successfully completed!'; PRINT @return_status_text; END; ELSE IF ((@LOGLEVEL in ('WARN')) and (@return_status <> 0)) BEGIN SET @return_status_text = 'WARN: Shrinking the database log file returns warnings or has failed, check the ID!'; PRINT @return_status_text; END; END; ELSE BEGIN SET @return_status_text = 'ERROR: Shrinking the database log was skipped because of previouse error(s)!'; END; ----------------------------------------------------------------------------------------------------------------------------- --===============================================-- Log result to table --=================================================-- IF ((@LOGLEVEL in ('INFO','WARN')) and (@return_status is not null) and (@return_status_text is not null)) BEGIN INSERT INTO [TBDD_MAINTAIN_DATABASE_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN]) VALUES (@LOGLEVEL, 'db_cursor', @DBName, @return_status, @return_status_text, @MY_PROCEDURE_NAME, GetDate()); END; ----------------------------------------------------------------------------------------------------------------------------- END; ELSE BEGIN PRINT 'INFO: No shrink action neccessary!'; END; ----------------------------------------------------------------------------------------------------------------------------- END; ELSE BEGIN PRINT 'WARN: Skipping to shrink the log file!'; END; ----------------------------------------------------------------------------------------------------------------------------- --=============================================-- Reset database recovery mode --===========================================-- IF (@SHRINKLOG = 1) BEGIN --=============================================-- Change db recovery mode --===============================================-- PRINT 'INFO: Reset the database recovery model back to: ' + @RecoveryModelActual + '.'; SET @SQLCommand = N'ALTER DATABASE [' + @DBName + '] SET RECOVERY ' + @RecoveryModelActual + ''; EXEC @return_status = sp_executesql @SQLCommand; IF ((@LOGLEVEL in ('INFO')) and (@return_status = 0)) BEGIN SET @return_status_text = 'INFO: Setting database back to the ' + @RecoveryModelActual + ' recovery model was successfully completed!'; PRINT @return_status_text; END; ELSE IF ((@LOGLEVEL in ('WARN')) and (@return_status <> 0)) BEGIN SET @return_status_text = 'WARN: Setting database back to the ' + @RecoveryModelActual + ' recovery model returns warnings or has failed, check the ID!'; PRINT @return_status_text; END; ----------------------------------------------------------------------------------------------------------------------------- --===============================================-- Log result to table --=================================================-- IF ((@LOGLEVEL in ('INFO','WARN')) and (@return_status is not null) and (@return_status_text is not null)) BEGIN INSERT INTO [TBDD_MAINTAIN_DATABASE_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN]) VALUES (@LOGLEVEL, 'db_cursor', @DBName, @return_status, @return_status_text, @MY_PROCEDURE_NAME, GetDate()); END; ----------------------------------------------------------------------------------------------------------------------------- END; ----------------------------------------------------------------------------------------------------------------------------- --=========================================-- Check database file growth --===========================================-- IF ((@CHECKFILEGROWTH = 1) and (@return_status = 0)) BEGIN PRINT 'INFO: Checking database file growth settings.'; BEGIN TRY BEGIN TRY DROP TABLE #FileGrowthList; END TRY BEGIN CATCH PRINT 'INFO: #FileGrowthList Temp table is already gone...'; END CATCH; CREATE TABLE #FileGrowthList (FileName NVARCHAR(128), FileType NVARCHAR(10), FileSizeInMB INT, GrowthDesc NVARCHAR(50), MaxSizeInMB INT, IsPercentGrowth BIT); INSERT INTO #FileGrowthList(FileName, FileType, FileSizeInMB, GrowthDesc, MaxSizeInMB, IsPercentGrowth) SELECT [name], [type_desc], ([size] / 128), CASE WHEN [is_percent_growth] = 1 THEN CAST([growth] AS NVARCHAR(20)) + '%' ELSE CAST(([growth] / 128) AS NVARCHAR(20)) + ' MB' END, CASE WHEN [max_size] = -1 THEN -1 ELSE ([max_size] / 128) END, [is_percent_growth] FROM [master].[sys].[master_files] WHERE [database_id] = DB_ID(@DBName); SELECT @FileGrowthCount = COUNT(*) FROM #FileGrowthList; PRINT 'INFO: Found: ' + CONVERT(VARCHAR,@FileGrowthCount) + ' file(s) to check.'; IF (@FileGrowthCount > 0) BEGIN DECLARE filegrowth_cursor CURSOR STATIC LOCAL FOR SELECT FileName, FileType, FileSizeInMB, GrowthDesc, MaxSizeInMB, IsPercentGrowth FROM #FileGrowthList; OPEN filegrowth_cursor; FETCH NEXT FROM filegrowth_cursor INTO @FileName, @FileType, @FileSizeInMB, @FileGrowthDesc, @FileMaxSizeInMB, @FileIsPercentGrowth; WHILE @@FETCH_STATUS = 0 BEGIN BEGIN TRY SET @FileMaxSizeText = CASE WHEN (@FileMaxSizeInMB < 0) THEN 'UNLIMITED' ELSE CONVERT(NVARCHAR(20),@FileMaxSizeInMB) END; SET @return_status_text = 'INFO: File [' + @FileName + '] (' + @FileType + ') SizeMB=' + CONVERT(VARCHAR(20),@FileSizeInMB) + ', Growth=' + @FileGrowthDesc + ', MaxSizeMB=' + @FileMaxSizeText; PRINT @return_status_text; IF ((@LOGLEVEL in ('INFO','WARN')) and (@return_status is not null) and (@return_status_text is not null)) BEGIN INSERT INTO [TBDD_MAINTAIN_DATABASE_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN]) VALUES (@LOGLEVEL, 'filegrowth_cursor', @DBName, @return_status, @return_status_text, @MY_PROCEDURE_NAME, GetDate()); END; IF (@FileIsPercentGrowth = 1) BEGIN SET @return_status_text = 'WARN: File [' + @FileName + '] uses percent growth (' + @FileGrowthDesc + ').'; PRINT @return_status_text; IF ((@LOGLEVEL in ('INFO','WARN')) and (@return_status is not null) and (@return_status_text is not null)) BEGIN INSERT INTO [TBDD_MAINTAIN_DATABASE_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN]) VALUES (@LOGLEVEL, 'filegrowth_cursor', @DBName, @return_status, @return_status_text, @MY_PROCEDURE_NAME, GetDate()); END; END; END TRY BEGIN CATCH -- Handle any errors that occur during the process. SELECT ERROR_MESSAGE() AS ErrorMessage; SET @RunHasErrors = 1; SET @return_status = -1; --================================================-- Log error to table --=================================================-- IF (@LOGLEVEL in ('INFO','WARN','ERROR')) BEGIN INSERT INTO [TBDD_MAINTAIN_DATABASE_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [ADDED_WHO], [ADDED_WHEN]) VALUES ('ERROR', 'filegrowth_cursor', @DBName, ERROR_MESSAGE(),@MY_PROCEDURE_NAME, GetDate()); END; ------------------------------------------------------------------------------------------------------------------------------ END CATCH; FETCH NEXT FROM filegrowth_cursor INTO @FileName, @FileType, @FileSizeInMB, @FileGrowthDesc, @FileMaxSizeInMB, @FileIsPercentGrowth; END; CLOSE filegrowth_cursor; DEALLOCATE filegrowth_cursor; END; ELSE BEGIN PRINT 'INFO: No database files found to check.'; END; BEGIN TRY DROP TABLE #FileGrowthList; END TRY BEGIN CATCH PRINT 'INFO: #FileGrowthList Temp table is already gone...'; END CATCH; END TRY BEGIN CATCH -- Handle any errors that occur during the process. SELECT ERROR_MESSAGE() AS ErrorMessage; SET @RunHasErrors = 1; SET @return_status = -1; --================================================-- Log error to table --=================================================-- IF (@LOGLEVEL in ('INFO','WARN','ERROR')) BEGIN INSERT INTO [TBDD_MAINTAIN_DATABASE_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [ADDED_WHO], [ADDED_WHEN]) VALUES ('ERROR', 'filegrowth', 'check', ERROR_MESSAGE(),@MY_PROCEDURE_NAME,GetDate()); END; ------------------------------------------------------------------------------------------------------------------------------ END CATCH; END ELSE BEGIN IF (@LOGLEVEL in ('INFO')) BEGIN SET @return_status_text = 'INFO: Skipping database file growth checks!'; PRINT @return_status_text; END; END; ------------------------------------------------------------------------------------------------------------------------------ --==============================================-- Change db working mode --===============================================-- IF (@FORCE = 1) BEGIN -- and ignore last result PRINT 'INFO: Set the database back to MULTI_USER mode'; SET @SQLCommand = N'ALTER DATABASE [' + @DBName + '] SET MULTI_USER; ALTER DATABASE [' + @DBName + '] SET ONLINE;'; EXEC @return_status = sp_executesql @SQLCommand; IF ((@LOGLEVEL in ('INFO')) and (@return_status = 0)) BEGIN SET @return_status_text = 'INFO: Setting the database to MULTI_USER mode was successfully completed!'; PRINT @return_status_text; END ELSE IF ((@LOGLEVEL in ('WARN')) and (@return_status <> 0)) BEGIN SET @return_status_text = 'WARN: Setting the database to MULTI_USER mode returns warnings or has failed, check the ID!'; PRINT @return_status_text; END; END ELSE BEGIN IF (@LOGLEVEL in ('INFO')) BEGIN SET @return_status_text = 'INFO: Skipping to change the database mode (FORCE = OFF)!'; PRINT @return_status_text; END; END; ----------------------------------------------------------------------------------------------------------------------------- --===============================================-- Log result to table --=================================================-- IF ((@LOGLEVEL in ('INFO','WARN')) and (@return_status is not null) and (@return_status_text is not null)) BEGIN INSERT INTO [TBDD_MAINTAIN_DATABASE_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN]) VALUES (@LOGLEVEL, 'db_cursor', @DBName, @return_status, @return_status_text, @MY_PROCEDURE_NAME, GetDate()); END; ----------------------------------------------------------------------------------------------------------------------------- -- Ensure temp table is droped and cursor is closed BEGIN BEGIN TRY DROP TABLE #DataFileList; END TRY BEGIN CATCH PRINT 'INFO: #DataFileList Temp table are already gone...'; END CATCH; IF (@REBUILDHEAPS = 1) BEGIN BEGIN TRY DROP TABLE #HeapList; END TRY BEGIN CATCH PRINT 'INFO: #HeapList Temp table are already gone...(1)'; END CATCH; BEGIN TRY CLOSE heap_cursor; DEALLOCATE heap_cursor; END TRY BEGIN CATCH PRINT 'INFO: Heap cursor is already closed and deallocated...(1)'; END CATCH; END; IF (@MAINTAINCOLUMNSTORE = 1) BEGIN BEGIN TRY DROP TABLE #ColumnstoreList; END TRY BEGIN CATCH PRINT 'INFO: #ColumnstoreList Temp table are already gone...(1)'; END CATCH; BEGIN TRY CLOSE columnstore_cursor; DEALLOCATE columnstore_cursor; END TRY BEGIN CATCH PRINT 'INFO: Columnstore cursor is already closed and deallocated...(1)'; END CATCH; END; IF (@CHECKFILEGROWTH = 1) BEGIN BEGIN TRY DROP TABLE #FileGrowthList; END TRY BEGIN CATCH PRINT 'INFO: #FileGrowthList Temp table are already gone...'; END CATCH; BEGIN TRY CLOSE filegrowth_cursor; DEALLOCATE filegrowth_cursor; END TRY BEGIN CATCH PRINT 'INFO: File growth cursor is already closed and deallocated...'; END CATCH; END; IF (@REBUILDINDEX = 1) BEGIN BEGIN TRY DROP TABLE #TableList; END TRY BEGIN CATCH PRINT 'INFO: #TableList Temp table are already gone...(1)'; END CATCH; BEGIN TRY DROP TABLE #IndexList; END TRY BEGIN CATCH PRINT 'INFO: #IndexList Temp table are already gone...(1)'; END CATCH; END; IF (@RECOMPILEPROCEDURES = 1) BEGIN BEGIN TRY DROP TABLE #ProcedureList; END TRY BEGIN CATCH PRINT 'INFO: #ProcedureList Temp table are already gone...(1)'; END CATCH; BEGIN TRY CLOSE procedure_cursor; DEALLOCATE procedure_cursor; END TRY BEGIN CATCH PRINT 'INFO: Procedure cursor is already closed and deallocated...(1)'; END CATCH; END; END; PRINT '-------------------------------'; FETCH NEXT FROM db_cursor INTO @DBName; END; CLOSE db_cursor; DEALLOCATE db_cursor; END ELSE BEGIN SET @return_status = 0; SET @return_status_text = 'So there is nothing to do...'; PRINT @return_status_text; --===============================================-- Log result to table --=================================================-- IF ((@LOGLEVEL in ('INFO','WARN','ERROR')) and (@return_status is not null) and (@return_status_text is not null)) BEGIN INSERT INTO [TBDD_MAINTAIN_DATABASE_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN]) VALUES ('WARN', 'db_list', 'count', @return_status, @return_status_text, @MY_PROCEDURE_NAME, GetDate()); END; ----------------------------------------------------------------------------------------------------------------------------- END; ----------------------------------------------------------------------------------------------------------------------------- --==============================================-- Clear system cache --================================================-- IF ((@FREESYSTEMCACHE = 1) and (@return_status = 0)) BEGIN PRINT 'INFO: Clearing SQL Server system cache.'; SET @SQLCommand = N'DBCC FREESYSTEMCACHE (''ALL'');'; EXEC @return_status = sp_executesql @SQLCommand; IF ((@LOGLEVEL in ('INFO')) and (@return_status = 0)) BEGIN SET @return_status_text = 'INFO: Clearing SQL Server system cache was successfully completed!'; PRINT @return_status_text; END; ELSE IF ((@LOGLEVEL in ('WARN')) and (@return_status <> 0)) BEGIN SET @return_status_text = 'WARN: Clearing SQL Server system cache returns warnings or has failed, check the ID!'; PRINT @return_status_text; END; END; ELSE BEGIN IF (@LOGLEVEL in ('INFO')) BEGIN SET @return_status_text = 'INFO: Skipping SQL Server system cache clearing!'; PRINT @return_status_text; END; END; ----------------------------------------------------------------------------------------------------------------------------- --===============================================-- Log result to table --=================================================-- IF ((@LOGLEVEL in ('INFO','WARN')) and (@return_status is not null) and (@return_status_text is not null)) BEGIN INSERT INTO [TBDD_MAINTAIN_DATABASE_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN]) VALUES (@LOGLEVEL, 'system_cache', 'clear', @return_status, @return_status_text, @MY_PROCEDURE_NAME, GetDate()); END; ----------------------------------------------------------------------------------------------------------------------------- --==============================================-- Clear session cache --================================================-- IF ((@FREESESSIONCACHE = 1) and (@return_status = 0)) BEGIN PRINT 'INFO: Clearing SQL Server session cache.'; SET @SQLCommand = N'DBCC FREESESSIONCACHE;'; EXEC @return_status = sp_executesql @SQLCommand; IF ((@LOGLEVEL in ('INFO')) and (@return_status = 0)) BEGIN SET @return_status_text = 'INFO: Clearing SQL Server session cache was successfully completed!'; PRINT @return_status_text; END; ELSE IF ((@LOGLEVEL in ('WARN')) and (@return_status <> 0)) BEGIN SET @return_status_text = 'WARN: Clearing SQL Server session cache returns warnings or has failed, check the ID!'; PRINT @return_status_text; END; END; ELSE BEGIN IF (@LOGLEVEL in ('INFO')) BEGIN SET @return_status_text = 'INFO: Skipping SQL Server session cache clearing!'; PRINT @return_status_text; END; END; ----------------------------------------------------------------------------------------------------------------------------- --===============================================-- Log result to table --=================================================-- IF ((@LOGLEVEL in ('INFO','WARN')) and (@return_status is not null) and (@return_status_text is not null)) BEGIN INSERT INTO [TBDD_MAINTAIN_DATABASE_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN]) VALUES (@LOGLEVEL, 'session_cache', 'clear', @return_status, @return_status_text, @MY_PROCEDURE_NAME, GetDate()); END; ----------------------------------------------------------------------------------------------------------------------------- --==============================================-- Shrink tempdb --================================================-- IF ((@SHRINKTEMPDB = 1) and (@return_status = 0)) BEGIN PRINT 'INFO: Shrink tempdb data and log files.'; IF OBJECT_ID('tempdb..#TempdbFileList') IS NOT NULL DROP TABLE #TempdbFileList; CREATE TABLE #TempdbFileList (FileName NVARCHAR(128)); INSERT INTO #TempdbFileList(FileName) SELECT [name] FROM [tempdb].[sys].[database_files] WHERE [type_desc] IN ('ROWS','LOG'); SELECT @TempdbFileCount = COUNT(*) FROM #TempdbFileList; PRINT 'INFO: Found: ' + CONVERT(VARCHAR,@TempdbFileCount) + ' tempdb file(s) to shrink.'; IF (@TempdbFileCount > 0) BEGIN BEGIN TRY DECLARE tempdb_cursor CURSOR STATIC LOCAL FOR SELECT FileName FROM #TempdbFileList; OPEN tempdb_cursor; FETCH NEXT FROM tempdb_cursor INTO @TempdbFileName; WHILE @@FETCH_STATUS = 0 BEGIN SET @SQLCommand = N'USE [tempdb]; DBCC SHRINKFILE (N''' + @TempdbFileName + ''', 0) WITH NO_INFOMSGS;'; EXEC @return_status = sp_executesql @SQLCommand; IF ((@LOGLEVEL in ('INFO')) and (@return_status = 0)) BEGIN SET @return_status_text = 'INFO: Shrinking tempdb file [' + @TempdbFileName + '] was successfully completed!'; PRINT @return_status_text; END ELSE IF ((@LOGLEVEL in ('WARN')) and (@return_status <> 0)) BEGIN SET @return_status_text = 'WARN: Shrinking tempdb file [' + @TempdbFileName + '] returns warnings or has failed, check the ID!'; PRINT @return_status_text; END; IF ((@LOGLEVEL in ('INFO','WARN')) and (@return_status is not null) and (@return_status_text is not null)) BEGIN INSERT INTO [TBDD_MAINTAIN_DATABASE_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN]) VALUES (@LOGLEVEL, 'tempdb_cursor', @TempdbFileName, @return_status, @return_status_text, @MY_PROCEDURE_NAME, GetDate()); END; FETCH NEXT FROM tempdb_cursor INTO @TempdbFileName; END; CLOSE tempdb_cursor; DEALLOCATE tempdb_cursor; END TRY BEGIN CATCH SET @RunHasErrors = 1; SET @return_status = -1; IF CURSOR_STATUS('local', 'tempdb_cursor') >= -1 BEGIN IF CURSOR_STATUS('local', 'tempdb_cursor') >= 0 CLOSE tempdb_cursor; DEALLOCATE tempdb_cursor; END; IF (@LOGLEVEL in ('INFO','WARN','ERROR')) BEGIN INSERT INTO [TBDD_MAINTAIN_DATABASE_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [ADDED_WHO], [ADDED_WHEN]) VALUES ('ERROR', 'tempdb', 'shrink', ERROR_MESSAGE(), @MY_PROCEDURE_NAME, GetDate()); END; END CATCH; END ELSE BEGIN PRINT 'INFO: No tempdb files found to shrink.'; END; IF OBJECT_ID('tempdb..#TempdbFileList') IS NOT NULL DROP TABLE #TempdbFileList; END ELSE BEGIN IF (@LOGLEVEL in ('INFO')) BEGIN SET @return_status_text = 'INFO: Skipping shrinking tempdb!'; PRINT @return_status_text; END; END; ----------------------------------------------------------------------------------------------------------------------------- --==============================================-- Cleanup maintenance log table --================================================-- IF ((@CLEANLOGS = 1) and (@return_status = 0)) BEGIN IF (@LOGRETENTIONDAYS > 0) BEGIN IF EXISTS (SELECT * FROM [INFORMATION_SCHEMA].[TABLES] WHERE [TABLE_NAME] = N'TBDD_MAINTAIN_DATABASE_LOG') BEGIN PRINT 'INFO: Cleanup maintenance log entries older than ' + CONVERT(VARCHAR,@LOGRETENTIONDAYS) + ' day(s).'; BEGIN TRY DELETE FROM [dbo].[TBDD_MAINTAIN_DATABASE_LOG] WHERE [ADDED_WHEN] < DATEADD(day, -@LOGRETENTIONDAYS, GETDATE()); SET @return_status = 0; IF ((@LOGLEVEL in ('INFO')) and (@return_status = 0)) BEGIN SET @return_status_text = 'INFO: Maintenance log cleanup successfully completed! Deleted: ' + CONVERT(VARCHAR,@@ROWCOUNT); PRINT @return_status_text; END; ELSE IF ((@LOGLEVEL in ('WARN')) and (@return_status <> 0)) BEGIN SET @return_status_text = 'WARN: Maintenance log cleanup returns warnings or has failed, check the ID!'; PRINT @return_status_text; END; IF ((@LOGLEVEL in ('INFO','WARN')) and (@return_status is not null) and (@return_status_text is not null)) BEGIN INSERT INTO [TBDD_MAINTAIN_DATABASE_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN]) VALUES (@LOGLEVEL, 'log_cleanup', 'cleanup', @return_status, @return_status_text, @MY_PROCEDURE_NAME, GetDate()); END; END TRY BEGIN CATCH -- Handle any errors that occur during the process. SELECT ERROR_MESSAGE() AS ErrorMessage; SET @RunHasErrors = 1; SET @return_status = -1; --================================================-- Log error to table --=================================================-- IF (@LOGLEVEL in ('INFO','WARN','ERROR')) BEGIN INSERT INTO [TBDD_MAINTAIN_DATABASE_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [ADDED_WHO], [ADDED_WHEN]) VALUES ('ERROR', 'log_cleanup', 'cleanup', ERROR_MESSAGE(),@MY_PROCEDURE_NAME,GetDate()); END; ------------------------------------------------------------------------------------------------------------------------------ END CATCH; END ELSE BEGIN PRINT 'WARN: Log table does not exist, skipping cleanup!'; END; END ELSE BEGIN PRINT 'INFO: Log retention days is 0, skipping cleanup.'; END; END ELSE BEGIN IF (@LOGLEVEL in ('INFO')) BEGIN SET @return_status_text = 'INFO: Skipping maintenance log cleanup!'; PRINT @return_status_text; END; END; ------------------------------------------------------------------------------------------------------------------------------ --==============================================-- Cycle SQL Server error logs --================================================-- IF ((@CYCLEERRORLOGS = 1) and (@return_status = 0)) BEGIN BEGIN TRY PRINT 'INFO: Cycling SQL Server error log.'; EXEC @return_status = [master].[dbo].[sp_cycle_errorlog]; IF ((@LOGLEVEL in ('INFO')) and (@return_status = 0)) BEGIN SET @return_status_text = 'INFO: Cycling SQL Server error log successfully completed!'; PRINT @return_status_text; END ELSE IF ((@LOGLEVEL in ('WARN')) and (@return_status <> 0)) BEGIN SET @return_status_text = 'WARN: Cycling SQL Server error log returns warnings or has failed, check the ID!'; PRINT @return_status_text; END; IF ((@LOGLEVEL in ('INFO','WARN')) and (@return_status is not null) and (@return_status_text is not null)) BEGIN INSERT INTO [TBDD_MAINTAIN_DATABASE_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN]) VALUES (@LOGLEVEL, 'errorlog', 'cycle', @return_status, @return_status_text, @MY_PROCEDURE_NAME, GetDate()); END; END TRY BEGIN CATCH -- Handle any errors that occur during the process. SELECT ERROR_MESSAGE() AS ErrorMessage; SET @RunHasErrors = 1; SET @return_status = -1; --================================================-- Log error to table --=================================================-- IF (@LOGLEVEL in ('INFO','WARN','ERROR')) BEGIN INSERT INTO [TBDD_MAINTAIN_DATABASE_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [ADDED_WHO], [ADDED_WHEN]) VALUES ('ERROR', 'errorlog', 'cycle', ERROR_MESSAGE(),@MY_PROCEDURE_NAME,GetDate()); END; ------------------------------------------------------------------------------------------------------------------------------ END CATCH; BEGIN TRY PRINT 'INFO: Cycling SQL Server Agent error log.'; EXEC @return_status = [msdb].[dbo].[sp_cycle_agent_errorlog]; IF ((@LOGLEVEL in ('INFO')) and (@return_status = 0)) BEGIN SET @return_status_text = 'INFO: Cycling SQL Server Agent error log successfully completed!'; PRINT @return_status_text; END; ELSE IF ((@LOGLEVEL in ('WARN')) and (@return_status <> 0)) BEGIN SET @return_status_text = 'WARN: Cycling SQL Server Agent error log returns warnings or has failed, check the ID!'; PRINT @return_status_text; END; IF ((@LOGLEVEL in ('INFO','WARN')) and (@return_status is not null) and (@return_status_text is not null)) BEGIN INSERT INTO [TBDD_MAINTAIN_DATABASE_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN]) VALUES (@LOGLEVEL, 'agent_errorlog', 'cycle', @return_status, @return_status_text, @MY_PROCEDURE_NAME, GetDate()); END; END TRY BEGIN CATCH -- Handle any errors that occur during the process. SELECT ERROR_MESSAGE() AS ErrorMessage; SET @RunHasErrors = 1; SET @return_status = -1; --================================================-- Log error to table --=================================================-- IF (@LOGLEVEL in ('INFO','WARN','ERROR')) BEGIN INSERT INTO [TBDD_MAINTAIN_DATABASE_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [ADDED_WHO], [ADDED_WHEN]) VALUES ('ERROR', 'agent_errorlog', 'cycle', ERROR_MESSAGE(),@MY_PROCEDURE_NAME,GetDate()); END; ------------------------------------------------------------------------------------------------------------------------------ END CATCH; END; ELSE BEGIN IF (@LOGLEVEL in ('INFO')) BEGIN SET @return_status_text = 'INFO: Skipping error log rotation!'; PRINT @return_status_text; END; END; ------------------------------------------------------------------------------------------------------------------------------ SET @return_status_text = 'END PROCEDURE [' + @MY_PROCEDURE_NAME + '] @ ' + CONVERT(varchar(50),GETDATE(),120); IF (@return_status <> 0) BEGIN SET @RunHasErrors = 1; END; IF ((@LOGLEVEL in ('INFO','WARN','ERROR')) and EXISTS ( SELECT 1 FROM [dbo].[TBDD_MAINTAIN_DATABASE_LOG] WHERE [LOG_LEVEL] = 'ERROR' AND [ADDED_WHO] = @MY_PROCEDURE_NAME AND [ADDED_WHEN] >= @RunStart )) BEGIN SET @RunHasErrors = 1; END; IF (@RunHasErrors = 1) BEGIN SET @return_status = -1; END; --================================================-- Log end to table --===================================================-- IF ((@LOGLEVEL in ('INFO')) and (@return_status is not null) and (@return_status_text is not null)) BEGIN INSERT INTO [TBDD_MAINTAIN_DATABASE_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN]) VALUES (@LOGLEVEL, 'closing', 'procedure', @return_status, @return_status_text, @MY_PROCEDURE_NAME, GetDate()); END; ----------------------------------------------------------------------------------------------------------------------------- PRINT ''; PRINT @return_status_text; PRINT '===================================================================================================='; Return @return_status; END; -- ================================================================= -- Example execution (defaults) -- ================================================================= -- EXEC [dbo].[PRDD_MAINTAIN_DATABASE] -- @pCHECKDB = 0, -- @pSHRINKLOG = 0, -- @pSHRINKDB = 0, -- @pSHRINKTEMPDB = 0, -- @pREBUILDINDEX = 0, -- @pRECOMPILEPROCEDURES = 0, -- @pCLEARQUERYCACHE = 0, -- @pFREESYSTEMCACHE = 0, -- @pFREESESSIONCACHE = 0, -- @pCLEARDBPROCCACHE = 0, -- @pUPDATESTATISTICS = 1, -- @pREBUILDHEAPS = 0, -- @pMAINTAINCOLUMNSTORE = 0, -- @pCHECKFILEGROWTH = 1, -- @pCLEANLOGS = 0, -- @pLOGRETENTIONDAYS = 30, -- @pCYCLEERRORLOGS = 0, -- @pFORCE = 0, -- @pINCLUDEDB = 'DD_ECM', -- @pEXCLUDEDB = 'master,model,msdb,tempdb', -- @pLOGLEVEL = 'ERROR';