601 lines
24 KiB
Transact-SQL
601 lines
24 KiB
Transact-SQL
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
|
|
(SPECNAME, Row_Caption, Area, xPosition, SequenceItem, Y_eq_lastrow, Display) values
|
|
('INVOICE_TYPE', '', 'TYPE', 10, 1, 0, 0),
|
|
('INVOICE_CURRENCY', '', 'TYPE', 10, 2, 0, 0),
|
|
('INVOICE_NUMBER', 'Rechnungsnummer/Invoice-No:', 'HEAD', 10, 3, 0, 1),
|
|
('INVOICE_DATE', 'Datum/Date:', 'HEAD', 10, 4, 0, 1),
|
|
('INVOICE_SERVICE_DATE','Leistungsdatum/Service date:', 'HEAD', 10, 5, 0, 1),
|
|
('INVOICE_SELLER_NAME', '', 'SELLER', 10, 6, 0, 1),
|
|
('INVOICE_SELLER_ADDRESS', '', 'SELLER', 10, 7, 0, 1),
|
|
('INVOICE_SELLER_POSTALCODE', '', 'SELLER', 10, 8, 0, 1),
|
|
('INVOICE_SELLER_CITY', '', 'SELLER', 35, 9, 1, 1),
|
|
('INVOICE_SELLER_TAX_ID', 'USt-ID/Seller tax ID:', 'SELLER', 10, 10, 0, 1),
|
|
('INVOICE_SELLER_ID', 'Lieferant-Nr/Seller ID:', 'SELLER', 10, 11, 0, 1),
|
|
('INVOICE_BUYER_NAME', '', 'BUYER', 10, 12, 0, 1),
|
|
('INVOICE_BUYER_ADRESS2', '', 'BUYER', 10, 13, 0, 1),
|
|
('INVOICE_BUYER_ADRESS', '', 'BUYER', 10, 14, 0, 1),
|
|
('INVOICE_BUYER_POSTALCODE', '', 'BUYER', 10, 15, 0, 1),
|
|
('INVOICE_BUYER_CITY', '', 'BUYER', 35, 16, 1, 1),
|
|
--('STATIC_Y_SWITCH', '271', 'INTERNAL', 35, 15, 0, 0),
|
|
('INVOICE_POSITION_AMOUNT', '', 'POSITION', 10, 17, 0, 0),
|
|
('INVOICE_POSITION_UNIT_TYPE', '', 'POSITION', 10, 18, 0, 0),
|
|
('INVOICE_POSITION_ARTICLE', '', 'POSITION', 10, 19, 0, 0),
|
|
('INVOICE_POSITION_NOTE', '', 'POSITION', 10, 20, 0, 0),
|
|
('INVOICE_TAXPOS_TAX_RATE', '', 'POSITION', 10, 21, 0, 0),
|
|
('INVOICE_POSITION_TAX_AMOUNT', '', 'POSITION', 10, 22, 0, 1),
|
|
('INVOICE_TOTAL_NET', 'Nettobetrag/Net amount:', 'AMOUNT', 10, 400, 0, 1),
|
|
('INVOICE_TOTAL_TAX', 'Steuerbetrag/Tax amount:', 'AMOUNT', 10, 401, 0, 1),
|
|
('INVOICE_TOTAL_GROSS', 'Bruttobetrag/Gross amount:', 'AMOUNT', 10, 402, 0, 1),
|
|
('INVOICE_TAXPOS_RATE', '', 'TAXPOS', 10, 403, 1, 0),
|
|
('INVOICE_TAXPOS_AMOUNT', '', 'TAXPOS', 10, 404, 0, 0),
|
|
('INVOICE_TAXPOS_TYPE', '', 'TAXPOS', 10, 405, 1, 1),
|
|
('INVOICE_TAXPOS_EXEMPTION_REASON', '', 'EXEMPTION', 10, 406, 0, 1),
|
|
('INVOICE_TAXPOS_EXEMPTION_REASON_CODE', '', 'EXEMPTION', 10, 407, 0, 1),
|
|
('INVOICE_PAYMENT_TERMS','', 'PAYMENT', 10, 500, 0, 1),
|
|
('INVOICE_PAYMENT_IBAN','IBAN:', 'PAYMENT', 10, 501, 0, 1),
|
|
('INVOICE_PAYMENT_BIC','BIC:', 'PAYMENT', 10, 502, 0, 1);
|
|
GO
|
|
--CHANGED 25.04.2025 INV_POSITION_UNIT_TYPE integriert
|
|
--CHANGED 06.03.2025 INV_POS_NOTE integriert
|
|
ALTER FUNCTION [dbo].[FNDD_ZUGFERD_VIEW_RECEIPT_CUST_RESULT] (@pMSGID VARCHAR(100))
|
|
RETURNS TABLE
|
|
AS RETURN
|
|
(
|
|
SELECt A.SPEC_NAME,A.ITEM_VALUE,A.Area,A.Row_Caption,A.xPosition,A.Y_eq_lastrow,A.SequenceItem ORDER_SEQ,A.Display FROM VWDD_ZUGFERD_VIEW_RECEIPT_TEMPLATE_ITEMS A
|
|
WHERE REFERENCE_GUID = @pMSGID
|
|
AND A.SPEC_NAME NOT IN ('INVOICE_POSITION_AMOUNT','INVOICE_POSITION_UNIT_TYPE','INVOICE_POSITION_NOTE',
|
|
'INVOICE_TAXPOS_TAX_RATE','INVOICE_POSITION_ARTICLE','INVOICE_TAXPOS_AMOUNT',
|
|
'INVOICE_TAXPOS_RATE','INVOICE_TAXPOS_TYPE','INVOICE_POSITION_TAX_AMOUNT')
|
|
UNION
|
|
SELECT SPEC_NAME,ITEM_VALUE,Area,'' Row_Caption,10 xPosition, 0 Y_eq_lastrow,SequenceItem ORDER_SEQ, Display FROM [dbo].[FNDD_ZUGFERD_VIEW_RECEIPT_POSITIONS] (@pMSGID)
|
|
UNION
|
|
SELECT SPEC_NAME,ITEM_VALUE,Area,'' Row_Caption,10 xPosition, 0 Y_eq_lastrow,SequenceItem ORDER_SEQ, Display FROM [dbo].[FNDD_ZUGFERD_VIEW_RECEIPT_TAX] (@pMSGID)
|
|
UNION
|
|
SELECT SPECNAME SPEC_NAME,Row_Caption,Area,Row_Caption Row_Caption,10 xPosition, 0 Y_eq_lastrow,SequenceItem ORDER_SEQ, Display FROM TBDD_ZUGFERD_VIEW_RECEIPT_TEMPLATE WHERE Area = 'INTERNAL'
|
|
)
|
|
GO
|
|
|
|
SET ANSI_NULLS ON
|
|
GO
|
|
SET QUOTED_IDENTIFIER ON
|
|
GO
|
|
--CHANGED 25.04.2025 INV_POSITION_UNIT_TYPE integriert
|
|
--CHANGED 06.03.2025 INV_POS_NOTE integriert
|
|
ALTER FUNCTION [dbo].[FNDD_ZUGFERD_VIEW_RECEIPT_POSITIONS] (@pMSGID VARCHAR(100))
|
|
RETURNS @TABLE TABLE(SPEC_NAME VARCHAR(100),ITEM_VALUE VARCHAR(250),Area VARCHAR(60),SequenceItem INT,Display BIT)
|
|
AS
|
|
BEGIN
|
|
DECLARE @GROUP_COUNTER INT,@INDEX INT = 15
|
|
DECLARE cursGroupCounter CURSOR FOR
|
|
select GROUP_COUNTER from TBEDMI_ITEM_VALUE WHERE REFERENCE_GUID = @pMSGID And SPEC_NAME = 'INVOICE_POSITION_AMOUNT' ORDER BY GROUP_COUNTER
|
|
OPEN cursGroupCounter
|
|
FETCH NEXT FROM cursGroupCounter INTO @GROUP_COUNTER
|
|
WHILE @@FETCH_STATUS = 0
|
|
BEGIN
|
|
DECLARE @SPEC_NAME VARCHAR(100),@ITEM_VALUE VARCHAR(100),@Display BIT
|
|
DECLARE cursPosItems CURSOR FOR
|
|
select A.SPEC_NAME,ITEM_VALUE,Display from TBEDMI_ITEM_VALUE A INNER JOIN TBDD_ZUGFERD_VIEW_RECEIPT_TEMPLATE B ON A.SPEC_NAME = B.SPECNAME WHERE REFERENCE_GUID = @pMSGID And A.SPEC_NAME IN ('INVOICE_POSITION_AMOUNT','INVOICE_POSITION_UNIT_TYPE',
|
|
'INVOICE_TAXPOS_TAX_RATE','INVOICE_POSITION_NOTE','INVOICE_POSITION_ARTICLE','INVOICE_POSITION_TAX_AMOUNT') AND GROUP_COUNTER = @GROUP_COUNTER ORDER BY B.SequenceItem
|
|
OPEN cursPosItems
|
|
FETCH NEXT FROM cursPosItems INTO @SPEC_NAME,@ITEM_VALUE,@Display
|
|
WHILE @@FETCH_STATUS = 0
|
|
BEGIN
|
|
SET @INDEX += 1
|
|
INSERT INTO @TABLE (SPEC_NAME,ITEM_VALUE,Area,SequenceItem,Display) VALUES
|
|
(@SPEC_NAME,@ITEM_VALUE,'POSITION',@INDEX,@Display)
|
|
FETCH NEXT FROM cursPosItems INTO @SPEC_NAME,@ITEM_VALUE,@Display
|
|
END
|
|
CLOSE cursPosItems
|
|
DEALLOCATE cursPosItems
|
|
FETCH NEXT FROM cursGroupCounter INTO @GROUP_COUNTER
|
|
END
|
|
CLOSE cursGroupCounter
|
|
DEALLOCATE cursGroupCounter
|
|
RETURN
|
|
END
|
|
GO
|
|
|
|
ALTER VIEW [dbo].[VWDD_ZUGFERD_VIEW_RECEIPT_TEMPLATE_ITEMS] AS
|
|
SELECT
|
|
A.SPEC_NAME,
|
|
A.ITEM_VALUE,
|
|
B.Area,
|
|
B.Row_Caption,
|
|
B.xPosition,
|
|
B.Y_eq_lastrow,
|
|
B.SequenceItem,
|
|
B.Display,
|
|
A.REFERENCE_GUID
|
|
FROM
|
|
(SELECT * FROM TBEDMI_ITEM_VALUE WHERE LEN(ITEM_VALUE) > 0 ) A INNER JOIN
|
|
(SELECT * FROM TBDD_ZUGFERD_VIEW_RECEIPT_TEMPLATE WHERE Active = 1) B ON A.SPEC_NAME = B.SPECNAME
|
|
GO
|
|
CREATE TABLE TBDD_COLUMNS_FORMAT
|
|
(
|
|
GUID INTEGER NOT NULL IDENTITY (1, 1),
|
|
MODULE VARCHAR(100) NOT NULL,
|
|
GRIDVIEW VARCHAR(100) NOT NULL,
|
|
COLUMN_TITLE VARCHAR(150) NOT NULL,
|
|
TYPE2FORMAT VARCHAR(100) NOT NULL,
|
|
ADDED_WHO VARCHAR(30) NOT NULL DEFAULT 'Digital Data',
|
|
ADDED_WHEN DATETIME NOT NULL DEFAULT (GETDATE()),
|
|
CHANGED_WHO VARCHAR(30),
|
|
CHANGED_WHEN DATETIME,
|
|
CONSTRAINT PK_TBDD_COLUMNS_FORMAT_GUID PRIMARY KEY (GUID)
|
|
)
|
|
GO
|
|
CREATE TRIGGER TBDD_COLUMNS_FORMAT_AFT_UPD ON TBDD_COLUMNS_FORMAT
|
|
FOR UPDATE
|
|
AS
|
|
UPDATE TBDD_COLUMNS_FORMAT SET CHANGED_WHEN = GETDATE()
|
|
FROM INSERTED
|
|
WHERE TBDD_COLUMNS_FORMAT.GUID = INSERTED.GUID
|
|
GO |