Maintain and add new SQL Procedures
This commit is contained in:
@@ -1,3 +1,8 @@
|
||||
SET ANSI_NULLS ON
|
||||
GO
|
||||
SET QUOTED_IDENTIFIER ON
|
||||
GO
|
||||
|
||||
-- [PRDD_MAINTAIN_DATABASES]
|
||||
-- =================================================================
|
||||
-- Checks database health, shrinks all database and log files
|
||||
@@ -12,17 +17,13 @@
|
||||
-- Tel.: 0641/202360 • E-Mail: info-flow@digitaldata.works
|
||||
-- =================================================================
|
||||
-- Creation Date / Author: 29.11.2024 / MK
|
||||
-- Version Date / Editor: 06.12.2024 / MK
|
||||
-- Version Number: 1.1.0.0
|
||||
-- Version Date / Editor: 13.12.2024 / MK
|
||||
-- Version Number: 1.1.0.1
|
||||
-- =================================================================
|
||||
-- History:
|
||||
-- 29.11.2024 / MK - First Version
|
||||
-- 06.12.2024 / MK - Added "SET ONLINE" after forced SINGLE_USER Mode, Added repair parameter for DBCHECK, added @pRECOMPILEPROCEDURES, some minor error fixes
|
||||
|
||||
SET ANSI_NULLS ON
|
||||
GO
|
||||
SET QUOTED_IDENTIFIER ON
|
||||
GO
|
||||
-- 13.12.2024 / MK - New way the get the procedure name, failsafe for parameters implemented
|
||||
|
||||
CREATE OR ALTER PROCEDURE [dbo].[PRDD_MAINTAIN_DATABASES] (
|
||||
@pCHECKDB BIT = 1, -- Set to 1 to make a check of the database before shrinking incl. soft repair function. Otherwise set to 0.
|
||||
@@ -43,19 +44,19 @@ BEGIN
|
||||
SET NOCOUNT ON;
|
||||
|
||||
-- declare new vars because of parameter sniffing
|
||||
DECLARE @CHECKDB BIT = @pCHECKDB,
|
||||
@SHRINKLOG BIT = @pSHRINKLOG,
|
||||
@SHRINKDB BIT = @pSHRINKDB,
|
||||
@REBUILDINDEX BIT = @pREBUILDINDEX,
|
||||
@RECOMPILEPROCEDURES BIT = @pRECOMPILEPROCEDURES,
|
||||
@CLEARQUERYCACHE BIT = @pCLEARQUERYCACHE,
|
||||
@FORCE BIT = @pFORCE,
|
||||
@INCLUDEDB NVARCHAR(1000) = @pINCLUDEDB,
|
||||
@EXCLUDEDB NVARCHAR(1000) = @pEXCLUDEDB,
|
||||
@LOGLEVEL NVARCHAR(25) = @pLOGLEVEL;
|
||||
DECLARE @CHECKDB BIT = ISNULL(@pCHECKDB,1),
|
||||
@SHRINKLOG BIT = ISNULL(@pSHRINKLOG,1),
|
||||
@SHRINKDB BIT = ISNULL(@pSHRINKDB,0),
|
||||
@REBUILDINDEX BIT = ISNULL(@pREBUILDINDEX,0),
|
||||
@RECOMPILEPROCEDURES BIT = ISNULL(@pRECOMPILEPROCEDURES,0),
|
||||
@CLEARQUERYCACHE BIT = ISNULL(@pCLEARQUERYCACHE,0),
|
||||
@FORCE BIT = ISNULL(@pFORCE,0),
|
||||
@INCLUDEDB NVARCHAR(1000) = LTRIM(RTRIM(ISNULL(@pINCLUDEDB,DB_NAME()))),
|
||||
@EXCLUDEDB NVARCHAR(1000) = LTRIM(RTRIM(ISNULL(@pEXCLUDEDB,'master,model,msdb,tempdb'))),
|
||||
@LOGLEVEL NVARCHAR(25) = LTRIM(RTRIM(ISNULL(@pLOGLEVEL,'ERROR')));
|
||||
|
||||
-- declare runtime vars
|
||||
DECLARE @MyProcedureName NVARCHAR(50) = 'PRDD_MAINTAIN_DATABASES';
|
||||
DECLARE @MyProcedureName NVARCHAR(128) = OBJECT_NAME(@@PROCID);
|
||||
DECLARE @ProcedureName NVARCHAR(50),
|
||||
@DBName NVARCHAR(100),
|
||||
@DBNameCount INT,
|
||||
@@ -1105,8 +1106,20 @@ BEGIN
|
||||
DEALLOCATE db_cursor;
|
||||
|
||||
END; ELSE BEGIN
|
||||
PRINT '';
|
||||
PRINT 'So there is nothing to do...';
|
||||
|
||||
SET @return_status = 0;
|
||||
SET @return_status_text = 'So there is nothing to do...';
|
||||
PRINT @return_status_text;
|
||||
|
||||
--===============================================-- Log result to table --=================================================--
|
||||
IF ((@LOGLEVEL in ('INFO','WARN','ERROR')) and (@return_status is not null) and (@return_status_text is not null)) BEGIN
|
||||
IF EXISTS (SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = N'TBDD_MAINTAIN_DATABASES_LOG') BEGIN
|
||||
INSERT INTO [TBDD_MAINTAIN_DATABASES_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN])
|
||||
VALUES ('WARN', 'db_list', 'count', @return_status, @return_status_text, @MyProcedureName, GetDate());
|
||||
END;
|
||||
END;
|
||||
-----------------------------------------------------------------------------------------------------------------------------
|
||||
|
||||
END;
|
||||
-----------------------------------------------------------------------------------------------------------------------------
|
||||
|
||||
@@ -1127,4 +1140,4 @@ BEGIN
|
||||
|
||||
Return @return_status;
|
||||
|
||||
END;
|
||||
END;
|
||||
Reference in New Issue
Block a user