-- [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: 22.11.2024 / HE,MK -- Version Date / Editor: 22.11.2024 / HE,MK -- Version Number: 1.0.0.0 -- ================================================================= -- History: -- 22.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]( @pTARGETSYSTEM VARCHAR(256) = 'WINLINE', -- Give target system: WINLINE or JTL-WAWI @pTARGETDB VARCHAR(256) = '[DD_CWLDATEN_DDVP]', -- Give target DB name (without schema!) @pTARGETSCHEMA VARCHAR(256) = '[dbo]', -- Give target DB schema @pTARGETTABLE VARCHAR(256) = '[t025]', -- Give target DB table @pTARGETDBCOLUMN VARCHAR(256) = '[c069]', -- Give target DB column @pDOCTYPE VARCHAR(256) = 'Ausgangsrechnung', -- Give doctype: Ausgangsangebot, Ausgangsauftrag, Ausgangslieferschein, Ausgangsrechnung @pDOCNR VARCHAR(256), -- Give docnr, like 'ARE-20234187' or 'AANG-20241060' @pDMSSTATUS VARCHAR(256), -- Give text to write in @pTARGETDBCOLUMN @pUSERNAME VARCHAR(50) = '[PRCUST_SET_DMS_STATUS_IN_WAWI]',-- Give the user of the Frontend call @pOVERWRITE BIT = 0, -- Set overwrite for @pTARGETDBCOLUMN: 0 = concat; 1 = overwrite @pLOGLEVEL VARCHAR(25) = 'ERROR' -- Set Loglevel to be written to table [TBCUST_SET_DMS_STATUS_IN_WAWI_LOG] ) AS BEGIN TRY SET NOCOUNT ON; DECLARE @TARGETSYSTEM VARCHAR(256) = @pTARGETSYSTEM, @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, @USERNAME VARCHAR(50) = @pUSERNAME, @OVERWRITE BIT = @pOVERWRITE, @LOGLEVEL VARCHAR(25) = @pLOGLEVEL, @DOCTYPECOLUMN VARCHAR(25) = NULL, @SQLCommand NVARCHAR(max) = NULL, @DOCCOUNT1 INT = 0, @DOCCOUNT2 INT = 0, @DMSSTATUSOLD VARCHAR(256) = NULL, @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 'PARAMETER01 - @TARGETSYSTEM: ' + CONVERT(VARCHAR(256),@TARGETSYSTEM); PRINT 'PARAMETER02 - @TARGETDB: ' + CONVERT(VARCHAR(256),@TARGETDB); PRINT 'PARAMETER03 - @TARGETSCHEMA: ' + CONVERT(VARCHAR(256),@TARGETSCHEMA); PRINT 'PARAMETER04 - @TARGETTABLE: ' + CONVERT(VARCHAR(256),@TARGETTABLE); PRINT 'PARAMETER05 - @TARGETDBCOLUMN: ' + CONVERT(VARCHAR(256),@TARGETDBCOLUMN); PRINT 'PARAMETER06 - @DOCTYPE: ' + CONVERT(VARCHAR(256),@DOCTYPE); PRINT 'PARAMETER07 - @DOCNR: ' + CONVERT(VARCHAR(256),@DOCNR); PRINT 'PARAMETER08 - @DMSSTATUS: ' + CONVERT(VARCHAR(256),@DMSSTATUS); PRINT 'PARAMETER09 - @USERNAME: ' + CONVERT(VARCHAR(50),@USERNAME); PRINT 'PARAMETER10 - @OVERWRITE: ' + CONVERT(VARCHAR(1),@OVERWRITE); PRINT 'PARAMETER11 - @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 --================================================-- IF (@TARGETSYSTEM = 'WINLINE') BEGIN SET @DOCTYPECOLUMN = CASE WHEN @DOCTYPE = 'Ausgangsangebot' THEN '[c043]' WHEN @DOCTYPE = 'Ausgangsauftrag' THEN '[c044]' WHEN @DOCTYPE = 'Ausgangslieferschein' THEN '[c045]' WHEN @DOCTYPE = 'Ausgangsrechnung' THEN '[c055]' ELSE NULL END; END; ELSE BEGIN PRINT 'Currently only WINLINE is available!' SET @DOCTYPECOLUMN = 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 @DOCCOUNT1 = count(*) FROM ' + @TARGETDB + '.' + @TARGETSCHEMA + '.' + @TARGETTABLE + ' WHERE ' + @DOCTYPECOLUMN + ' = ''' + @DOCNR + ''' '; PRINT 'Build Query @SQLCommand: ' + @SQLCommand EXEC @return_status = sp_executesql @SQLCommand,N'@DOCCOUNT1 INT OUTPUT', @DOCCOUNT1 OUTPUT; IF (@return_status = 0) BEGIN IF (@DOCCOUNT1 > 0) BEGIN PRINT 'Found: ' + CONVERT(VARCHAR(25),@DOCCOUNT1) + ' docs to update!' PRINT 'Checking if docs have a existing "dms text"' SET @SQLCommand = N'SELECT @DOCCOUNT2 = count(*) FROM ' + @TARGETDB + '.' + @TARGETSCHEMA + '.' + @TARGETTABLE + ' WHERE ' + @DOCTYPECOLUMN + ' = ''' + @DOCNR + ''' AND (' + @TARGETDBCOLUMN + ' = ''' + @DMSSTATUS + ''' OR ' + @TARGETDBCOLUMN + ' LIKE ''%' + @DMSSTATUS + ''' OR ' + @TARGETDBCOLUMN + ' LIKE ''' + @DMSSTATUS + '%'' OR ' + @TARGETDBCOLUMN + ' LIKE ''%' + @DMSSTATUS + '%'') '; PRINT 'Build "DMS Text" Query @SQLCommand: ' + @SQLCommand EXEC @return_status = sp_executesql @SQLCommand,N'@DOCCOUNT2 INT OUTPUT', @DOCCOUNT2 OUTPUT; IF (@return_status = 0) BEGIN PRINT 'Query was successful!' PRINT 'Found: ' + CONVERT(VARCHAR(25),@DOCCOUNT2) + ' docs with the dms text duplicate!' IF (@DOCCOUNT2 > 0) BEGIN PRINT 'Given dms text is already there, no update needed!'; SET @return_status = 1; END; ELSE BEGIN PRINT 'Given dms text is not there, update needed!'; IF ((@OVERWRITE = 0) and (@DOCCOUNT1 > 0)) BEGIN SET @SQLCommand = N'SELECT TOP 1 @DMSSTATUSOLD = ' + @TARGETDBCOLUMN + ' FROM ' + @TARGETDB + '.' + @TARGETSCHEMA + '.' + @TARGETTABLE + ' WHERE ' + @DOCTYPECOLUMN + ' = ''' + @DOCNR + ''' AND ' + @TARGETDBCOLUMN + ' IS NOT NULL AND ' + @TARGETDBCOLUMN + ' <> '''' '; PRINT 'Build "DMS Text" Query for existing values @SQLCommand: ' + @SQLCommand PRINT 'Found: ' + CONVERT(VARCHAR(25),@DOCCOUNT1) + ' docs with a existing dms text!' EXEC @return_status = sp_executesql @SQLCommand,N'@DMSSTATUSOLD VARCHAR(256) OUTPUT', @DMSSTATUSOLD OUTPUT; IF ((@return_status = 0)) BEGIN PRINT 'Query was successful!' IF (@DMSSTATUSOLD <> @DMSSTATUS) BEGIN PRINT 'Extending DMS status text' SET @DMSSTATUS = concat(@DMSSTATUSOLD,'; ',@DMSSTATUS) END; SET @DMSSTATUS = CASE WHEN LEFT(@DMSSTATUS,2) = '; ' THEN SUBSTRING(@DMSSTATUS, 2, LEN(@DMSSTATUS)-2) ELSE @DMSSTATUS END; END; ELSE BEGIN PRINT 'Query has failed!' PRINT '@DMSSTATUS keeps untouched!' END; END; ELSE IF ((@OVERWRITE = 1) or (@DOCCOUNT1 = 0)) BEGIN PRINT 'Overwrite is enabled and or no doc with existing dms text found!' END; --===========================================-- data collected updating row --=============================================-- SET @SQLCommand = N'SET NOCOUNT ON; UPDATE ' + @TARGETDB + '.' + @TARGETSCHEMA + '.' + @TARGETTABLE + ' SET ' + @TARGETDBCOLUMN + ' = ''' + @DMSSTATUS + ''' WHERE ' + @DOCTYPECOLUMN + ' = ''' + @DOCNR + ''' '; 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; END; ELSE BEGIN PRINT 'Query has failed!'; SET @return_status = 0; 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; ----------------------------------------------------------------------------------------------------------------------------- IF (@return_status = 1) SET @return_status_text = 'SUCCESS'; ELSE SET @return_status_text = 'FAILED'; PRINT ''; PRINT 'PROCEDURE Result: ' + @return_status_text PRINT 'PROCEDURE - END [PRCUST_SET_DMS_STATUS_IN_WAWI] @ ' + CONVERT(varchar(50),GETDATE(),120); PRINT '==============================='; --==============================================-- Log result to table --===============================================-- 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, @USERNAME ,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(), @USERNAME, GetDate()); END; END; ----------------------------------------------------------------------------------------------------------------------------- PRINT ''; PRINT 'PROCEDURE Result: ERROR! ' + ERROR_MESSAGE(); 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