8
0
Skriptentwickung/current/[PRDD_BACKUP_DATABASES]/[PRDD_BACKUP_DATABASES].sql

531 lines
28 KiB
Transact-SQL

SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
-- [PRDD_BACKUP_DATABASES]
-- =================================================================
-- Saving database to LOCAL (!!) backup folder
-- Minimum requirement: MS SQL Server 2016
--
-- Returns: INT Value - 0 = Everything worked well
-- =================================================================
-- 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: 13.12.2024 / MK
-- Version Date / Editor: 13.12.2024 / MK
-- Version Number: 1.0.0.0
-- =================================================================
-- History:
-- 13.12.2024 / MK - First Version
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.
@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.
@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].
-- 'INFO' includes Infos, Warnings and Errors, 'WARN' only warnings and Errors and 'ERROR' only Errors.
)
AS
BEGIN
SET NOCOUNT ON;
-- declare new vars because of parameter sniffing
DECLARE @COMPRESSION BIT = ISNULL(@pCOMPRESSION,0),
@LOCALBACKUPPATH NVARCHAR(255) = LTRIM(RTRIM(ISNULL(@pLOCALBACKUPPATH,''))),
@SUBDIRECTORY NVARCHAR(50) = LTRIM(RTRIM(ISNULL(@pSUBDIRECTORY,'Date_YYYYMMDD'))),
@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')));
-- declare runtime vars
DECLARE @MyProcedureName NVARCHAR(128) = OBJECT_NAME(@@PROCID);
DECLARE @DBName NVARCHAR(100),
@DBNameCount INT,
@FULLLOCALBACKUPPATH NVARCHAR(255),
@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),
@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);
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);
--=================================================-- 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 '@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);
-----------------------------------------------------------------------------------------------------------------------------
--==============================================-- Prepare the log table --================================================--
IF (@LOGLEVEL is not NULL) BEGIN
PRINT '';
IF EXISTS (SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = N'TBDD_BACKUP_DATABASES_LOG') BEGIN
PRINT 'Log table already exists';
END; ELSE BEGIN
PRINT 'Log table does not exists, trying to create...';
CREATE TABLE [dbo].[TBDD_BACKUP_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_BACKUP_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_BACKUP_DATABASES_LOG] ADD CONSTRAINT [DF_TBDD_BACKUP_DATABASES_LOG_ADDED_WHO] DEFAULT ('DEFAULT') FOR [ADDED_WHO];
ALTER TABLE [dbo].[TBDD_BACKUP_DATABASES_LOG] ADD CONSTRAINT [DF_TBDD_BACKUP_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_BACKUP_DATABASES_LOG') BEGIN
INSERT INTO [TBDD_BACKUP_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;
-----------------------------------------------------------------------------------------------------------------------------
--================================================-- Check sql edition --=================================================--
IF (CONVERT(VARCHAR(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
SET @return_status_text = 'This is not an Express Version of the SQL Server, so backup COMPRESSION is available!';
SET @ProductEditionSimpleString = 'Standard/Datacenter';
END;
-----------------------------------------------------------------------------------------------------------------------------
--===================================================-- Log 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_BACKUP_DATABASES_LOG') BEGIN
INSERT INTO [TBDD_BACKUP_DATABASES_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN])
VALUES (@LOGLEVEL,'preparing', 'procedure', @return_status, 'Found SQL Edition: ' + @ProductEditionSimpleString, @MyProcedureName, 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 (@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] = @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_BACKUP_DATABASES_LOG') BEGIN
INSERT INTO [TBDD_BACKUP_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 main loop (cursor) --============================================--
IF (@DBNameCount > 0) BEGIN
IF LEN(@LOCALBACKUPPATH) > 0 and (@LOCALBACKUPPATH like '%\%') BEGIN
--==========================================-- Checking system configuration --============================================--
PRINT 'Checking system configuration';
SELECT @sysconfigurations = SUM(CAST([value] AS INT))
FROM [master].[sys].[configurations]
WHERE [name] in ('show advanced options','Ole Automation Procedures','xp_cmdshell');
If (@sysconfigurations = 3) BEGIN
SET @return_status = 0;
SET @return_status_text = 'System configuration does fit! (' + CONVERT(varchar,@sysconfigurations) + ')';
PRINT @return_status_text;
END; ELSE BEGIN
PRINT 'System configuration does NOT fit! Try to reconfigure... (' + CONVERT(varchar,@sysconfigurations) + ')';
EXEC sp_configure 'show advanced options', 1;
RECONFIGURE WITH OVERRIDE;
EXEC sp_configure 'Ole Automation Procedures', 1;
RECONFIGURE WITH OVERRIDE;
EXEC sp_configure 'xp_cmdshell', 1;
RECONFIGURE WITH OVERRIDE;
-- Check again
SELECT @sysconfigurations = SUM(CAST(value AS INT))
FROM [master].[sys].[configurations]
WHERE [name] in ('show advanced options','Ole Automation Procedures','xp_cmdshell');
If (@sysconfigurations = 3) BEGIN
SET @return_status = 0;
SET @return_status_text = 'System configuration does fit, now! (' + CONVERT(varchar,@sysconfigurations) + ')';
PRINT @return_status_text;
END; ELSE BEGIN
SET @return_status = 1;
SET @return_status_text = 'System configuration does NOT fit! (' + CONVERT(varchar,@sysconfigurations) + ')';
PRINT @return_status_text;
END;
END;
-----------------------------------------------------------------------------------------------------------------------------
--===============================================-- Log result to table --=================================================--
IF (@LOGLEVEL in ('INFO','WARN')) BEGIN
IF EXISTS (SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = N'TBDD_BACKUP_DATABASES_LOG') BEGIN
INSERT INTO [TBDD_BACKUP_DATABASES_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN])
VALUES (@LOGLEVEL, 'server_check', 'filesystem_config',@return_status, @return_status_text, @MyProcedureName, GetDate());
END;
END;
-----------------------------------------------------------------------------------------------------------------------------
If (@return_status = 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
PRINT ' ';
PRINT '-------------------------------';
PRINT 'Now processing: ' + CONVERT(varchar(100),@DBName);
--==============================================-- Preparing backup path --================================================--
-- Chekc if base path exits
SET @CMDCommand = 'IF EXIST "' + @LOCALBACKUPPATH + '" (echo 1) ELSE (echo 0)';
CREATE TABLE #CMDCommandResult (Output NVARCHAR(255));
INSERT INTO #CMDCommandResult (Output)
EXEC xp_cmdshell @CMDCommand;
SELECT @CMDCommandResult = CAST(Output AS INT) FROM #CMDCommandResult WHERE Output IS NOT NULL;
DROP TABLE #CMDCommandResult;
IF (@CMDCommandResult = 1) BEGIN
SET @return_status = 0;
SET @return_status_text = 'Directory (' + @LOCALBACKUPPATH + ') does exist!';
PRINT @return_status_text;
--===============================================-- Log result to table --=================================================--
IF ((@LOGLEVEL in ('INFO','WARN')) and (@return_status is not null) and (@return_status_text is not null)) BEGIN
IF EXISTS (SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = N'TBDD_BACKUP_DATABASES_LOG') BEGIN
INSERT INTO [TBDD_BACKUP_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 (@SUBDIRECTORY like '%Date_YYYYMMDD%') BEGIN
SELECT @FULLLOCALBACKUPPATH = @LOCALBACKUPPATH + '\' + @Date_YYYYMMDD + '\';
END; ELSE IF (LEN(@SUBDIRECTORY) >= 1) BEGIN
SELECT @FULLLOCALBACKUPPATH = @LOCALBACKUPPATH + '\' + @SUBDIRECTORY + '\';
END; ELSE BEGIN
SELECT @FULLLOCALBACKUPPATH = @LOCALBACKUPPATH + '\';
END;
SET @FULLLOCALBACKUPPATH = REPLACE(@FULLLOCALBACKUPPATH,'\\','\');
PRINT 'Final backup path set: ' + @FULLLOCALBACKUPPATH;
EXECUTE @return_status = master.dbo.xp_create_subdir @FULLLOCALBACKUPPATH;
IF (@return_status = 0) BEGIN
SET @return_status_text = 'Creating database backup path successfully completed!';
PRINT @return_status_text;
END; ELSE BEGIN
SET @return_status_text = 'Creating database backup path returns warnings or has failed, check the access rights!';
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_BACKUP_DATABASES_LOG') BEGIN
INSERT INTO [TBDD_BACKUP_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 (@return_status = 0) BEGIN
SET @FULLLOCALBACKUPPATH += @DBName + '.BAK';
SET @return_status_text = 'Starting backup to: ' + @FULLLOCALBACKUPPATH;
PRINT @return_status_text;
--===============================================-- Log result to table --=================================================--
IF ((@LOGLEVEL in ('INFO','WARN')) and (@return_status is not null) and (@return_status_text is not null)) BEGIN
IF EXISTS (SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = N'TBDD_BACKUP_DATABASES_LOG') BEGIN
INSERT INTO [TBDD_BACKUP_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 (@ProductEditionSimpleString = 'Express') BEGIN
SET @SQLCommand = 'BACKUP DATABASE [' + @DBName + '] TO DISK = ''' + @FULLLOCALBACKUPPATH + ''' WITH FORMAT, CHECKSUM;';
END; ELSE BEGIN
SET @SQLCommand = 'BACKUP DATABASE [' + @DBName + '] TO DISK = ''' + @FULLLOCALBACKUPPATH + ''' WITH FORMAT, COMPRESSION, CHECKSUM;';
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_BACKUP_DATABASES_LOG') BEGIN
INSERT INTO [TBDD_BACKUP_DATABASES_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN])
VALUES (@LOGLEVEL, 'db_cursor', @DBName, @return_status, @SQLCommand, @MyProcedureName, GetDate());
END;
END;
-----------------------------------------------------------------------------------------------------------------------------
BEGIN TRY
EXEC sp_executesql @SQLCommand;
SET @return_status = 0;
SET @return_status_text = 'Backup successful!';
END TRY
BEGIN CATCH
-- Handle any errors that occur during the process.
SELECT ERROR_MESSAGE() AS ErrorMessage;
SET @return_status = 1;
SET @return_status_text = 'Backup failed!';
END CATCH;
--===============================================-- 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_BACKUP_DATABASES_LOG') BEGIN
INSERT INTO [TBDD_BACKUP_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
SET @return_status_text = 'Cannot backup database because of the previous error!';
PRINT @return_status_text;
--===============================================-- Log result to table --=================================================--
IF ((@LOGLEVEL in ('INFO','WARN','ERROR')) and (@return_status is not null) and (@return_status_text is not null)) BEGIN
IF EXISTS (SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = N'TBDD_BACKUP_DATABASES_LOG') BEGIN
INSERT INTO [TBDD_BACKUP_DATABASES_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN])
VALUES ('ERROR', 'db_cursor', @DBName, @return_status, @return_status_text, @MyProcedureName, GetDate());
END;
END;
-----------------------------------------------------------------------------------------------------------------------------
END;
-----------------------------------------------------------------------------------------------------------------------------
END; ELSE BEGIN
SET @return_status = 1;
SET @return_status_text = 'Directory (' + @LOCALBACKUPPATH + ') does not exist!';
PRINT @return_status_text;
--===============================================-- Log result to table --=================================================--
IF ((@LOGLEVEL in ('INFO','WARN','ERROR')) and (@return_status is not null) and (@return_status_text is not null)) BEGIN
IF EXISTS (SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = N'TBDD_BACKUP_DATABASES_LOG') BEGIN
INSERT INTO [TBDD_BACKUP_DATABASES_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN])
VALUES ('ERROR', 'db_cursor', @DBName, @return_status, @return_status_text, @MyProcedureName, GetDate());
END;
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_BACKUP_DATABASES_LOG') BEGIN
INSERT INTO [TBDD_BACKUP_DATABASES_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [ADDED_WHO], [ADDED_WHEN])
VALUES ('ERROR', 'db_cursor', @DBName, ERROR_MESSAGE(),@MyProcedureName,GetDate());
END;
END;
-----------------------------------------------------------------------------------------------------------------------------
BEGIN TRY
DROP TABLE #CMDCommandResult;
END TRY
BEGIN CATCH
PRINT '#CMDCommandResult Temp table is already gone...';
END CATCH;
END CATCH;
FETCH NEXT FROM db_cursor INTO @DBName;
END;
CLOSE db_cursor;
DEALLOCATE db_cursor;
END; ELSE BEGIN
SET @return_status = 1;
SET @return_status_text = 'Cannot backup database, because of system configuration!';
PRINT @return_status_text;
--===============================================-- Log result to table --=================================================--
IF ((@LOGLEVEL in ('INFO','WARN','ERROR')) and (@return_status is not null) and (@return_status_text is not null)) BEGIN
IF EXISTS (SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = N'TBDD_BACKUP_DATABASES_LOG') BEGIN
INSERT INTO [TBDD_BACKUP_DATABASES_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN])
VALUES ('ERROR', 'server_check', 'filesystem_config', @return_status, @return_status_text, @MyProcedureName, GetDate());
END;
END;
-----------------------------------------------------------------------------------------------------------------------------
END;
-- Ensure temp table is droped and cursor is closed
BEGIN TRY
DROP TABLE #DBList;
END TRY
BEGIN CATCH
PRINT '#DBList Temp table is already gone...';
END CATCH;
BEGIN TRY
DROP TABLE #CMDCommandResult;
END TRY
BEGIN CATCH
PRINT '#CMDCommandResult Temp table is already gone...';
END CATCH;
END; ELSE BEGIN
SET @return_status = 1;
SET @return_status_text = 'Invalid LOCALBACKUPPATH!';
PRINT @return_status_text;
--===============================================-- Log result to table --=================================================--
IF ((@LOGLEVEL in ('INFO','WARN','ERROR')) and (@return_status is not null) and (@return_status_text is not null)) BEGIN
IF EXISTS (SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = N'TBDD_BACKUP_DATABASES_LOG') BEGIN
INSERT INTO [TBDD_BACKUP_DATABASES_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN])
VALUES ('ERROR', 'server_check', 'filesystem_config', @return_status, @return_status_text, @MyProcedureName, GetDate());
END;
END;
-----------------------------------------------------------------------------------------------------------------------------
END;
END; ELSE BEGIN
SET @return_status = 0;
SET @return_status_text = 'So there is nothing to do...';
PRINT @return_status_text;
--===============================================-- Log result to table --=================================================--
IF ((@LOGLEVEL in ('INFO','WARN','ERROR')) and (@return_status is not null) and (@return_status_text is not null)) BEGIN
IF EXISTS (SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = N'TBDD_BACKUP_DATABASES_LOG') BEGIN
INSERT INTO [TBDD_BACKUP_DATABASES_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN])
VALUES ('WARN', 'db_list', 'count', @return_status, @return_status_text, @MyProcedureName, GetDate());
END;
END;
-----------------------------------------------------------------------------------------------------------------------------
END;
-----------------------------------------------------------------------------------------------------------------------------
SET @return_status_text = 'END ' + @MyProcedureName + ' @ ' + 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_BACKUP_DATABASES_LOG') BEGIN
INSERT INTO [TBDD_BACKUP_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 - ' + @return_status_text;
PRINT '===============================';
Return @return_status;
END;