-- [PRDD_MAINTAIN_DATABASES] -- ================================================================= -- Checks database health, shrinks all database and log files -- and recreates indizes in a maintanance run. -- Minimum requirement: MS SQL Server 2016 -- -- Returns: Table with results -- ================================================================= -- Copyright (c) 2024 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: 18.11.2024 / MK -- Version Date / Editor: 18.11.2024 / MK -- Version Number: 1.0.0.0 -- ================================================================= -- History: -- 18.11.2024 / MK - First Version SET ANSI_NULLS ON GO 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 ) AS BEGIN SET NOCOUNT ON; DECLARE @DBName NVARCHAR(100), @LogFileName NVARCHAR(100), @CurrentLogFileSizeMB INT, @MinimumLogFileSizeMB INT, @TargetLogFileSizeMB INT, @CHECKDB BIT = @pCHECKDB, @SHRINKLOG BIT = @pSHRINKLOG, @SHRINKDB BIT = @pSHRINKDB, @REBUILDINDEX BIT = @pREBUILDINDEX, @FORCE BIT = @pFORCE, @INCLUDEDB NVARCHAR(1000) = @pINCLUDEDB, @EXCLUDEDB NVARCHAR(1000) = @pEXCLUDEDB, @LOGLEVEL NVARCHAR(25) = @pLOGLEVEL, @ProductVersion sql_variant, @ProductMainVersion INT, @ProductLevel sql_variant, @ProductEdition sql_variant, @SchemaName NVARCHAR(50), @TableName NVARCHAR(256), @SQLCommand NVARCHAR(MAX) = NULL, @return_status NVARCHAR(50) = 0, @return_status_text NVARCHAR(MAX) = 'START [PRDD_MAINTAIN_DATABASES] @ ' + 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); --=================================================-- Get server infos --==================================================-- SELECT @ProductVersion = SERVERPROPERTY('productversion'), @ProductLevel = SERVERPROPERTY ('productlevel'), @ProductEdition = SERVERPROPERTY ('edition'); SET @ProductMainVersion = ISNULL(LEFT(convert(VARCHAR(100),@ProductVersion), CHARINDEX('.', convert(VARCHAR(100),@ProductVersion)) - 1),0); PRINT ''; PRINT 'Informations about this Server:'; PRINT '@ProductVersion: ' + CONVERT(VARCHAR(100),@ProductVersion); PRINT '@ProductMainVersion: ' + CONVERT(VARCHAR(100),@ProductMainVersion); PRINT '@ProductLevel: ' + CONVERT(VARCHAR(100),@ProductLevel); PRINT '@ProductEdition: ' + CONVERT(VARCHAR(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_DATABASES_LOG') BEGIN PRINT 'Log table already exists' END; ELSE BEGIN PRINT 'Log table does not exists, trying to create...'; CREATE TABLE [dbo].[TBDD_MAINTAIN_DATABASES_LOG]( [GUID] [bigint] IDENTITY(1,1) NOT NULL, [LOG_LEVEL] [varchar](25) NOT NULL, [MESSAGE1] [varchar](max) NOT NULL, [MESSAGE2] [varchar](max) NULL, [MESSAGE3] [varchar](max) NULL, [MESSAGE4] [varchar](max) NULL, [MESSAGE5] [varchar](max) NULL, [COMMENT] [varchar](max) NULL, [ADDED_WHO] [varchar](50) NOT NULL, [ADDED_WHEN] [datetime] NOT NULL, CONSTRAINT [PK_TBDD_MAINTAIN_DATABASES_LOG] PRIMARY KEY CLUSTERED ( [GUID] ASC )WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY] ) ON [PRIMARY] TEXTIMAGE_ON [PRIMARY]; ALTER TABLE [dbo].[TBDD_MAINTAIN_DATABASES_LOG] ADD CONSTRAINT [DF_TBDD_MAINTAIN_DATABASES_LOG_ADDED_WHO] DEFAULT ('DEFAULT') FOR [ADDED_WHO]; ALTER TABLE [dbo].[TBDD_MAINTAIN_DATABASES_LOG] ADD CONSTRAINT [DF_TBDD_MAINTAIN_DATABASES_LOG_ADDED_WHEN] DEFAULT (getdate()) FOR [ADDED_WHEN]; END; 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()); END; END; ----------------------------------------------------------------------------------------------------------------------------- --=============================================-- Get the dbs for the loop --==============================================-- -- 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 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; ----------------------------------------------------------------------------------------------------------------------------- --=============================================-- Create the loop (cursor) --==============================================-- DECLARE db_cursor CURSOR READ_ONLY 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 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; 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; 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; ----------------------------------------------------------------------------------------------------------------------------- --===============================================-- 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; ----------------------------------------------------------------------------------------------------------------------------- --===============================================-- 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; 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; 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; ----------------------------------------------------------------------------------------------------------------------------- --===============================================-- 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()); 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; 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 sp_executesql @SQLCommand; ----------------------------------------------------------------------------------------------------------------------------- --===================================================-- Now, do it! --=====================================================-- 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) SET @SQLCommand = N'USE [' + @DBName + ']; DBCC SHRINKFILE (''' + @LogFileName + ''', ' + CAST(@TargetLogFileSizeMB AS VARCHAR) + ') WITH WAIT_AT_LOW_PRIORITY (ABORT_AFTER_WAIT = BLOCKERS);'; ELSE SET @SQLCommand = N'USE [' + @DBName + ']; DBCC SHRINKFILE (''' + @LogFileName + ''', ' + CAST(@TargetLogFileSizeMB AS VARCHAR) + ') WITH WAIT_AT_LOW_PRIORITY (ABORT_AFTER_WAIT = SELF);'; 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 EXEC sp_executesql @SQLCommand; ----------------------------------------------------------------------------------------------------------------------------- --=============================================-- Change db recovery mode --===============================================-- PRINT 'Reset the database recovery model.' SET @SQLCommand = N'ALTER DATABASE [' + @DBName + '] SET RECOVERY FULL'; EXEC sp_executesql @SQLCommand; ----------------------------------------------------------------------------------------------------------------------------- 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) SET @SQLCommand = N'USE [' + @DBName + ']; DBCC SHRINKDATABASE ([' + @DBName + ']) WITH WAIT_AT_LOW_PRIORITY (ABORT_AFTER_WAIT = BLOCKERS);'; ELSE SET @SQLCommand = N'USE [' + @DBName + ']; DBCC SHRINKDATABASE ([' + @DBName + ']) WITH WAIT_AT_LOW_PRIORITY (ABORT_AFTER_WAIT = SELF);'; 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; 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, 'table_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 are already gone...' 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 = 'Rebuild database indexes was successfully done!'; PRINT @return_status_text; END; IF ((@LOGLEVEL in ('WARN')) and (@return_status <> 0)) BEGIN SET @return_status_text = 'Rebuild database indexes 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, 'table_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 READ_ONLY 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; 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; --===============================================-- 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()); END; 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 (@LOGLEVEL, 'table_cursor', @DBName, ERROR_MESSAGE(),'PRDD_MAINTAIN_DATABASES',GetDate()); END; END; ----------------------------------------------------------------------------------------------------------------------------- END CATCH; FETCH NEXT FROM table_cursor INTO @SchemaName, @TableName; END; CLOSE table_cursor; DEALLOCATE table_cursor; -- Drop the temporary table DROP TABLE #TableList; SET @return_status_text = 'Skipping the recreation of the database indexes!'; 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; ----------------------------------------------------------------------------------------------------------------------------- --===============================================-- 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()); END; END; ----------------------------------------------------------------------------------------------------------------------------- --==============================================-- Change db working mode --===============================================-- IF (@FORCE = 1) -- and ignore last result BEGIN 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 SINGLE_USER mode was successfully completed!'; PRINT @return_status_text; END; 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; ----------------------------------------------------------------------------------------------------------------------------- --===============================================-- 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()); 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; BEGIN TRY DROP TABLE #TableList; END TRY BEGIN CATCH PRINT '#TableList Temp table are already gone...' END CATCH; PRINT '-------------------------------' 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. IF (@FORCE = 1) BEGIN PRINT 'Set the database back to MULTI_USER mode' SET @SQLCommand = N'ALTER DATABASE [' + @DBName + '] SET MULTI_USER'; EXEC @return_status = sp_executesql @SQLCommand; END ELSE BEGIN PRINT 'Dont change the database mode!'; 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...' END CATCH; CLOSE table_cursor; DEALLOCATE table_cursor; ----------------------------------------------------------------------------------------------------------------------------- END CATCH; FETCH NEXT FROM db_cursor INTO @DBName; END; CLOSE db_cursor; DEALLOCATE db_cursor; ----------------------------------------------------------------------------------------------------------------------------- SET @return_status_text = 'END [PRDD_MAINTAIN_DATABASES] @ ' + CONVERT(varchar(50),GETDATE(),120); --================================================-- 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()); END; END; ----------------------------------------------------------------------------------------------------------------------------- PRINT '' PRINT 'PROCEDURE - END [PRDD_MAINTAIN_DATABASES] @ ' + CONVERT(varchar(50),GETDATE(),120); PRINT '==============================='; -- Template for a SQL Job - modify the @owner_login_nam --USE [msdb] --GO --BEGIN TRANSACTION --DECLARE @ReturnCode INT --SELECT @ReturnCode = 0 --IF NOT EXISTS (SELECT name FROM msdb.dbo.syscategories WHERE name=N'[Uncategorized (Local)]' AND category_class=1) --BEGIN --EXEC @ReturnCode = msdb.dbo.sp_add_category @class=N'JOB', @type=N'LOCAL', @name=N'[Uncategorized (Local)]' --IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback --END --DECLARE @jobId BINARY(16) --EXEC @ReturnCode = msdb.dbo.sp_add_job @job_name=N'PRDD_MAINTAIN_DATABASES', -- @enabled=1, -- @notify_level_eventlog=0, -- @notify_level_email=0, -- @notify_level_netsend=0, -- @notify_level_page=0, -- @delete_level=0, -- @description=N'Runs Digital Data maintanance script', -- @category_name=N'[Uncategorized (Local)]', -- @owner_login_name=N'DD-SAN01\Administrator', @job_id = @jobId OUTPUT --IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback --/****** Object: Step [PRDD_MAINTAIN_DATABASES] Script Date: 18.11.2024 17:52:02 ******/ --EXEC @ReturnCode = msdb.dbo.sp_add_jobstep @job_id=@jobId, @step_name=N'PRDD_MAINTAIN_DATABASES', -- @step_id=1, -- @cmdexec_success_code=0, -- @on_success_action=1, -- @on_success_step_id=0, -- @on_fail_action=2, -- @on_fail_step_id=0, -- @retry_attempts=0, -- @retry_interval=0, -- @os_run_priority=0, @subsystem=N'TSQL', -- @command=N'DECLARE @return_value int --EXEC @return_value = [dbo].[PRDD_MAINTAIN_DATABASES] -- @pCHECKDB = 1, -- @pSHRINKLOG = 1, -- @pSHRINKDB = 1, -- @pREBUILDINDEX = 1, -- @pLOGLEVEL = ''INFO'', -- @pFORCE = 0 --SELECT ''Return Value'' = @return_value --GO', -- @database_name=N'DD_ECM', -- @flags=0 --IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback --EXEC @ReturnCode = msdb.dbo.sp_update_job @job_id = @jobId, @start_step_id = 1 --IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback --EXEC @ReturnCode = msdb.dbo.sp_add_jobschedule @job_id=@jobId, @name=N'Every-Sunday-Morning', -- @enabled=1, -- @freq_type=8, -- @freq_interval=1, -- @freq_subday_type=1, -- @freq_subday_interval=0, -- @freq_relative_interval=0, -- @freq_recurrence_factor=1, -- @active_start_date=20240101, -- @active_end_date=99991231, -- @active_start_time=30000, -- @active_end_time=235959, -- @schedule_uid=N'a4d9dfcc-6135-4178-9154-f0a437974147' --IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback --EXEC @ReturnCode = msdb.dbo.sp_add_jobserver @job_id = @jobId, @server_name = N'(local)' --IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback --COMMIT TRANSACTION --GOTO EndSave --QuitWithRollback: -- IF (@@TRANCOUNT > 0) ROLLBACK TRANSACTION --EndSave: --GO END