[PRDD_MAINTAIN_DATABASES]: First real working version
This commit is contained in:
parent
694ebaaf1c
commit
ab16f36426
@ -11,12 +11,12 @@
|
||||
-- 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
|
||||
-- Creation Date / Author: 29.11.2024 / MK
|
||||
-- Version Date / Editor: 29.11.2024 / MK
|
||||
-- Version Number: 1.0.0.0
|
||||
-- =================================================================
|
||||
-- History:
|
||||
-- 18.11.2024 / MK - First Version
|
||||
-- 29.11.2024 / MK - First Version
|
||||
|
||||
SET ANSI_NULLS ON
|
||||
GO
|
||||
@ -39,19 +39,22 @@ BEGIN
|
||||
|
||||
SET NOCOUNT ON;
|
||||
|
||||
DECLARE @DBName NVARCHAR(100),
|
||||
@LogFileName NVARCHAR(100),
|
||||
@CurrentLogFileSizeMB INT,
|
||||
@MinimumLogFileSizeMB INT,
|
||||
@TargetLogFileSizeMB INT,
|
||||
@CHECKDB BIT = @pCHECKDB,
|
||||
-- decalare new vars because of parameter sniffing
|
||||
DECLARE @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,
|
||||
@LOGLEVEL NVARCHAR(25) = @pLOGLEVEL;
|
||||
|
||||
-- decalare runtime vars
|
||||
DECLARE @DBName NVARCHAR(100),
|
||||
@LogFileName NVARCHAR(100),
|
||||
@CurrentLogFileSizeMB INT,
|
||||
@MinimumLogFileSizeMB INT,
|
||||
@TargetLogFileSizeMB INT,
|
||||
@ProductVersion sql_variant,
|
||||
@ProductMainVersion INT,
|
||||
@ProductLevel sql_variant,
|
||||
@ -86,15 +89,11 @@ BEGIN
|
||||
-----------------------------------------------------------------------------------------------------------------------------
|
||||
|
||||
--==============================================-- Prepare the log table --================================================--
|
||||
IF (@LOGLEVEL is not NULL)
|
||||
BEGIN
|
||||
IF (@LOGLEVEL is not NULL) BEGIN
|
||||
PRINT ''
|
||||
IF EXISTS (SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = N'TBDD_MAINTAIN_DATABASES_LOG')
|
||||
BEGIN
|
||||
IF EXISTS (SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = N'TBDD_MAINTAIN_DATABASES_LOG') BEGIN
|
||||
PRINT 'Log table already exists'
|
||||
END;
|
||||
ELSE
|
||||
BEGIN
|
||||
END; ELSE BEGIN
|
||||
PRINT 'Log table does not exists, trying to create...';
|
||||
|
||||
CREATE TABLE [dbo].[TBDD_MAINTAIN_DATABASES_LOG](
|
||||
@ -123,10 +122,8 @@ BEGIN
|
||||
-----------------------------------------------------------------------------------------------------------------------------
|
||||
|
||||
--===============================================-- 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
|
||||
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;
|
||||
@ -137,17 +134,14 @@ BEGIN
|
||||
-- Create a temporary table to hold the table names
|
||||
CREATE TABLE #DBList (DBName NVARCHAR(256));
|
||||
|
||||
IF (@INCLUDEDB is not NULL)
|
||||
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
|
||||
END; ELSE BEGIN
|
||||
INSERT INTO #DBList(DBName)
|
||||
SELECT [name] as 'DBName'
|
||||
FROM [master].[sys].[databases]
|
||||
@ -158,13 +152,12 @@ BEGIN
|
||||
-----------------------------------------------------------------------------------------------------------------------------
|
||||
|
||||
--=============================================-- Create the loop (cursor) --==============================================--
|
||||
DECLARE db_cursor CURSOR READ_ONLY LOCAL FOR
|
||||
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
|
||||
WHILE @@FETCH_STATUS = 0 BEGIN
|
||||
BEGIN TRY
|
||||
|
||||
PRINT ' '
|
||||
@ -172,27 +165,21 @@ BEGIN
|
||||
PRINT 'Now processing: ' + CONVERT(varchar(100),@DBName);
|
||||
|
||||
--==============================================-- Change db working mode --===============================================--
|
||||
IF (@FORCE = 1) and (@return_status = 0)
|
||||
BEGIN
|
||||
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
|
||||
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
|
||||
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
|
||||
|
||||
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;
|
||||
@ -200,10 +187,8 @@ 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
|
||||
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;
|
||||
@ -211,27 +196,21 @@ BEGIN
|
||||
-----------------------------------------------------------------------------------------------------------------------------
|
||||
|
||||
--===============================================-- Check db consistency --================================================--
|
||||
IF (@CHECKDB = 1) and (@return_status = 0)
|
||||
BEGIN
|
||||
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
|
||||
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
|
||||
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
|
||||
|
||||
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;
|
||||
@ -239,10 +218,8 @@ 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
|
||||
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;
|
||||
@ -250,8 +227,8 @@ BEGIN
|
||||
-----------------------------------------------------------------------------------------------------------------------------
|
||||
|
||||
--============================================-- Prepare shrinking the log--===============================================--
|
||||
IF (@SHRINKLOG = 1)
|
||||
BEGIN
|
||||
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)
|
||||
@ -260,24 +237,27 @@ BEGIN
|
||||
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;
|
||||
-----------------------------------------------------------------------------------------------------------------------------
|
||||
|
||||
--===============================================-- 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
|
||||
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());
|
||||
VALUES (@LOGLEVEL, 'db_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
|
||||
SET @TargetLogFileSizeMB = CASE WHEN @CurrentLogFileSizeMB * 0.1 < @MinimumLogFileSizeMB
|
||||
THEN @MinimumLogFileSizeMB
|
||||
ELSE @CurrentLogFileSizeMB * 0.1
|
||||
END;
|
||||
@ -286,84 +266,128 @@ BEGIN
|
||||
-----------------------------------------------------------------------------------------------------------------------------
|
||||
|
||||
--=================================================-- Schrink db logs --===================================================--
|
||||
IF (@CurrentLogFileSizeMB > @TargetLogFileSizeMB)
|
||||
BEGIN
|
||||
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;
|
||||
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, 'PRDD_MAINTAIN_DATABASES',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)
|
||||
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);';
|
||||
ELSE
|
||||
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
|
||||
ELSE
|
||||
BEGIN
|
||||
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
|
||||
EXEC sp_executesql @SQLCommand;
|
||||
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, '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 sp_executesql @SQLCommand;
|
||||
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;
|
||||
-----------------------------------------------------------------------------------------------------------------------------
|
||||
|
||||
END
|
||||
ELSE
|
||||
BEGIN
|
||||
PRINT 'No shrink action neccessary!';
|
||||
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
|
||||
|
||||
END; ELSE BEGIN
|
||||
PRINT 'No shrink action neccessary!';
|
||||
END;
|
||||
-----------------------------------------------------------------------------------------------------------------------------
|
||||
|
||||
END; ELSE BEGIN
|
||||
PRINT 'Dont shrink the log file!';
|
||||
END
|
||||
END;
|
||||
-----------------------------------------------------------------------------------------------------------------------------
|
||||
|
||||
--================================================-- Shrink db as well --==================================================--
|
||||
IF ((@SHRINKDB = 1) and (@return_status = 0))
|
||||
BEGIN
|
||||
IF ((@SHRINKDB = 1) and (@return_status = 0)) BEGIN
|
||||
PRINT 'Shrink the database to reclaim unused space.';
|
||||
IF (@ProductMainVersion >= 16)
|
||||
BEGIN
|
||||
IF (@FORCE = 1)
|
||||
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);';
|
||||
ELSE
|
||||
END; ELSE BEGIN
|
||||
SET @SQLCommand = N'USE [' + @DBName + ']; DBCC SHRINKDATABASE ([' + @DBName + ']) WITH WAIT_AT_LOW_PRIORITY (ABORT_AFTER_WAIT = SELF);';
|
||||
END
|
||||
ELSE
|
||||
BEGIN
|
||||
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
|
||||
END;
|
||||
|
||||
EXEC @return_status = sp_executesql @SQLCommand;
|
||||
|
||||
IF ((@LOGLEVEL in ('INFO')) and (@return_status = 0))
|
||||
BEGIN
|
||||
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
|
||||
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
|
||||
|
||||
END; ELSE BEGIN
|
||||
IF (@LOGLEVEL in ('INFO')) BEGIN
|
||||
SET @return_status_text = 'Skipping shrinking the database!';
|
||||
PRINT @return_status_text;
|
||||
END;
|
||||
@ -371,26 +395,23 @@ 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
|
||||
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());
|
||||
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
|
||||
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...'
|
||||
PRINT '#TableList Temp table is already gone... (1)'
|
||||
END CATCH;
|
||||
|
||||
-- Create a temporary table to hold the table names
|
||||
@ -404,71 +425,55 @@ BEGIN
|
||||
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!';
|
||||
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 ((@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
|
||||
|
||||
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
|
||||
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());
|
||||
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
|
||||
IF ((@REBUILDINDEX = 1) and (@return_status = 0) and (SELECT COUNT(*) FROM #TableList) > 0) BEGIN
|
||||
|
||||
DECLARE table_cursor CURSOR READ_ONLY LOCAL FOR
|
||||
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
|
||||
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
|
||||
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
|
||||
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;
|
||||
|
||||
--===============================================-- 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
|
||||
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;
|
||||
@ -482,10 +487,8 @@ BEGIN
|
||||
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
|
||||
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;
|
||||
@ -504,14 +507,11 @@ BEGIN
|
||||
-- Drop the temporary table
|
||||
DROP TABLE #TableList;
|
||||
|
||||
SET @return_status_text = 'Skipping the recreation of the database indexes!';
|
||||
SET @return_status_text = 'Recreation of the database indexes successfully completed!';
|
||||
PRINT @return_status_text;
|
||||
|
||||
END;
|
||||
ELSE
|
||||
BEGIN
|
||||
IF (@LOGLEVEL in ('INFO'))
|
||||
BEGIN
|
||||
END; ELSE BEGIN
|
||||
IF (@LOGLEVEL in ('INFO')) BEGIN
|
||||
SET @return_status_text = 'Skipping the recreation of the database indexes!';
|
||||
PRINT @return_status_text;
|
||||
END;
|
||||
@ -519,38 +519,29 @@ 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
|
||||
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());
|
||||
VALUES (@LOGLEVEL, 'db_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
|
||||
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 SINGLE_USER mode was successfully completed!';
|
||||
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;
|
||||
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
|
||||
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;
|
||||
@ -558,12 +549,10 @@ 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
|
||||
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());
|
||||
VALUES (@LOGLEVEL, 'db_cursor', @DBName, @return_status, @return_status_text, 'PRDD_MAINTAIN_DATABASES',GetDate());
|
||||
END;
|
||||
END;
|
||||
-----------------------------------------------------------------------------------------------------------------------------
|
||||
@ -580,7 +569,7 @@ BEGIN
|
||||
DROP TABLE #TableList;
|
||||
END TRY
|
||||
BEGIN CATCH
|
||||
PRINT '#TableList Temp table are already gone...'
|
||||
PRINT '#TableList Temp table are already gone...(2)'
|
||||
END CATCH;
|
||||
|
||||
PRINT '-------------------------------'
|
||||
@ -591,10 +580,8 @@ BEGIN
|
||||
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
|
||||
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;
|
||||
@ -603,25 +590,32 @@ BEGIN
|
||||
|
||||
--==============================================-- 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'
|
||||
--==============================================-- 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;
|
||||
END
|
||||
ELSE
|
||||
BEGIN
|
||||
PRINT 'Dont change the database mode!';
|
||||
END
|
||||
|
||||
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
|
||||
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());
|
||||
VALUES (@LOGLEVEL, 'db_cursor', @DBName, @return_status, @return_status_text, 'PRDD_MAINTAIN_DATABASES',GetDate());
|
||||
END;
|
||||
END;
|
||||
-----------------------------------------------------------------------------------------------------------------------------
|
||||
@ -639,118 +633,38 @@ BEGIN
|
||||
DROP TABLE #TableList;
|
||||
END TRY
|
||||
BEGIN CATCH
|
||||
PRINT '#TableList Temp table are already gone...'
|
||||
PRINT '#TableList Temp table are already gone...(3)'
|
||||
END CATCH;
|
||||
|
||||
CLOSE table_cursor;
|
||||
DEALLOCATE table_cursor;
|
||||
CLOSE table_cursor
|
||||
DEALLOCATE table_cursor
|
||||
-----------------------------------------------------------------------------------------------------------------------------
|
||||
|
||||
END CATCH;
|
||||
|
||||
FETCH NEXT FROM db_cursor INTO @DBName;
|
||||
|
||||
END;
|
||||
|
||||
CLOSE db_cursor;
|
||||
DEALLOCATE db_cursor;
|
||||
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
|
||||
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 '';
|
||||
PRINT 'PROCEDURE - END [PRDD_MAINTAIN_DATABASES] @ ' + CONVERT(varchar(50),GETDATE(),120);
|
||||
PRINT '===============================';
|
||||
|
||||
Return @return_status;
|
||||
|
||||
-- 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
|
||||
END;
|
||||
|
||||
Loading…
x
Reference in New Issue
Block a user