PRDD_MAINTAIN_DATABASES: Improved safty checks
This commit is contained in:
parent
c4060d8f1c
commit
e94cfe0821
@ -1,3 +1,6 @@
|
||||
USE [DD_SYS]
|
||||
GO
|
||||
|
||||
SET ANSI_NULLS ON
|
||||
GO
|
||||
SET QUOTED_IDENTIFIER ON
|
||||
@ -11,19 +14,20 @@ GO
|
||||
--
|
||||
-- Returns: INT Value - 0 = Everything worked well
|
||||
-- =================================================================
|
||||
-- Copyright (c) 2024 by Digital Data GmbH
|
||||
-- Copyright (c) 2025 by Digital Data GmbH
|
||||
--
|
||||
-- Digital Data GmbH • Ludwig-Rinn-Strasse 16 • D-35452 Heuchelheim
|
||||
-- Tel.: 0641/202360 • E-Mail: info-flow@digitaldata.works
|
||||
-- =================================================================
|
||||
-- Creation Date / Author: 29.11.2024 / MK
|
||||
-- Version Date / Editor: 13.12.2024 / MK
|
||||
-- Version Number: 1.1.0.1
|
||||
-- Version Date / Editor: 20.03.2025 / MK
|
||||
-- Version Number: 1.2.0.0
|
||||
-- =================================================================
|
||||
-- History:
|
||||
-- 29.11.2024 / MK - First Version
|
||||
-- 06.12.2024 / MK - Added "SET ONLINE" after forced SINGLE_USER Mode, Added repair parameter for DBCHECK, added @pRECOMPILEPROCEDURES, some minor error fixes
|
||||
-- 13.12.2024 / MK - New way the get the procedure name, failsafe for parameters implemented
|
||||
-- 20.03.2025 / MK - Improved safty checks
|
||||
|
||||
CREATE OR ALTER PROCEDURE [dbo].[PRDD_MAINTAIN_DATABASES] (
|
||||
@pCHECKDB BIT = 1, -- Set to 1 to make a check of the database before shrinking incl. soft repair function. Otherwise set to 0.
|
||||
@ -61,9 +65,10 @@ BEGIN
|
||||
@DBName NVARCHAR(100),
|
||||
@DBNameCount INT,
|
||||
@LogFileName NVARCHAR(100),
|
||||
@CurrentLogFileSizeMB INT,
|
||||
@MinimumLogFileSizeMB INT,
|
||||
@TargetLogFileSizeMB INT,
|
||||
@CurrentLogFileSizeInMB INT,
|
||||
@MinimumLogFileSizeInMB INT,
|
||||
@MaximumLogFileSizeInMB INT,
|
||||
@TargetLogFileSizeInMB INT,
|
||||
@ProductVersion sql_variant,
|
||||
@ProductMainVersion INT,
|
||||
@ProductLevel sql_variant,
|
||||
@ -160,14 +165,14 @@ BEGIN
|
||||
IF (@INCLUDEDB is not NULL) BEGIN
|
||||
INSERT INTO #DBList(DBName)
|
||||
SELECT [name] as 'DBName'
|
||||
FROM [master].[sys].[databases]
|
||||
FROM [master].[sys].[databases] (NOLOCK)
|
||||
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]
|
||||
FROM [master].[sys].[databases] (NOLOCK)
|
||||
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
|
||||
@ -178,7 +183,7 @@ 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]
|
||||
FROM [master].[sys].[databases] (NOLOCK)
|
||||
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
|
||||
@ -327,10 +332,16 @@ BEGIN
|
||||
|
||||
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';
|
||||
SET @SQLCommand = N'USE [' + @DBName + '];
|
||||
ALTER DATABASE [' + @DBName + '] SET RECOVERY SIMPLE;
|
||||
DBCC CHECKDB ([' + @DBName + '],REPAIR_REBUILD) WITH NO_INFOMSGS, ALL_ERRORMSGS;
|
||||
ALTER DATABASE [' + @DBName + '] SET RECOVERY FULL;';
|
||||
END; ELSE BEGIN
|
||||
PRINT 'Check the database for consistency and health.';
|
||||
SET @SQLCommand = N'USE [' + @DBName + ']; DBCC CHECKDB ([' + @DBName + ']) WITH NO_INFOMSGS, ALL_ERRORMSGS';
|
||||
SET @SQLCommand = N'USE [' + @DBName + '];
|
||||
ALTER DATABASE [' + @DBName + '] SET RECOVERY SIMPLE;
|
||||
DBCC CHECKDB ([' + @DBName + ']) WITH NO_INFOMSGS, ALL_ERRORMSGS;
|
||||
ALTER DATABASE [' + @DBName + '] SET RECOVERY FULL;';
|
||||
END;
|
||||
|
||||
EXEC @return_status = sp_executesql @SQLCommand;
|
||||
@ -365,11 +376,11 @@ 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;
|
||||
SET @SQLCommand = N'SELECT TOP 1 @LogFileName = [name], @CurrentLogFileSizeInMB = ([size] / 128), @MinimumLogFileSizeInMB = ([growth] / 128), @MaximumLogFileSizeInMB = ([max_size] / 128)
|
||||
FROM [master].[sys].[master_files] (NOLOCK)
|
||||
WHERE [database_id] = DB_ID(''' + @DBName + ''') AND [STATE_DESC] = ''ONLINE'' AND [type_desc] = ''LOG''';
|
||||
EXEC @return_status = sp_executesql @SQLCommand, N'@LogFileName VARCHAR(100) OUTPUT, @CurrentLogFileSizeInMB INT OUTPUT, @MinimumLogFileSizeInMB INT OUTPUT, @MaximumLogFileSizeInMB INT OUTPUT',
|
||||
@LogFileName OUTPUT, @CurrentLogFileSizeInMB OUTPUT, @MinimumLogFileSizeInMB OUTPUT, @MaximumLogFileSizeInMB OUTPUT;
|
||||
|
||||
IF ((@LOGLEVEL in ('INFO')) and (@return_status = 0)) BEGIN
|
||||
SET @return_status_text = 'Getting log file settings was successfully completed!';
|
||||
@ -384,23 +395,26 @@ BEGIN
|
||||
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());
|
||||
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
|
||||
PRINT 'The @CurrentLogFileSizeInMB is: ' + CONVERT(VARCHAR(1000),@CurrentLogFileSizeInMB);
|
||||
PRINT 'The @MinimumLogFileSizeInMB is: ' + CONVERT(VARCHAR(1000),@MinimumLogFileSizeInMB);
|
||||
PRINT 'The @MaximumLogFileSizeInMB is: ' + CONVERT(VARCHAR(1000),@MaximumLogFileSizeInMB);
|
||||
|
||||
SET @TargetLogFileSizeInMB = CASE WHEN (@MinimumLogFileSizeInMB < @CurrentLogFileSizeInMB) AND (@MinimumLogFileSizeInMB < @MaximumLogFileSizeInMB)
|
||||
THEN @MinimumLogFileSizeInMB
|
||||
ELSE @CurrentLogFileSizeInMB
|
||||
END;
|
||||
|
||||
PRINT 'The @TargetLogFileSizeMB is: ' + CONVERT(VARCHAR(1000),@TargetLogFileSizeMB);
|
||||
PRINT 'The @TargetLogFileSizeInMB is: ' + CONVERT(VARCHAR(1000),@TargetLogFileSizeInMB);
|
||||
-----------------------------------------------------------------------------------------------------------------------------
|
||||
|
||||
--=================================================-- Schrink db logs --===================================================--
|
||||
IF (@CurrentLogFileSizeMB > @TargetLogFileSizeMB) BEGIN
|
||||
IF (@CurrentLogFileSizeInMB > @TargetLogFileSizeInMB) BEGIN
|
||||
|
||||
--=============================================-- Change db recovery mode --===============================================--
|
||||
PRINT 'Truncating the log needs to change the database recovery model to SIMPLE.';
|
||||
@ -430,13 +444,13 @@ 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;';
|
||||
SET @SQLCommand = N'USE [' + @DBName + ']; DBCC SHRINKFILE (''' + @LogFileName + ''', ' + CAST(@TargetLogFileSizeInMB AS VARCHAR) + ') WITH WAIT_AT_LOW_PRIORITY (ABORT_AFTER_WAIT = BLOCKERS), NO_INFOMSGS;';
|
||||
END; ELSE BEGIN
|
||||
SET @SQLCommand = N'USE [' + @DBName + ']; DBCC SHRINKFILE (''' + @LogFileName + ''', ' + CAST(@TargetLogFileSizeMB AS VARCHAR) + ') WITH WAIT_AT_LOW_PRIORITY (ABORT_AFTER_WAIT = SELF), NO_INFOMSGS;';
|
||||
SET @SQLCommand = N'USE [' + @DBName + ']; DBCC SHRINKFILE (''' + @LogFileName + ''', ' + CAST(@TargetLogFileSizeInMB AS VARCHAR) + ') WITH WAIT_AT_LOW_PRIORITY (ABORT_AFTER_WAIT = SELF), NO_INFOMSGS;';
|
||||
END;
|
||||
END; ELSE BEGIN
|
||||
PRINT '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;';
|
||||
SET @SQLCommand = N'USE [' + @DBName + ']; DBCC SHRINKFILE (''' + @LogFileName + ''', ' + CAST(@TargetLogFileSizeInMB AS VARCHAR) + ') WITH NO_INFOMSGS;';
|
||||
END;
|
||||
|
||||
EXEC @return_status = sp_executesql @SQLCommand;
|
||||
|
||||
Loading…
x
Reference in New Issue
Block a user