8
0

PRDD_BACKUP_DATABASES: Missing variables declared, Minor corrections

This commit is contained in:
2025-06-06 17:08:32 +02:00
parent 7e0de876ec
commit c4060d8f1c

View File

@@ -1,3 +1,6 @@
USE [DD_SYS]
GO
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
@@ -10,22 +13,26 @@ 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: 13.12.2024 / MK
-- Version Date / Editor: 13.12.2024 / MK
-- Version Number: 1.0.0.0
-- Version Date / Editor: 30.05.2025 / MK
-- Version Number: 1.2.0.1
-- =================================================================
-- History:
-- 13.12.2024 / MK - First Version
-- 28.05.2025 / MP - Missing variables declared
-- 30.05.2025 / MK - Minor corrections
CREATE OR ALTER PROCEDURE [dbo].[PRDD_BACKUP_DATABASES] (
@pCOMPRESSION BIT = 1, -- Set to 1 to compress the database backup file (This option is not available in SQL Express Versions!). Otherwise set to 0.
@pCOMPRESSION BIT = 0, -- Set to 1 to compress the database backup file (This option is not available in SQL Express Versions!). Otherwise set to 0.
@pSHRINKLOG BIT = 1, -- Set to 1 to shrink the log file after backup. Otherwise set to 0.
@pLOCALBACKUPPATH NVARCHAR(200) = 'F:\Sicherung', -- Set the LOCAL Backup path. If path doesnt exist, it will be created.
@pSUBDIRECTORY NVARCHAR(50) = 'Date_YYYYMMDD', -- Set 'Date_YYYYMMDD' (which is Failsafe) for a backup subdir like '\path\20241213'. Every other value will used a static subdirectory name for creation.
@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_BACKUP_DATABASES_LOG].
@@ -38,8 +45,10 @@ BEGIN
-- declare new vars because of parameter sniffing
DECLARE @COMPRESSION BIT = ISNULL(@pCOMPRESSION,0),
@SHRINKLOG BIT = ISNULL(@pSHRINKLOG,1),
@LOCALBACKUPPATH NVARCHAR(255) = LTRIM(RTRIM(ISNULL(@pLOCALBACKUPPATH,''))),
@SUBDIRECTORY NVARCHAR(50) = LTRIM(RTRIM(ISNULL(@pSUBDIRECTORY,'Date_YYYYMMDD'))),
@FORCE BIT = ISNULL(@pFORCE,0),
@INCLUDEDB NVARCHAR(1000) = LTRIM(RTRIM(ISNULL(@pINCLUDEDB,DB_NAME()))),
@EXCLUDEDB NVARCHAR(1000) = LTRIM(RTRIM(ISNULL(@pEXCLUDEDB,'master,model,msdb,tempdb'))),
@LOGLEVEL NVARCHAR(25) = LTRIM(RTRIM(ISNULL(@pLOGLEVEL,'ERROR')));
@@ -48,41 +57,48 @@ BEGIN
DECLARE @MyProcedureName NVARCHAR(128) = OBJECT_NAME(@@PROCID);
DECLARE @DBName NVARCHAR(100),
@DBNameCount INT,
@LogFileName NVARCHAR(100),
@FULLLOCALBACKUPPATH NVARCHAR(255),
@CurrentLogFileSizeInMB INT,
@MinimumLogFileSizeInMB INT,
@MaximumLogFileSizeInMB INT,
@TargetLogFileSizeInMB INT,
@ProductVersion sql_variant,
@ProductMainVersion INT,
@ProductLevel sql_variant,
@ProductEdition sql_variant,
@ProductEditionSimpleString NVARCHAR(50),
@MySessionID NVARCHAR(50) = @@SPID,
@Date_YYYYMMDD NVARCHAR(20) = CONVERT(VARCHAR(20),GETDATE(),112),
@Date_YYYYMMDD NVARCHAR(20) = CONVERT(NVARCHAR(20),GETDATE(),112),
@sysconfigurations INT = 0,
@SQLCommand NVARCHAR(1000) = NULL,
@CMDCommand NVARCHAR(1000) = NULL,
@CMDCommandResult INT = 0,
@return_status NVARCHAR(50) = 0,
@return_status_text NVARCHAR(MAX) = 'START ' + @MyProcedureName + ' @ ' + CONVERT(varchar(50),GETDATE(),120);
@return_status_text NVARCHAR(MAX) = 'START ' + @MyProcedureName + ' @ ' + CONVERT(NVARCHAR(50),GETDATE(),120);
PRINT '==============================='
PRINT 'PROCEDURE - ' + @return_status_text;
PRINT 'PARAMETER01 - @COMPRESSION: ' + CONVERT(VARCHAR(200),@COMPRESSION);
PRINT 'PARAMETER02 - @LOCALBACKUPPATH: ' + CONVERT(VARCHAR(50),@LOCALBACKUPPATH);
PRINT 'PARAMETER03 - @SUBDIRECTORY: ' + CONVERT(VARCHAR(1),@SUBDIRECTORY);
PRINT 'PARAMETER04 - @INCLUDEDB: ' + CONVERT(VARCHAR(1000),@INCLUDEDB);
PRINT 'PARAMETER05 - @EXCLUDEDB: ' + CONVERT(VARCHAR(1000),@EXCLUDEDB);
PRINT 'PARAMETER06 - @LOGLEVEL: ' + CONVERT(VARCHAR(25),@LOGLEVEL);
PRINT 'PARAMETER01 - @COMPRESSION: ' + CONVERT(NVARCHAR(1),@COMPRESSION);
PRINT 'PARAMETER02 - @SHRINKLOG: ' + CONVERT(NVARCHAR(1),@SHRINKLOG);
PRINT 'PARAMETER03 - @LOCALBACKUPPATH: ' + CONVERT(NVARCHAR(50),@LOCALBACKUPPATH);
PRINT 'PARAMETER04 - @SUBDIRECTORY: ' + CONVERT(NVARCHAR(1),@SUBDIRECTORY);
PRINT 'PARAMETER05 - @FORCE: ' + CONVERT(NVARCHAR(1),@FORCE);
PRINT 'PARAMETER06 - @INCLUDEDB: ' + CONVERT(NVARCHAR(1000),@INCLUDEDB);
PRINT 'PARAMETER07 - @EXCLUDEDB: ' + CONVERT(NVARCHAR(1000),@EXCLUDEDB);
PRINT 'PARAMETER08 - @LOGLEVEL: ' + CONVERT(NVARCHAR(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);
SET @ProductMainVersion = ISNULL(LEFT(convert(NVARCHAR(100),@ProductVersion), CHARINDEX('.', convert(NVARCHAR(100),@ProductVersion)) - 1),0);
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);
PRINT '@ProductEdition: ' + CONVERT(VARCHAR(100),@ProductEdition);
PRINT '@MySessionID: ' + CONVERT(NVARCHAR(100),@MySessionID);
PRINT '@ProductVersion: ' + CONVERT(NVARCHAR(100),@ProductVersion);
PRINT '@ProductMainVersion: ' + CONVERT(NVARCHAR(100),@ProductMainVersion);
PRINT '@ProductLevel: ' + CONVERT(NVARCHAR(100),@ProductLevel);
PRINT '@ProductEdition: ' + CONVERT(NVARCHAR(100),@ProductEdition);
-----------------------------------------------------------------------------------------------------------------------------
--==============================================-- Prepare the log table --================================================--
@@ -131,7 +147,7 @@ BEGIN
-----------------------------------------------------------------------------------------------------------------------------
--================================================-- Check sql edition --=================================================--
IF (CONVERT(VARCHAR(100),@ProductEdition) like '%express%') BEGIN
IF (CONVERT(NVARCHAR(100),@ProductEdition) like '%express%') BEGIN
SET @return_status_text = 'This is an Express Version of the SQL Server, so backup COMPRESSION is not available!';
SET @ProductEditionSimpleString = 'Express';
END; ELSE BEGIN
@@ -186,7 +202,7 @@ BEGIN
SELECT @DBNameCount = COUNT(*) FROM #DBList;
-----------------------------------------------------------------------------------------------------------------------------
SET @return_status_text = 'Found ' + convert(VARCHAR,@DBNameCount) + ' database(s) to process!';
SET @return_status_text = 'Found ' + convert(NVARCHAR,@DBNameCount) + ' database(s) to process!';
PRINT @return_status_text;
--===============================================-- Log result to table --=================================================--
@@ -214,12 +230,12 @@ BEGIN
If (@sysconfigurations = 3) BEGIN
SET @return_status = 0;
SET @return_status_text = 'System configuration does fit! (' + CONVERT(varchar,@sysconfigurations) + ')';
SET @return_status_text = 'System configuration does fit! (' + CONVERT(NVARCHAR,@sysconfigurations) + ')';
PRINT @return_status_text;
END; ELSE BEGIN
PRINT 'System configuration does NOT fit! Try to reconfigure... (' + CONVERT(varchar,@sysconfigurations) + ')';
PRINT 'System configuration does NOT fit! Try to reconfigure... (' + CONVERT(NVARCHAR,@sysconfigurations) + ')';
EXEC sp_configure 'show advanced options', 1;
RECONFIGURE WITH OVERRIDE;
@@ -235,11 +251,11 @@ BEGIN
If (@sysconfigurations = 3) BEGIN
SET @return_status = 0;
SET @return_status_text = 'System configuration does fit, now! (' + CONVERT(varchar,@sysconfigurations) + ')';
SET @return_status_text = 'System configuration does fit, now! (' + CONVERT(NVARCHAR,@sysconfigurations) + ')';
PRINT @return_status_text;
END; ELSE BEGIN
SET @return_status = 1;
SET @return_status_text = 'System configuration does NOT fit! (' + CONVERT(varchar,@sysconfigurations) + ')';
SET @return_status_text = 'System configuration does NOT fit! (' + CONVERT(NVARCHAR,@sysconfigurations) + ')';
PRINT @return_status_text;
END;
@@ -267,7 +283,7 @@ BEGIN
PRINT ' ';
PRINT '-------------------------------';
PRINT 'Now processing: ' + CONVERT(varchar(100),@DBName);
PRINT 'Now processing: ' + CONVERT(NVARCHAR(100),@DBName);
--==============================================-- Preparing backup path --================================================--
@@ -378,6 +394,159 @@ BEGIN
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], @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!';
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;
-----------------------------------------------------------------------------------------------------------------------------
--===============================================-- 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;
-----------------------------------------------------------------------------------------------------------------------------
--===========================================-- Calculate target file size --==============================================--
PRINT 'The @CurrentLogFileSizeInMB is: ' + CONVERT(NVARCHAR(1000),@CurrentLogFileSizeInMB);
PRINT 'The @MinimumLogFileSizeInMB is: ' + CONVERT(NVARCHAR(1000),@MinimumLogFileSizeInMB);
PRINT 'The @MaximumLogFileSizeInMB is: ' + CONVERT(NVARCHAR(1000),@MaximumLogFileSizeInMB);
SET @TargetLogFileSizeInMB = CASE WHEN (@MinimumLogFileSizeInMB < @CurrentLogFileSizeInMB) AND (@MinimumLogFileSizeInMB < @MaximumLogFileSizeInMB)
THEN @MinimumLogFileSizeInMB
ELSE @CurrentLogFileSizeInMB
END;
PRINT 'The @TargetLogFileSizeInMB is: ' + CONVERT(NVARCHAR(1000),@TargetLogFileSizeInMB);
-----------------------------------------------------------------------------------------------------------------------------
--=================================================-- Schrink db logs --===================================================--
IF (@CurrentLogFileSizeInMB > @TargetLogFileSizeInMB) 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 = '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 = '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, '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(@TargetLogFileSizeInMB AS VARCHAR) + ') WITH WAIT_AT_LOW_PRIORITY (ABORT_AFTER_WAIT = BLOCKERS), NO_INFOMSGS;';
END; ELSE BEGIN
SET @SQLCommand = N'USE [' + @DBName + ']; DBCC SHRINKFILE (''' + @LogFileName + ''', ' + CAST(@TargetLogFileSizeInMB AS VARCHAR) + ') WITH WAIT_AT_LOW_PRIORITY (ABORT_AFTER_WAIT = SELF), NO_INFOMSGS;';
END;
END; ELSE BEGIN
PRINT 'Because of the sql server version, DBCC SHRINKFILE is not applicable with the FORCE parameter!';
SET @SQLCommand = N'USE [' + @DBName + ']; DBCC SHRINKFILE (''' + @LogFileName + ''', ' + CAST(@TargetLogFileSizeInMB AS VARCHAR) + ') WITH NO_INFOMSGS;';
END;
EXEC @return_status = sp_executesql @SQLCommand;
IF ((@LOGLEVEL in ('INFO')) and (@return_status = 0)) BEGIN
SET @return_status_text = '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;
-----------------------------------------------------------------------------------------------------------------------------
END; ELSE BEGIN
SET @return_status_text = 'Cannot backup database because of the previous error!';
@@ -510,7 +679,7 @@ BEGIN
END;
-----------------------------------------------------------------------------------------------------------------------------
SET @return_status_text = 'END ' + @MyProcedureName + ' @ ' + CONVERT(varchar(50),GETDATE(),120);
SET @return_status_text = 'END ' + @MyProcedureName + ' @ ' + CONVERT(NVARCHAR(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
@@ -527,4 +696,4 @@ BEGIN
Return @return_status;
END;
END;