From ecc6138ffc2bc4258076f90ecaece5b99c435635 Mon Sep 17 00:00:00 2001 From: KammM Date: Mon, 25 Nov 2024 00:50:44 +0100 Subject: [PATCH] PRCUST_SET_DMS_STATUS_IN_WAWI: Renamed to PRDD_SET_STATUS_IN_THIRDPARTY_DB --- .../[PRCUST_SET_DMS_STATUS_IN_WAWI].sql | 285 ------------------ .../[PRDD_SET_STATUS_IN_THIRDPARTY_DB].sql | 267 ++++++++++++++++ 2 files changed, 267 insertions(+), 285 deletions(-) delete mode 100644 DD-VMP02-DB01/SQL-Server/Prozeduren/[PRCUST_SET_DMS_STATUS_IN_WAWI].sql create mode 100644 DD-VMP02-DB01/SQL-Server/Prozeduren/[PRDD_SET_STATUS_IN_THIRDPARTY_DB].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 deleted file mode 100644 index f438c67..0000000 --- a/DD-VMP02-DB01/SQL-Server/Prozeduren/[PRCUST_SET_DMS_STATUS_IN_WAWI].sql +++ /dev/null @@ -1,285 +0,0 @@ --- [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 diff --git a/DD-VMP02-DB01/SQL-Server/Prozeduren/[PRDD_SET_STATUS_IN_THIRDPARTY_DB].sql b/DD-VMP02-DB01/SQL-Server/Prozeduren/[PRDD_SET_STATUS_IN_THIRDPARTY_DB].sql new file mode 100644 index 0000000..11ec34f --- /dev/null +++ b/DD-VMP02-DB01/SQL-Server/Prozeduren/[PRDD_SET_STATUS_IN_THIRDPARTY_DB].sql @@ -0,0 +1,267 @@ +-- [PRDD_SET_STATUS_IN_THIRDPARTY_DB] +-- ================================================================= +-- 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: 25.11.2024 / HE,MK +-- Version Date / Editor: 25.11.2024 / HE,MK +-- Version Number: 1.0.0.0 +-- ================================================================= +-- History: +-- 25.11.2024 / HE,MK - First Version + +SET ANSI_NULLS ON +GO +SET QUOTED_IDENTIFIER ON +GO + +CREATE OR ALTER PROCEDURE [PRDD_SET_STATUS_IN_THIRDPARTY_DB]( + @pTARGET_DB NVARCHAR(256) = '[DD_CWLDATEN_DDVP]', -- Give target DB name (without schema!) + @pTARGET_SCHEMA NVARCHAR(256) = '[dbo]', -- Give target DB schema + @pTARGET_TABLE NVARCHAR(256) = '[t025]', -- Give target DB table + @pTARGET_COLUMN NVARCHAR(256) = '[c069]', -- Give target DB column + @pREF_DOC_TYPE NVARCHAR(256) = 'Ausgangsrechnung', -- Give REF_DOC_TYPE, eg.: Ausgangsangebot, Ausgangsauftrag, Ausgangslieferschein, Ausgangsrechnung (ONLY FOR LOGGING PURPOSE!) + @pREF_DOC_NR_COLUMN NVARCHAR(256) = '[c055]', -- Give the column where the REF_DOC_NR is stored (eg. WINLINE: Ausgangsangebot=[c043], Ausgangsauftrag=[c044], Ausgangslieferschein=[c045], ) + @pREF_DOC_NR NVARCHAR(256), -- Give REF_DOC_NR, like 'ARE-20234187' or 'AANG-20241060' + @pADDITIONAL_WHERE NVARCHAR(256) = '', -- Give an additional WHERE clause like ' AND [COLUMN] IS NOT NULL' + @pSTATUS_TEXT NVARCHAR(256), -- Give text to write in @pTARGET_COLUMN + @pSTATUS_TEXT_MAX_LEN INT = 60, -- Give the max lenght of the target field for the status text + @pUSERNAME NVARCHAR(50) = '[PRDD_SET_STATUS_IN_THIRDPARTY_DB]', -- Give the user of the Frontend call, for the logging + @pOVERWRITE BIT = 0, -- Set overwrite for @pTARGET_COLUMN: 0 = concat; 1 = overwrite + @pLOGLEVEL NVARCHAR(25) = 'ERROR' -- Set Loglevel (ERROR or INFO) to be written to table [TBDD_SET_STATUS_IN_THIRDPARTY_DB_LOG] +) +AS +BEGIN TRY + + SET NOCOUNT ON; + + -- decalare new vars because of parameter sniffing + DECLARE @TARGET_DB NVARCHAR(256) = @pTARGET_DB, + @TARGET_SCHEMA NVARCHAR(256) = @pTARGET_SCHEMA, + @TARGET_TABLE NVARCHAR(256) = @pTARGET_TABLE, + @TARGET_COLUMN NVARCHAR(256) = @pTARGET_COLUMN, + @REF_DOC_TYPE NVARCHAR(256) = @pREF_DOC_TYPE, + @REF_DOC_NR_COLUMN NVARCHAR(256) = @pREF_DOC_NR_COLUMN, + @REF_DOC_NR NVARCHAR(256) = @pREF_DOC_NR, + @ADDITIONAL_WHERE NVARCHAR(256) = @pADDITIONAL_WHERE, + @STATUS_TEXT NVARCHAR(256) = @pSTATUS_TEXT, + @STATUS_TEXT_MAX_LEN INT = @pSTATUS_TEXT_MAX_LEN, + @USERNAME NVARCHAR(50) = @pUSERNAME, + @OVERWRITE BIT = @pOVERWRITE, + @LOGLEVEL NVARCHAR(25) = @pLOGLEVEL; + + -- decalare runtime vars + DECLARE @LINE_COUNT_1 INT = 0, + @LINE_COUNT_2 INT = 0, + @STATUS_TEXT_OLD_VALUE NVARCHAR(256) = NULL, + @SQL_COMMAND NVARCHAR(2000) = NULL, + @RETURN_STATUS NVARCHAR(256) = NULL, + @RETURN_STATUS_TEXT NVARCHAR(256) = NULL; + + PRINT '===============================' + PRINT 'PROCEDURE - START [PRDD_SET_STATUS_IN_THIRDPARTY_DB] @ ' + CONVERT(NVARCHAR(50),GETDATE(),120); + PRINT 'PARAMETER01 - @TARGET_DB: ' + CONVERT(NVARCHAR(256),@TARGET_DB); + PRINT 'PARAMETER02 - @TARGET_SCHEMA: ' + CONVERT(NVARCHAR(256),@TARGET_SCHEMA); + PRINT 'PARAMETER03 - @TARGET_TABLE: ' + CONVERT(NVARCHAR(256),@TARGET_TABLE); + PRINT 'PARAMETER04 - @TARGET_COLUMN: ' + CONVERT(NVARCHAR(256),@TARGET_COLUMN); + PRINT 'PARAMETER05 - @REF_DOC_TYPE: ' + CONVERT(NVARCHAR(256),@REF_DOC_TYPE); + PRINT 'PARAMETER06 - @REF_DOC_NR_COLUMN ' + CONVERT(NVARCHAR(256),@REF_DOC_NR_COLUMN); + PRINT 'PARAMETER07 - @REF_DOC_NR: ' + CONVERT(NVARCHAR(256),@REF_DOC_NR); + PRINT 'PARAMETER08 - @ADDITIONAL_WHERE ' + CONVERT(NVARCHAR(256),@ADDITIONAL_WHERE); + PRINT 'PARAMETER09 - @STATUS_TEXT: ' + CONVERT(NVARCHAR(256),@STATUS_TEXT); + PRINT 'PARAMETER10 - @STATUS_TEXT_MAX_LEN ' + CONVERT(NVARCHAR(256),@STATUS_TEXT_MAX_LEN); + PRINT 'PARAMETER11 - @USERNAME: ' + CONVERT(NVARCHAR(50),@USERNAME); + PRINT 'PARAMETER12 - @OVERWRITE: ' + CONVERT(NVARCHAR(1),@OVERWRITE); + PRINT 'PARAMETER13 - @LOGLEVEL: ' + CONVERT(NVARCHAR(25),@LOGLEVEL); + + --==============================================-- Prepare the log table --================================================-- + IF (@LOGLEVEL is not NULL) BEGIN + PRINT ''; + IF EXISTS (SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = N'TBDD_SET_STATUS_IN_THIRDPARTY_DB_LOG') BEGIN + PRINT 'Log table already exists'; + + END; ELSE BEGIN + PRINT 'Log table does not exists, trying to create...'; + + CREATE TABLE [dbo].[TBDD_SET_STATUS_IN_THIRDPARTY_DB_LOG]( + [GUID] [bigint] IDENTITY(1,1) NOT NULL, + [LOG_LEVEL] [NVARCHAR](25) NOT NULL, + [MESSAGE1] [NVARCHAR](max) NOT NULL, + [MESSAGE2] [NVARCHAR](max) NULL, + [MESSAGE3] [NVARCHAR](max) NULL, + [MESSAGE4] [NVARCHAR](max) NULL, + [MESSAGE5] [NVARCHAR](max) NULL, + [COMMENT] [NVARCHAR](max) NULL, + [ADDED_WHO] [NVARCHAR](50) NOT NULL, + [ADDED_WHEN] [datetime] NOT NULL, + CONSTRAINT [PK_TBDD_SET_STATUS_IN_THIRDPARTY_DB_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].[TBDD_SET_STATUS_IN_THIRDPARTY_DB_LOG] ADD CONSTRAINT [DF_TBDD_SET_STATUS_IN_THIRDPARTY_DB_LOG_ADDED_WHO] DEFAULT ('DEFAULT') FOR [ADDED_WHO]; + + ALTER TABLE [dbo].[TBDD_SET_STATUS_IN_THIRDPARTY_DB_LOG] ADD CONSTRAINT [DF_TBDD_SET_STATUS_IN_THIRDPARTY_DB_LOG_ADDED_WHEN] DEFAULT (getdate()) FOR [ADDED_WHEN]; + END; + END; + ----------------------------------------------------------------------------------------------------------------------------- + + --========================================-- Are there target lines to update? --==========================================-- + PRINT 'Check if there is a valid target there' + SET @SQL_COMMAND = N'SELECT @LINE_COUNT_1 = count(*) + FROM ' + @TARGET_DB + '.' + @TARGET_SCHEMA + '.' + @TARGET_TABLE + ' + WHERE ' + @REF_DOC_NR_COLUMN + ' = ''' + @REF_DOC_NR + ''' ' + @ADDITIONAL_WHERE; + PRINT 'Build Query @SQL_COMMAND: ' + @SQL_COMMAND; + EXEC @RETURN_STATUS = sp_executesql @SQL_COMMAND,N'@LINE_COUNT_1 INT OUTPUT', @LINE_COUNT_1 OUTPUT; + + IF (@RETURN_STATUS = 0) BEGIN + IF (@LINE_COUNT_1 > 0) BEGIN + PRINT 'Found: ' + CONVERT(NVARCHAR(25),@LINE_COUNT_1) + ' docs to update!'; + PRINT 'Checking if docs have a existing "status text"'; + SET @SQL_COMMAND = N'SELECT @LINE_COUNT_2 = count(*) + FROM ' + @TARGET_DB + '.' + @TARGET_SCHEMA + '.' + @TARGET_TABLE + ' + WHERE ' + @REF_DOC_NR_COLUMN + ' = ''' + @REF_DOC_NR + ''' + AND (' + @TARGET_COLUMN + ' = ''' + @STATUS_TEXT + ''' + OR ' + @TARGET_COLUMN + ' LIKE ''%' + @STATUS_TEXT + ''' + OR ' + @TARGET_COLUMN + ' LIKE ''' + @STATUS_TEXT + '%'' + OR ' + @TARGET_COLUMN + ' LIKE ''%' + @STATUS_TEXT + '%'') ' + + @ADDITIONAL_WHERE; + PRINT 'Build "status text" Query @SQL_COMMAND: ' + @SQL_COMMAND; + EXEC @RETURN_STATUS = sp_executesql @SQL_COMMAND,N'@LINE_COUNT_2 INT OUTPUT', @LINE_COUNT_2 OUTPUT; + + IF (@RETURN_STATUS = 0) BEGIN + PRINT 'Query was successful!'; + PRINT 'Found: ' + CONVERT(NVARCHAR(25),@LINE_COUNT_2) + ' docs with the status text duplicate!'; + + IF (@LINE_COUNT_2 > 0) BEGIN + PRINT 'Given status text is already there, no update needed!'; + SET @RETURN_STATUS = 1; + + END; ELSE BEGIN + PRINT 'Given status text is not there, update needed!'; + + IF ((@OVERWRITE = 0) and (@LINE_COUNT_1 > 0)) BEGIN + SET @SQL_COMMAND = N'SELECT TOP 1 @STATUS_TEXT_OLD_VALUE = ' + @TARGET_COLUMN + ' + FROM ' + @TARGET_DB + '.' + @TARGET_SCHEMA + '.' + @TARGET_TABLE + ' + WHERE ' + @REF_DOC_NR_COLUMN + ' = ''' + @REF_DOC_NR + ''' + AND ' + @TARGET_COLUMN + ' IS NOT NULL + AND ' + @TARGET_COLUMN + ' <> '''' ' + + @ADDITIONAL_WHERE; + PRINT 'Build "status text" Query for existing values @SQL_COMMAND: ' + @SQL_COMMAND; + PRINT 'Found: ' + CONVERT(NVARCHAR(25),@LINE_COUNT_1) + ' docs with a existing status text!'; + EXEC @RETURN_STATUS = sp_executesql @SQL_COMMAND,N'@STATUS_TEXT_OLD_VALUE NVARCHAR(256) OUTPUT', @STATUS_TEXT_OLD_VALUE OUTPUT; + + IF ((@RETURN_STATUS = 0)) BEGIN + PRINT 'Query was successful!'; + + IF (@STATUS_TEXT_OLD_VALUE <> @STATUS_TEXT) BEGIN + PRINT 'Extending DMS status text'; + SET @STATUS_TEXT = concat(@STATUS_TEXT_OLD_VALUE,'; ',@STATUS_TEXT); + END; + + SET @STATUS_TEXT = CASE WHEN LEFT(@STATUS_TEXT,2) = '; ' + THEN SUBSTRING(@STATUS_TEXT, 2, LEN(@STATUS_TEXT)-2) + ELSE @STATUS_TEXT + END; + END; ELSE BEGIN + PRINT 'Query has failed!'; + PRINT '@STATUS_TEXT keeps untouched!'; + END; + + END; ELSE IF ((@OVERWRITE = 1) or (@LINE_COUNT_1 = 0)) BEGIN + PRINT 'Overwrite is enabled and or no doc with existing status text found!'; + END; + + --===========================================-- data collected updating row --=============================================-- + + -- Check STATUS TEXT for its lenght + SET @STATUS_TEXT = LTRIM(RTRIM(@STATUS_TEXT)) + IF (LEN(@STATUS_TEXT) > @STATUS_TEXT_MAX_LEN) + SET @STATUS_TEXT = LEFT(@STATUS_TEXT,@STATUS_TEXT_MAX_LEN) + + SET @SQL_COMMAND = N'SET NOCOUNT ON; + UPDATE ' + @TARGET_DB + '.' + @TARGET_SCHEMA + '.' + @TARGET_TABLE + ' + SET ' + @TARGET_COLUMN + ' = ''' + @STATUS_TEXT + ''' + WHERE ' + @REF_DOC_NR_COLUMN + ' = ''' + @REF_DOC_NR + ''' ' + @ADDITIONAL_WHERE; + PRINT 'Build Update @SQL_COMMAND: ' + @SQL_COMMAND; + EXEC @RETURN_STATUS = sp_executesql @SQL_COMMAND; + + IF (@RETURN_STATUS = 0) BEGIN + PRINT 'Update was successful!'; + SET @RETURN_STATUS = 1; + END; ELSE BEGIN + PRINT 'Update has failed!'; + PRINT '@RETURN_STATUS: ' + CONVERT(NVARCHAR(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; + ----------------------------------------------------------------------------------------------------------------------------- + + 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 [PRDD_SET_STATUS_IN_THIRDPARTY_DB] @ ' + CONVERT(NVARCHAR(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'TBDD_SET_STATUS_IN_THIRDPARTY_DB_LOG') BEGIN + INSERT INTO [TBDD_SET_STATUS_IN_THIRDPARTY_DB_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [MESSAGE5], [ADDED_WHO], [ADDED_WHEN]) + VALUES (@LOGLEVEL, concat(@TARGET_DB,'.',@TARGET_SCHEMA,'.',@TARGET_TABLE,'.',@TARGET_COLUMN), concat(@REF_DOC_TYPE,' - Nr: ',@REF_DOC_NR), @STATUS_TEXT, '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'TBDD_SET_STATUS_IN_THIRDPARTY_DB_LOG') BEGIN + INSERT INTO [TBDD_SET_STATUS_IN_THIRDPARTY_DB_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [MESSAGE5], [ADDED_WHO], [ADDED_WHEN]) + VALUES ('ERROR', concat(@TARGET_DB,'.',@TARGET_SCHEMA,'.',@TARGET_TABLE,'.',@TARGET_COLUMN), concat(@REF_DOC_TYPE,' - Nr: ',@REF_DOC_NR), @STATUS_TEXT, 'OVERWRITE = ' + convert(NVARCHAR,@OVERWRITE), ERROR_MESSAGE(), @USERNAME, GetDate()); + END; + END; + ----------------------------------------------------------------------------------------------------------------------------- + + PRINT ''; + PRINT 'PROCEDURE Result: ERROR! ' + ERROR_MESSAGE(); + PRINT 'PROCEDURE - END [PRDD_SET_STATUS_IN_THIRDPARTY_DB] @ ' + CONVERT(varchar(50),GETDATE(),120); + PRINT '==============================='; + + RETURN 0; -- Because of the target index in windream! + +END CATCH; +GO