232 lines
10 KiB
Transact-SQL
232 lines
10 KiB
Transact-SQL
UPDATE TBDD_MODULES SET DB_VERSION = '1.5.7' WHERE SHORT_NAME = 'SIG_ENV_CR'
|
|
GO
|
|
|
|
|
|
--Changed 04.09.2025 MS Status 103 - Korrektur Y Werte mit Offset
|
|
--Changed 14.07.2025 MS Termination of commands, Fehler Rückgabe von select
|
|
--Changed 22.05.2025 MS Ablehnung über insert mit Envelope-Creator als User
|
|
--Changed 23.04.2025 MS Neuer Dokumenten und Withdrawn-Status
|
|
--CHANGED 06.06.2024 MS Status 2007, emailMeldungen integriert
|
|
--CHANGED 11.06.2024 MS Status 2007, Cursor für andere REceiver
|
|
ALTER TRIGGER [dbo].[TBSIG_ENVELOPE_HISTORY_AFT_INS] ON [dbo].[TBSIG_ENVELOPE_HISTORY]
|
|
WITH EXECUTE AS CALLER
|
|
FOR INSERT
|
|
AS
|
|
BEGIN TRY
|
|
DECLARE
|
|
@GUID BIGINT,
|
|
@ENVELOPE_ID INTEGER,
|
|
@STATUS INTEGER,
|
|
@USER_REFERENCE VARCHAR(100)
|
|
SELECT
|
|
@GUID = GUID,
|
|
@ENVELOPE_ID = ENVELOPE_ID,
|
|
@STATUS = STATUS,
|
|
@USER_REFERENCE = USER_REFERENCE
|
|
FROM INSERTED
|
|
PRINT 'STATUS IS: ' + CONVERT(VARCHAR(10),@STATUS)
|
|
--PRÜFEN OB ES EIN STATUS VOM WEBCLIENT IST 0 2
|
|
IF LEFT(CONVERT(VARCHAR(5),@STATUS),1) = 1
|
|
BEGIN
|
|
PRINT 'REGULÄRER 1erStatus.. '
|
|
IF @STATUS IN (1001, 1002, 1003, 1007, 1008, 1009,10009)
|
|
UPDATE TBSIG_ENVELOPE SET STATUS = @STATUS WHERE GUID = @ENVELOPE_ID;
|
|
IF @STATUS = 1003 /*ENVELOPE QUEUED*/
|
|
BEGIN
|
|
DECLARE @RECEL_GUID BIGINT,@POS_Y FLOAT, @OFFSET FLOAT = '0.3'
|
|
DECLARE cursChangeYPos CURSOR FOR
|
|
SELECT GUID, POSITION_Y FROM TBSIG_DOCUMENT_RECEIVER_ELEMENT where DOCUMENT_ID IN (SELECT GUID FROM TBSIG_ENVELOPE_DOCUMENT where ENVELOPE_ID = @ENVELOPE_ID) ORDER BY ADDED_WHEN
|
|
OPEN cursChangeYPos
|
|
FETCH NEXT FROM cursChangeYPos INTO @RECEL_GUID,@POS_Y
|
|
WHILE @@FETCH_STATUS = 0
|
|
BEGIN
|
|
--SET @POS_Y = @POS_Y - @OFFSET
|
|
UPDATE TBSIG_DOCUMENT_RECEIVER_ELEMENT SET POSITION_Y = @POS_Y - @OFFSET, CHANGED_WHO = 'OFFSET_Y_POS' WHERE GUID = @RECEL_GUID;
|
|
FETCH NEXT FROM cursChangeYPos INTO @RECEL_GUID,@POS_Y
|
|
END
|
|
CLOSE cursChangeYPos
|
|
DEALLOCATE cursChangeYPos
|
|
END
|
|
END
|
|
ELSE IF LEFT(CONVERT(VARCHAR(5),@STATUS),1) = 2
|
|
BEGIN
|
|
|
|
IF @STATUS = 2005 /*DOKUMENT SIGINIERT*/
|
|
BEGIN
|
|
DECLARE @COUNT_SIGNED INT, @COUNT_SIGNERS INT
|
|
SELECT @COUNT_SIGNED = COUNT(GUID) FROM TBSIG_ENVELOPE_HISTORY WHERE ENVELOPE_ID = @ENVELOPE_ID AND STATUS = 2005
|
|
SELECT @COUNT_SIGNERS = COUNT(REC_ID) FROM VWSIG_ENVELOPE_RECEIVER WHERE ENV_ID = @ENVELOPE_ID
|
|
IF @COUNT_SIGNED = @COUNT_SIGNERS
|
|
BEGIN
|
|
UPDATE TBSIG_ENVELOPE SET STATUS = 1006 WHERE GUID = @ENVELOPE_ID; /*FULLY SIGNED*/
|
|
INSERT INTO TBSIG_ENVELOPE_HISTORY (ENVELOPE_ID, USER_REFERENCE, STATUS, ACTION_DATE) VALUES (@ENVELOPE_ID, 'System', 1006, DATEADD(second, 5, GETDATE()));
|
|
END
|
|
ELSE
|
|
UPDATE TBSIG_ENVELOPE SET STATUS = 1005 WHERE GUID = @ENVELOPE_ID; /*PARTLY SIGNED*/
|
|
END
|
|
ELSE IF @STATUS = 2007 /*VORGANG DURCH USER ABGELEHNT*/
|
|
BEGIN
|
|
DECLARE @COMMENT VARCHAR(500),@REC_EMAIL VARCHAR(200),@EML_BODY_ADM VARCHAR(3000),@EML_SUBJ_ADM VARCHAR(3000),@EML_BODY_REC VARCHAR(3000),@EML_SUBJ_REC VARCHAR(3000),
|
|
@EML_BODY_REC2 VARCHAR(3000),@EML_SUBJ_REC2 VARCHAR(3000)
|
|
,@ADM_MAIL VARCHAR(250),@ADM_NAME VARCHAR(200),@TITLE VARCHAR(200),@NAME_PORTAL VARCHAR(100),@NAME_RECEIVER VARCHAR(150),@SENDING_PROFILE INT,@ENV_UUID VARCHAR(200)
|
|
SELECT @COMMENT = COMMENT,@REC_EMAIL = USER_REFERENCE FROM INSERTED;
|
|
SELECT @NAME_PORTAL = [EXTERNAL_PROGRAM_NAME],@SENDING_PROFILE = SENDING_PROFILE FROM [DD_ECM].[dbo].[TBSIG_CONFIG];
|
|
SELECT @EML_BODY_ADM = BODY,@EML_SUBJ_ADM = SUBJECT FROM TBSIG_EMAIL_TEMPLATE WHERE NAME = 'DocumentRejected_ADM';
|
|
SELECT @EML_BODY_REC = BODY,@EML_SUBJ_REC = SUBJECT FROM TBSIG_EMAIL_TEMPLATE WHERE NAME = 'DocumentRejected_REC';
|
|
SELECT @EML_BODY_REC2 = BODY,@EML_SUBJ_REC2 = SUBJECT FROM TBSIG_EMAIL_TEMPLATE WHERE NAME = 'DocumentRejected_REC_2';
|
|
|
|
SELECT @ADM_MAIL = USER_EMAIL,@ADM_NAME = USER_PRE_NAME, @TITLE = TITLE,@ENV_UUID = [ENVELOPE_UUID] FROM VWSIG_ENVELOPE_DATA WHERE ENVELOPE_ID = @ENVELOPE_ID;
|
|
|
|
SELECT @NAME_RECEIVER = [NAME] FROM [DD_ECM].[dbo].[VWSIG_ENVELOPE_RECEIVER] where ENV_ID = @ENVELOPE_ID AND REC_EMAIL = @REC_EMAIL;
|
|
IF @NAME_RECEIVER IS NULL
|
|
BEGIN
|
|
SET @NAME_RECEIVER = 'signFLOW - SYSTEM'
|
|
END
|
|
SET @EML_BODY_ADM = REPLACE(@EML_BODY_ADM,'[NAME_RECEIVER]',@NAME_RECEIVER)
|
|
SET @EML_BODY_ADM = REPLACE(@EML_BODY_ADM,'[NAME_SENDER]',@ADM_NAME)
|
|
--PRINT '#1' + @EML_BODY_ADM
|
|
--PRINT '#2' + @EML_BODY_ADM
|
|
SET @EML_BODY_ADM = REPLACE(@EML_BODY_ADM,'[DOCUMENT_TITLE]',@TITLE)
|
|
--PRINT '#3' + @EML_BODY_ADM
|
|
SET @EML_BODY_ADM = REPLACE(@EML_BODY_ADM,'[REASON]',@COMMENT)
|
|
--PRINT '#4' + @EML_BODY_ADM
|
|
SET @EML_BODY_ADM = REPLACE(@EML_BODY_ADM,'[NAME_PORTAL]',@NAME_PORTAL)
|
|
PRINT '@EML_BODY_ADM: '
|
|
PRINT @EML_BODY_ADM
|
|
SET @EML_SUBJ_ADM = REPLACE(@EML_SUBJ_ADM,'[DOCUMENT_TITLE]',@TITLE)
|
|
PRINT '@EML_SUBJ_ADM: '
|
|
PRINT @EML_SUBJ_ADM
|
|
PRINT 'EMAIL1...'
|
|
INSERT INTO [dbo].[TBEMLP_EMAIL_OUT] (EMAIL_ADRESS, EMAIL_SUBJ, EMAIL_BODY, ADDED_WHO, SENDING_PROFILE, REFERENCE_ID, REFERENCE_STRING, REMINDER_TYPE_ID, WF_ID)
|
|
VALUES (@ADM_MAIL, @EML_SUBJ_ADM, @EML_BODY_ADM, 'SIG RECEIVER REJECTED1', @SENDING_PROFILE, @ENVELOPE_ID, @ENV_UUID, 202377, @STATUS);
|
|
SET @EML_BODY_REC = REPLACE(@EML_BODY_REC,'[NAME_SENDER]',@ADM_NAME)
|
|
SET @EML_BODY_REC = REPLACE(@EML_BODY_REC,'[NAME_RECEIVER]',@NAME_RECEIVER)
|
|
SET @EML_BODY_REC = REPLACE(@EML_BODY_REC,'[DOCUMENT_TITLE]',@TITLE)
|
|
SET @EML_BODY_REC = REPLACE(@EML_BODY_REC,'[REASON]',@COMMENT)
|
|
SET @EML_BODY_REC = REPLACE(@EML_BODY_REC,'[NAME_PORTAL]',@NAME_PORTAL)
|
|
SET @EML_BODY_REC = REPLACE(@EML_BODY_REC,'[DOCUMENT_TITLE]',@TITLE)
|
|
SET @EML_SUBJ_REC = REPLACE(@EML_SUBJ_REC,'[DOCUMENT_TITLE]',@TITLE)
|
|
|
|
IF @REC_EMAIL <> @ADM_MAIL
|
|
BEGIN
|
|
PRINT 'EMAIL2...'
|
|
INSERT INTO [dbo].[TBEMLP_EMAIL_OUT] (EMAIL_ADRESS, EMAIL_SUBJ, EMAIL_BODY, ADDED_WHO, SENDING_PROFILE, REFERENCE_ID, REFERENCE_STRING, REMINDER_TYPE_ID, WF_ID)
|
|
VALUES (@REC_EMAIL, @EML_SUBJ_REC, @EML_BODY_REC, 'SIG RECEIVER REJECTED2', @SENDING_PROFILE, @ENVELOPE_ID, @ENV_UUID, 202377, @STATUS);
|
|
END
|
|
|
|
/*Andere Receiver über die Ablehnung informieren*/
|
|
SET @EML_SUBJ_REC2 = REPLACE(@EML_SUBJ_REC2,'[DOCUMENT_TITLE]',@TITLE)
|
|
DECLARE @BODY_RECEIVER NVARCHAR(MAX),@EML_RECEIVER2 VARCHAR(250)
|
|
DECLARE cursReceiver_TBSIG_ENVELOPE_HISTORY CURSOR FOR
|
|
SELECT [NAME], [REC_EMAIL] FROM [DD_ECM].[dbo].[VWSIG_ENVELOPE_RECEIVER] where ENV_ID = @ENVELOPE_ID AND REC_EMAIL <> @REC_EMAIL
|
|
OPEN cursReceiver_TBSIG_ENVELOPE_HISTORY
|
|
FETCH NEXT FROM cursReceiver_TBSIG_ENVELOPE_HISTORY INTO @NAME_RECEIVER,@EML_RECEIVER2
|
|
WHILE @@FETCH_STATUS = 0
|
|
BEGIN
|
|
PRINT '@EML_BODY_REC2: ' + @EML_BODY_REC2
|
|
SET @BODY_RECEIVER = @EML_BODY_REC2
|
|
SET @BODY_RECEIVER = REPLACE(@BODY_RECEIVER,'[NAME_SENDER]',@ADM_NAME)
|
|
SET @BODY_RECEIVER = REPLACE(@BODY_RECEIVER,'[NAME_RECEIVER]',@NAME_RECEIVER)
|
|
SET @BODY_RECEIVER = REPLACE(@BODY_RECEIVER,'[DOCUMENT_TITLE]',@TITLE)
|
|
SET @BODY_RECEIVER = REPLACE(@BODY_RECEIVER,'[REASON]',@COMMENT)
|
|
SET @BODY_RECEIVER = REPLACE(@BODY_RECEIVER,'[NAME_PORTAL]',@NAME_PORTAL)
|
|
SET @BODY_RECEIVER = REPLACE(@BODY_RECEIVER,'[DOCUMENT_TITLE]',@TITLE)
|
|
SET @BODY_RECEIVER = REPLACE(@BODY_RECEIVER,'[DOCUMENT_TITLE]',@TITLE)
|
|
PRINT 'EMAIL3...'
|
|
INSERT INTO [dbo].[TBEMLP_EMAIL_OUT] (EMAIL_ADRESS, EMAIL_SUBJ, EMAIL_BODY, ADDED_WHO, SENDING_PROFILE, REFERENCE_ID, REFERENCE_STRING, REMINDER_TYPE_ID, WF_ID)
|
|
VALUES (@EML_RECEIVER2, @EML_SUBJ_REC2, @BODY_RECEIVER, 'SIG RECEIVER REJECTED3', @SENDING_PROFILE, @ENVELOPE_ID, @ENV_UUID, 202377, @STATUS);
|
|
FETCH NEXT FROM cursReceiver_TBSIG_ENVELOPE_HISTORY INTO @NAME_RECEIVER,@EML_RECEIVER2
|
|
END
|
|
CLOSE cursReceiver_TBSIG_ENVELOPE_HISTORY
|
|
DEALLOCATE cursReceiver_TBSIG_ENVELOPE_HISTORY
|
|
UPDATE TBSIG_ENVELOPE SET STATUS = 10007,COMMENT = @COMMENT WHERE GUID = @ENVELOPE_ID; /*Umschlag abgelehnt*/
|
|
END
|
|
END
|
|
ELSE IF LEFT(CONVERT(VARCHAR(5),@STATUS),1) = 3
|
|
IF @STATUS = 3001 /*EMAIL OUT SIGNATUREINLADUNG*/
|
|
BEGIN
|
|
DECLARE @COUNT_MSG_OUT INT, @COUNT_USERS2_SIGN INT
|
|
SELECT @COUNT_MSG_OUT = COUNT(GUID) FROM TBSIG_ENVELOPE_HISTORY WHERE ENVELOPE_ID = @ENVELOPE_ID AND STATUS = 3001 ;
|
|
PRINT '@COUNT_MSG_OUT:' + CONVERT(VARCHAR(3),@COUNT_MSG_OUT)
|
|
SELECT @COUNT_USERS2_SIGN = COUNT(REC_ID) FROM VWSIG_ENVELOPE_RECEIVER WHERE ENV_ID = @ENVELOPE_ID;
|
|
PRINT '@@COUNT_USERS2_SIGN:' + CONVERT(VARCHAR(3),@COUNT_USERS2_SIGN)
|
|
IF @COUNT_MSG_OUT = @COUNT_USERS2_SIGN
|
|
UPDATE TBSIG_ENVELOPE SET STATUS = 1004 WHERE GUID = @ENVELOPE_ID; /*ALL INVITATIONS SENT*/
|
|
-- INSERT INTO TBSIG_ENVELOPE_HISTORY (ENVELOPE_ID,USER_REFERENCE,STATUS,ACTION_DATE) VALUES (@ENVELOPE_ID,'Digital Data Email-Service',1004,GETDATE())
|
|
END
|
|
|
|
END TRY
|
|
BEGIN CATCH
|
|
PRINT 'ERROR IN PROCEDURE: ' + CONVERT(VARCHAR(30),ERROR_PROCEDURE())
|
|
+ ' - ERROR-MESSAGE: '
|
|
+ CONVERT(VARCHAR(500),ERROR_MESSAGE())
|
|
END CATCH
|
|
GO
|
|
|
|
ALTER TABLE TBSIG_DOCUMENT_RECEIVER_ELEMENT
|
|
ADD CHANGED_WHO NVARCHAR(100);
|
|
GO
|
|
CREATE TRIGGER [dbo].[TBSIG_DOCUMENT_RECEIVER_ELEMENT_AFT_INS] ON [dbo].[TBSIG_DOCUMENT_RECEIVER_ELEMENT]
|
|
WITH EXECUTE AS CALLER
|
|
FOR INSERT
|
|
AS
|
|
BEGIN TRY
|
|
DECLARE
|
|
@POS_X FLOAT,
|
|
@POS_Y FLOAT
|
|
|
|
SELECT
|
|
@POS_X = POSITION_X,
|
|
@POS_Y = POSITION_Y
|
|
FROM INSERTED
|
|
|
|
SELECT @POS_X = ROUND(@POS_X, 1);
|
|
SELECT @POS_Y = ROUND(@POS_Y, 1);
|
|
UPDATE TBSIG_DOCUMENT_RECEIVER_ELEMENT SET
|
|
POSITION_X = @POS_X,
|
|
POSITION_Y = @POS_Y,
|
|
CHANGED_WHO = 'TBSIG_DOC_REC_EL_AFT_INS'
|
|
FROM INSERTED
|
|
WHERE TBSIG_DOCUMENT_RECEIVER_ELEMENT.GUID = INSERTED.GUID
|
|
|
|
|
|
END TRY
|
|
BEGIN CATCH
|
|
PRINT 'ERROR IN Trigger [TBSIG_DOCUMENT_RECEIVER_ELEMENT_AFT_INS]:'
|
|
+ ' - ERROR-MESSAGE: ' + CONVERT(VARCHAR(500),ERROR_MESSAGE())
|
|
END CATCH
|
|
GO
|
|
|
|
CREATE TRIGGER [dbo].[TBSIG_DOCUMENT_RECEIVER_ELEMENT_AFT_UPD] ON [dbo].[TBSIG_DOCUMENT_RECEIVER_ELEMENT]
|
|
WITH EXECUTE AS CALLER
|
|
FOR UPDATE
|
|
AS
|
|
BEGIN TRY
|
|
DECLARE
|
|
@POS_X FLOAT,
|
|
@POS_Y FLOAT,
|
|
@CHANGEDWHO NVARCHAR(100)
|
|
|
|
SELECT
|
|
@POS_X = POSITION_X,
|
|
@POS_Y = POSITION_Y,
|
|
@CHANGEDWHO = CHANGED_WHO
|
|
FROM INSERTED
|
|
IF @CHANGEDWHO <> 'OFFSET_Y_POS'
|
|
BEGIN
|
|
SELECT @POS_X = ROUND(@POS_X, 1);
|
|
SELECT @POS_Y = ROUND(@POS_Y, 1);
|
|
UPDATE TBSIG_DOCUMENT_RECEIVER_ELEMENT SET
|
|
POSITION_X = @POS_X,
|
|
POSITION_Y = @POS_Y,
|
|
CHANGED_WHO = 'TBSIG_DOC_REC_EL_AFT_UPD'
|
|
FROM INSERTED
|
|
WHERE TBSIG_DOCUMENT_RECEIVER_ELEMENT.GUID = INSERTED.GUID
|
|
END
|
|
|
|
END TRY
|
|
BEGIN CATCH
|
|
PRINT 'ERROR IN Trigger [TBSIG_DOCUMENT_RECEIVER_ELEMENT_AFT_UPD]:'
|
|
+ ' - ERROR-MESSAGE: ' + CONVERT(VARCHAR(500),ERROR_MESSAGE())
|
|
END CATCH
|
|
GO |