From ec79e8dcfbf423e67e6a20f7cec03a523a8d70c7 Mon Sep 17 00:00:00 2001 From: KammM Date: Tue, 19 Nov 2024 14:48:17 +0100 Subject: [PATCH] PRCUST_SET_DMS_STATUS_IN_WAWI: First version of DMS Status Updateer --- .../[PRCUST_SET_DMS_STATUS_IN_WAWI].sql | 229 ++++++++++++++++++ 1 file changed, 229 insertions(+) create mode 100644 DD-VMP02-DB01/SQL-Server/Prozeduren/[PRCUST_SET_DMS_STATUS_IN_WAWI].sql diff --git a/DD-VMP02-DB01/SQL-Server/Prozeduren/[PRCUST_SET_DMS_STATUS_IN_WAWI].sql b/DD-VMP02-DB01/SQL-Server/Prozeduren/[PRCUST_SET_DMS_STATUS_IN_WAWI].sql new file mode 100644 index 0000000..fdac5de --- /dev/null +++ b/DD-VMP02-DB01/SQL-Server/Prozeduren/[PRCUST_SET_DMS_STATUS_IN_WAWI].sql @@ -0,0 +1,229 @@ +-- [PRCUST_SET_DMS_STATUS_IN_WAWI] +-- ================================================================= +-- Set DMS status info into a text field +-- +-- Returns: 1 = SUCCESS; 0 = FAILED +-- ================================================================= +-- Copyright (c) 2024 by Digital Data GmbH +-- +-- Digital Data GmbH • Ludwig-Rinn-Strasse 16 • D-35452 Heuchelheim +-- Tel.: 0641/202360 • E-Mail: info-flow@digitaldata.works +-- ================================================================= +-- Creation Date / Author: 19.11.2024 / HE,MK +-- Version Date / Editor: 19.11.2024 / HE,MK +-- Version Number: 1.0.0.0 +-- ================================================================= +-- History: +-- 19.11.2024 / HE,MK - First Version + +SET ANSI_NULLS ON +GO +SET QUOTED_IDENTIFIER ON +GO + +CREATE OR ALTER PROCEDURE [PRCUST_SET_DMS_STATUS_IN_WAWI]( + @pTARGETDB VARCHAR(256) = '[DD_CWLDATEN_DDVP]', + @pTARGETSCHEMA VARCHAR(256) = '[dbo]', + @pTARGETTABLE VARCHAR(256) = '[t025]', + @pTARGETDBCOLUMN VARCHAR(256) = '[c069]', + @pDOCTYPE VARCHAR(256) = 'Eingangsrechnung', + @pDOCNR VARCHAR(256), + @pDMSSTATUS VARCHAR(256), + @pOVERWRITE BIT = 0, + @pLOGLEVEL VARCHAR(25) = 'ERROR' +) +AS +BEGIN TRY + + SET NOCOUNT ON; + + DECLARE @TARGETDB VARCHAR(256) = @pTARGETDB, + @TARGETSCHEMA VARCHAR(256) = @pTARGETSCHEMA, + @TARGETTABLE VARCHAR(256) = @pTARGETTABLE, + @TARGETDBCOLUMN VARCHAR(256) = @pTARGETDBCOLUMN, + @DOCTYPE VARCHAR(256) = @pDOCTYPE, + @DOCNR VARCHAR(256) = @pDOCNR, + @DMSSTATUS VARCHAR(256) = @pDMSSTATUS, + @OVERWRITE BIT = @pOVERWRITE, + @LOGLEVEL VARCHAR(25) = @pLOGLEVEL, + @DOCTYPECOLUMN VARCHAR(25) = NULL, + @SQLCommand NVARCHAR(max) = NULL, + @DOCCOUNT INT = 0, + @return_status VARCHAR(256) = NULL, + @return_status_text VARCHAR(256) = NULL; + + PRINT '===============================' + PRINT 'PROCEDURE - START [PRCUST_SET_DMS_STATUS_IN_WAWI] @ ' + CONVERT(varchar(50),GETDATE(),120); + PRINT 'PARAMETER1 - @TARGETDB: ' + CONVERT(VARCHAR(256),@TARGETDB); + PRINT 'PARAMETER2 - @TARGETSCHEMA: ' + CONVERT(VARCHAR(256),@TARGETSCHEMA); + PRINT 'PARAMETER3 - @TARGETTABLE: ' + CONVERT(VARCHAR(256),@TARGETTABLE); + PRINT 'PARAMETER4 - @TARGETDBCOLUMN: ' + CONVERT(VARCHAR(256),@TARGETDBCOLUMN); + PRINT 'PARAMETER5 - @DOCTYPE: ' + CONVERT(VARCHAR(256),@DOCTYPE); + PRINT 'PARAMETER6 - @DOCNR: ' + CONVERT(VARCHAR(256),@DOCNR); + PRINT 'PARAMETER7 - @DMSSTATUS: ' + CONVERT(VARCHAR(256),@DMSSTATUS); + PRINT 'PARAMETER8 - @OVERWRITE: ' + CONVERT(VARCHAR(1),@OVERWRITE); + PRINT 'PARAMETER9 - @LOGLEVEL: ' + CONVERT(VARCHAR(25),@LOGLEVEL); + + --==============================================-- Prepare the log table --================================================-- + IF (@LOGLEVEL is not NULL) + BEGIN + PRINT '' + IF EXISTS (SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = N'TBCUST_SET_DMS_STATUS_IN_WAWI_LOG') + BEGIN + PRINT 'Log table already exists' + END; + ELSE + BEGIN + PRINT 'Log table does not exists, trying to create...'; + + CREATE TABLE [dbo].[TBCUST_SET_DMS_STATUS_IN_WAWI_LOG]( + [GUID] [bigint] IDENTITY(1,1) NOT NULL, + [LOG_LEVEL] [varchar](25) NOT NULL, + [MESSAGE1] [varchar](max) NOT NULL, + [MESSAGE2] [varchar](max) NULL, + [MESSAGE3] [varchar](max) NULL, + [MESSAGE4] [varchar](max) NULL, + [MESSAGE5] [varchar](max) NULL, + [COMMENT] [varchar](max) NULL, + [ADDED_WHO] [varchar](50) NOT NULL, + [ADDED_WHEN] [datetime] NOT NULL, + CONSTRAINT [PK_TBCUST_SET_DMS_STATUS_IN_WAWI_LOG] PRIMARY KEY CLUSTERED + ( + [GUID] ASC + )WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY] + ) ON [PRIMARY] TEXTIMAGE_ON [PRIMARY]; + + ALTER TABLE [dbo].[TBCUST_SET_DMS_STATUS_IN_WAWI_LOG] ADD CONSTRAINT [DF_TBCUST_SET_DMS_STATUS_IN_WAWI_LOG_ADDED_WHO] DEFAULT ('DEFAULT') FOR [ADDED_WHO]; + + ALTER TABLE [dbo].[TBCUST_SET_DMS_STATUS_IN_WAWI_LOG] ADD CONSTRAINT [DF_TBCUST_SET_DMS_STATUS_IN_WAWI_LOG_ADDED_WHEN] DEFAULT (getdate()) FOR [ADDED_WHEN]; + + END; + END; + ----------------------------------------------------------------------------------------------------------------------------- + + --==============================================-- Determ doctype column --================================================-- + SET @DOCTYPECOLUMN = CASE + WHEN @DOCTYPE = 'Eingangsangebot' + THEN '[c043]' + WHEN @DOCTYPE = 'Eingangsauftrag' + THEN '[c044]' + WHEN @DOCTYPE = 'Eingangslieferschein' + THEN '[c045]' + WHEN @DOCTYPE = 'Eingangsrechnung' + THEN '[c055]' + ELSE NULL + END; + PRINT ''; + PRINT 'Determ @DOCTYPECOLUMN: ' + ISNULL(@DOCTYPECOLUMN,''); + ----------------------------------------------------------------------------------------------------------------------------- + + --========================================-- Are there target lines to update? --==========================================-- + IF (@DOCTYPECOLUMN is not NULL) + BEGIN + + PRINT 'Check if there is a valid target there' + SET @SQLCommand = N'SELECT @DOCCOUNT = count(*) FROM ' + @TARGETDB + '.' + @TARGETSCHEMA + '.' + @TARGETTABLE + ' WHERE ' + @DOCTYPECOLUMN + ' = ''' + @DOCNR + ''' '; + PRINT 'Build Query @SQLCommand: ' + @SQLCommand + + EXEC @return_status = sp_executesql @SQLCommand,N'@DOCCOUNT INT OUTPUT', @DOCCOUNT OUTPUT; + IF ((@return_status = 0)) + BEGIN + IF (@DOCCOUNT > 0) + BEGIN + PRINT 'Found: ' + CONVERT(VARCHAR(25),@DOCCOUNT) + ' doc to update!' + + SET @SQLCommand = N'SELECT @DOCCOUNT = count(*) FROM ' + @TARGETDB + '.' + @TARGETSCHEMA + '.' + @TARGETTABLE + ' WHERE ' + @DOCTYPECOLUMN + ' = ''' + @DOCNR + ''' AND ' + @TARGETDBCOLUMN + ' IS NOT NULL'; + PRINT 'Build "DMS Text" Query @SQLCommand: ' + @SQLCommand + EXEC @return_status = sp_executesql @SQLCommand,N'@DOCCOUNT INT OUTPUT', @DOCCOUNT OUTPUT; + + IF ((@OVERWRITE = 0) and (@DOCCOUNT > 0)) + BEGIN + SET @SQLCommand = N'UPDATE ' + @TARGETDB + '.' + @TARGETSCHEMA + '.' + @TARGETTABLE + ' SET ' + @TARGETDBCOLUMN + ' = concat(' + @TARGETDBCOLUMN + ',''; ''' +', ''' + @DMSSTATUS + ''') WHERE ' + @DOCTYPECOLUMN + ' = ''' + @DOCNR + ''' '; + END; + ELSE + BEGIN + SET @SQLCommand = N'UPDATE ' + @TARGETDB + '.' + @TARGETSCHEMA + '.' + @TARGETTABLE + ' SET ' + @TARGETDBCOLUMN + ' = ''' + @DMSSTATUS + ''' WHERE ' + @DOCTYPECOLUMN + ' = ''' + @DOCNR + ''' '; + END; + + PRINT 'Build Update @SQLCommand: ' + @SQLCommand + EXEC @return_status = sp_executesql @SQLCommand + + IF ((@return_status = 0)) + BEGIN + PRINT 'Update was successful!' + SET @return_status = 1; + END; + ELSE + BEGIN + PRINT 'Update has failed!' + PRINT '@return_status: ' + CONVERT(VARCHAR(50),@return_status) + END; + + END; + ELSE + BEGIN + PRINT 'No doc were found!' + SET @return_status = 0; + END; + END; + ELSE + BEGIN + PRINT 'Error at dynamic SQL!' + SET @return_status = 0; + END; + END; + ELSE + BEGIN + PRINT 'Invalid call!' + SET @return_status = 0; + END; + ----------------------------------------------------------------------------------------------------------------------------- + + PRINT ''; + PRINT 'PROCEDURE - END [PRCUST_SET_DMS_STATUS_IN_WAWI] @ ' + CONVERT(varchar(50),GETDATE(),120); + PRINT '==============================='; + + --==============================================-- Log result to table --===============================================-- + IF (@return_status = 1) + SET @return_status_text = 'SUCCESS'; + ELSE + SET @return_status_text = 'FAILED'; + + IF (@LOGLEVEL in ('INFO','WARN')) + BEGIN + IF EXISTS (SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = N'TBCUST_SET_DMS_STATUS_IN_WAWI_LOG') + BEGIN + INSERT INTO [TBCUST_SET_DMS_STATUS_IN_WAWI_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [MESSAGE5], [ADDED_WHO], [ADDED_WHEN]) + VALUES (@LOGLEVEL, concat(@TARGETDB,'.',@TARGETSCHEMA,'.',@TARGETTABLE,'.',@TARGETDBCOLUMN), concat(@DOCTYPE,' - Nr: ',@DOCNR), @DMSSTATUS, 'OVERWRITE = ' + convert(varchar,@OVERWRITE), @return_status_text, 'PRCUST_SET_DMS_STATUS_IN_WAWI',GetDate()); + END; + END; + ----------------------------------------------------------------------------------------------------------------------------- + + + RETURN @return_status -- Because of the target index in windream! + +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'TBCUST_SET_DMS_STATUS_IN_WAWI_LOG') + BEGIN + INSERT INTO [TBCUST_SET_DMS_STATUS_IN_WAWI_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [MESSAGE5], [ADDED_WHO], [ADDED_WHEN]) + VALUES ('ERROR', concat(@TARGETDB,'.',@TARGETSCHEMA,'.',@TARGETTABLE,'.',@TARGETDBCOLUMN), concat(@DOCTYPE,' - Nr: ',@DOCNR), @DMSSTATUS, 'OVERWRITE = ' + convert(varchar,@OVERWRITE), ERROR_MESSAGE(), 'PRCUST_SET_DMS_STATUS_IN_WAWI',GetDate()); + END; + END; + ----------------------------------------------------------------------------------------------------------------------------- + + PRINT ''; + PRINT 'PROCEDURE - END [PRCUST_SET_DMS_STATUS_IN_WAWI] @ ' + CONVERT(varchar(50),GETDATE(),120); + PRINT '==============================='; + + RETURN 0 -- Because of the target index in windream! + +END CATCH; +GO