diff --git a/current/[PRDD_MAINTAIN_DATABASES]/[PRDD_MAINTAIN_DATABASES].sql b/current/[PRDD_MAINTAIN_DATABASES]/[PRDD_MAINTAIN_DATABASES].sql index 75c15b8..bb78839 100644 --- a/current/[PRDD_MAINTAIN_DATABASES]/[PRDD_MAINTAIN_DATABASES].sql +++ b/current/[PRDD_MAINTAIN_DATABASES]/[PRDD_MAINTAIN_DATABASES].sql @@ -4,7 +4,7 @@ -- and recreates indizes in a maintanance run. -- Minimum requirement: MS SQL Server 2016 -- --- Returns: Table with results +-- Returns: INT Value - 0 = Everything worked well -- ================================================================= -- Copyright (c) 2024 by Digital Data GmbH -- @@ -12,11 +12,12 @@ -- Tel.: 0641/202360 • E-Mail: info-flow@digitaldata.works -- ================================================================= -- Creation Date / Author: 29.11.2024 / MK --- Version Date / Editor: 29.11.2024 / MK --- Version Number: 1.0.0.0 +-- Version Date / Editor: 06.12.2024 / MK +-- Version Number: 1.1.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 SET ANSI_NULLS ON GO @@ -24,33 +25,40 @@ SET QUOTED_IDENTIFIER ON GO CREATE OR ALTER PROCEDURE [dbo].[PRDD_MAINTAIN_DATABASES] ( - @pCHECKDB BIT = 1, -- Set to 1 to make a check of the database before shrinking. Otherwise set to 0. - @pSHRINKLOG BIT = 1, -- 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!) - @pREBUILDINDEX BIT = 1, -- Set to 1 to recreate all database indxes. Otherwise set to 0. - @pFORCE BIT = 0, -- Set to 1 to force the shrinking, it will cut all current sessens. 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_DATABASES_LOG] - -- 'INFO' includes Warnings and Errors, 'WARN' only warnings and Errors and 'ERROR' only Errors + @pCHECKDB BIT = 1, -- Set to 1 to make a check of the database before shrinking incl. soft repair function. Otherwise set to 0. + @pSHRINKLOG BIT = 1, -- 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!) + @pREBUILDINDEX BIT = 0, -- Set to 1 to 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. + @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_DATABASES_LOG] + -- 'INFO' includes Infos, Warnings and Errors, 'WARN' only warnings and Errors and 'ERROR' only Errors ) AS BEGIN SET NOCOUNT ON; - -- decalare new vars because of parameter sniffing + -- declare new vars because of parameter sniffing DECLARE @CHECKDB BIT = @pCHECKDB, @SHRINKLOG BIT = @pSHRINKLOG, @SHRINKDB BIT = @pSHRINKDB, @REBUILDINDEX BIT = @pREBUILDINDEX, + @RECOMPILEPROCEDURES BIT = @pRECOMPILEPROCEDURES, + @CLEARQUERYCACHE BIT = @pCLEARQUERYCACHE, @FORCE BIT = @pFORCE, @INCLUDEDB NVARCHAR(1000) = @pINCLUDEDB, @EXCLUDEDB NVARCHAR(1000) = @pEXCLUDEDB, @LOGLEVEL NVARCHAR(25) = @pLOGLEVEL; - -- decalare runtime vars - DECLARE @DBName NVARCHAR(100), + -- declare runtime vars + DECLARE @MyProcedureName NVARCHAR(50) = 'PRDD_MAINTAIN_DATABASES'; + DECLARE @ProcedureName NVARCHAR(50), + @DBName NVARCHAR(100), + @DBNameCount INT, @LogFileName NVARCHAR(100), @CurrentLogFileSizeMB INT, @MinimumLogFileSizeMB INT, @@ -61,20 +69,28 @@ BEGIN @ProductEdition sql_variant, @SchemaName NVARCHAR(50), @TableName NVARCHAR(256), - @SQLCommand NVARCHAR(MAX) = NULL, + @LoginName NVARCHAR(50), + @HostName NVARCHAR(50), + @SessionID NVARCHAR(50) = NULL, + @MySessionID NVARCHAR(50) = @@SPID, + @SQLCommand NVARCHAR(MAX) = NULL, + @TableListCount INT = 0, + @ProcedureListCount INT = 0, @return_status NVARCHAR(50) = 0, - @return_status_text NVARCHAR(MAX) = 'START [PRDD_MAINTAIN_DATABASES] @ ' + CONVERT(varchar(50),GETDATE(),120); + @return_status_text NVARCHAR(MAX) = 'START ' + @MyProcedureName + ' @ ' + CONVERT(varchar(50),GETDATE(),120); PRINT '===============================' - PRINT 'PROCEDURE - START [PRDD_MAINTAIN_DATABASES] @ ' + CONVERT(varchar(50),GETDATE(),120); - PRINT 'PARAMETER1 - @CHECKDB: ' + CONVERT(VARCHAR(1),@CHECKDB); - PRINT 'PARAMETER2 - @SHRINKLOG: ' + CONVERT(VARCHAR(1),@SHRINKLOG); - PRINT 'PARAMETER3 - @SHRINKDB: ' + CONVERT(VARCHAR(1),@SHRINKDB); - PRINT 'PARAMETER4 - @REBUILDINDEX: ' + CONVERT(VARCHAR(1),@REBUILDINDEX); - PRINT 'PARAMETER5 - @FORCE: ' + CONVERT(VARCHAR(1),@FORCE); - PRINT 'PARAMETER6 - @INCLUDEDB: ' + CONVERT(VARCHAR(1000),@INCLUDEDB); - PRINT 'PARAMETER7 - @EXCLUDEDB: ' + CONVERT(VARCHAR(1000),@EXCLUDEDB); - PRINT 'PARAMETER8 - @LOGLEVEL: ' + CONVERT(VARCHAR(25),@LOGLEVEL); + PRINT 'PROCEDURE - ' + @return_status_text; + PRINT 'PARAMETER01 - @CHECKDB: ' + CONVERT(VARCHAR(1),@CHECKDB); + PRINT 'PARAMETER02 - @SHRINKLOG: ' + CONVERT(VARCHAR(1),@SHRINKLOG); + PRINT 'PARAMETER03 - @SHRINKDB: ' + CONVERT(VARCHAR(1),@SHRINKDB); + PRINT 'PARAMETER04 - @REBUILDINDEX: ' + CONVERT(VARCHAR(1),@REBUILDINDEX); + PRINT 'PARAMETER05 - @RECOMPILEPROCEDURES: ' + CONVERT(VARCHAR(1),@RECOMPILEPROCEDURES); + PRINT 'PARAMETER06 - @CLEARQUERYCACHE: ' + CONVERT(VARCHAR(1),@CLEARQUERYCACHE); + PRINT 'PARAMETER07 - @FORCE: ' + CONVERT(VARCHAR(1),@FORCE); + PRINT 'PARAMETER08 - @INCLUDEDB: ' + CONVERT(VARCHAR(1000),@INCLUDEDB); + PRINT 'PARAMETER09 - @EXCLUDEDB: ' + CONVERT(VARCHAR(1000),@EXCLUDEDB); + PRINT 'PARAMETER10 - @LOGLEVEL: ' + CONVERT(VARCHAR(25),@LOGLEVEL); --=================================================-- Get server infos --==================================================-- SELECT @ProductVersion = SERVERPROPERTY('productversion'), @ProductLevel = SERVERPROPERTY ('productlevel'), @ProductEdition = SERVERPROPERTY ('edition'); @@ -82,6 +98,7 @@ BEGIN PRINT ''; PRINT 'Informations about this Server:'; + PRINT '@MySessionID: ' + CONVERT(VARCHAR(100),@MySessionID); PRINT '@ProductVersion: ' + CONVERT(VARCHAR(100),@ProductVersion); PRINT '@ProductMainVersion: ' + CONVERT(VARCHAR(100),@ProductMainVersion); PRINT '@ProductLevel: ' + CONVERT(VARCHAR(100),@ProductLevel); @@ -90,9 +107,9 @@ BEGIN --==============================================-- Prepare the log table --================================================-- IF (@LOGLEVEL is not NULL) BEGIN - PRINT '' + PRINT ''; IF EXISTS (SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = N'TBDD_MAINTAIN_DATABASES_LOG') BEGIN - PRINT 'Log table already exists' + PRINT 'Log table already exists'; END; ELSE BEGIN PRINT 'Log table does not exists, trying to create...'; @@ -118,14 +135,17 @@ BEGIN ALTER TABLE [dbo].[TBDD_MAINTAIN_DATABASES_LOG] ADD CONSTRAINT [DF_TBDD_MAINTAIN_DATABASES_LOG_ADDED_WHEN] DEFAULT (getdate()) FOR [ADDED_WHEN]; END; + END; ELSE BEGIN + PRINT ''; + PRINT 'Skipping Logging to log table!'; END; ----------------------------------------------------------------------------------------------------------------------------- --===============================================-- Log start to table --=================================================-- IF ((@LOGLEVEL in ('INFO')) and (@return_status is not null) and (@return_status_text is not null)) BEGIN IF EXISTS (SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = N'TBDD_MAINTAIN_DATABASES_LOG') BEGIN - INSERT INTO [TBDD_MAINTAIN_DATABASES_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN]) - VALUES (@LOGLEVEL,'preparing', 'procedure', @return_status, @return_status_text, 'PRDD_MAINTAIN_DATABASES',GetDate()); + INSERT INTO [TBDD_MAINTAIN_DATABASES_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN]) + VALUES (@LOGLEVEL,'preparing', 'procedure', @return_status, @return_status_text, @MyProcedureName, GetDate()); END; END; ----------------------------------------------------------------------------------------------------------------------------- @@ -134,150 +154,227 @@ BEGIN -- Create a temporary table to hold the table names CREATE TABLE #DBList (DBName NVARCHAR(256)); - IF (@INCLUDEDB is not NULL) BEGIN - INSERT INTO #DBList(DBName) - SELECT [name] as 'DBName' - FROM [master].[sys].[databases] - WHERE [name] IN (SELECT [value] FROM STRING_SPLIT(@INCLUDEDB, ',')) -- include these databases - AND [state] = 0 -- database is online - AND [is_in_standby] = 0; -- database is not read only for log shipping + 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 [value] FROM STRING_SPLIT(@INCLUDEDB, ',')) -- 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 [value] FROM STRING_SPLIT(@EXCLUDEDB, ',')) -- 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 '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] NOT IN (SELECT [value] FROM STRING_SPLIT(@EXCLUDEDB, ',')) -- exclude these databases + WHERE [name] = @INCLUDEDB -- 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 = 'Found ' + convert(VARCHAR,@DBNameCount) + ' database(s) to process!'; + PRINT @return_status_text; + + --===============================================-- Log result to table --=================================================-- + IF (@LOGLEVEL in ('INFO','WARN')) BEGIN + IF EXISTS (SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = N'TBDD_MAINTAIN_DATABASES_LOG') BEGIN + INSERT INTO [TBDD_MAINTAIN_DATABASES_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN]) + VALUES (@LOGLEVEL, 'db_list', 'count', @return_status, @return_status_text, @MyProcedureName, GetDate()); + END; END; ----------------------------------------------------------------------------------------------------------------------------- - --=============================================-- Create the loop (cursor) --==============================================-- - DECLARE db_cursor CURSOR STATIC LOCAL FOR - SELECT [DBName] as 'DBName' FROM #DBList + --==========================================-- 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 - BEGIN TRY + OPEN db_cursor + FETCH NEXT FROM db_cursor INTO @DBName + WHILE @@FETCH_STATUS = 0 BEGIN + BEGIN TRY - PRINT ' ' - PRINT '-------------------------------' - PRINT 'Now processing: ' + CONVERT(varchar(100),@DBName); + PRINT ' '; + PRINT '-------------------------------'; + PRINT 'Now processing: ' + CONVERT(varchar(100),@DBName); - --==============================================-- Change db working mode --===============================================-- - IF (@FORCE = 1) and (@return_status = 0) BEGIN - PRINT 'Set the database to SINGLE_USER mode to terminate all active sessions.' - SET @SQLCommand = N'ALTER DATABASE [' + @DBName + '] SET SINGLE_USER WITH ROLLBACK IMMEDIATE'; - EXEC @return_status = sp_executesql @SQLCommand; + --==============================================-- Change db working mode --===============================================-- + IF (@FORCE = 1) and (@return_status = 0) BEGIN + + PRINT '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] (NOLOCK) + 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 '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 = '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 = '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 + IF EXISTS (SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = N'TBDD_MAINTAIN_DATABASES_LOG') BEGIN + INSERT INTO [TBDD_MAINTAIN_DATABASES_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN]) + VALUES (@LOGLEVEL, 'kill_cursor', @DBName, @return_status, @return_status_text, @MyProcedureName, GetDate()); + END; + END; + ----------------------------------------------------------------------------------------------------------------------------- + + END TRY + BEGIN CATCH + + -- Handle any errors that occur during the process. + SELECT ERROR_MESSAGE() AS ErrorMessage; + + SET @SQLCommand = NULL; + + --===============================================-- Log result to table --=================================================-- + IF ((@LOGLEVEL is not null) and (@return_status is not null) and (@return_status_text is not null)) BEGIN + IF EXISTS (SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = N'TBDD_MAINTAIN_DATABASES_LOG') BEGIN + INSERT INTO [TBDD_MAINTAIN_DATABASES_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [ADDED_WHO], [ADDED_WHEN]) + VALUES ('ERROR', 'kill_cursor', @DBName, ERROR_MESSAGE(),@MyProcedureName, GetDate()); + END; + END; + ----------------------------------------------------------------------------------------------------------------------------- + + END CATCH; + + FETCH NEXT FROM kill_cursor INTO @SessionID, @LoginName, @HostName; + + END; + + CLOSE kill_cursor; + DEALLOCATE kill_cursor; + ----------------------------------------------------------------------------------------------------------------------------- + + PRINT '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 = '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 = 'Setting the database to SINGLE_USER mode 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 + IF EXISTS (SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = N'TBDD_MAINTAIN_DATABASES_LOG') BEGIN + INSERT INTO [TBDD_MAINTAIN_DATABASES_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN]) + VALUES (@LOGLEVEL, 'db_cursor', @DBName, @return_status, @return_status_text, @MyProcedureName, GetDate()); + END; + END; + ----------------------------------------------------------------------------------------------------------------------------- + + END; ELSE BEGIN + + IF (@LOGLEVEL in ('INFO')) BEGIN + SET @return_status_text = '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 + IF EXISTS (SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = N'TBDD_MAINTAIN_DATABASES_LOG') BEGIN + INSERT INTO [TBDD_MAINTAIN_DATABASES_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN]) + VALUES (@LOGLEVEL, 'db_cursor', @DBName, @return_status, @return_status_text, @MyProcedureName, GetDate()); + END; + END; + ----------------------------------------------------------------------------------------------------------------------------- - IF ((@LOGLEVEL in ('INFO')) and (@return_status = 0)) BEGIN - SET @return_status_text = '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 = 'Setting the database to SINGLE_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 = 'Skipping to change the database mode (FORCE = OFF)!'; - PRINT @return_status_text; - END; - END; - ----------------------------------------------------------------------------------------------------------------------------- + --===============================================-- Check db consistency --================================================-- + IF (@CHECKDB = 1) and (@return_status = 0) BEGIN - --===============================================-- Log result to table --=================================================-- - IF ((@LOGLEVEL in ('INFO','WARN')) and (@return_status is not null) and (@return_status_text is not null)) BEGIN - IF EXISTS (SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = N'TBDD_MAINTAIN_DATABASES_LOG') BEGIN - INSERT INTO [TBDD_MAINTAIN_DATABASES_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN]) - VALUES (@LOGLEVEL, 'db_cursor', @DBName, @return_status, @return_status_text, 'PRDD_MAINTAIN_DATABASES',GetDate()); - END; - END; - ----------------------------------------------------------------------------------------------------------------------------- + IF (@FORCE = 1) BEGIN + PRINT 'Check the database for consistency and health and try soft repair.'; + SET @SQLCommand = N'USE [' + @DBName + ']; DBCC CHECKDB ([' + @DBName + '], REPAIR_REBUILD) WITH NO_INFOMSGS, ALL_ERRORMSGS'; + END; ELSE BEGIN + PRINT 'Check the database for consistency and health.'; + SET @SQLCommand = N'USE [' + @DBName + ']; DBCC CHECKDB ([' + @DBName + ']) WITH NO_INFOMSGS, ALL_ERRORMSGS'; + END; - --===============================================-- Check db consistency --================================================-- - IF (@CHECKDB = 1) and (@return_status = 0) BEGIN - PRINT 'Check the database for consistency and health.'; - SET @SQLCommand = N'DBCC CHECKDB ([' + @DBName + ']) WITH NO_INFOMSGS, ALL_ERRORMSGS'; - EXEC @return_status = sp_executesql @SQLCommand; + EXEC @return_status = sp_executesql @SQLCommand; - IF ((@LOGLEVEL in ('INFO')) and (@return_status = 0)) BEGIN - SET @return_status_text = '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 = 'Check the database for consistency and health returns warnings or has failed, check the ID!'; - PRINT @return_status_text; - END; + IF ((@LOGLEVEL in ('INFO')) and (@return_status = 0)) BEGIN + SET @return_status_text = '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 = '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 = '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 - IF EXISTS (SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = N'TBDD_MAINTAIN_DATABASES_LOG') BEGIN - INSERT INTO [TBDD_MAINTAIN_DATABASES_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN]) - VALUES (@LOGLEVEL, 'db_cursor', @DBName, @return_status, @return_status_text, 'PRDD_MAINTAIN_DATABASES',GetDate()); - END; - END; - ----------------------------------------------------------------------------------------------------------------------------- - - --============================================-- Prepare shrinking the log--===============================================-- - IF (@SHRINKLOG = 1) BEGIN - - --===========================================-- Get infos about the log file --============================================-- - PRINT 'Get the current and minimum size of the log file in MB.'; - SET @SQLCommand = N'SELECT TOP 1 @LogFileName = [name], @CurrentLogFileSizeMB = ([size] / 128), @MinimumLogFileSizeMB = ([growth] * 8) - FROM [master].[sys].[master_files] - WHERE [database_id] = DB_ID(''' + @DBName + ''') AND [type_desc] = ''LOG'''; - EXEC @return_status = sp_executesql @SQLCommand, N'@LogFileName VARCHAR(100) OUTPUT, @CurrentLogFileSizeMB INT OUTPUT, @MinimumLogFileSizeMB INT OUTPUT', - @LogFileName OUTPUT, @CurrentLogFileSizeMB OUTPUT, @MinimumLogFileSizeMB OUTPUT; - - IF ((@LOGLEVEL in ('INFO')) and (@return_status = 0)) BEGIN - SET @return_status_text = '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 = 'Getting log file settings returns warnings or has failed, check the ID!'; - PRINT @return_status_text; + END; ELSE BEGIN + IF (@LOGLEVEL in ('INFO')) BEGIN + SET @return_status_text = '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 IF EXISTS (SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = N'TBDD_MAINTAIN_DATABASES_LOG') BEGIN - INSERT INTO [TBDD_MAINTAIN_DATABASES_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN]) - VALUES (@LOGLEVEL, 'db_cursor', @DBName, @return_status, @return_status_text, 'PRDD_MAINTAIN_DATABASES',GetDate()); + INSERT INTO [TBDD_MAINTAIN_DATABASES_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN]) + VALUES (@LOGLEVEL, 'db_cursor', @DBName, @return_status, @return_status_text, @MyProcedureName, GetDate()); END; END; ----------------------------------------------------------------------------------------------------------------------------- - --===========================================-- Calculate target file size --==============================================-- - PRINT 'The @CurrentLogFileSizeMB is: ' + CONVERT(VARCHAR(1000),@CurrentLogFileSizeMB); - SET @TargetLogFileSizeMB = CASE WHEN @CurrentLogFileSizeMB * 0.1 < @MinimumLogFileSizeMB - THEN @MinimumLogFileSizeMB - ELSE @CurrentLogFileSizeMB * 0.1 - END; + --============================================-- Prepare shrinking the log--===============================================-- + IF (@SHRINKLOG = 1) BEGIN - PRINT 'The @TargetLogFileSizeMB is: ' + CONVERT(VARCHAR(1000),@TargetLogFileSizeMB); - ----------------------------------------------------------------------------------------------------------------------------- - - --=================================================-- Schrink db logs --===================================================-- - IF (@CurrentLogFileSizeMB > @TargetLogFileSizeMB) BEGIN - - --=============================================-- Change db recovery mode --===============================================-- - PRINT 'Truncating the log needs to change the database recovery model to SIMPLE.'; - SET @SQLCommand = N'ALTER DATABASE [' + @DBName + '] SET RECOVERY SIMPLE'; - EXEC @return_status = sp_executesql @SQLCommand; + --===========================================-- Get infos about the log file --============================================-- + PRINT 'Get the current and minimum size of the log file in MB.'; + SET @SQLCommand = N'SELECT TOP 1 @LogFileName = [name], @CurrentLogFileSizeMB = ([size] / 128), @MinimumLogFileSizeMB = ([growth] * 8) + FROM [master].[sys].[master_files] + WHERE [database_id] = DB_ID(''' + @DBName + ''') AND [type_desc] = ''LOG'''; + EXEC @return_status = sp_executesql @SQLCommand, N'@LogFileName VARCHAR(100) OUTPUT, @CurrentLogFileSizeMB INT OUTPUT, @MinimumLogFileSizeMB INT OUTPUT', + @LogFileName OUTPUT, @CurrentLogFileSizeMB OUTPUT, @MinimumLogFileSizeMB OUTPUT; IF ((@LOGLEVEL in ('INFO')) and (@return_status = 0)) BEGIN - SET @return_status_text = 'Setting database to the simple recovery model was successfully completed!'; + SET @return_status_text = '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 = 'Setting database to the simple recovery model returns warnings or has failed, check the ID!'; + SET @return_status_text = 'Getting log file settings returns warnings or has failed, check the ID!'; PRINT @return_status_text; END; ----------------------------------------------------------------------------------------------------------------------------- @@ -285,369 +382,732 @@ BEGIN --===============================================-- Log result to table --=================================================-- IF ((@LOGLEVEL in ('INFO','WARN')) and (@return_status is not null) and (@return_status_text is not null)) BEGIN IF EXISTS (SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = N'TBDD_MAINTAIN_DATABASES_LOG') BEGIN - INSERT INTO [TBDD_MAINTAIN_DATABASES_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN]) - VALUES (@LOGLEVEL, 'db_cursor', @DBName, @return_status, @return_status_text, 'PRDD_MAINTAIN_DATABASES',GetDate()); + INSERT INTO [TBDD_MAINTAIN_DATABASES_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN]) + VALUES (@LOGLEVEL, 'db_cursor', @DBName, @return_status, @return_status_text, @MyProcedureName, GetDate()); END; END; ----------------------------------------------------------------------------------------------------------------------------- - --===================================================-- Now, do it! --=====================================================-- - IF (@return_status = 0) BEGIN - PRINT 'Shrink the truncated log file to 10% of its current size or the minimum size, whichever is larger.'; - IF (@ProductMainVersion >= 16) BEGIN - IF (@FORCE = 1) BEGIN - SET @SQLCommand = N'USE [' + @DBName + ']; DBCC SHRINKFILE (''' + @LogFileName + ''', ' + CAST(@TargetLogFileSizeMB AS VARCHAR) + ') WITH WAIT_AT_LOW_PRIORITY (ABORT_AFTER_WAIT = BLOCKERS);'; - END; ELSE BEGIN - SET @SQLCommand = N'USE [' + @DBName + ']; DBCC SHRINKFILE (''' + @LogFileName + ''', ' + CAST(@TargetLogFileSizeMB AS VARCHAR) + ') WITH WAIT_AT_LOW_PRIORITY (ABORT_AFTER_WAIT = SELF);'; - END; - END; ELSE BEGIN - PRINT 'Because of the sql server version, DBCC SHRINKFILE is not applicable with the FORCE parameter!' - SET @SQLCommand = N'USE [' + @DBName + ']; DBCC SHRINKFILE (''' + @LogFileName + ''', ' + CAST(@TargetLogFileSizeMB AS VARCHAR) + ');'; - END; + --===========================================-- Calculate target file size --==============================================-- + PRINT 'The @CurrentLogFileSizeMB is: ' + CONVERT(VARCHAR(1000),@CurrentLogFileSizeMB); + SET @TargetLogFileSizeMB = CASE WHEN @CurrentLogFileSizeMB * 0.1 < @MinimumLogFileSizeMB + THEN @MinimumLogFileSizeMB + ELSE @CurrentLogFileSizeMB * 0.1 + END; + PRINT 'The @TargetLogFileSizeMB is: ' + CONVERT(VARCHAR(1000),@TargetLogFileSizeMB); + ----------------------------------------------------------------------------------------------------------------------------- + + --=================================================-- Schrink db logs --===================================================-- + IF (@CurrentLogFileSizeMB > @TargetLogFileSizeMB) BEGIN + + --=============================================-- Change db recovery mode --===============================================-- + PRINT 'Truncating the log needs to change the database recovery model to SIMPLE.'; + SET @SQLCommand = N'ALTER DATABASE [' + @DBName + '] SET RECOVERY SIMPLE'; EXEC @return_status = sp_executesql @SQLCommand; IF ((@LOGLEVEL in ('INFO')) and (@return_status = 0)) BEGIN - SET @return_status_text = 'Shrinking the database log file was successfully completed!'; + SET @return_status_text = 'Setting database to the simple recovery model was successfully completed!'; PRINT @return_status_text; END; ELSE IF ((@LOGLEVEL in ('WARN')) and (@return_status <> 0)) BEGIN - SET @return_status_text = '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 = '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 - IF EXISTS (SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = N'TBDD_MAINTAIN_DATABASES_LOG') BEGIN - INSERT INTO [TBDD_MAINTAIN_DATABASES_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN]) - VALUES (@LOGLEVEL, 'db_cursor', @DBName, @return_status, @return_status_text, 'PRDD_MAINTAIN_DATABASES',GetDate()); - END; - END; - ----------------------------------------------------------------------------------------------------------------------------- - - --=============================================-- Change db recovery mode --===============================================-- - PRINT 'Reset the database recovery model.' - SET @SQLCommand = N'ALTER DATABASE [' + @DBName + '] SET RECOVERY FULL'; - EXEC @return_status = sp_executesql @SQLCommand; - - IF ((@LOGLEVEL in ('INFO')) and (@return_status = 0)) BEGIN - SET @return_status_text = 'Setting database back to the full recovery model was successfully completed!'; - PRINT @return_status_text; - END; ELSE IF ((@LOGLEVEL in ('WARN')) and (@return_status <> 0)) BEGIN - SET @return_status_text = 'Setting database back to the full 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 - IF EXISTS (SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = N'TBDD_MAINTAIN_DATABASES_LOG') BEGIN - INSERT INTO [TBDD_MAINTAIN_DATABASES_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN]) - VALUES (@LOGLEVEL, 'db_cursor', @DBName, @return_status, @return_status_text, 'PRDD_MAINTAIN_DATABASES',GetDate()); - END; - END; - ----------------------------------------------------------------------------------------------------------------------------- - - END; ELSE BEGIN - PRINT 'No shrink action neccessary!'; - END; - ----------------------------------------------------------------------------------------------------------------------------- - - END; ELSE BEGIN - PRINT 'Dont shrink the log file!'; - END; - ----------------------------------------------------------------------------------------------------------------------------- - - --================================================-- Shrink db as well --==================================================-- - IF ((@SHRINKDB = 1) and (@return_status = 0)) BEGIN - PRINT 'Shrink the database to reclaim unused space.'; - IF (@ProductMainVersion >= 16) BEGIN - IF (@FORCE = 1) BEGIN - SET @SQLCommand = N'USE [' + @DBName + ']; DBCC SHRINKDATABASE ([' + @DBName + ']) WITH WAIT_AT_LOW_PRIORITY (ABORT_AFTER_WAIT = BLOCKERS);'; - END; ELSE BEGIN - SET @SQLCommand = N'USE [' + @DBName + ']; DBCC SHRINKDATABASE ([' + @DBName + ']) WITH WAIT_AT_LOW_PRIORITY (ABORT_AFTER_WAIT = SELF);'; - END; - END; ELSE BEGIN - PRINT 'Because of the sql server version, DBCC SHRINKDATABASE is not applicable with the FORCE parameter!' - SET @SQLCommand = N'USE [' + @DBName + ']; DBCC SHRINKDATABASE ([' + @DBName + ']);'; - END; - - EXEC @return_status = sp_executesql @SQLCommand; - - IF ((@LOGLEVEL in ('INFO')) and (@return_status = 0)) BEGIN - SET @return_status_text = 'Shrinking the database was successfully completed!'; - PRINT @return_status_text; - END; ELSE IF ((@LOGLEVEL in ('WARN')) and (@return_status <> 0)) BEGIN - SET @return_status_text = 'Shrinking the database 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 = '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 - IF EXISTS (SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = N'TBDD_MAINTAIN_DATABASES_LOG') BEGIN - INSERT INTO [TBDD_MAINTAIN_DATABASES_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN]) - VALUES (@LOGLEVEL, 'db_cursor', @DBName, @return_status, @return_status_text, 'PRDD_MAINTAIN_DATABASES',GetDate()); - END; - END; - ----------------------------------------------------------------------------------------------------------------------------- - - --=============================================-- Rebuild database indexes --==============================================-- - IF ((@REBUILDINDEX = 1) and (@return_status = 0)) BEGIN - PRINT 'Prepare to rebuild database indexes.'; - - BEGIN TRY - DROP TABLE #TableList; - END TRY - BEGIN CATCH - PRINT '#TableList 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 = '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 = 'Getting the tables 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 = '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 - IF EXISTS (SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = N'TBDD_MAINTAIN_DATABASES_LOG') BEGIN - INSERT INTO [TBDD_MAINTAIN_DATABASES_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN]) - VALUES (@LOGLEVEL, 'db_cursor', @DBName, @return_status, @return_status_text, 'PRDD_MAINTAIN_DATABASES',GetDate()); - END; - END; - ----------------------------------------------------------------------------------------------------------------------------- - - IF ((@REBUILDINDEX = 1) and (@return_status = 0) and (SELECT COUNT(*) FROM #TableList) > 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 'Rebuild Index for table: ' + CONVERT(VARCHAR(1000),@TableName); - SET @SQLCommand = 'ALTER INDEX ALL ON [' + @DBName + '].[' + @SchemaName + '].[' + @TableName + '] ' + - 'REBUILD WITH (FILLFACTOR = 80, SORT_IN_TEMPDB = ON, STATISTICS_NORECOMPUTE = ON)'; - EXEC @return_status = sp_executesql @SQLCommand; - - IF ((@LOGLEVEL in ('INFO')) and (@return_status = 0)) BEGIN - SET @return_status_text = 'Recreation the database indexes of Table [' + @TableName + '] successfully completed!'; - PRINT @return_status_text; - END; ELSE IF ((@LOGLEVEL in ('WARN')) and (@return_status <> 0)) BEGIN - SET @return_status_text = 'Recreation the database indexes of Table [' + @TableName + '] returns warnings or has failed, check the ID!'; + SET @return_status_text = 'Setting database to the simple 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 IF EXISTS (SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = N'TBDD_MAINTAIN_DATABASES_LOG') BEGIN - INSERT INTO [TBDD_MAINTAIN_DATABASES_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN]) - VALUES (@LOGLEVEL, 'table_cursor', @DBName, @return_status, @return_status_text, 'PRDD_MAINTAIN_DATABASES',GetDate()); + INSERT INTO [TBDD_MAINTAIN_DATABASES_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN]) + VALUES (@LOGLEVEL, 'db_cursor', @DBName, @return_status, @return_status_text, @MyProcedureName, GetDate()); END; END; ----------------------------------------------------------------------------------------------------------------------------- + --===================================================-- Now, do it! --=====================================================-- + IF (@return_status = 0) BEGIN + PRINT 'Shrink the truncated log file to 10% of its current size or the minimum size, whichever is larger.'; + IF (@ProductMainVersion >= 16) BEGIN + IF (@FORCE = 1) BEGIN + SET @SQLCommand = N'USE [' + @DBName + ']; DBCC SHRINKFILE (''' + @LogFileName + ''', ' + CAST(@TargetLogFileSizeMB 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(@TargetLogFileSizeMB AS VARCHAR) + ') WITH WAIT_AT_LOW_PRIORITY (ABORT_AFTER_WAIT = SELF), NO_INFOMSGS;'; + END; + END; ELSE BEGIN + PRINT 'Because of the sql server version, DBCC SHRINKFILE is not applicable with the FORCE parameter!'; + SET @SQLCommand = N'USE [' + @DBName + ']; DBCC SHRINKFILE (''' + @LogFileName + ''', ' + CAST(@TargetLogFileSizeMB 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 = '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 = '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 = '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 + IF EXISTS (SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = N'TBDD_MAINTAIN_DATABASES_LOG') BEGIN + INSERT INTO [TBDD_MAINTAIN_DATABASES_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN]) + VALUES (@LOGLEVEL, 'db_cursor', @DBName, @return_status, @return_status_text, @MyProcedureName, GetDate()); + END; + END; + ----------------------------------------------------------------------------------------------------------------------------- + + --=============================================-- Change db recovery mode --===============================================-- + PRINT 'Reset the database recovery model.' + SET @SQLCommand = N'ALTER DATABASE [' + @DBName + '] SET RECOVERY FULL'; + EXEC @return_status = sp_executesql @SQLCommand; + + IF ((@LOGLEVEL in ('INFO')) and (@return_status = 0)) BEGIN + SET @return_status_text = 'Setting database back to the full recovery model was successfully completed!'; + PRINT @return_status_text; + END; ELSE IF ((@LOGLEVEL in ('WARN')) and (@return_status <> 0)) BEGIN + SET @return_status_text = 'Setting database back to the full 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 + IF EXISTS (SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = N'TBDD_MAINTAIN_DATABASES_LOG') BEGIN + INSERT INTO [TBDD_MAINTAIN_DATABASES_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN]) + VALUES (@LOGLEVEL, 'db_cursor', @DBName, @return_status, @return_status_text, @MyProcedureName, GetDate()); + END; + END; + ----------------------------------------------------------------------------------------------------------------------------- + + END; ELSE BEGIN + PRINT 'No shrink action neccessary!'; + END; + ----------------------------------------------------------------------------------------------------------------------------- + + END; ELSE BEGIN + PRINT 'Skipping to shrink the log file!'; + END; + ----------------------------------------------------------------------------------------------------------------------------- + + --================================================-- Shrink db as well --==================================================-- + IF ((@SHRINKDB = 1) and (@return_status = 0)) BEGIN + PRINT 'Shrink the database to reclaim unused space.'; + IF (@ProductMainVersion >= 16) BEGIN + IF (@FORCE = 1) BEGIN + SET @SQLCommand = N'USE [' + @DBName + ']; DBCC SHRINKDATABASE ([' + @DBName + ']) WITH WAIT_AT_LOW_PRIORITY (ABORT_AFTER_WAIT = BLOCKERS), NO_INFOMSGS;'; + END; ELSE BEGIN + SET @SQLCommand = N'USE [' + @DBName + ']; DBCC SHRINKDATABASE ([' + @DBName + ']) WITH WAIT_AT_LOW_PRIORITY (ABORT_AFTER_WAIT = SELF), NO_INFOMSGS;'; + END; + END; ELSE BEGIN + PRINT 'Because of the sql server version, DBCC SHRINKDATABASE is not applicable with the FORCE parameter!'; + SET @SQLCommand = N'USE [' + @DBName + ']; DBCC SHRINKDATABASE ([' + @DBName + ']) WITH NO_INFOMSGS;'; + END; + + EXEC @return_status = sp_executesql @SQLCommand; + + IF ((@LOGLEVEL in ('INFO')) and (@return_status = 0)) BEGIN + SET @return_status_text = 'Shrinking the database was successfully completed!'; + PRINT @return_status_text; + END; ELSE IF ((@LOGLEVEL in ('WARN')) and (@return_status <> 0)) BEGIN + SET @return_status_text = 'Shrinking the database 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 = '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 + IF EXISTS (SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = N'TBDD_MAINTAIN_DATABASES_LOG') BEGIN + INSERT INTO [TBDD_MAINTAIN_DATABASES_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN]) + VALUES (@LOGLEVEL, 'db_cursor', @DBName, @return_status, @return_status_text, @MyProcedureName, GetDate()); + END; + END; + ----------------------------------------------------------------------------------------------------------------------------- + + --=============================================-- Rebuild database indexes --==============================================-- + IF ((@REBUILDINDEX = 1) and (@return_status = 0)) BEGIN + PRINT 'Prepare to rebuild database indexes.'; + + BEGIN TRY + DROP TABLE #TableList; END TRY BEGIN CATCH - - -- Handle any errors that occur during the process. - SELECT ERROR_MESSAGE() AS ErrorMessage; - - --================================================-- Log error to table --=================================================-- - IF (@LOGLEVEL in ('INFO','WARN','ERROR')) BEGIN - IF EXISTS (SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = N'TBDD_MAINTAIN_DATABASES_LOG') BEGIN - INSERT INTO [TBDD_MAINTAIN_DATABASES_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [ADDED_WHO], [ADDED_WHEN]) - VALUES (@LOGLEVEL, 'table_cursor', @DBName, ERROR_MESSAGE(),'PRDD_MAINTAIN_DATABASES',GetDate()); - END; - END; - ----------------------------------------------------------------------------------------------------------------------------- - + PRINT '#TableList 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 = '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 = '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 'Found: ' + convert(VARCHAR,@TableListCount) + ' tables to reindex'; + END; ELSE BEGIN + SET @TableListCount = 0; + PRINT 'Found: no tables to reindex'; + END; + + END; ELSE BEGIN + IF (@LOGLEVEL in ('INFO')) BEGIN + SET @return_status_text = '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 + IF EXISTS (SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = N'TBDD_MAINTAIN_DATABASES_LOG') BEGIN + INSERT INTO [TBDD_MAINTAIN_DATABASES_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN]) + VALUES (@LOGLEVEL, 'db_cursor', @DBName, @return_status, @return_status_text, @MyProcedureName, GetDate()); + END; + END; + ----------------------------------------------------------------------------------------------------------------------------- + + IF ((@REBUILDINDEX = 1) and (@return_status = 0) and (@TableListCount > 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 - END; + PRINT 'Rebuild Index for table: ' + CONVERT(VARCHAR(1000),@TableName); + SET @SQLCommand = 'ALTER INDEX ALL ON [' + @DBName + '].[' + @SchemaName + '].[' + @TableName + '] ' + + 'REBUILD WITH (FILLFACTOR = 80, SORT_IN_TEMPDB = ON, STATISTICS_NORECOMPUTE = ON)'; + EXEC @return_status = sp_executesql @SQLCommand; - CLOSE table_cursor; - DEALLOCATE table_cursor; + IF ((@LOGLEVEL in ('INFO')) and (@return_status = 0)) BEGIN + SET @return_status_text = 'Recreation the database indexes of Table [' + @TableName + '] successfully completed!'; + PRINT @return_status_text; + END; ELSE IF ((@LOGLEVEL in ('WARN')) and (@return_status <> 0)) BEGIN + SET @return_status_text = 'Recreation the database indexes of Table [' + @TableName + '] returns warnings or has failed, check the ID!'; + PRINT @return_status_text; + END; - -- Drop the temporary table - DROP TABLE #TableList; + --===============================================-- Log result to table --=================================================-- + IF ((@LOGLEVEL in ('INFO','WARN')) and (@return_status is not null) and (@return_status_text is not null)) BEGIN + IF EXISTS (SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = N'TBDD_MAINTAIN_DATABASES_LOG') BEGIN + INSERT INTO [TBDD_MAINTAIN_DATABASES_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN]) + VALUES (@LOGLEVEL, 'table_cursor', @DBName, @return_status, @return_status_text, @MyProcedureName, GetDate()); + END; + END; + ----------------------------------------------------------------------------------------------------------------------------- - SET @return_status_text = 'Recreation of the database indexes successfully completed!'; - PRINT @return_status_text; + -- Short break to avoid access violations + WAITFOR DELAY '00:00:03'; - END; ELSE BEGIN - IF (@LOGLEVEL in ('INFO')) BEGIN - SET @return_status_text = 'Skipping the recreation of the database indexes!'; + ----------------------------------------------------------------------------------------------------------------------------- + PRINT '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] (NOLOCK) + 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 '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 = '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 = '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 + IF EXISTS (SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = N'TBDD_MAINTAIN_DATABASES_LOG') BEGIN + INSERT INTO [TBDD_MAINTAIN_DATABASES_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN]) + VALUES (@LOGLEVEL, 'kill_cursor', @DBName, @return_status, @return_status_text, @MyProcedureName, GetDate()); + END; + END; + ----------------------------------------------------------------------------------------------------------------------------- + + END TRY + BEGIN CATCH + + -- Handle any errors that occur during the process. + SELECT ERROR_MESSAGE() AS ErrorMessage; + + SET @SQLCommand = NULL; + + --===============================================-- Log result to table --=================================================-- + IF ((@LOGLEVEL is not null) and (@return_status is not null) and (@return_status_text is not null)) BEGIN + IF EXISTS (SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = N'TBDD_MAINTAIN_DATABASES_LOG') BEGIN + INSERT INTO [TBDD_MAINTAIN_DATABASES_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [ADDED_WHO], [ADDED_WHEN]) + VALUES ('ERROR', 'kill_cursor', @DBName, ERROR_MESSAGE(),@MyProcedureName, GetDate()); + END; + END; + ----------------------------------------------------------------------------------------------------------------------------- + + END CATCH; + + FETCH NEXT FROM kill_cursor INTO @SessionID, @LoginName, @HostName; + + END; + + CLOSE kill_cursor; + DEALLOCATE kill_cursor; + ----------------------------------------------------------------------------------------------------------------------------- + + 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; + + --================================================-- Log error to table --=================================================-- + IF (@LOGLEVEL in ('INFO','WARN','ERROR')) BEGIN + IF EXISTS (SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = N'TBDD_MAINTAIN_DATABASES_LOG') BEGIN + INSERT INTO [TBDD_MAINTAIN_DATABASES_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [ADDED_WHO], [ADDED_WHEN]) + VALUES ('ERROR', 'table_cursor', @DBName, ERROR_MESSAGE(),@MyProcedureName, GetDate()); + END; + 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 = 'Recreation of the database indexes successfully completed!'; PRINT @return_status_text; + + END; ELSE BEGIN + IF (@LOGLEVEL in ('INFO')) BEGIN + SET @return_status_text = 'Skipping the recreation of the database indexes!'; + PRINT @return_status_text; + END; 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 - IF EXISTS (SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = N'TBDD_MAINTAIN_DATABASES_LOG') BEGIN - INSERT INTO [TBDD_MAINTAIN_DATABASES_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN]) - VALUES (@LOGLEVEL, 'db_cursor', @DBName, @return_status, @return_status_text, 'PRDD_MAINTAIN_DATABASES',GetDate()); + --===============================================-- Log result to table --=================================================-- + IF ((@LOGLEVEL in ('INFO','WARN')) and (@return_status is not null) and (@return_status_text is not null)) BEGIN + IF EXISTS (SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = N'TBDD_MAINTAIN_DATABASES_LOG') BEGIN + INSERT INTO [TBDD_MAINTAIN_DATABASES_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN]) + VALUES (@LOGLEVEL, 'db_cursor', @DBName, @return_status, @return_status_text, @MyProcedureName, GetDate()); + END; END; - END; - ----------------------------------------------------------------------------------------------------------------------------- + ----------------------------------------------------------------------------------------------------------------------------- - --==============================================-- Change db working mode --===============================================-- - IF (@FORCE = 1) BEGIN -- and ignore last result - PRINT 'Set the database back to MULTI_USER mode'; - SET @SQLCommand = N'ALTER DATABASE [' + @DBName + '] SET MULTI_USER'; - EXEC @return_status = sp_executesql @SQLCommand; + --=========================================-- Prepare to recompile Procedures --===========================================-- + IF ((@RECOMPILEPROCEDURES = 1) and (@return_status = 0)) BEGIN + PRINT 'Prepare to recompile database procedures.'; - IF ((@LOGLEVEL in ('INFO')) and (@return_status = 0)) BEGIN - SET @return_status_text = 'Setting the database to MULTI_USER mode was successfully completed!'; + BEGIN TRY + DROP TABLE #ProcedureList; + END TRY + BEGIN CATCH + PRINT '#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_CATALOG, SPECIFIC_NAME + FROM [' + @DBName + '].INFORMATION_SCHEMA.ROUTINES (NOLOCK) + WHERE ROUTINE_TYPE = ''PROCEDURE'' + AND SPECIFIC_NAME <> ''' + @MyProcedureName + ''' + ORDER BY SPECIFIC_NAME;'; + EXEC @return_status = sp_executesql @SQLCommand; + + IF ((@LOGLEVEL in ('INFO')) and (@return_status = 0)) BEGIN + SET @return_status_text = '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 = '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 'Found: ' + convert(VARCHAR,@ProcedureListCount) + ' procedures to recompile'; + END; ELSE BEGIN + SET @ProcedureListCount = 0; + PRINT 'Found: no procedures to recompile'; + END; + + END; ELSE BEGIN + IF (@LOGLEVEL in ('INFO')) BEGIN + SET @return_status_text = '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 + IF EXISTS (SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = N'TBDD_MAINTAIN_DATABASES_LOG') BEGIN + INSERT INTO [TBDD_MAINTAIN_DATABASES_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN]) + VALUES (@LOGLEVEL, 'db_cursor', @DBName, @return_status, @return_status_text, @MyProcedureName, GetDate()); + END; + END; + ----------------------------------------------------------------------------------------------------------------------------- + + --===============================================-- Recompile Procedures --================================================-- + IF ((@RECOMPILEPROCEDURES = 1) and (@return_status = 0) and (@ProcedureListCount > 0)) BEGIN + + PRINT '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 = '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 = '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 + IF EXISTS (SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = N'TBDD_MAINTAIN_DATABASES_LOG') BEGIN + INSERT INTO [TBDD_MAINTAIN_DATABASES_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN]) + VALUES (@LOGLEVEL, 'procedure_cursor', @DBName, @return_status, @return_status_text, @MyProcedureName, GetDate()); + END; + 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 'Recompile procedure: ' + CONVERT(VARCHAR(1000),@ProcedureName); + SET @SQLCommand = 'USE [' + @DBName + ']; EXEC sp_recompile ''' + @ProcedureName + '''; '; + EXEC @return_status = sp_executesql @SQLCommand; + + IF ((@LOGLEVEL in ('INFO')) and (@return_status = 0)) BEGIN + SET @return_status_text = 'Recompiling the procedure [' + @ProcedureName + '] successfully completed!'; + PRINT @return_status_text; + END; ELSE IF ((@LOGLEVEL in ('WARN')) and (@return_status <> 0)) BEGIN + SET @return_status_text = 'Recompiling the procedure [' + @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 + IF EXISTS (SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = N'TBDD_MAINTAIN_DATABASES_LOG') BEGIN + INSERT INTO [TBDD_MAINTAIN_DATABASES_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN]) + VALUES (@LOGLEVEL, 'procedure_cursor', @DBName, @return_status, @return_status_text, @MyProcedureName, GetDate()); + END; + 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; + + --================================================-- Log error to table --=================================================-- + IF (@LOGLEVEL in ('INFO','WARN','ERROR')) BEGIN + IF EXISTS (SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = N'TBDD_MAINTAIN_DATABASES_LOG') BEGIN + INSERT INTO [TBDD_MAINTAIN_DATABASES_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [ADDED_WHO], [ADDED_WHEN]) + VALUES ('ERROR', 'procedure_cursor', @DBName, ERROR_MESSAGE(),@MyProcedureName, GetDate()); + END; + 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 = 'Recompiling of procedures successfully completed!'; PRINT @return_status_text; - END; ELSE IF ((@LOGLEVEL in ('WARN')) and (@return_status <> 0)) BEGIN - SET @return_status_text = '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 = '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 - IF EXISTS (SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = N'TBDD_MAINTAIN_DATABASES_LOG') BEGIN - INSERT INTO [TBDD_MAINTAIN_DATABASES_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN]) - VALUES (@LOGLEVEL, 'db_cursor', @DBName, @return_status, @return_status_text, 'PRDD_MAINTAIN_DATABASES',GetDate()); + END; ELSE BEGIN + IF (@LOGLEVEL in ('INFO')) BEGIN + SET @return_status_text = 'Skipping the recompiling of the procedures!'; + PRINT @return_status_text; + END; 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 + IF EXISTS (SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = N'TBDD_MAINTAIN_DATABASES_LOG') BEGIN + INSERT INTO [TBDD_MAINTAIN_DATABASES_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN]) + VALUES (@LOGLEVEL, 'procedure_cursor', @DBName, @return_status, @return_status_text, @MyProcedureName, GetDate()); + END; + END; + ----------------------------------------------------------------------------------------------------------------------------- + + --================================================-- Clear Query Cache --==================================================-- + + IF ((@CLEARQUERYCACHE = 1) and (@return_status = 0)) BEGIN + + PRINT '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 = '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 = '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 = '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 + IF EXISTS (SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = N'TBDD_MAINTAIN_DATABASES_LOG') BEGIN + INSERT INTO [TBDD_MAINTAIN_DATABASES_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN]) + VALUES (@LOGLEVEL, 'db_cursor', @DBName, @return_status, @return_status_text, @MyProcedureName, GetDate()); + END; + END; + ----------------------------------------------------------------------------------------------------------------------------- + + --==============================================-- Change db working mode --===============================================-- + IF (@FORCE = 1) BEGIN -- and ignore last result + PRINT '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 = '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 = '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 = '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 + IF EXISTS (SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = N'TBDD_MAINTAIN_DATABASES_LOG') BEGIN + INSERT INTO [TBDD_MAINTAIN_DATABASES_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN]) + VALUES (@LOGLEVEL, 'db_cursor', @DBName, @return_status, @return_status_text, @MyProcedureName, GetDate()); + END; + END; + ----------------------------------------------------------------------------------------------------------------------------- + + -- Ensure temp table is droped and cursor is closed + BEGIN TRY + DROP TABLE #DBList; + END TRY + BEGIN CATCH + PRINT '#DBList Temp table are already gone...'; + END CATCH; + + IF (@REBUILDINDEX = 1) BEGIN + + BEGIN TRY + DROP TABLE #TableList; + END TRY + BEGIN CATCH + PRINT '#TableList Temp table are already gone...(1)'; + END CATCH; + + END; + + IF (@RECOMPILEPROCEDURES = 1) BEGIN + + BEGIN TRY + DROP TABLE #ProcedureList; + END TRY + BEGIN CATCH + PRINT '#ProcedureList Temp table are already gone...(1)'; + END CATCH; + + BEGIN TRY + CLOSE procedure_cursor; + DEALLOCATE procedure_cursor; + END TRY + BEGIN CATCH + PRINT 'Procedure cursor is already closed and deallocated...(1)'; + END CATCH; + + END; + + PRINT '-------------------------------'; - -- Ensure temp table is droped and cursor is closed - BEGIN TRY - DROP TABLE #DBList; END TRY BEGIN CATCH - PRINT '#DBList Temp table are already gone...' + -- Handle any errors that occur during the process. + SELECT ERROR_MESSAGE() AS ErrorMessage; + + --================================================-- Log error to table --=================================================-- + IF (@LOGLEVEL in ('INFO','WARN','ERROR')) BEGIN + IF EXISTS (SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = N'TBDD_MAINTAIN_DATABASES_LOG') BEGIN + INSERT INTO [TBDD_MAINTAIN_DATABASES_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [ADDED_WHO], [ADDED_WHEN]) + VALUES ('ERROR', 'db_cursor', @DBName, ERROR_MESSAGE(),@MyProcedureName,GetDate()); + END; + END; + ----------------------------------------------------------------------------------------------------------------------------- + + --==============================================-- Change db working mode --===============================================-- + -- Ensure the database is set back to MULTI_USER mode in case of errors. + --==============================================-- Change db working mode --===============================================-- + IF (@FORCE = 1) BEGIN -- and ignore last result + PRINT '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 = '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 = '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 = 'Skipping to change the database mode (FORCE = OFF)!'; + PRINT @return_status_text; + END; + END; + ----------------------------------------------------------------------------------------------------------------------------- + + --===============================================-- Log start to table --=================================================-- + IF ((@LOGLEVEL in ('INFO','WARN')) and (@return_status is not null) and (@return_status_text is not null)) BEGIN + IF EXISTS (SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = N'TBDD_MAINTAIN_DATABASES_LOG') BEGIN + INSERT INTO [TBDD_MAINTAIN_DATABASES_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN]) + VALUES (@LOGLEVEL, 'db_cursor', @DBName, @return_status, @return_status_text, @MyProcedureName, GetDate()); + END; + END; + ----------------------------------------------------------------------------------------------------------------------------- + + --=====================================================-- Clean up --======================================================-- + -- Ensure temp table is droped and cursor is closed + BEGIN TRY + DROP TABLE #DBList; + END TRY + BEGIN CATCH + PRINT '#DBList Temp table are already gone...'; + END CATCH; + + IF (@REBUILDINDEX = 1) BEGIN + + BEGIN TRY + DROP TABLE #TableList; + END TRY + BEGIN CATCH + PRINT '#TableList Temp table are already gone...(2)'; + END CATCH; + + BEGIN TRY + CLOSE table_cursor; + DEALLOCATE table_cursor; + END TRY + BEGIN CATCH + PRINT 'Table cursor is already closed and deallocated...(2)'; + END CATCH; + + END; + + IF (@RECOMPILEPROCEDURES = 1) BEGIN + + BEGIN TRY + DROP TABLE #ProcedureList; + END TRY + BEGIN CATCH + PRINT '#ProcedureList Temp table are already gone...(2)'; + END CATCH; + + BEGIN TRY + CLOSE procedure_cursor; + DEALLOCATE procedure_cursor; + END TRY + BEGIN CATCH + PRINT 'Procedure cursor is already closed and deallocated...(2)'; + END CATCH; + + END; + ----------------------------------------------------------------------------------------------------------------------------- + END CATCH; - BEGIN TRY - DROP TABLE #TableList; - END TRY - BEGIN CATCH - PRINT '#TableList Temp table are already gone...(2)' - END CATCH; + FETCH NEXT FROM db_cursor INTO @DBName; - PRINT '-------------------------------' + END; - END TRY - BEGIN CATCH - -- Handle any errors that occur during the process. - SELECT ERROR_MESSAGE() AS ErrorMessage; - - --================================================-- Log error to table --=================================================-- - IF (@LOGLEVEL in ('INFO','WARN','ERROR')) BEGIN - IF EXISTS (SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = N'TBDD_MAINTAIN_DATABASES_LOG') BEGIN - INSERT INTO [TBDD_MAINTAIN_DATABASES_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [ADDED_WHO], [ADDED_WHEN]) - VALUES ('ERROR', 'db_cursor', @DBName, ERROR_MESSAGE(),'PRDD_MAINTAIN_DATABASES',GetDate()); - END; - END; - ----------------------------------------------------------------------------------------------------------------------------- - - --==============================================-- Change db working mode --===============================================-- - -- Ensure the database is set back to MULTI_USER mode in case of errors. - --==============================================-- Change db working mode --===============================================-- - IF (@FORCE = 1) BEGIN -- and ignore last result - PRINT 'Set the database back to MULTI_USER mode'; - SET @SQLCommand = N'ALTER DATABASE [' + @DBName + '] SET MULTI_USER'; - EXEC @return_status = sp_executesql @SQLCommand; - - IF ((@LOGLEVEL in ('INFO')) and (@return_status = 0)) BEGIN - SET @return_status_text = '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 = '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 = 'Skipping to change the database mode (FORCE = OFF)!'; - PRINT @return_status_text; - END; - END; - ----------------------------------------------------------------------------------------------------------------------------- - - --===============================================-- Log start to table --=================================================-- - IF ((@LOGLEVEL in ('INFO','WARN')) and (@return_status is not null) and (@return_status_text is not null)) BEGIN - IF EXISTS (SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = N'TBDD_MAINTAIN_DATABASES_LOG') BEGIN - INSERT INTO [TBDD_MAINTAIN_DATABASES_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN]) - VALUES (@LOGLEVEL, 'db_cursor', @DBName, @return_status, @return_status_text, 'PRDD_MAINTAIN_DATABASES',GetDate()); - END; - END; - ----------------------------------------------------------------------------------------------------------------------------- - - --=====================================================-- Clean up --======================================================-- - -- Ensure temp table is droped and cursor is closed - BEGIN TRY - DROP TABLE #DBList; - END TRY - BEGIN CATCH - PRINT '#DBList Temp table are already gone...' - END CATCH; - - BEGIN TRY - DROP TABLE #TableList; - END TRY - BEGIN CATCH - PRINT '#TableList Temp table are already gone...(3)' - END CATCH; - - CLOSE table_cursor - DEALLOCATE table_cursor - ----------------------------------------------------------------------------------------------------------------------------- - - END CATCH; - - FETCH NEXT FROM db_cursor INTO @DBName; + CLOSE db_cursor; + DEALLOCATE db_cursor; + END; ELSE BEGIN + PRINT ''; + PRINT 'So there is nothing to do...'; END; - - CLOSE db_cursor - DEALLOCATE db_cursor ----------------------------------------------------------------------------------------------------------------------------- SET @return_status_text = 'END [PRDD_MAINTAIN_DATABASES] @ ' + CONVERT(varchar(50),GETDATE(),120); @@ -655,14 +1115,14 @@ BEGIN --================================================-- Log end to table --===================================================-- IF ((@LOGLEVEL in ('INFO')) and (@return_status is not null) and (@return_status_text is not null)) BEGIN IF EXISTS (SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = N'TBDD_MAINTAIN_DATABASES_LOG') BEGIN - INSERT INTO [TBDD_MAINTAIN_DATABASES_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN]) - VALUES (@LOGLEVEL,'closing', 'procedure', @return_status, @return_status_text, 'PRDD_MAINTAIN_DATABASES',GetDate()); + INSERT INTO [TBDD_MAINTAIN_DATABASES_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN]) + VALUES (@LOGLEVEL, 'closing', 'procedure', @return_status, @return_status_text, @MyProcedureName, GetDate()); END; END; ----------------------------------------------------------------------------------------------------------------------------- PRINT ''; - PRINT 'PROCEDURE - END [PRDD_MAINTAIN_DATABASES] @ ' + CONVERT(varchar(50),GETDATE(),120); + PRINT 'PROCEDURE - ' + @return_status_text; PRINT '==============================='; Return @return_status;