[PRDD_MAINTAIN_DATABASES]: Added "SET ONLINE" after forced SINGLE_USER Mode, Added repair parameter for DBCHECK, added @pRECOMPILEPROCEDURES, some minor error fixes
This commit is contained in:
@@ -4,7 +4,7 @@
|
|||||||
-- and recreates indizes in a maintanance run.
|
-- and recreates indizes in a maintanance run.
|
||||||
-- Minimum requirement: MS SQL Server 2016
|
-- Minimum requirement: MS SQL Server 2016
|
||||||
--
|
--
|
||||||
-- Returns: Table with results
|
-- Returns: INT Value - 0 = Everything worked well
|
||||||
-- =================================================================
|
-- =================================================================
|
||||||
-- Copyright (c) 2024 by Digital Data GmbH
|
-- Copyright (c) 2024 by Digital Data GmbH
|
||||||
--
|
--
|
||||||
@@ -12,11 +12,12 @@
|
|||||||
-- Tel.: 0641/202360 • E-Mail: info-flow@digitaldata.works
|
-- Tel.: 0641/202360 • E-Mail: info-flow@digitaldata.works
|
||||||
-- =================================================================
|
-- =================================================================
|
||||||
-- Creation Date / Author: 29.11.2024 / MK
|
-- Creation Date / Author: 29.11.2024 / MK
|
||||||
-- Version Date / Editor: 29.11.2024 / MK
|
-- Version Date / Editor: 06.12.2024 / MK
|
||||||
-- Version Number: 1.0.0.0
|
-- Version Number: 1.1.0.0
|
||||||
-- =================================================================
|
-- =================================================================
|
||||||
-- History:
|
-- History:
|
||||||
-- 29.11.2024 / MK - First Version
|
-- 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
|
||||||
|
|
||||||
SET ANSI_NULLS ON
|
SET ANSI_NULLS ON
|
||||||
GO
|
GO
|
||||||
@@ -24,33 +25,40 @@ SET QUOTED_IDENTIFIER ON
|
|||||||
GO
|
GO
|
||||||
|
|
||||||
CREATE OR ALTER PROCEDURE [dbo].[PRDD_MAINTAIN_DATABASES] (
|
CREATE OR ALTER PROCEDURE [dbo].[PRDD_MAINTAIN_DATABASES] (
|
||||||
@pCHECKDB BIT = 1, -- Set to 1 to make a check of the database before shrinking. Otherwise set to 0.
|
@pCHECKDB BIT = 1, -- Set to 1 to make a check of the database before shrinking incl. soft repair function. Otherwise set to 0.
|
||||||
@pSHRINKLOG BIT = 1, -- Set to 1 to shrink the log file. Otherwise set to 0.
|
@pSHRINKLOG BIT = 1, -- Set to 1 to shrink the log file. Otherwise set to 0.
|
||||||
@pSHRINKDB BIT = 0, -- Set to 1 to shrink the database file as well. Otherwise set to 0. (Dont use on FILESTREAM databases!)
|
@pSHRINKDB BIT = 0, -- Set to 1 to shrink the database file as well. Otherwise set to 0. (Dont use on FILESTREAM databases!)
|
||||||
@pREBUILDINDEX BIT = 1, -- Set to 1 to recreate all database indxes. Otherwise set to 0.
|
@pREBUILDINDEX BIT = 0, -- Set to 1 to recreate all database indexes. Otherwise set to 0.
|
||||||
@pFORCE BIT = 0, -- Set to 1 to force the shrinking, it will cut all current sessens. Otherwise set to 0.
|
@pRECOMPILEPROCEDURES BIT = 0, -- Set to 1 to recompile all database procedures. Otherwise set to 0.
|
||||||
|
@pCLEARQUERYCACHE BIT = 0, -- Set to 1 to clear the QL query cache via DROPCLEANBUFFERS. Otherwise set to 0.
|
||||||
|
@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
|
@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.
|
@pEXCLUDEDB NVARCHAR(1000) = 'master,model,msdb,tempdb', -- Set a list of exluded databases. Default exclusen are the system databases.
|
||||||
@pLOGLEVEL NVARCHAR(25) = 'ERROR' -- Set to 'INFO','WARN' OR 'ERROR' (or NULL to disable), logging to table: [TBDD_MAINTAIN_DATABASES_LOG]
|
@pLOGLEVEL NVARCHAR(25) = 'ERROR' -- Set to 'INFO','WARN' OR 'ERROR' (or NULL to disable), logging to table: [TBDD_MAINTAIN_DATABASES_LOG]
|
||||||
-- 'INFO' includes Warnings and Errors, 'WARN' only warnings and Errors and 'ERROR' only Errors
|
-- 'INFO' includes Infos, Warnings and Errors, 'WARN' only warnings and Errors and 'ERROR' only Errors
|
||||||
)
|
)
|
||||||
AS
|
AS
|
||||||
BEGIN
|
BEGIN
|
||||||
|
|
||||||
SET NOCOUNT ON;
|
SET NOCOUNT ON;
|
||||||
|
|
||||||
-- decalare new vars because of parameter sniffing
|
-- declare new vars because of parameter sniffing
|
||||||
DECLARE @CHECKDB BIT = @pCHECKDB,
|
DECLARE @CHECKDB BIT = @pCHECKDB,
|
||||||
@SHRINKLOG BIT = @pSHRINKLOG,
|
@SHRINKLOG BIT = @pSHRINKLOG,
|
||||||
@SHRINKDB BIT = @pSHRINKDB,
|
@SHRINKDB BIT = @pSHRINKDB,
|
||||||
@REBUILDINDEX BIT = @pREBUILDINDEX,
|
@REBUILDINDEX BIT = @pREBUILDINDEX,
|
||||||
|
@RECOMPILEPROCEDURES BIT = @pRECOMPILEPROCEDURES,
|
||||||
|
@CLEARQUERYCACHE BIT = @pCLEARQUERYCACHE,
|
||||||
@FORCE BIT = @pFORCE,
|
@FORCE BIT = @pFORCE,
|
||||||
@INCLUDEDB NVARCHAR(1000) = @pINCLUDEDB,
|
@INCLUDEDB NVARCHAR(1000) = @pINCLUDEDB,
|
||||||
@EXCLUDEDB NVARCHAR(1000) = @pEXCLUDEDB,
|
@EXCLUDEDB NVARCHAR(1000) = @pEXCLUDEDB,
|
||||||
@LOGLEVEL NVARCHAR(25) = @pLOGLEVEL;
|
@LOGLEVEL NVARCHAR(25) = @pLOGLEVEL;
|
||||||
|
|
||||||
-- decalare runtime vars
|
-- declare runtime vars
|
||||||
DECLARE @DBName NVARCHAR(100),
|
DECLARE @MyProcedureName NVARCHAR(50) = 'PRDD_MAINTAIN_DATABASES';
|
||||||
|
DECLARE @ProcedureName NVARCHAR(50),
|
||||||
|
@DBName NVARCHAR(100),
|
||||||
|
@DBNameCount INT,
|
||||||
@LogFileName NVARCHAR(100),
|
@LogFileName NVARCHAR(100),
|
||||||
@CurrentLogFileSizeMB INT,
|
@CurrentLogFileSizeMB INT,
|
||||||
@MinimumLogFileSizeMB INT,
|
@MinimumLogFileSizeMB INT,
|
||||||
@@ -61,20 +69,28 @@ BEGIN
|
|||||||
@ProductEdition sql_variant,
|
@ProductEdition sql_variant,
|
||||||
@SchemaName NVARCHAR(50),
|
@SchemaName NVARCHAR(50),
|
||||||
@TableName NVARCHAR(256),
|
@TableName NVARCHAR(256),
|
||||||
|
@LoginName NVARCHAR(50),
|
||||||
|
@HostName NVARCHAR(50),
|
||||||
|
@SessionID NVARCHAR(50) = NULL,
|
||||||
|
@MySessionID NVARCHAR(50) = @@SPID,
|
||||||
@SQLCommand NVARCHAR(MAX) = NULL,
|
@SQLCommand NVARCHAR(MAX) = NULL,
|
||||||
|
@TableListCount INT = 0,
|
||||||
|
@ProcedureListCount INT = 0,
|
||||||
@return_status NVARCHAR(50) = 0,
|
@return_status NVARCHAR(50) = 0,
|
||||||
@return_status_text NVARCHAR(MAX) = 'START [PRDD_MAINTAIN_DATABASES] @ ' + CONVERT(varchar(50),GETDATE(),120);
|
@return_status_text NVARCHAR(MAX) = 'START ' + @MyProcedureName + ' @ ' + CONVERT(varchar(50),GETDATE(),120);
|
||||||
|
|
||||||
PRINT '==============================='
|
PRINT '==============================='
|
||||||
PRINT 'PROCEDURE - START [PRDD_MAINTAIN_DATABASES] @ ' + CONVERT(varchar(50),GETDATE(),120);
|
PRINT 'PROCEDURE - ' + @return_status_text;
|
||||||
PRINT 'PARAMETER1 - @CHECKDB: ' + CONVERT(VARCHAR(1),@CHECKDB);
|
PRINT 'PARAMETER01 - @CHECKDB: ' + CONVERT(VARCHAR(1),@CHECKDB);
|
||||||
PRINT 'PARAMETER2 - @SHRINKLOG: ' + CONVERT(VARCHAR(1),@SHRINKLOG);
|
PRINT 'PARAMETER02 - @SHRINKLOG: ' + CONVERT(VARCHAR(1),@SHRINKLOG);
|
||||||
PRINT 'PARAMETER3 - @SHRINKDB: ' + CONVERT(VARCHAR(1),@SHRINKDB);
|
PRINT 'PARAMETER03 - @SHRINKDB: ' + CONVERT(VARCHAR(1),@SHRINKDB);
|
||||||
PRINT 'PARAMETER4 - @REBUILDINDEX: ' + CONVERT(VARCHAR(1),@REBUILDINDEX);
|
PRINT 'PARAMETER04 - @REBUILDINDEX: ' + CONVERT(VARCHAR(1),@REBUILDINDEX);
|
||||||
PRINT 'PARAMETER5 - @FORCE: ' + CONVERT(VARCHAR(1),@FORCE);
|
PRINT 'PARAMETER05 - @RECOMPILEPROCEDURES: ' + CONVERT(VARCHAR(1),@RECOMPILEPROCEDURES);
|
||||||
PRINT 'PARAMETER6 - @INCLUDEDB: ' + CONVERT(VARCHAR(1000),@INCLUDEDB);
|
PRINT 'PARAMETER06 - @CLEARQUERYCACHE: ' + CONVERT(VARCHAR(1),@CLEARQUERYCACHE);
|
||||||
PRINT 'PARAMETER7 - @EXCLUDEDB: ' + CONVERT(VARCHAR(1000),@EXCLUDEDB);
|
PRINT 'PARAMETER07 - @FORCE: ' + CONVERT(VARCHAR(1),@FORCE);
|
||||||
PRINT 'PARAMETER8 - @LOGLEVEL: ' + CONVERT(VARCHAR(25),@LOGLEVEL);
|
PRINT 'PARAMETER08 - @INCLUDEDB: ' + CONVERT(VARCHAR(1000),@INCLUDEDB);
|
||||||
|
PRINT 'PARAMETER09 - @EXCLUDEDB: ' + CONVERT(VARCHAR(1000),@EXCLUDEDB);
|
||||||
|
PRINT 'PARAMETER10 - @LOGLEVEL: ' + CONVERT(VARCHAR(25),@LOGLEVEL);
|
||||||
|
|
||||||
--=================================================-- Get server infos --==================================================--
|
--=================================================-- Get server infos --==================================================--
|
||||||
SELECT @ProductVersion = SERVERPROPERTY('productversion'), @ProductLevel = SERVERPROPERTY ('productlevel'), @ProductEdition = SERVERPROPERTY ('edition');
|
SELECT @ProductVersion = SERVERPROPERTY('productversion'), @ProductLevel = SERVERPROPERTY ('productlevel'), @ProductEdition = SERVERPROPERTY ('edition');
|
||||||
@@ -82,6 +98,7 @@ BEGIN
|
|||||||
|
|
||||||
PRINT '';
|
PRINT '';
|
||||||
PRINT 'Informations about this Server:';
|
PRINT 'Informations about this Server:';
|
||||||
|
PRINT '@MySessionID: ' + CONVERT(VARCHAR(100),@MySessionID);
|
||||||
PRINT '@ProductVersion: ' + CONVERT(VARCHAR(100),@ProductVersion);
|
PRINT '@ProductVersion: ' + CONVERT(VARCHAR(100),@ProductVersion);
|
||||||
PRINT '@ProductMainVersion: ' + CONVERT(VARCHAR(100),@ProductMainVersion);
|
PRINT '@ProductMainVersion: ' + CONVERT(VARCHAR(100),@ProductMainVersion);
|
||||||
PRINT '@ProductLevel: ' + CONVERT(VARCHAR(100),@ProductLevel);
|
PRINT '@ProductLevel: ' + CONVERT(VARCHAR(100),@ProductLevel);
|
||||||
@@ -90,9 +107,9 @@ BEGIN
|
|||||||
|
|
||||||
--==============================================-- Prepare the log table --================================================--
|
--==============================================-- Prepare the log table --================================================--
|
||||||
IF (@LOGLEVEL is not NULL) BEGIN
|
IF (@LOGLEVEL is not NULL) BEGIN
|
||||||
PRINT ''
|
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'
|
PRINT 'Log table already exists';
|
||||||
END; ELSE BEGIN
|
END; ELSE BEGIN
|
||||||
PRINT 'Log table does not exists, trying to create...';
|
PRINT 'Log table does not exists, trying to create...';
|
||||||
|
|
||||||
@@ -118,6 +135,9 @@ BEGIN
|
|||||||
ALTER TABLE [dbo].[TBDD_MAINTAIN_DATABASES_LOG] ADD CONSTRAINT [DF_TBDD_MAINTAIN_DATABASES_LOG_ADDED_WHEN] DEFAULT (getdate()) FOR [ADDED_WHEN];
|
ALTER TABLE [dbo].[TBDD_MAINTAIN_DATABASES_LOG] ADD CONSTRAINT [DF_TBDD_MAINTAIN_DATABASES_LOG_ADDED_WHEN] DEFAULT (getdate()) FOR [ADDED_WHEN];
|
||||||
|
|
||||||
END;
|
END;
|
||||||
|
END; ELSE BEGIN
|
||||||
|
PRINT '';
|
||||||
|
PRINT 'Skipping Logging to log table!';
|
||||||
END;
|
END;
|
||||||
-----------------------------------------------------------------------------------------------------------------------------
|
-----------------------------------------------------------------------------------------------------------------------------
|
||||||
|
|
||||||
@@ -125,7 +145,7 @@ BEGIN
|
|||||||
IF ((@LOGLEVEL in ('INFO')) and (@return_status is not null) and (@return_status_text is not null)) 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
|
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])
|
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());
|
VALUES (@LOGLEVEL,'preparing', 'procedure', @return_status, @return_status_text, @MyProcedureName, GetDate());
|
||||||
END;
|
END;
|
||||||
END;
|
END;
|
||||||
-----------------------------------------------------------------------------------------------------------------------------
|
-----------------------------------------------------------------------------------------------------------------------------
|
||||||
@@ -134,6 +154,8 @@ BEGIN
|
|||||||
-- Create a temporary table to hold the table names
|
-- Create a temporary table to hold the table names
|
||||||
CREATE TABLE #DBList (DBName NVARCHAR(256));
|
CREATE TABLE #DBList (DBName NVARCHAR(256));
|
||||||
|
|
||||||
|
IF (@ProductMainVersion >= 13) BEGIN
|
||||||
|
|
||||||
IF (@INCLUDEDB is not NULL) BEGIN
|
IF (@INCLUDEDB is not NULL) BEGIN
|
||||||
INSERT INTO #DBList(DBName)
|
INSERT INTO #DBList(DBName)
|
||||||
SELECT [name] as 'DBName'
|
SELECT [name] as 'DBName'
|
||||||
@@ -149,25 +171,118 @@ BEGIN
|
|||||||
AND [state] = 0 -- database is online
|
AND [state] = 0 -- database is online
|
||||||
AND [is_in_standby] = 0; -- database is not read only for log shipping
|
AND [is_in_standby] = 0; -- database is not read only for log shipping
|
||||||
END;
|
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;
|
||||||
-----------------------------------------------------------------------------------------------------------------------------
|
-----------------------------------------------------------------------------------------------------------------------------
|
||||||
|
|
||||||
--=============================================-- Create the loop (cursor) --==============================================--
|
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_MAINTAIN_DATABASES_LOG') BEGIN
|
||||||
|
INSERT INTO [TBDD_MAINTAIN_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
|
||||||
|
|
||||||
DECLARE db_cursor CURSOR STATIC LOCAL FOR
|
DECLARE db_cursor CURSOR STATIC LOCAL FOR
|
||||||
SELECT [DBName] as 'DBName' FROM #DBList
|
SELECT [DBName] as 'DBName' FROM #DBList;
|
||||||
|
|
||||||
OPEN db_cursor
|
OPEN db_cursor
|
||||||
FETCH NEXT FROM db_cursor INTO @DBName
|
FETCH NEXT FROM db_cursor INTO @DBName
|
||||||
WHILE @@FETCH_STATUS = 0 BEGIN
|
WHILE @@FETCH_STATUS = 0 BEGIN
|
||||||
BEGIN TRY
|
BEGIN TRY
|
||||||
|
|
||||||
PRINT ' '
|
PRINT ' ';
|
||||||
PRINT '-------------------------------'
|
PRINT '-------------------------------';
|
||||||
PRINT 'Now processing: ' + CONVERT(varchar(100),@DBName);
|
PRINT 'Now processing: ' + CONVERT(varchar(100),@DBName);
|
||||||
|
|
||||||
--==============================================-- Change db working mode --===============================================--
|
--==============================================-- 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';
|
PRINT 'Closing active database connections... first time';
|
||||||
|
DECLARE kill_cursor CURSOR STATIC LOCAL FOR
|
||||||
|
SELECT CONVERT(NVARCHAR(5), [session_id]) as 'SessionID',
|
||||||
|
CONVERT(NVARCHAR(50), [login_name]) as 'LoginName',
|
||||||
|
CONVERT(NVARCHAR(50), [host_name]) as 'HostName'
|
||||||
|
FROM [master].[sys].[dm_exec_sessions] (NOLOCK)
|
||||||
|
WHERE [is_user_process] = 1
|
||||||
|
AND [database_id] = db_id(@DBName)
|
||||||
|
AND [session_id] <> @MySessionID;
|
||||||
|
|
||||||
|
OPEN kill_cursor;
|
||||||
|
FETCH NEXT FROM kill_cursor INTO @SessionID, @LoginName, @HostName;
|
||||||
|
WHILE @@FETCH_STATUS = 0 BEGIN
|
||||||
|
|
||||||
|
BEGIN TRY
|
||||||
|
SET @SQLCommand = 'KILL ' + @SessionID + ';';
|
||||||
|
PRINT 'Killing @SessionID: ' + @SessionID + ', @LoginName: ' + @LoginName + ', @HostName: ' + @HostName;
|
||||||
|
EXEC sp_executesql @SQLCommand;
|
||||||
|
SET @SQLCommand = NULL;
|
||||||
|
|
||||||
|
IF ((@LOGLEVEL in ('INFO')) and (@return_status = 0)) BEGIN
|
||||||
|
SET @return_status_text = 'Closing connections to database was successfully completed!';
|
||||||
|
PRINT @return_status_text;
|
||||||
|
END; ELSE IF ((@LOGLEVEL in ('WARN')) and (@return_status <> 0)) BEGIN
|
||||||
|
SET @return_status_text = 'Closing connections to database 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, 'kill_cursor', @DBName, @return_status, @return_status_text, @MyProcedureName, GetDate());
|
||||||
|
END;
|
||||||
|
END;
|
||||||
|
-----------------------------------------------------------------------------------------------------------------------------
|
||||||
|
|
||||||
|
END TRY
|
||||||
|
BEGIN CATCH
|
||||||
|
|
||||||
|
-- Handle any errors that occur during the process.
|
||||||
|
SELECT ERROR_MESSAGE() AS ErrorMessage;
|
||||||
|
|
||||||
|
SET @SQLCommand = NULL;
|
||||||
|
|
||||||
|
--===============================================-- Log result to table --=================================================--
|
||||||
|
IF ((@LOGLEVEL is not null) 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], [ADDED_WHO], [ADDED_WHEN])
|
||||||
|
VALUES ('ERROR', 'kill_cursor', @DBName, ERROR_MESSAGE(),@MyProcedureName, GetDate());
|
||||||
|
END;
|
||||||
|
END;
|
||||||
|
-----------------------------------------------------------------------------------------------------------------------------
|
||||||
|
|
||||||
|
END CATCH;
|
||||||
|
|
||||||
|
FETCH NEXT FROM kill_cursor INTO @SessionID, @LoginName, @HostName;
|
||||||
|
|
||||||
|
END;
|
||||||
|
|
||||||
|
CLOSE kill_cursor;
|
||||||
|
DEALLOCATE kill_cursor;
|
||||||
|
-----------------------------------------------------------------------------------------------------------------------------
|
||||||
|
|
||||||
|
PRINT 'Set the database to SINGLE_USER mode to avoid multiple active sessions.';
|
||||||
|
SET @SQLCommand = N'ALTER DATABASE [' + @DBName + '] SET SINGLE_USER WITH ROLLBACK IMMEDIATE;';
|
||||||
EXEC @return_status = sp_executesql @SQLCommand;
|
EXEC @return_status = sp_executesql @SQLCommand;
|
||||||
|
|
||||||
IF ((@LOGLEVEL in ('INFO')) and (@return_status = 0)) BEGIN
|
IF ((@LOGLEVEL in ('INFO')) and (@return_status = 0)) BEGIN
|
||||||
@@ -178,27 +293,45 @@ BEGIN
|
|||||||
PRINT @return_status_text;
|
PRINT @return_status_text;
|
||||||
END;
|
END;
|
||||||
|
|
||||||
|
--===============================================-- Log result to table --=================================================--
|
||||||
|
IF ((@LOGLEVEL in ('INFO','WARN')) and (@return_status is not null) and (@return_status_text is not null)) BEGIN
|
||||||
|
IF EXISTS (SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = N'TBDD_MAINTAIN_DATABASES_LOG') BEGIN
|
||||||
|
INSERT INTO [TBDD_MAINTAIN_DATABASES_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN])
|
||||||
|
VALUES (@LOGLEVEL, 'db_cursor', @DBName, @return_status, @return_status_text, @MyProcedureName, GetDate());
|
||||||
|
END;
|
||||||
|
END;
|
||||||
|
-----------------------------------------------------------------------------------------------------------------------------
|
||||||
|
|
||||||
END; ELSE BEGIN
|
END; ELSE BEGIN
|
||||||
|
|
||||||
IF (@LOGLEVEL in ('INFO')) BEGIN
|
IF (@LOGLEVEL in ('INFO')) BEGIN
|
||||||
SET @return_status_text = 'Skipping to change the database mode (FORCE = OFF)!';
|
SET @return_status_text = 'Skipping to change the database mode (FORCE = OFF)!';
|
||||||
PRINT @return_status_text;
|
PRINT @return_status_text;
|
||||||
END;
|
END;
|
||||||
END;
|
|
||||||
-----------------------------------------------------------------------------------------------------------------------------
|
|
||||||
|
|
||||||
--===============================================-- Log result to table --=================================================--
|
--===============================================-- Log result to table --=================================================--
|
||||||
IF ((@LOGLEVEL in ('INFO','WARN')) and (@return_status is not null) and (@return_status_text is not null)) 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
|
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])
|
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, @MyProcedureName, GetDate());
|
||||||
END;
|
END;
|
||||||
END;
|
END;
|
||||||
-----------------------------------------------------------------------------------------------------------------------------
|
-----------------------------------------------------------------------------------------------------------------------------
|
||||||
|
|
||||||
|
END;
|
||||||
|
-----------------------------------------------------------------------------------------------------------------------------
|
||||||
|
|
||||||
--===============================================-- Check db consistency --================================================--
|
--===============================================-- Check db consistency --================================================--
|
||||||
IF (@CHECKDB = 1) and (@return_status = 0) BEGIN
|
IF (@CHECKDB = 1) and (@return_status = 0) 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';
|
||||||
|
END; ELSE BEGIN
|
||||||
PRINT 'Check the database for consistency and health.';
|
PRINT 'Check the database for consistency and health.';
|
||||||
SET @SQLCommand = N'DBCC CHECKDB ([' + @DBName + ']) WITH NO_INFOMSGS, ALL_ERRORMSGS';
|
SET @SQLCommand = N'USE [' + @DBName + ']; DBCC CHECKDB ([' + @DBName + ']) WITH NO_INFOMSGS, ALL_ERRORMSGS';
|
||||||
|
END;
|
||||||
|
|
||||||
EXEC @return_status = sp_executesql @SQLCommand;
|
EXEC @return_status = sp_executesql @SQLCommand;
|
||||||
|
|
||||||
IF ((@LOGLEVEL in ('INFO')) and (@return_status = 0)) BEGIN
|
IF ((@LOGLEVEL in ('INFO')) and (@return_status = 0)) BEGIN
|
||||||
@@ -221,7 +354,7 @@ BEGIN
|
|||||||
IF ((@LOGLEVEL in ('INFO','WARN')) and (@return_status is not null) and (@return_status_text is not null)) 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
|
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])
|
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, @MyProcedureName, GetDate());
|
||||||
END;
|
END;
|
||||||
END;
|
END;
|
||||||
-----------------------------------------------------------------------------------------------------------------------------
|
-----------------------------------------------------------------------------------------------------------------------------
|
||||||
@@ -250,7 +383,7 @@ BEGIN
|
|||||||
IF ((@LOGLEVEL in ('INFO','WARN')) and (@return_status is not null) and (@return_status_text is not null)) 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
|
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])
|
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, @MyProcedureName, GetDate());
|
||||||
END;
|
END;
|
||||||
END;
|
END;
|
||||||
-----------------------------------------------------------------------------------------------------------------------------
|
-----------------------------------------------------------------------------------------------------------------------------
|
||||||
@@ -286,7 +419,7 @@ BEGIN
|
|||||||
IF ((@LOGLEVEL in ('INFO','WARN')) and (@return_status is not null) and (@return_status_text is not null)) 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
|
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])
|
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, @MyProcedureName, GetDate());
|
||||||
END;
|
END;
|
||||||
END;
|
END;
|
||||||
-----------------------------------------------------------------------------------------------------------------------------
|
-----------------------------------------------------------------------------------------------------------------------------
|
||||||
@@ -296,13 +429,13 @@ BEGIN
|
|||||||
PRINT 'Shrink the truncated log file to 10% of its current size or the minimum size, whichever is larger.';
|
PRINT 'Shrink the truncated log file to 10% of its current size or the minimum size, whichever is larger.';
|
||||||
IF (@ProductMainVersion >= 16) BEGIN
|
IF (@ProductMainVersion >= 16) BEGIN
|
||||||
IF (@FORCE = 1) 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);';
|
SET @SQLCommand = N'USE [' + @DBName + ']; DBCC SHRINKFILE (''' + @LogFileName + ''', ' + CAST(@TargetLogFileSizeMB AS VARCHAR) + ') WITH WAIT_AT_LOW_PRIORITY (ABORT_AFTER_WAIT = BLOCKERS), NO_INFOMSGS;';
|
||||||
END; ELSE BEGIN
|
END; ELSE BEGIN
|
||||||
SET @SQLCommand = N'USE [' + @DBName + ']; DBCC SHRINKFILE (''' + @LogFileName + ''', ' + CAST(@TargetLogFileSizeMB AS VARCHAR) + ') WITH WAIT_AT_LOW_PRIORITY (ABORT_AFTER_WAIT = SELF);';
|
SET @SQLCommand = N'USE [' + @DBName + ']; DBCC SHRINKFILE (''' + @LogFileName + ''', ' + CAST(@TargetLogFileSizeMB AS VARCHAR) + ') WITH WAIT_AT_LOW_PRIORITY (ABORT_AFTER_WAIT = SELF), NO_INFOMSGS;';
|
||||||
END;
|
END;
|
||||||
END; ELSE BEGIN
|
END; ELSE BEGIN
|
||||||
PRINT 'Because of the sql server version, DBCC SHRINKFILE is not applicable with the FORCE parameter!'
|
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) + ');';
|
SET @SQLCommand = N'USE [' + @DBName + ']; DBCC SHRINKFILE (''' + @LogFileName + ''', ' + CAST(@TargetLogFileSizeMB AS VARCHAR) + ') WITH NO_INFOMSGS;';
|
||||||
END;
|
END;
|
||||||
|
|
||||||
EXEC @return_status = sp_executesql @SQLCommand;
|
EXEC @return_status = sp_executesql @SQLCommand;
|
||||||
@@ -324,7 +457,7 @@ BEGIN
|
|||||||
IF ((@LOGLEVEL in ('INFO','WARN')) and (@return_status is not null) and (@return_status_text is not null)) 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
|
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])
|
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, @MyProcedureName, GetDate());
|
||||||
END;
|
END;
|
||||||
END;
|
END;
|
||||||
-----------------------------------------------------------------------------------------------------------------------------
|
-----------------------------------------------------------------------------------------------------------------------------
|
||||||
@@ -347,7 +480,7 @@ BEGIN
|
|||||||
IF ((@LOGLEVEL in ('INFO','WARN')) and (@return_status is not null) and (@return_status_text is not null)) 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
|
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])
|
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, @MyProcedureName, GetDate());
|
||||||
END;
|
END;
|
||||||
END;
|
END;
|
||||||
-----------------------------------------------------------------------------------------------------------------------------
|
-----------------------------------------------------------------------------------------------------------------------------
|
||||||
@@ -358,7 +491,7 @@ BEGIN
|
|||||||
-----------------------------------------------------------------------------------------------------------------------------
|
-----------------------------------------------------------------------------------------------------------------------------
|
||||||
|
|
||||||
END; ELSE BEGIN
|
END; ELSE BEGIN
|
||||||
PRINT 'Dont shrink the log file!';
|
PRINT 'Skipping to shrink the log file!';
|
||||||
END;
|
END;
|
||||||
-----------------------------------------------------------------------------------------------------------------------------
|
-----------------------------------------------------------------------------------------------------------------------------
|
||||||
|
|
||||||
@@ -367,13 +500,13 @@ BEGIN
|
|||||||
PRINT 'Shrink the database to reclaim unused space.';
|
PRINT 'Shrink the database to reclaim unused space.';
|
||||||
IF (@ProductMainVersion >= 16) BEGIN
|
IF (@ProductMainVersion >= 16) BEGIN
|
||||||
IF (@FORCE = 1) BEGIN
|
IF (@FORCE = 1) BEGIN
|
||||||
SET @SQLCommand = N'USE [' + @DBName + ']; DBCC SHRINKDATABASE ([' + @DBName + ']) WITH WAIT_AT_LOW_PRIORITY (ABORT_AFTER_WAIT = BLOCKERS);';
|
SET @SQLCommand = N'USE [' + @DBName + ']; DBCC SHRINKDATABASE ([' + @DBName + ']) WITH WAIT_AT_LOW_PRIORITY (ABORT_AFTER_WAIT = BLOCKERS), NO_INFOMSGS;';
|
||||||
END; ELSE BEGIN
|
END; ELSE BEGIN
|
||||||
SET @SQLCommand = N'USE [' + @DBName + ']; DBCC SHRINKDATABASE ([' + @DBName + ']) WITH WAIT_AT_LOW_PRIORITY (ABORT_AFTER_WAIT = SELF);';
|
SET @SQLCommand = N'USE [' + @DBName + ']; DBCC SHRINKDATABASE ([' + @DBName + ']) WITH WAIT_AT_LOW_PRIORITY (ABORT_AFTER_WAIT = SELF), NO_INFOMSGS;';
|
||||||
END;
|
END;
|
||||||
END; ELSE BEGIN
|
END; ELSE BEGIN
|
||||||
PRINT 'Because of the sql server version, DBCC SHRINKDATABASE is not applicable with the FORCE parameter!'
|
PRINT 'Because of the sql server version, DBCC SHRINKDATABASE is not applicable with the FORCE parameter!';
|
||||||
SET @SQLCommand = N'USE [' + @DBName + ']; DBCC SHRINKDATABASE ([' + @DBName + ']);';
|
SET @SQLCommand = N'USE [' + @DBName + ']; DBCC SHRINKDATABASE ([' + @DBName + ']) WITH NO_INFOMSGS;';
|
||||||
END;
|
END;
|
||||||
|
|
||||||
EXEC @return_status = sp_executesql @SQLCommand;
|
EXEC @return_status = sp_executesql @SQLCommand;
|
||||||
@@ -398,7 +531,7 @@ BEGIN
|
|||||||
IF ((@LOGLEVEL in ('INFO','WARN')) and (@return_status is not null) and (@return_status_text is not null)) 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
|
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])
|
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, @MyProcedureName, GetDate());
|
||||||
END;
|
END;
|
||||||
END;
|
END;
|
||||||
-----------------------------------------------------------------------------------------------------------------------------
|
-----------------------------------------------------------------------------------------------------------------------------
|
||||||
@@ -411,11 +544,11 @@ BEGIN
|
|||||||
DROP TABLE #TableList;
|
DROP TABLE #TableList;
|
||||||
END TRY
|
END TRY
|
||||||
BEGIN CATCH
|
BEGIN CATCH
|
||||||
PRINT '#TableList Temp table is already gone... (1)'
|
PRINT '#TableList Temp table is already gone... (1)';
|
||||||
END CATCH;
|
END CATCH;
|
||||||
|
|
||||||
-- Create a temporary table to hold the table names
|
-- Create a temporary table to hold the table names
|
||||||
CREATE TABLE #TableList (SchemaName NVARCHAR(50), TableName NVARCHAR(256), );
|
CREATE TABLE #TableList (SchemaName NVARCHAR(50), TableName NVARCHAR(256));
|
||||||
|
|
||||||
-- Set the context to the specified database and fill the temporary table
|
-- Set the context to the specified database and fill the temporary table
|
||||||
SET @SQLCommand = ' INSERT INTO #TableList (SchemaName, TableName)
|
SET @SQLCommand = ' INSERT INTO #TableList (SchemaName, TableName)
|
||||||
@@ -433,6 +566,14 @@ BEGIN
|
|||||||
PRINT @return_status_text;
|
PRINT @return_status_text;
|
||||||
END;
|
END;
|
||||||
|
|
||||||
|
IF (@return_status = 0) BEGIN
|
||||||
|
SELECT @TableListCount = COUNT(*) FROM #TableList;
|
||||||
|
PRINT 'Found: ' + convert(VARCHAR,@TableListCount) + ' tables to reindex';
|
||||||
|
END; ELSE BEGIN
|
||||||
|
SET @TableListCount = 0;
|
||||||
|
PRINT 'Found: no tables to reindex';
|
||||||
|
END;
|
||||||
|
|
||||||
END; ELSE BEGIN
|
END; ELSE BEGIN
|
||||||
IF (@LOGLEVEL in ('INFO')) BEGIN
|
IF (@LOGLEVEL in ('INFO')) BEGIN
|
||||||
SET @return_status_text = 'Skipping rebuilding database indexes!';
|
SET @return_status_text = 'Skipping rebuilding database indexes!';
|
||||||
@@ -444,12 +585,12 @@ BEGIN
|
|||||||
IF ((@LOGLEVEL in ('INFO','WARN')) and (@return_status is not null) and (@return_status_text is not null)) 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
|
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])
|
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, @MyProcedureName, GetDate());
|
||||||
END;
|
END;
|
||||||
END;
|
END;
|
||||||
-----------------------------------------------------------------------------------------------------------------------------
|
-----------------------------------------------------------------------------------------------------------------------------
|
||||||
|
|
||||||
IF ((@REBUILDINDEX = 1) and (@return_status = 0) and (SELECT COUNT(*) FROM #TableList) > 0) BEGIN
|
IF ((@REBUILDINDEX = 1) and (@return_status = 0) and (@TableListCount > 0)) BEGIN
|
||||||
|
|
||||||
DECLARE table_cursor CURSOR STATIC LOCAL FOR
|
DECLARE table_cursor CURSOR STATIC LOCAL FOR
|
||||||
SELECT SchemaName, TableName FROM #TableList;
|
SELECT SchemaName, TableName FROM #TableList;
|
||||||
@@ -458,6 +599,7 @@ BEGIN
|
|||||||
FETCH NEXT FROM table_cursor INTO @SchemaName, @TableName;
|
FETCH NEXT FROM table_cursor INTO @SchemaName, @TableName;
|
||||||
WHILE @@FETCH_STATUS = 0 BEGIN
|
WHILE @@FETCH_STATUS = 0 BEGIN
|
||||||
BEGIN TRY
|
BEGIN TRY
|
||||||
|
|
||||||
PRINT 'Rebuild Index for table: ' + CONVERT(VARCHAR(1000),@TableName);
|
PRINT 'Rebuild Index for table: ' + CONVERT(VARCHAR(1000),@TableName);
|
||||||
SET @SQLCommand = 'ALTER INDEX ALL ON [' + @DBName + '].[' + @SchemaName + '].[' + @TableName + '] ' +
|
SET @SQLCommand = 'ALTER INDEX ALL ON [' + @DBName + '].[' + @SchemaName + '].[' + @TableName + '] ' +
|
||||||
'REBUILD WITH (FILLFACTOR = 80, SORT_IN_TEMPDB = ON, STATISTICS_NORECOMPUTE = ON)';
|
'REBUILD WITH (FILLFACTOR = 80, SORT_IN_TEMPDB = ON, STATISTICS_NORECOMPUTE = ON)';
|
||||||
@@ -475,11 +617,82 @@ BEGIN
|
|||||||
IF ((@LOGLEVEL in ('INFO','WARN')) and (@return_status is not null) and (@return_status_text is not null)) 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
|
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])
|
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, 'table_cursor', @DBName, @return_status, @return_status_text, @MyProcedureName, GetDate());
|
||||||
END;
|
END;
|
||||||
END;
|
END;
|
||||||
-----------------------------------------------------------------------------------------------------------------------------
|
-----------------------------------------------------------------------------------------------------------------------------
|
||||||
|
|
||||||
|
-- Short break to avoid access violations
|
||||||
|
WAITFOR DELAY '00:00:03';
|
||||||
|
|
||||||
|
-----------------------------------------------------------------------------------------------------------------------------
|
||||||
|
PRINT 'Closing active database connections... again';
|
||||||
|
DECLARE kill_cursor CURSOR STATIC LOCAL FOR
|
||||||
|
SELECT CONVERT(NVARCHAR(5), [session_id]) as 'SessionID',
|
||||||
|
CONVERT(NVARCHAR(50), [login_name]) as 'LoginName',
|
||||||
|
CONVERT(NVARCHAR(50), [host_name]) as 'HostName'
|
||||||
|
FROM [master].[sys].[dm_exec_sessions] (NOLOCK)
|
||||||
|
WHERE [is_user_process] = 1
|
||||||
|
AND [database_id] = db_id(@DBName)
|
||||||
|
AND [session_id] <> @MySessionID;
|
||||||
|
|
||||||
|
OPEN kill_cursor;
|
||||||
|
FETCH NEXT FROM kill_cursor INTO @SessionID, @LoginName, @HostName;
|
||||||
|
WHILE @@FETCH_STATUS = 0 BEGIN
|
||||||
|
|
||||||
|
BEGIN TRY
|
||||||
|
|
||||||
|
SET @SQLCommand = 'KILL ' + @SessionID + ';';
|
||||||
|
PRINT 'Killing @SessionID: ' + @SessionID + ', @LoginName: ' + @LoginName + ', @HostName: ' + @HostName;
|
||||||
|
EXEC sp_executesql @SQLCommand;
|
||||||
|
SET @SQLCommand = NULL;
|
||||||
|
|
||||||
|
IF ((@LOGLEVEL in ('INFO')) and (@return_status = 0)) BEGIN
|
||||||
|
SET @return_status_text = 'Closing connections to database was successfully completed!';
|
||||||
|
PRINT @return_status_text;
|
||||||
|
END; ELSE IF ((@LOGLEVEL in ('WARN')) and (@return_status <> 0)) BEGIN
|
||||||
|
SET @return_status_text = 'Closing connections to database 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, 'kill_cursor', @DBName, @return_status, @return_status_text, @MyProcedureName, GetDate());
|
||||||
|
END;
|
||||||
|
END;
|
||||||
|
-----------------------------------------------------------------------------------------------------------------------------
|
||||||
|
|
||||||
|
END TRY
|
||||||
|
BEGIN CATCH
|
||||||
|
|
||||||
|
-- Handle any errors that occur during the process.
|
||||||
|
SELECT ERROR_MESSAGE() AS ErrorMessage;
|
||||||
|
|
||||||
|
SET @SQLCommand = NULL;
|
||||||
|
|
||||||
|
--===============================================-- Log result to table --=================================================--
|
||||||
|
IF ((@LOGLEVEL is not null) 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], [ADDED_WHO], [ADDED_WHEN])
|
||||||
|
VALUES ('ERROR', 'kill_cursor', @DBName, ERROR_MESSAGE(),@MyProcedureName, GetDate());
|
||||||
|
END;
|
||||||
|
END;
|
||||||
|
-----------------------------------------------------------------------------------------------------------------------------
|
||||||
|
|
||||||
|
END CATCH;
|
||||||
|
|
||||||
|
FETCH NEXT FROM kill_cursor INTO @SessionID, @LoginName, @HostName;
|
||||||
|
|
||||||
|
END;
|
||||||
|
|
||||||
|
CLOSE kill_cursor;
|
||||||
|
DEALLOCATE kill_cursor;
|
||||||
|
-----------------------------------------------------------------------------------------------------------------------------
|
||||||
|
|
||||||
|
FETCH NEXT FROM table_cursor INTO @SchemaName, @TableName;
|
||||||
|
|
||||||
END TRY
|
END TRY
|
||||||
BEGIN CATCH
|
BEGIN CATCH
|
||||||
|
|
||||||
@@ -490,15 +703,15 @@ BEGIN
|
|||||||
IF (@LOGLEVEL in ('INFO','WARN','ERROR')) BEGIN
|
IF (@LOGLEVEL in ('INFO','WARN','ERROR')) BEGIN
|
||||||
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
|
||||||
INSERT INTO [TBDD_MAINTAIN_DATABASES_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [ADDED_WHO], [ADDED_WHEN])
|
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());
|
VALUES ('ERROR', 'table_cursor', @DBName, ERROR_MESSAGE(),@MyProcedureName, GetDate());
|
||||||
END;
|
END;
|
||||||
END;
|
END;
|
||||||
-----------------------------------------------------------------------------------------------------------------------------
|
-----------------------------------------------------------------------------------------------------------------------------
|
||||||
|
|
||||||
END CATCH;
|
|
||||||
|
|
||||||
FETCH NEXT FROM table_cursor INTO @SchemaName, @TableName;
|
FETCH NEXT FROM table_cursor INTO @SchemaName, @TableName;
|
||||||
|
|
||||||
|
END CATCH;
|
||||||
|
|
||||||
END;
|
END;
|
||||||
|
|
||||||
CLOSE table_cursor;
|
CLOSE table_cursor;
|
||||||
@@ -522,7 +735,198 @@ BEGIN
|
|||||||
IF ((@LOGLEVEL in ('INFO','WARN')) and (@return_status is not null) and (@return_status_text is not null)) 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
|
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])
|
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, @MyProcedureName, GetDate());
|
||||||
|
END;
|
||||||
|
END;
|
||||||
|
-----------------------------------------------------------------------------------------------------------------------------
|
||||||
|
|
||||||
|
--=========================================-- Prepare to recompile Procedures --===========================================--
|
||||||
|
IF ((@RECOMPILEPROCEDURES = 1) and (@return_status = 0)) BEGIN
|
||||||
|
PRINT 'Prepare to recompile database procedures.';
|
||||||
|
|
||||||
|
BEGIN TRY
|
||||||
|
DROP TABLE #ProcedureList;
|
||||||
|
END TRY
|
||||||
|
BEGIN CATCH
|
||||||
|
PRINT '#ProcedureList Temp table is already gone... (1)';
|
||||||
|
END CATCH;
|
||||||
|
|
||||||
|
-- Create a temporary table to hold the procedure names
|
||||||
|
CREATE TABLE #ProcedureList (SchemaName NVARCHAR(50), ProcedureName NVARCHAR(256));
|
||||||
|
|
||||||
|
-- Set the context to the specified database and fill the temporary table
|
||||||
|
SET @SQLCommand = ' INSERT INTO #ProcedureList (SchemaName, ProcedureName)
|
||||||
|
SELECT SPECIFIC_CATALOG, SPECIFIC_NAME
|
||||||
|
FROM [' + @DBName + '].INFORMATION_SCHEMA.ROUTINES (NOLOCK)
|
||||||
|
WHERE ROUTINE_TYPE = ''PROCEDURE''
|
||||||
|
AND SPECIFIC_NAME <> ''' + @MyProcedureName + '''
|
||||||
|
ORDER BY SPECIFIC_NAME;';
|
||||||
|
EXEC @return_status = sp_executesql @SQLCommand;
|
||||||
|
|
||||||
|
IF ((@LOGLEVEL in ('INFO')) and (@return_status = 0)) BEGIN
|
||||||
|
SET @return_status_text = 'Getting the procedures was successfully done!';
|
||||||
|
PRINT @return_status_text;
|
||||||
|
END; ELSE IF ((@LOGLEVEL in ('WARN')) and (@return_status <> 0)) BEGIN
|
||||||
|
SET @return_status_text = 'Getting the procedures returns warnings or has failed, check the ID!';
|
||||||
|
PRINT @return_status_text;
|
||||||
|
END;
|
||||||
|
|
||||||
|
IF (@return_status = 0) BEGIN
|
||||||
|
SELECT @ProcedureListCount = COUNT(*) FROM #ProcedureList;
|
||||||
|
PRINT 'Found: ' + convert(VARCHAR,@ProcedureListCount) + ' procedures to recompile';
|
||||||
|
END; ELSE BEGIN
|
||||||
|
SET @ProcedureListCount = 0;
|
||||||
|
PRINT 'Found: no procedures to recompile';
|
||||||
|
END;
|
||||||
|
|
||||||
|
END; ELSE BEGIN
|
||||||
|
IF (@LOGLEVEL in ('INFO')) BEGIN
|
||||||
|
SET @return_status_text = 'Skipping recompiling procedures!';
|
||||||
|
PRINT @return_status_text;
|
||||||
|
END;
|
||||||
|
END;
|
||||||
|
-----------------------------------------------------------------------------------------------------------------------------
|
||||||
|
|
||||||
|
--===============================================-- Log result to table --=================================================--
|
||||||
|
IF ((@LOGLEVEL in ('INFO','WARN')) and (@return_status is not null) and (@return_status_text is not null)) BEGIN
|
||||||
|
IF EXISTS (SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = N'TBDD_MAINTAIN_DATABASES_LOG') BEGIN
|
||||||
|
INSERT INTO [TBDD_MAINTAIN_DATABASES_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN])
|
||||||
|
VALUES (@LOGLEVEL, 'db_cursor', @DBName, @return_status, @return_status_text, @MyProcedureName, GetDate());
|
||||||
|
END;
|
||||||
|
END;
|
||||||
|
-----------------------------------------------------------------------------------------------------------------------------
|
||||||
|
|
||||||
|
--===============================================-- Recompile Procedures --================================================--
|
||||||
|
IF ((@RECOMPILEPROCEDURES = 1) and (@return_status = 0) and (@ProcedureListCount > 0)) BEGIN
|
||||||
|
|
||||||
|
PRINT 'Removing all procedure elements from the query plan cache.';
|
||||||
|
SET @SQLCommand = N'USE [' + @DBName + ']; DBCC FREEPROCCACHE;';
|
||||||
|
EXEC @return_status = sp_executesql @SQLCommand;
|
||||||
|
|
||||||
|
IF ((@LOGLEVEL in ('INFO')) and (@return_status = 0)) BEGIN
|
||||||
|
SET @return_status_text = 'Removing all procedure elements was successfully completed!';
|
||||||
|
PRINT @return_status_text;
|
||||||
|
END; ELSE IF ((@LOGLEVEL in ('WARN')) and (@return_status <> 0)) BEGIN
|
||||||
|
SET @return_status_text = 'Removing all procedure elements 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, 'procedure_cursor', @DBName, @return_status, @return_status_text, @MyProcedureName, GetDate());
|
||||||
|
END;
|
||||||
|
END;
|
||||||
|
-----------------------------------------------------------------------------------------------------------------------------
|
||||||
|
|
||||||
|
DECLARE procedure_cursor CURSOR STATIC LOCAL FOR
|
||||||
|
SELECT SchemaName, ProcedureName FROM #ProcedureList;
|
||||||
|
|
||||||
|
OPEN procedure_cursor;
|
||||||
|
FETCH NEXT FROM procedure_cursor INTO @SchemaName, @ProcedureName;
|
||||||
|
WHILE @@FETCH_STATUS = 0 BEGIN
|
||||||
|
BEGIN TRY
|
||||||
|
|
||||||
|
PRINT 'Recompile procedure: ' + CONVERT(VARCHAR(1000),@ProcedureName);
|
||||||
|
SET @SQLCommand = 'USE [' + @DBName + ']; EXEC sp_recompile ''' + @ProcedureName + '''; ';
|
||||||
|
EXEC @return_status = sp_executesql @SQLCommand;
|
||||||
|
|
||||||
|
IF ((@LOGLEVEL in ('INFO')) and (@return_status = 0)) BEGIN
|
||||||
|
SET @return_status_text = 'Recompiling the procedure [' + @ProcedureName + '] successfully completed!';
|
||||||
|
PRINT @return_status_text;
|
||||||
|
END; ELSE IF ((@LOGLEVEL in ('WARN')) and (@return_status <> 0)) BEGIN
|
||||||
|
SET @return_status_text = 'Recompiling the procedure [' + @ProcedureName + '] 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, 'procedure_cursor', @DBName, @return_status, @return_status_text, @MyProcedureName, GetDate());
|
||||||
|
END;
|
||||||
|
END;
|
||||||
|
-----------------------------------------------------------------------------------------------------------------------------
|
||||||
|
|
||||||
|
FETCH NEXT FROM procedure_cursor INTO @SchemaName, @ProcedureName;
|
||||||
|
|
||||||
|
END TRY
|
||||||
|
BEGIN CATCH
|
||||||
|
|
||||||
|
-- Handle any errors that occur during the process.
|
||||||
|
SELECT ERROR_MESSAGE() AS ErrorMessage;
|
||||||
|
|
||||||
|
--================================================-- Log error to table --=================================================--
|
||||||
|
IF (@LOGLEVEL in ('INFO','WARN','ERROR')) BEGIN
|
||||||
|
IF EXISTS (SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = N'TBDD_MAINTAIN_DATABASES_LOG') BEGIN
|
||||||
|
INSERT INTO [TBDD_MAINTAIN_DATABASES_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [ADDED_WHO], [ADDED_WHEN])
|
||||||
|
VALUES ('ERROR', 'procedure_cursor', @DBName, ERROR_MESSAGE(),@MyProcedureName, GetDate());
|
||||||
|
END;
|
||||||
|
END;
|
||||||
|
-----------------------------------------------------------------------------------------------------------------------------
|
||||||
|
|
||||||
|
FETCH NEXT FROM procedure_cursor INTO @SchemaName, @ProcedureName;
|
||||||
|
|
||||||
|
END CATCH;
|
||||||
|
|
||||||
|
END;
|
||||||
|
|
||||||
|
CLOSE procedure_cursor;
|
||||||
|
DEALLOCATE procedure_cursor;
|
||||||
|
|
||||||
|
-- Drop the temporary table
|
||||||
|
DROP TABLE #ProcedureList;
|
||||||
|
|
||||||
|
SET @return_status_text = 'Recompiling of procedures successfully completed!';
|
||||||
|
PRINT @return_status_text;
|
||||||
|
|
||||||
|
END; ELSE BEGIN
|
||||||
|
IF (@LOGLEVEL in ('INFO')) BEGIN
|
||||||
|
SET @return_status_text = 'Skipping the recompiling of the procedures!';
|
||||||
|
PRINT @return_status_text;
|
||||||
|
END;
|
||||||
|
END;
|
||||||
|
-----------------------------------------------------------------------------------------------------------------------------
|
||||||
|
|
||||||
|
--===============================================-- Log result to table --=================================================--
|
||||||
|
IF ((@LOGLEVEL in ('INFO','WARN')) and (@return_status is not null) and (@return_status_text is not null)) BEGIN
|
||||||
|
IF EXISTS (SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = N'TBDD_MAINTAIN_DATABASES_LOG') BEGIN
|
||||||
|
INSERT INTO [TBDD_MAINTAIN_DATABASES_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN])
|
||||||
|
VALUES (@LOGLEVEL, 'procedure_cursor', @DBName, @return_status, @return_status_text, @MyProcedureName, GetDate());
|
||||||
|
END;
|
||||||
|
END;
|
||||||
|
-----------------------------------------------------------------------------------------------------------------------------
|
||||||
|
|
||||||
|
--================================================-- Clear Query Cache --==================================================--
|
||||||
|
|
||||||
|
IF ((@CLEARQUERYCACHE = 1) and (@return_status = 0)) BEGIN
|
||||||
|
|
||||||
|
PRINT 'Removing the sql query cache.';
|
||||||
|
SET @SQLCommand = N'USE [' + @DBName + ']; DBCC DROPCLEANBUFFERS;';
|
||||||
|
EXEC @return_status = sp_executesql @SQLCommand;
|
||||||
|
|
||||||
|
IF ((@LOGLEVEL in ('INFO')) and (@return_status = 0)) BEGIN
|
||||||
|
SET @return_status_text = 'Removing sql query cache was successfully completed!';
|
||||||
|
PRINT @return_status_text;
|
||||||
|
END; ELSE IF ((@LOGLEVEL in ('WARN')) and (@return_status <> 0)) BEGIN
|
||||||
|
SET @return_status_text = 'Removing sql query cache returns warnings or has failed, check the ID!';
|
||||||
|
PRINT @return_status_text;
|
||||||
|
END;
|
||||||
|
|
||||||
|
END; ELSE BEGIN
|
||||||
|
IF (@LOGLEVEL in ('INFO')) BEGIN
|
||||||
|
SET @return_status_text = 'Skipping the query cache clearing!';
|
||||||
|
PRINT @return_status_text;
|
||||||
|
END;
|
||||||
|
END;
|
||||||
|
-----------------------------------------------------------------------------------------------------------------------------
|
||||||
|
|
||||||
|
--===============================================-- Log result to table --=================================================--
|
||||||
|
IF ((@LOGLEVEL in ('INFO','WARN')) and (@return_status is not null) and (@return_status_text is not null)) BEGIN
|
||||||
|
IF EXISTS (SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = N'TBDD_MAINTAIN_DATABASES_LOG') BEGIN
|
||||||
|
INSERT INTO [TBDD_MAINTAIN_DATABASES_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN])
|
||||||
|
VALUES (@LOGLEVEL, 'db_cursor', @DBName, @return_status, @return_status_text, @MyProcedureName, GetDate());
|
||||||
END;
|
END;
|
||||||
END;
|
END;
|
||||||
-----------------------------------------------------------------------------------------------------------------------------
|
-----------------------------------------------------------------------------------------------------------------------------
|
||||||
@@ -530,7 +934,7 @@ BEGIN
|
|||||||
--==============================================-- Change db working mode --===============================================--
|
--==============================================-- Change db working mode --===============================================--
|
||||||
IF (@FORCE = 1) BEGIN -- and ignore last result
|
IF (@FORCE = 1) BEGIN -- and ignore last result
|
||||||
PRINT 'Set the database back to MULTI_USER mode';
|
PRINT 'Set the database back to MULTI_USER mode';
|
||||||
SET @SQLCommand = N'ALTER DATABASE [' + @DBName + '] SET MULTI_USER';
|
SET @SQLCommand = N'ALTER DATABASE [' + @DBName + '] SET MULTI_USER; ALTER DATABASE [' + @DBName + '] SET ONLINE;';
|
||||||
EXEC @return_status = sp_executesql @SQLCommand;
|
EXEC @return_status = sp_executesql @SQLCommand;
|
||||||
|
|
||||||
IF ((@LOGLEVEL in ('INFO')) and (@return_status = 0)) BEGIN
|
IF ((@LOGLEVEL in ('INFO')) and (@return_status = 0)) BEGIN
|
||||||
@@ -552,7 +956,7 @@ BEGIN
|
|||||||
IF ((@LOGLEVEL in ('INFO','WARN')) and (@return_status is not null) and (@return_status_text is not null)) 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
|
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])
|
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, @MyProcedureName, GetDate());
|
||||||
END;
|
END;
|
||||||
END;
|
END;
|
||||||
-----------------------------------------------------------------------------------------------------------------------------
|
-----------------------------------------------------------------------------------------------------------------------------
|
||||||
@@ -562,17 +966,40 @@ BEGIN
|
|||||||
DROP TABLE #DBList;
|
DROP TABLE #DBList;
|
||||||
END TRY
|
END TRY
|
||||||
BEGIN CATCH
|
BEGIN CATCH
|
||||||
PRINT '#DBList Temp table are already gone...'
|
PRINT '#DBList Temp table are already gone...';
|
||||||
END CATCH;
|
END CATCH;
|
||||||
|
|
||||||
|
IF (@REBUILDINDEX = 1) BEGIN
|
||||||
|
|
||||||
BEGIN TRY
|
BEGIN TRY
|
||||||
DROP TABLE #TableList;
|
DROP TABLE #TableList;
|
||||||
END TRY
|
END TRY
|
||||||
BEGIN CATCH
|
BEGIN CATCH
|
||||||
PRINT '#TableList Temp table are already gone...(2)'
|
PRINT '#TableList Temp table are already gone...(1)';
|
||||||
END CATCH;
|
END CATCH;
|
||||||
|
|
||||||
PRINT '-------------------------------'
|
END;
|
||||||
|
|
||||||
|
IF (@RECOMPILEPROCEDURES = 1) BEGIN
|
||||||
|
|
||||||
|
BEGIN TRY
|
||||||
|
DROP TABLE #ProcedureList;
|
||||||
|
END TRY
|
||||||
|
BEGIN CATCH
|
||||||
|
PRINT '#ProcedureList Temp table are already gone...(1)';
|
||||||
|
END CATCH;
|
||||||
|
|
||||||
|
BEGIN TRY
|
||||||
|
CLOSE procedure_cursor;
|
||||||
|
DEALLOCATE procedure_cursor;
|
||||||
|
END TRY
|
||||||
|
BEGIN CATCH
|
||||||
|
PRINT 'Procedure cursor is already closed and deallocated...(1)';
|
||||||
|
END CATCH;
|
||||||
|
|
||||||
|
END;
|
||||||
|
|
||||||
|
PRINT '-------------------------------';
|
||||||
|
|
||||||
END TRY
|
END TRY
|
||||||
BEGIN CATCH
|
BEGIN CATCH
|
||||||
@@ -583,7 +1010,7 @@ BEGIN
|
|||||||
IF (@LOGLEVEL in ('INFO','WARN','ERROR')) BEGIN
|
IF (@LOGLEVEL in ('INFO','WARN','ERROR')) BEGIN
|
||||||
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
|
||||||
INSERT INTO [TBDD_MAINTAIN_DATABASES_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [ADDED_WHO], [ADDED_WHEN])
|
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());
|
VALUES ('ERROR', 'db_cursor', @DBName, ERROR_MESSAGE(),@MyProcedureName,GetDate());
|
||||||
END;
|
END;
|
||||||
END;
|
END;
|
||||||
-----------------------------------------------------------------------------------------------------------------------------
|
-----------------------------------------------------------------------------------------------------------------------------
|
||||||
@@ -593,7 +1020,7 @@ BEGIN
|
|||||||
--==============================================-- Change db working mode --===============================================--
|
--==============================================-- Change db working mode --===============================================--
|
||||||
IF (@FORCE = 1) BEGIN -- and ignore last result
|
IF (@FORCE = 1) BEGIN -- and ignore last result
|
||||||
PRINT 'Set the database back to MULTI_USER mode';
|
PRINT 'Set the database back to MULTI_USER mode';
|
||||||
SET @SQLCommand = N'ALTER DATABASE [' + @DBName + '] SET MULTI_USER';
|
SET @SQLCommand = N'ALTER DATABASE [' + @DBName + '] SET MULTI_USER; ALTER DATABASE [' + @DBName + '] SET ONLINE;';
|
||||||
EXEC @return_status = sp_executesql @SQLCommand;
|
EXEC @return_status = sp_executesql @SQLCommand;
|
||||||
|
|
||||||
IF ((@LOGLEVEL in ('INFO')) and (@return_status = 0)) BEGIN
|
IF ((@LOGLEVEL in ('INFO')) and (@return_status = 0)) BEGIN
|
||||||
@@ -615,7 +1042,7 @@ BEGIN
|
|||||||
IF ((@LOGLEVEL in ('INFO','WARN')) and (@return_status is not null) and (@return_status_text is not null)) 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
|
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])
|
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, @MyProcedureName, GetDate());
|
||||||
END;
|
END;
|
||||||
END;
|
END;
|
||||||
-----------------------------------------------------------------------------------------------------------------------------
|
-----------------------------------------------------------------------------------------------------------------------------
|
||||||
@@ -626,18 +1053,46 @@ BEGIN
|
|||||||
DROP TABLE #DBList;
|
DROP TABLE #DBList;
|
||||||
END TRY
|
END TRY
|
||||||
BEGIN CATCH
|
BEGIN CATCH
|
||||||
PRINT '#DBList Temp table are already gone...'
|
PRINT '#DBList Temp table are already gone...';
|
||||||
END CATCH;
|
END CATCH;
|
||||||
|
|
||||||
|
IF (@REBUILDINDEX = 1) BEGIN
|
||||||
|
|
||||||
BEGIN TRY
|
BEGIN TRY
|
||||||
DROP TABLE #TableList;
|
DROP TABLE #TableList;
|
||||||
END TRY
|
END TRY
|
||||||
BEGIN CATCH
|
BEGIN CATCH
|
||||||
PRINT '#TableList Temp table are already gone...(3)'
|
PRINT '#TableList Temp table are already gone...(2)';
|
||||||
END CATCH;
|
END CATCH;
|
||||||
|
|
||||||
CLOSE table_cursor
|
BEGIN TRY
|
||||||
DEALLOCATE table_cursor
|
CLOSE table_cursor;
|
||||||
|
DEALLOCATE table_cursor;
|
||||||
|
END TRY
|
||||||
|
BEGIN CATCH
|
||||||
|
PRINT 'Table cursor is already closed and deallocated...(2)';
|
||||||
|
END CATCH;
|
||||||
|
|
||||||
|
END;
|
||||||
|
|
||||||
|
IF (@RECOMPILEPROCEDURES = 1) BEGIN
|
||||||
|
|
||||||
|
BEGIN TRY
|
||||||
|
DROP TABLE #ProcedureList;
|
||||||
|
END TRY
|
||||||
|
BEGIN CATCH
|
||||||
|
PRINT '#ProcedureList Temp table are already gone...(2)';
|
||||||
|
END CATCH;
|
||||||
|
|
||||||
|
BEGIN TRY
|
||||||
|
CLOSE procedure_cursor;
|
||||||
|
DEALLOCATE procedure_cursor;
|
||||||
|
END TRY
|
||||||
|
BEGIN CATCH
|
||||||
|
PRINT 'Procedure cursor is already closed and deallocated...(2)';
|
||||||
|
END CATCH;
|
||||||
|
|
||||||
|
END;
|
||||||
-----------------------------------------------------------------------------------------------------------------------------
|
-----------------------------------------------------------------------------------------------------------------------------
|
||||||
|
|
||||||
END CATCH;
|
END CATCH;
|
||||||
@@ -646,8 +1101,13 @@ BEGIN
|
|||||||
|
|
||||||
END;
|
END;
|
||||||
|
|
||||||
CLOSE db_cursor
|
CLOSE db_cursor;
|
||||||
DEALLOCATE db_cursor
|
DEALLOCATE db_cursor;
|
||||||
|
|
||||||
|
END; ELSE BEGIN
|
||||||
|
PRINT '';
|
||||||
|
PRINT 'So there is nothing to do...';
|
||||||
|
END;
|
||||||
-----------------------------------------------------------------------------------------------------------------------------
|
-----------------------------------------------------------------------------------------------------------------------------
|
||||||
|
|
||||||
SET @return_status_text = 'END [PRDD_MAINTAIN_DATABASES] @ ' + CONVERT(varchar(50),GETDATE(),120);
|
SET @return_status_text = 'END [PRDD_MAINTAIN_DATABASES] @ ' + CONVERT(varchar(50),GETDATE(),120);
|
||||||
@@ -656,13 +1116,13 @@ BEGIN
|
|||||||
IF ((@LOGLEVEL in ('INFO')) and (@return_status is not null) and (@return_status_text is not null)) 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
|
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])
|
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());
|
VALUES (@LOGLEVEL, 'closing', 'procedure', @return_status, @return_status_text, @MyProcedureName, GetDate());
|
||||||
END;
|
END;
|
||||||
END;
|
END;
|
||||||
-----------------------------------------------------------------------------------------------------------------------------
|
-----------------------------------------------------------------------------------------------------------------------------
|
||||||
|
|
||||||
PRINT '';
|
PRINT '';
|
||||||
PRINT 'PROCEDURE - END [PRDD_MAINTAIN_DATABASES] @ ' + CONVERT(varchar(50),GETDATE(),120);
|
PRINT 'PROCEDURE - ' + @return_status_text;
|
||||||
PRINT '===============================';
|
PRINT '===============================';
|
||||||
|
|
||||||
Return @return_status;
|
Return @return_status;
|
||||||
|
|||||||
Reference in New Issue
Block a user