8
0
Files
Skriptentwickung/current/[DD_ECM]-Database/DEX_SQL/[PRDEX_CHECK_SYSTEM].sql
2026-02-24 16:43:48 +01:00

343 lines
38 KiB
Transact-SQL
Raw Blame History

This file contains invisible Unicode characters
This file contains invisible Unicode characters that are indistinguishable to humans but may be processed differently by a computer. If you think that this is intentional, you can safely ignore this warning. Use the Escape button to reveal them.
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
-- [PRDEX_CHECK_SYSTEM]
-- =================================================================
-- Checks if all requirements for DEX are given.
-- In case of db objects changed, search for "Define all needed objects".
--
-- Returns: INTEGER; 0 = ok; 0 <> nicht ok
-- =================================================================
-- Copyright (c) 2025 by Digital Data GmbH
--
-- Digital Data GmbH • Ludwig-Rinn-Strasse 16 • D-35452 Heuchelheim
-- Tel.: 0641/202360 • E-Mail: info-flow@digitaldata.works
-- =================================================================
-- Creation Date / Author: 01.08.2025 / MK
-- Version Date / Editor: 01.08.2025 / MK
-- Version Number: 1.0.0.0
-- =================================================================
-- History:
-- 01.08.2025 / MK - First Version
CREATE OR ALTER PROCEDURE [dbo].[PRDEX_CHECK_SYSTEM](
@pPROFILE_ID BIGINT,
@pBATCH_ID NVARCHAR(25) = NULL,
@pBATCH_CREATOR NVARCHAR(50) = NULL,
@pLOG_LEVEL NVARCHAR(25) = NULL
)
AS
BEGIN TRY
SET NOCOUNT ON;
-- declare new vars because of parameter sniffing
DECLARE @PROFILE_ID BIGINT = @pPROFILE_ID,
@BATCH_ID NVARCHAR(25) = ISNULL(@pBATCH_ID,'0'),
@BATCH_CREATOR NVARCHAR(128) = ISNULL(@pBATCH_CREATOR,OBJECT_NAME(@@PROCID)),
@LOG_LEVEL NVARCHAR(25) = ISNULL(UPPER(@pLOG_LEVEL),'INFO');
-- declare runtime vars
DECLARE @MY_PROCEDURE_NAME NVARCHAR(128) = OBJECT_NAME(@@PROCID);
DECLARE @ACTIVE_FLAG BIT = 1,
@INACTIVE_FLAG BIT = 0,
@SQL_VERSION_CURRENTLY INT = 0,
@SQL_VERSION_MINIMUM INT = 13,
@SQL_USER_PERMISSIONS INT = 0,
@DB_VERSION NVARCHAR(25) = NULL,
@MISSING_OBJECTS_LIST NVARCHAR(2000) = NULL,
@REFERENCE1 NVARCHAR(150) = NULL,
@REFERENCE2 NVARCHAR(150) = NULL,
@REFERENCE3 NVARCHAR(150) = NULL,
@REFERENCE4 NVARCHAR(150) = NULL,
@REFERENCE5 NVARCHAR(150) = NULL,
@MODULE_SHORT_NAME NVARCHAR(10) = 'DEX',
@RETURN_STATUS INT = 0,
@RETURN_STATUS_TEXT NVARCHAR(MAX) = concat('START PROCEDURE [',@MY_PROCEDURE_NAME,'] @ ',CONVERT(varchar(50),GETDATE(),120)),
@RETURN_ERROR_TEXT NVARCHAR(MAX) = '';
-- List of mandatory objects
DECLARE @REQUIRED_OBJECTS TABLE(DB_OBJECT_NAME NVARCHAR(128),DB_OBJECT_TYPE CHAR(2));
-- In-memory table for missing objects
DECLARE @MISSING_OBJECTS TABLE(DB_OBJECT_NAME NVARCHAR(128),DB_OBJECT_TYPE CHAR(2));
PRINT '====================================================================================================';
PRINT @RETURN_STATUS_TEXT;
PRINT '';
PRINT 'PARAMETER01 - @PROFILE_ID: ' + CONVERT(NVARCHAR(50),ISNULL(@PROFILE_ID,'<NO-VALUE>'));
PRINT 'PARAMETER02 - @BATCH_ID: ' + CONVERT(NVARCHAR(50),ISNULL(@BATCH_ID,'<NO-VALUE>'));
PRINT 'PARAMETER03 - @BATCH_CREATOR: ' + CONVERT(NVARCHAR(50),ISNULL(@BATCH_CREATOR,'<NO-VALUE>'));
PRINT 'PARAMETER04 - @LOG_LEVEL: ' + CONVERT(NVARCHAR(50),ISNULL(@LOG_LEVEL,'<NO-VALUE>'));
PRINT '';
--===================================================-- Log result to table --===================================================--
IF (@LOG_LEVEL in ('INFO')) BEGIN
EXEC [PRDEX_WRITE_LOG] @pLOG_LEVEL = N'INFO', @pPROFILE_ID = @PROFILE_ID, @pBATCH_ID = @BATCH_ID,
@pREFERENCE1 = @REFERENCE1, @pREFERENCE2 = @REFERENCE2, @pREFERENCE3 = @REFERENCE3,
@pREFERENCE4 = @REFERENCE4, @pREFERENCE5 = @REFERENCE5, @pRETURN_CODE = @RETURN_STATUS,
@pMESSAGE1 = @RETURN_STATUS_TEXT, @pMESSAGE2 = @RETURN_ERROR_TEXT, @pADDED_WHO = @MY_PROCEDURE_NAME;
END;
-----------------------------------------------------------------------------------------------------------------------------------
--=================================================-- Check sql server version --================================================--
SET @SQL_VERSION_CURRENTLY = ISNULL(CONVERT(INT, SERVERPROPERTY('ProductMajorVersion')),0);
IF (@SQL_VERSION_CURRENTLY < @SQL_VERSION_MINIMUM) BEGIN
--====================================================-- exception / error --====================================================--
SET @RETURN_STATUS = 50012;
SET @RETURN_STATUS_TEXT = concat('SQL Server Check','');
SET @RETURN_ERROR_TEXT = concat('Requires at least SQL Server - Major Version ',convert(VARCHAR(10),@SQL_VERSION_MINIMUM),' .');
THROW @RETURN_STATUS,@RETURN_ERROR_TEXT,1;
-----------------------------------------------------------------------------------------------------------------------------------
END; ELSE BEGIN
--======================================================-- Output result --======================================================--
SET @RETURN_STATUS = 0;
SET @RETURN_STATUS_TEXT = concat('SQL Server Version seems to fit: ','@SQL_VERSION_CURRENTLY: ' + CONVERT(NVARCHAR(50),@SQL_VERSION_CURRENTLY));
SET @RETURN_ERROR_TEXT = concat('','');
PRINT 'INFO: ' + @RETURN_STATUS_TEXT;
-----------------------------------------------------------------------------------------------------------------------------------
--===================================================-- Log result to table --===================================================--
IF (@LOG_LEVEL in ('INFO')) BEGIN
EXEC [PRDEX_WRITE_LOG] @pLOG_LEVEL = N'INFO', @pPROFILE_ID = @PROFILE_ID, @pBATCH_ID = @BATCH_ID,
@pREFERENCE1 = @REFERENCE1, @pREFERENCE2 = @REFERENCE2, @pREFERENCE3 = @REFERENCE3,
@pREFERENCE4 = @REFERENCE4, @pREFERENCE5 = @REFERENCE5, @pRETURN_CODE = @RETURN_STATUS,
@pMESSAGE1 = @RETURN_STATUS_TEXT, @pMESSAGE2 = @RETURN_ERROR_TEXT, @pADDED_WHO = @MY_PROCEDURE_NAME;
END;
-----------------------------------------------------------------------------------------------------------------------------------
END;
-----------------------------------------------------------------------------------------------------------------------------------
--==================================================-- Check sql user rights --==================================================
SET @SQL_USER_PERMISSIONS = ISNULL(HAS_PERMS_BY_NAME(DB_NAME(), 'DATABASE', 'CONTROL'),0);
IF (@SQL_USER_PERMISSIONS = 0) BEGIN
--======================================================-- Output result --======================================================--
SET @RETURN_STATUS = 50013;
SET @RETURN_STATUS_TEXT = concat('Permission Check','');
SET @RETURN_ERROR_TEXT = concat('User needs CONTROL rights on the database','');
THROW @RETURN_STATUS,@RETURN_ERROR_TEXT,1;
-----------------------------------------------------------------------------------------------------------------------------------
END; ELSE BEGIN
--======================================================-- Output result --======================================================--
SET @RETURN_STATUS = 0;
SET @RETURN_STATUS_TEXT = concat('SQL User Found has CONTROL rights on DB!','');
SET @RETURN_ERROR_TEXT = concat('','');
PRINT 'INFO: ' + @RETURN_STATUS_TEXT;
-----------------------------------------------------------------------------------------------------------------------------------
--===================================================-- Log result to table --===================================================--
IF (@LOG_LEVEL in ('INFO')) BEGIN
EXEC [PRDEX_WRITE_LOG] @pLOG_LEVEL = N'INFO', @pPROFILE_ID = @PROFILE_ID, @pBATCH_ID = @BATCH_ID,
@pREFERENCE1 = @REFERENCE1, @pREFERENCE2 = @REFERENCE2, @pREFERENCE3 = @REFERENCE3,
@pREFERENCE4 = @REFERENCE4, @pREFERENCE5 = @REFERENCE5, @pRETURN_CODE = @RETURN_STATUS,
@pMESSAGE1 = @RETURN_STATUS_TEXT, @pMESSAGE2 = @RETURN_ERROR_TEXT, @pADDED_WHO = @MY_PROCEDURE_NAME;
END;
END;
-----------------------------------------------------------------------------------------------------------------------------------
--================================================-- Check if DEX if licensed --=================================================--
SET @DB_VERSION = ISNULL((SELECT TOP 1 [DB_VERSION]
FROM [TBDD_MODULES]
WHERE LTRIM(RTRIM([SHORT_NAME])) = @MODULE_SHORT_NAME
AND LEN([LICENSE]) > 3
AND [ACTIVE] = @ACTIVE_FLAG),'0');
IF ((LEN(@DB_VERSION) = 0) OR (@DB_VERSION = '0')) BEGIN
--====================================================-- exception / error --====================================================--
SET @RETURN_STATUS = 50003;
SET @RETURN_STATUS_TEXT = concat('License check','');
SET @RETURN_ERROR_TEXT = concat('Found no valid module license! ','@DB_VERSION: ',CONVERT(NVARCHAR(50),@DB_VERSION));
THROW @RETURN_STATUS,@RETURN_ERROR_TEXT,1;
-----------------------------------------------------------------------------------------------------------------------------------
END; ELSE BEGIN
--======================================================-- Output result --======================================================--
SET @RETURN_STATUS = 0;
SET @RETURN_STATUS_TEXT = concat('Found valid module license! ','@DB_VERSION: ',CONVERT(NVARCHAR(50),@DB_VERSION));
SET @RETURN_ERROR_TEXT = concat('','');
PRINT 'INFO: ' + @RETURN_STATUS_TEXT;
-----------------------------------------------------------------------------------------------------------------------------------
--===================================================-- Log result to table --===================================================--
IF (@LOG_LEVEL in ('INFO')) BEGIN
EXEC [PRDEX_WRITE_LOG] @pLOG_LEVEL = N'INFO', @pPROFILE_ID = @PROFILE_ID, @pBATCH_ID = @BATCH_ID,
@pREFERENCE1 = @REFERENCE1, @pREFERENCE2 = @REFERENCE2, @pREFERENCE3 = @REFERENCE3,
@pREFERENCE4 = @REFERENCE4, @pREFERENCE5 = @REFERENCE5, @pRETURN_CODE = @RETURN_STATUS,
@pMESSAGE1 = @RETURN_STATUS_TEXT, @pMESSAGE2 = @RETURN_ERROR_TEXT, @pADDED_WHO = @MY_PROCEDURE_NAME;
END;
-----------------------------------------------------------------------------------------------------------------------------------
END;
-----------------------------------------------------------------------------------------------------------------------------------
--================================================-- Define all needed objects --================================================--
INSERT INTO @REQUIRED_OBJECTS (DB_OBJECT_NAME, DB_OBJECT_TYPE)
VALUES ('[dbo].[FNDEX_GET_NEXT_BATCH_ID]','TF'),
('[dbo].[FNDEX_GET_NEXT_EXPORT_NUMBER]','TF'),
('[dbo].[PRDEX_CHECK_SYSTEM]','P'),
('[dbo].[PRDEX_CLEAN_UP]','P'),
('[dbo].[PRDEX_GET_INPUT]','P'),
('[dbo].[PRDEX_GET_INPUT_CONTENT]','P'),
('[dbo].[PRDEX_REGISTER_PROCESS]','P'),
('[dbo].[PRDEX_RUN_MAINPROCESSING]','P'),
('[dbo].[PRDEX_RUN_POSTPROCESSING]','P'),
('[dbo].[PRDEX_RUN_PREPROCESSING]','P'),
('[dbo].[PRDEX_SET_EXPORT_FILENAME]','P'),
('[dbo].[PRDEX_SET_EXPORT_NUMBER]','P'),
('[dbo].[PRDEX_SET_QUERY]','P'),
('[dbo].[PRDEX_START_PROFILE_EXECUTION]','P'),
('[dbo].[PRDEX_WRITE_FILE]','P'),
('[dbo].[PRDEX_WRITE_LOG]','P'),
('[dbo].[PRDEX_WRITE_OUTPUT]','P'),
('[dbo].[TBDEX_CFG_OUT_DB]','U'),
('[dbo].[TBDEX_CFG_OUT_FILE]','U'),
('[dbo].[TBDEX_CFG_OUT_STRUCTURE]','U'),
('[dbo].[TBDEX_CFG_PROFILE]','U'),
('[dbo].[TBDEX_CFG_RESOURCES]','U'),
('[dbo].[TBDEX_IN]','U'),
('[dbo].[TBDEX_OUT]','U'),
('[dbo].[TBDEX_OUT_REFERENCES]','U'),
('[dbo].[TBDEX_RUN_LOG]','U'),
('[dbo].[TBDEX_RUN_NUMBER_RANGE]','U'),
('[dbo].[TBDEX_RUN_PROFILE]','U'),
('[dbo].[TBDEX_TMP_PROCESS]','U'),
('[dbo].[TBDEX_TMP_PROCESS_REFERENCES]','U'),
('[dbo].[TBDEX_TMP_QUERY]','U'),
('[dbo].[VWDEX_OUT]','V'),
('[dbo].[VWDEX_PROFILE]','V'),
('[dbo].[VWDEX_RESOURCES]','V');
-- U = User Table, V = View, P = Stored Procedure, TF = Table Function, FN = Scalar Function
-----------------------------------------------------------------------------------------------------------------------------------
--===================================================-- List missing objects --==================================================--
INSERT INTO @MISSING_OBJECTS (DB_OBJECT_NAME, DB_OBJECT_TYPE)
SELECT [RO].[DB_OBJECT_NAME],[RO].[DB_OBJECT_TYPE]
FROM @REQUIRED_OBJECTS AS [RO]
WHERE NOT EXISTS (SELECT 1 FROM [sys].[objects] AS [SYSO]
WHERE [SYSO].[object_id] = OBJECT_ID([RO].[DB_OBJECT_NAME])
AND [SYSO].[type] COLLATE Latin1_General_CI_AS = [RO].[DB_OBJECT_TYPE] COLLATE Latin1_General_CI_AS);
IF EXISTS (SELECT 1 FROM @MISSING_OBJECTS) BEGIN
SET @MISSING_OBJECTS_LIST = (SELECT STRING_AGG(DB_OBJECT_NAME, ',') WITHIN GROUP (ORDER BY DB_OBJECT_NAME) AS DB_OBJECT_NAMEs FROM @MISSING_OBJECTS);
--====================================================-- exception / error --====================================================--
SET @RETURN_STATUS = 50014;
SET @RETURN_STATUS_TEXT = concat('Check DEX system objects.','');
SET @RETURN_ERROR_TEXT = concat('Some required objects are missing from the database:',@MISSING_OBJECTS_LIST);
THROW @RETURN_STATUS,@RETURN_ERROR_TEXT,1;
-----------------------------------------------------------------------------------------------------------------------------------
END; ELSE BEGIN
--======================================================-- Output result --======================================================--
SET @RETURN_STATUS = 0;
SET @RETURN_STATUS_TEXT = concat('Found all required DEX DB Objects!','');
SET @RETURN_ERROR_TEXT = concat('','');
PRINT 'INFO: ' + @RETURN_STATUS_TEXT;
-----------------------------------------------------------------------------------------------------------------------------------
--===================================================-- Log result to table --===================================================--
IF (@LOG_LEVEL in ('INFO')) BEGIN
EXEC [PRDEX_WRITE_LOG] @pLOG_LEVEL = N'INFO', @pPROFILE_ID = @PROFILE_ID, @pBATCH_ID = @BATCH_ID,
@pREFERENCE1 = @REFERENCE1, @pREFERENCE2 = @REFERENCE2, @pREFERENCE3 = @REFERENCE3,
@pREFERENCE4 = @REFERENCE4, @pREFERENCE5 = @REFERENCE5, @pRETURN_CODE = @RETURN_STATUS,
@pMESSAGE1 = @RETURN_STATUS_TEXT, @pMESSAGE2 = @RETURN_ERROR_TEXT, @pADDED_WHO = @MY_PROCEDURE_NAME;
END;
-----------------------------------------------------------------------------------------------------------------------------------
END;
-----------------------------------------------------------------------------------------------------------------------------------
--======================================================-- Output result --======================================================--
SET @RETURN_STATUS = 0;
SET @RETURN_STATUS_TEXT = concat('END PROCEDURE [',@MY_PROCEDURE_NAME,'] @ ',CONVERT(NVARCHAR(50),GETDATE(),120));
SET @RETURN_ERROR_TEXT = concat('','');
PRINT '';
PRINT @RETURN_STATUS_TEXT;
PRINT '====================================================================================================';
-----------------------------------------------------------------------------------------------------------------------------------
--===================================================-- Log result to table --===================================================--
IF (@LOG_LEVEL in ('INFO')) BEGIN
EXEC [PRDEX_WRITE_LOG] @pLOG_LEVEL = N'INFO', @pPROFILE_ID = @PROFILE_ID, @pBATCH_ID = @BATCH_ID,
@pREFERENCE1 = @REFERENCE1, @pREFERENCE2 = @REFERENCE2, @pREFERENCE3 = @REFERENCE3,
@pREFERENCE4 = @REFERENCE4, @pREFERENCE5 = @REFERENCE5, @pRETURN_CODE = @RETURN_STATUS,
@pMESSAGE1 = @RETURN_STATUS_TEXT, @pMESSAGE2 = @RETURN_ERROR_TEXT, @pADDED_WHO = @MY_PROCEDURE_NAME;
END;
-----------------------------------------------------------------------------------------------------------------------------------
RETURN @RETURN_STATUS;
END TRY BEGIN CATCH
--====================================================-- exception / error --====================================================--
IF (@@TRANCOUNT > 0) BEGIN
ROLLBACK TRANSACTION;
END;
PRINT 'ERROR: ' + @RETURN_ERROR_TEXT;
-----------------------------------------------------------------------------------------------------------------------------------
--===================================================-- Log result to table --===================================================--
IF (@LOG_LEVEL in ('INFO','WARN','ERROR')) BEGIN
EXEC [PRDEX_WRITE_LOG] @pLOG_LEVEL = N'ERROR', @pPROFILE_ID = @PROFILE_ID, @pBATCH_ID = @BATCH_ID,
@pREFERENCE1 = @REFERENCE1, @pREFERENCE2 = @REFERENCE2, @pREFERENCE3 = @REFERENCE3,
@pREFERENCE4 = @REFERENCE4, @pREFERENCE5 = @REFERENCE5, @pRETURN_CODE = @RETURN_STATUS,
@pMESSAGE1 = @RETURN_STATUS_TEXT, @pMESSAGE2 = @RETURN_ERROR_TEXT, @pADDED_WHO = @MY_PROCEDURE_NAME;
END;
-----------------------------------------------------------------------------------------------------------------------------------
--======================================================-- Output result --======================================================--
SET @RETURN_STATUS = CASE WHEN @RETURN_STATUS > 50000 THEN @RETURN_STATUS ELSE 50000 END;
SET @RETURN_STATUS_TEXT = concat('END PROCEDURE [',@MY_PROCEDURE_NAME,'] @ ',CONVERT(NVARCHAR(50),GETDATE(),120));
SET @RETURN_ERROR_TEXT = concat('ERROR MESSAGE: ',CONVERT(NVARCHAR(500),ERROR_MESSAGE()));
PRINT 'ERROR IN PROCEDURE: [' + @MY_PROCEDURE_NAME + ']' + char(13) + @RETURN_ERROR_TEXT;
PRINT @RETURN_STATUS_TEXT;
PRINT '====================================================================================================';
-----------------------------------------------------------------------------------------------------------------------------------
--===================================================-- Log result to table --===================================================--
IF (@LOG_LEVEL in ('INFO','WARN','ERROR')) BEGIN
EXEC [PRDEX_WRITE_LOG] @pLOG_LEVEL = N'ERROR', @pPROFILE_ID = @PROFILE_ID, @pBATCH_ID = @BATCH_ID,
@pREFERENCE1 = @REFERENCE1, @pREFERENCE2 = @REFERENCE2, @pREFERENCE3 = @REFERENCE3,
@pREFERENCE4 = @REFERENCE4, @pREFERENCE5 = @REFERENCE5, @pRETURN_CODE = @RETURN_STATUS,
@pMESSAGE1 = @RETURN_STATUS_TEXT, @pMESSAGE2 = @RETURN_ERROR_TEXT, @pADDED_WHO = @MY_PROCEDURE_NAME;
END;
-----------------------------------------------------------------------------------------------------------------------------------
RETURN @RETURN_STATUS;
END CATCH;