OrgFLOW Update, dadurch auch DD_ECM

This commit is contained in:
Developer01
2025-06-12 09:09:36 +02:00
parent 25eeb6d310
commit ba27b6989c
19 changed files with 1118 additions and 1197 deletions

View File

@@ -1,5 +1,469 @@
UPDATE TBDD_BASECONFIG SET DB_VERSION = '1.9.8.5';
GO
/****** Object: StoredProcedure [dbo].[PRDD_SEND_REJECTION_MAIL] Script Date: 15.05.2025 09:29:08 ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
-- PRDD_SEND_REJECTION_MAIL
-- =================================================================
-- Die Procedure verschickt die Ablehnungsmails für
-- - ZUGFeRD-Service
-- - E-Mail Profiler
--
-- Dabei werden die codierten Ablehnungsgründe mit dem
-- E-Mail-Template verknüpft.
-- =================================================================
-- 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: 13.03.2024 / MP
-- =================================================================
-- History:
-- 13.03.2024 / MP - Prozedur erstellt
-- 10.04.2024 / MP - RECEIPT_EMAIL_PHRASE ergänzt
-- 17.04.2024 / MP - ZUGFeRD Integration fertiggestellt
-- 18.04.2024 / MP - DEPLOYMENT_ENVIRONMENT (PROD/TEST) auswerten, um 2. Mail zu verhindern.
-- 22.04.2024 / MP - Verwende FNCUST_SPLIT_STRING_WITH_GUID, um Ablehnungsgründe zu splitten
-- 24.04.2024 / MP - REMINDER_TYPE_ID muss ungleich 1 sein
CREATE PROCEDURE [dbo].[PRDD_SEND_REJECTION_MAIL]
@REF_MSGID VARCHAR(250) -- E-Mail MessageID
, @IDB_OBJ_ID BIGINT = 0 -- IDB_OBJ_ID
, @SENDING_PROFILE INTEGER = 0 -- Absenderprofil
, @REJ_SOURCE VARCHAR(50) -- Welcher Prozess lehnt ab?
, @MAIL_TEMPLATE INTEGER -- Welches Template soll verwendet werden?
, @REJ_REASONS VARCHAR(250) -- Liste mit IDs von Ablehnungsgründen, getrennt durch '|'
, @REPLACE_PARAM1 VARCHAR(MAX) -- Zusätzlicher Text-Parameter, ersetzt Platzhalter @REPLACE_PARAM1
, @REPLACE_PARAM2 VARCHAR(MAX) -- Zusätzlicher Text-Parameter, ersetzt Platzhalter @REPLACE_PARAM2
, @WF_ID INTEGER = 0 -- WorkflowID
AS
BEGIN
SET NOCOUNT ON;
DECLARE @EMAIL_ADRESS VARCHAR(250), @EMAIL_SUBJECT VARCHAR(250), @EMAIL_BODY VARCHAR(MAX), @COMMENT VARCHAR(500), @EMAIL_PATH VARCHAR(512),
@EMAIL_BODY1 VARCHAR(MAX), @EMAIL_BODY2 VARCHAR(MAX), @LANGUAGE VARCHAR(5), @CONNECTED_TEMPLATE_ID INTEGER,
@EMAIL_BODY1_CON VARCHAR(MAX), @EMAIL_BODY2_CON VARCHAR(MAX), @LANGUAGE_CON VARCHAR(5),
@REASON_ID VARCHAR(100), @REJ_REASON VARCHAR(900), @ORG_EMAIL_SUBJECT VARCHAR(250), @ORG_EMAIL_DATE VARCHAR(25),
@FILENAME VARCHAR(512), @REL_PATH VARCHAR(250), @PROCEDURE_NAME VARCHAR(30), @ALREADY_SENT_TODAY BIT,
@EMAIL_ADRESS_2 VARCHAR(250), @DEPLOYMENT_ENVIRONMENT VARCHAR(10);
DECLARE @REJ_REASON_TEMP_TABLE TABLE (REJ_ID VARCHAR(100), REJ_REASON VARCHAR(900), LANGUAGE VARCHAR(5));
SET @PROCEDURE_NAME = 'PRDD_SEND_REJECTION_MAIL'
-- ====================================================================================================================================
-- Prüfe Parameter
-- ====================================================================================================================================
IF @REF_MSGID IS NULL OR LEN(@REF_MSGID) <= 0
BEGIN
PRINT @PROCEDURE_NAME + ' - ### Parameter @REF_MSGID is NULL or Empty! ###'
RETURN;
END
IF @REJ_SOURCE IS NULL OR LEN(@REJ_SOURCE) <= 0
BEGIN
SET @REJ_SOURCE = 'Unkown Source (PRDD_SEND_REJECTION_MAIL)'
END
IF @MAIL_TEMPLATE <= 0
BEGIN
PRINT @PROCEDURE_NAME + ' - ### Parameter @MAIL_TEMPLATE is invalid! ###'
RETURN;
END
-- ====================================================================================================================================
-- Lade Daten des E-Mail-Eingangs
-- ====================================================================================================================================
DECLARE @TEMP_DATE DATETIME
SELECT
@EMAIL_ADRESS = EMAIL_FROM,
@ORG_EMAIL_SUBJECT = EMAIL_SUBJECT,
@TEMP_DATE = EMAIL_DATE
FROM [DD_ECM].[dbo].[TBEMLP_HISTORY]
WHERE EMAIL_MSGID = @REF_MSGID;
IF @EMAIL_ADRESS IS NULL OR LEN(@EMAIL_ADRESS) <= 0
BEGIN
PRINT @PROCEDURE_NAME + ' - ### EMAIL_ADRESS IS NULL or Empty! ###'
SET @EMAIL_ADRESS = 'm.schreiber@digitaldata.works'
SET @ORG_EMAIL_SUBJECT = 'Default Subject!'
SET @TEMP_DATE = '2024-01-01'
END
SET @ALREADY_SENT_TODAY = 0
IF @IDB_OBJ_ID > 0 AND @IDB_OBJ_ID <> 99999
BEGIN
IF EXISTS(SELECT 1
FROM TBEMLP_EMAIL_OUT
WHERE REFERENCE_ID = @IDB_OBJ_ID AND EMAIL_ADRESS = @EMAIL_ADRESS AND ADDED_WHO = @REJ_SOURCE AND CONVERT(DATE,ADDED_WHEN) = CONVERT(DATE,GETDATE()))
BEGIN
SET @ALREADY_SENT_TODAY = 1
END
END
ELSE
BEGIN
IF EXISTS(SELECT 1
FROM TBEMLP_EMAIL_OUT
WHERE REFERENCE_STRING = @REF_MSGID AND EMAIL_ADRESS = @EMAIL_ADRESS AND ADDED_WHO = @REJ_SOURCE AND CONVERT(DATE,ADDED_WHEN) = CONVERT(DATE,GETDATE()))
BEGIN
SET @ALREADY_SENT_TODAY = 1
END
END
IF @ALREADY_SENT_TODAY = 1
BEGIN
PRINT @PROCEDURE_NAME + ' - ### EMAIL with same reference already send today! ###'
--RETURN;
END
SET @ORG_EMAIL_DATE = CONVERT(VARCHAR(25), @TEMP_DATE, 120) -- yyyy-mm-dd hh:mm:ss
SELECT
@EMAIL_ADRESS_2 = ITEM_VALUE
FROM DD_ECM.dbo.TBEDMI_ITEM_VALUE
WHERE REFERENCE_GUID = @REF_MSGID
AND SPEC_NAME = 'INVOICE_SELLER_EMAIL';
-- ====================================================================================================================================
-- E-Mail-Absender
-- ====================================================================================================================================
IF @SENDING_PROFILE <= 0
BEGIN
SELECT @SENDING_PROFILE = CONVERT(INTEGER, CAT_STRING)
FROM IDB.dbo.TBIDB_CATALOG
WHERE CAT_TITLE = 'REJECTION_EMAIL_PROFILE'
END
IF @SENDING_PROFILE <= 0
BEGIN
PRINT @PROCEDURE_NAME + ' - ### No SENDING PROFILE found! ###'
RETURN;
END
-- ====================================================================================================================================
-- Lade Konfiguration aus TBIDB_CATALOG
-- ====================================================================================================================================
SELECT @DEPLOYMENT_ENVIRONMENT = CAT_STRING
FROM IDB.dbo.TBIDB_CATALOG
WHERE CAT_TITLE = 'DEPLOYMENT_ENVIRONMENT';
-- ====================================================================================================================================
-- Lade E-Mail-Template(s)
-- ====================================================================================================================================
IF NOT EXISTS (SELECT 1 FROM [DD_ECM].[dbo].[TBDD_EMAIL_TEMPLATE] WHERE GUID = @MAIL_TEMPLATE)
BEGIN
PRINT @PROCEDURE_NAME + ' - ### No EMAIL TEMPLATE found! ###'
RETURN;
END
SELECT
@EMAIL_SUBJECT = EMAIL_SUBJECT,
@EMAIL_BODY1 = EMAIL_BODY1,
@EMAIL_BODY2 = EMAIL_BODY2,
@LANGUAGE = [LANGUAGE],
@CONNECTED_TEMPLATE_ID = CONNECTED_TEMPLATE
FROM [DD_ECM].[dbo].[TBDD_EMAIL_TEMPLATE]
WHERE GUID = @MAIL_TEMPLATE;
IF @CONNECTED_TEMPLATE_ID > 0
BEGIN
SELECT
@EMAIL_BODY1_CON = EMAIL_BODY1,
@EMAIL_BODY2_CON = EMAIL_BODY2,
@LANGUAGE_CON = [LANGUAGE]
FROM [DD_ECM].[dbo].[TBDD_EMAIL_TEMPLATE]
WHERE GUID = @CONNECTED_TEMPLATE_ID;
END
ELSE
BEGIN
SET @LANGUAGE_CON = @LANGUAGE
END
-- ====================================================================================================================================
-- Lade Ablehnungsgründe in temporäre Tabelle
-- ====================================================================================================================================
IF @REJ_REASONS IS NULL OR LEN(@REJ_REASONS) <= 0
BEGIN
PRINT @PROCEDURE_NAME + ' - ### NO Rejection Reasons! ###'
RETURN;
END
IF @REJ_REASONS LIKE '%|%'
BEGIN
-- Es gibt mehrere Gründe
DECLARE cursorGetRejReasons CURSOR LOCAL FAST_FORWARD FOR
SELECT Item FROM DD_ECM.[dbo].[FNCUST_SPLIT_STRING_WITH_GUID] (@REJ_REASONS, '|')
OPEN cursorGetRejReasons
FETCH NEXT FROM cursorGetRejReasons INTO @REASON_ID
WHILE @@FETCH_STATUS = 0
BEGIN
INSERT INTO @REJ_REASON_TEMP_TABLE (REJ_ID, REJ_REASON, [LANGUAGE])
SELECT TITLE AS REJ_ID, STRING1 AS REJ_REASON, [LANGUAGE]
FROM [DD_ECM].[dbo].[TBDD_GUI_LANGUAGE_PHRASE]
WHERE [TITLE] = 'RejectReason' + @REASON_ID AND [LANGUAGE] IN (@LANGUAGE, @LANGUAGE_CON);
FETCH NEXT FROM cursorGetRejReasons INTO @REASON_ID
END
CLOSE cursorGetRejReasons
DEALLOCATE cursorGetRejReasons
END
ELSE
BEGIN
INSERT INTO @REJ_REASON_TEMP_TABLE (REJ_ID, REJ_REASON, [LANGUAGE])
SELECT TITLE AS REJ_ID, STRING1 AS REJ_REASON, [LANGUAGE]
FROM [DD_ECM].[dbo].[TBDD_GUI_LANGUAGE_PHRASE]
WHERE [TITLE] = @REJ_REASONS AND [LANGUAGE] IN (@LANGUAGE, @LANGUAGE_CON);
END
-- ====================================================================================================================================
-- Stelle E-Mail Body zusammen
-- ====================================================================================================================================
DECLARE @REASON_COUNTER INTEGER
SET @REASON_COUNTER = 1
SET @EMAIL_BODY = '<html><body style=''font-family:""Arial"";font-size:10.0pt''>'
SET @EMAIL_BODY += @EMAIL_BODY1
DECLARE cursorSelectRejReasons CURSOR LOCAL FAST_FORWARD FOR
SELECT REJ_ID, REJ_REASON
FROM @REJ_REASON_TEMP_TABLE
WHERE [LANGUAGE] = @LANGUAGE;
OPEN cursorSelectRejReasons
FETCH NEXT FROM cursorSelectRejReasons INTO @REASON_ID, @REJ_REASON
WHILE @@FETCH_STATUS = 0
BEGIN
IF @REASON_COUNTER > 1
BEGIN
SET @EMAIL_BODY += '<br/>' + @REJ_REASON;
END
ELSE
BEGIN
-- 1. Zeile
SET @EMAIL_BODY += @REJ_REASON
END
SET @REASON_COUNTER += 1;
FETCH NEXT FROM cursorSelectRejReasons INTO @REASON_ID, @REJ_REASON
END
CLOSE cursorSelectRejReasons
DEALLOCATE cursorSelectRejReasons
SET @EMAIL_BODY += @EMAIL_BODY2
IF @CONNECTED_TEMPLATE_ID > 0
BEGIN
SET @REASON_COUNTER = 1
SET @EMAIL_BODY += '<p>====================================================================================================================================<p/>'
SET @EMAIL_BODY += @EMAIL_BODY1_CON
DECLARE cursorSelectRejReasonsCon CURSOR LOCAL FAST_FORWARD FOR
SELECT REJ_ID, REJ_REASON
FROM @REJ_REASON_TEMP_TABLE
WHERE [LANGUAGE] = @LANGUAGE_CON;
OPEN cursorSelectRejReasonsCon
FETCH NEXT FROM cursorSelectRejReasonsCon INTO @REASON_ID, @REJ_REASON
WHILE @@FETCH_STATUS = 0
BEGIN
IF @REASON_COUNTER > 1
BEGIN
SET @EMAIL_BODY += '<br/>' + @REJ_REASON;
END
ELSE
BEGIN
-- 1. Zeile
SET @EMAIL_BODY += @REJ_REASON
END
SET @REASON_COUNTER += 1;
FETCH NEXT FROM cursorSelectRejReasonsCon INTO @REASON_ID, @REJ_REASON
END
CLOSE cursorSelectRejReasonsCon
DEALLOCATE cursorSelectRejReasonsCon
SET @EMAIL_BODY += @EMAIL_BODY2_CON
END
SET @EMAIL_BODY += '<p>(' + @REJ_REASONS + ')</p>'
SET @EMAIL_BODY += '</body></html>'
-- ====================================================================================================================================
-- Ersetze Platzhalter in SUBJECT und BODY
-- ====================================================================================================================================
DECLARE @LAST_USER VARCHAR(100), @LAST_USER_EMAIL VARCHAR(100), @ORG_INVOICE_NR VARCHAR(50), @INVOICE_NR_VALUE VARCHAR(50)
SET @ORG_INVOICE_NR = '[KEINE BELEGNR GEFUNDEN/GELIEFERT]'
SET @INVOICE_NR_VALUE = ''
SET @LAST_USER = 'No User so far'
SET @LAST_USER_EMAIL = ''
SET @ORG_EMAIL_SUBJECT = REPLACE(@ORG_EMAIL_SUBJECT,'[EXTERNAL] ', '')
IF EXISTS(SELECT ITEM_VALUE FROM [DD_ECM].[dbo].TBEDMI_ITEM_VALUE WHERE REFERENCE_GUID = @REF_MSGID and SPEC_NAME = 'INVOICE_NUMBER')
BEGIN
SELECT @INVOICE_NR_VALUE = ITEM_VALUE
FROM [DD_ECM].[dbo].TBEDMI_ITEM_VALUE
WHERE REFERENCE_GUID = @REF_MSGID and SPEC_NAME = 'INVOICE_NUMBER';
SET @ORG_INVOICE_NR = @INVOICE_NR_VALUE;
END
IF @IDB_OBJ_ID > 0 AND @IDB_OBJ_ID <> 99999
BEGIN
SELECT
@LAST_USER = PRENAME + ' ' + COALESCE([NAME],''),
@LAST_USER_EMAIL = EMAIL
FROM [DD_ECM].[dbo].TBDD_USER
--WHERE USERNAME = [DD_ECM].[dbo].[FNPM_LAST_WORKUSER_DOC] (@IDB_OBJ_ID)
END
--PRINT '@REPLACE_PARAM1:' + @REPLACE_PARAM1
SET @EMAIL_SUBJECT = REPLACE(@EMAIL_SUBJECT, '@ORG_INVOICE_NR', @ORG_INVOICE_NR)
SET @EMAIL_BODY = REPLACE(@EMAIL_BODY, '@ORG_EMAIL_MSGID', @REF_MSGID)
SET @EMAIL_BODY = REPLACE(@EMAIL_BODY, '@ORG_INVOICE_NR', @ORG_INVOICE_NR)
SET @EMAIL_BODY = REPLACE(@EMAIL_BODY, '@ORG_EMAIL_SUBJECT', @ORG_EMAIL_SUBJECT)
SET @EMAIL_BODY = REPLACE(@EMAIL_BODY, '@ORG_EMAIL_DATE', @ORG_EMAIL_DATE)
SET @EMAIL_BODY = REPLACE(@EMAIL_BODY, '@LAST_USER', @LAST_USER)
SET @EMAIL_BODY = REPLACE(@EMAIL_BODY, '@LAST_USER_EMAIL', @LAST_USER_EMAIL)
SET @EMAIL_BODY = REPLACE(@EMAIL_BODY, '@REPLACE_PARAM1', @REPLACE_PARAM1)
SET @EMAIL_BODY = REPLACE(@EMAIL_BODY, '@REPLACE_PARAM2', @REPLACE_PARAM2)
--Print @EMAIL_BODY
-- ====================================================================================================================================
-- Ersetze Platzhalter @RECEIPT_EMAIL_PHRASE / @RECEIPT_EMAIL_PHRASE_EN im BODY
-- ====================================================================================================================================
DECLARE @RECEIPT_EMAIL_DE_PHRASE VARCHAR(100), @RECEIPT_EMAIL_EN_PHRASE VARCHAR(100)
SET @RECEIPT_EMAIL_DE_PHRASE = 'Email'
SET @RECEIPT_EMAIL_EN_PHRASE = 'Email'
-- Wenn Belegnummer vorliegt, dann konkreter Text
IF LEN(@INVOICE_NR_VALUE) > 1
BEGIN
SET @RECEIPT_EMAIL_DE_PHRASE = 'Rechnung ' + @INVOICE_NR_VALUE
SET @RECEIPT_EMAIL_EN_PHRASE = 'Invoice ' + @INVOICE_NR_VALUE
END
SET @EMAIL_BODY = REPLACE(@EMAIL_BODY, '@RECEIPT_EMAIL_DE_PHRASE', @RECEIPT_EMAIL_DE_PHRASE)
SET @EMAIL_BODY = REPLACE(@EMAIL_BODY, '@RECEIPT_EMAIL_EN_PHRASE', @RECEIPT_EMAIL_EN_PHRASE)
-- ====================================================================================================================================
-- Evtl. vorhandener Dateianhang
-- ====================================================================================================================================
SET @EMAIL_PATH = ''
IF @IDB_OBJ_ID > 0 AND @IDB_OBJ_ID <> 99999
BEGIN
SELECT @REL_PATH = [CAT_STRING] FROM [IDB].[dbo].[TBIDB_CATALOG] WHERE [CAT_TITLE] = 'FILESTORE_PRAEFIX';
SELECT @FILENAME = RELATIVE_PATH FROM [IDB].[dbo].[TBIDB_DOC_INFO] WHERE IDB_OBJ_ID = @IDB_OBJ_ID;
IF LEN(@FILENAME) > 0
BEGIN
BEGIN
IF @FILENAME NOT LIKE @REL_PATH + '%'
BEGIN
SET @FILENAME = @REL_PATH + @FILENAME
END
END
SET @EMAIL_PATH = @FILENAME
END
ELSE
SET @EMAIL_PATH = 'F:\DocumentProcessing\Output\File\DocumentKindAssigned\ZUGFeRD\Success\archive\'
END
-- ====================================================================================================================================
-- Füge E-Mail-Daten in Tabelle ein
-- ====================================================================================================================================
INSERT INTO [DD_ECM].[dbo].[TBEMLP_EMAIL_OUT]
(
[SENDING_PROFILE] -- REQUIRED
, [REFERENCE_ID] -- REQUIRED
, [REFERENCE_STRING]
, [WF_ID] -- REQUIRED
, [EMAIL_ADRESS] -- REQUIRED
, [EMAIL_SUBJ] -- REQUIRED
, [EMAIL_BODY] -- REQUIRED
, [COMMENT]
, [ADDED_WHO] -- REQUIRED
, [EMAIL_ATTMT1]
, [REMINDER_TYPE_ID]
) VALUES (
@SENDING_PROFILE
, @IDB_OBJ_ID
, @REF_MSGID
, @WF_ID
, @EMAIL_ADRESS
, @EMAIL_SUBJECT
, @EMAIL_BODY
, @COMMENT
, @REJ_SOURCE
, @EMAIL_PATH
, 77
);
-- ====================================================================================================================================
-- Füge E-Mail-Daten in Tabelle ein, falls 2. E-Mail-Adresse vorliegt, und
-- diese sich von der 1. E-Mail-Adresse unterscheidet!
-- ====================================================================================================================================
IF @DEPLOYMENT_ENVIRONMENT = 'PROD' AND
LEN(@EMAIL_ADRESS_2) > 0 AND @EMAIL_ADRESS <> @EMAIL_ADRESS_2
BEGIN
INSERT INTO [DD_ECM].[dbo].[TBEMLP_EMAIL_OUT]
(
[SENDING_PROFILE] -- REQUIRED
, [REFERENCE_ID] -- REQUIRED
, [REFERENCE_STRING]
, [WF_ID] -- REQUIRED
, [EMAIL_ADRESS] -- REQUIRED
, [EMAIL_SUBJ] -- REQUIRED
, [EMAIL_BODY] -- REQUIRED
, [COMMENT]
, [ADDED_WHO] -- REQUIRED
, [EMAIL_ATTMT1]
, [REMINDER_TYPE_ID]
) VALUES (
@SENDING_PROFILE
, @IDB_OBJ_ID
, @REF_MSGID
, @WF_ID
, @EMAIL_ADRESS_2 -- EMAIL_ADRESS_2
, @EMAIL_SUBJECT
, @EMAIL_BODY
, @COMMENT
, @REJ_SOURCE
, @EMAIL_PATH
, 77
);
END
END
GO
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
DELETE FROM TBDD_ZUGFERD_VIEW_RECEIPT_TEMPLATE;
Insert INTO TBDD_ZUGFERD_VIEW_RECEIPT_TEMPLATE