1183 lines
49 KiB
Transact-SQL

-----------------------------------------------------------------------------------------
-- Nur bei der erste Ausführung !!!
ALTER TABLE TBPMO_KONFIGURATION
ADD ENTITY_TABLENAME VARCHAR(50) DEFAULT 'TBPMO_ENTITY_TABLE' NOT NULL
GO
-----------------------------------------------------------------------------------------
ALTER TABLE TBPMO_FORM_SQL ALTER COLUMN SQL_COMMAND NVARCHAR(MAX);
ALTER TABLE TBPMO_FORM_SQL ALTER COLUMN SQL_COMMAND1 NVARCHAR(MAX);
ALTER TABLE TBPMO_FORM_SQL ALTER COLUMN SQL_COMMAND2 NVARCHAR(MAX);
ALTER TABLE TBPMO_FORM_SQL ALTER COLUMN SQL_COMMAND3 NVARCHAR(MAX);
ALTER TABLE TBPMO_FORM_SQL ALTER COLUMN SQL_COMMAND4 NVARCHAR(MAX);
GO
CREATE PROCEDURE PRPMO_CREATE_ENTITY_TABLE(@pENTITY_ID INT)
--ALTER PROCEDURE PRPMO_CREATE_ENTITY_TABLE(@pENTITY_ID INT)
AS
DECLARE @SQL_BEGIN NVARCHAR(MAX),
@SQL_END NVARCHAR(MAX),
@SQL NVARCHAR(MAX),
@SQL_DEF_CONSTR NVARCHAR(MAX),
@CONTROL_ID INT,
@RESULT NVARCHAR(MAX),
@TYPEID INT,
@TABINDEX INT,
@ZAEHLER INT = 1,
@DEFAULT VARCHAR(50),
@COL_NAME VARCHAR(50),
@ENTITY_TABLENAME VARCHAR(50)
--select Top 10 * from VWTEMP_PMO_FORM1
DECLARE c_SPALTENNAMEN CURSOR FOR SELECT T.GUID AS CONTROL_ID,'[' + T.COL_NAME + ']' AS 'COL_NAME',T2.GUID AS TYP_ID,T1.TAB_INDEX, T.DEFAULT_VALUE FROM TBPMO_CONTROL T,TBPMO_CONTROL_SCREEN T1,TBPMO_CONTROL_TYPE T2
WHERE T.SHOW_COLUMN = 1 AND T.[COL_NAME] <> '' AND T.GUID = T1.CONTROL_ID AND T.CONTROL_TYPE_ID = T2.GUID AND T.FORM_ID = @pENTITY_ID AND LEN(ISNULL(T.COL_NAME,'')) > 0 AND T.CONTROL_TYPE_ID NOT IN (1,5)
--UNION
--SELECT T.GUID AS CONTROL_ID,'[' + T3.CAPTION + ']' AS 'COL_NAME',T2.GUID as TYP_ID,T1.TAB_INDEX, T.DEFAULT_VALUE FROM TBPMO_CONTROL T,TBPMO_CONTROL_SCREEN T1,TBPMO_CONTROL_TYPE T2, TBPMO_CONTROL_LANGUAGE T3
--WHERE T.GUID = T1.CONTROL_ID AND T.CONTROL_TYPE_ID = T2.GUID AND T1.GUID = T3.CONTROL_SCREEN_ID AND T.FORM_ID = 13 AND T.CONTROL_TYPE_ID = 1 AND LEN(ISNULL(T.SQL_COMMAND_1,'')) > 0
ORDER BY TAB_INDEX
BEGIN
SELECT @ENTITY_TABLENAME = ENTITY_TABLENAME FROM TBPMO_KONFIGURATION WHERE GUID = 1
SET @SQL = 'IF EXISTS (SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = ''@TABLE@ENT'')
drop table @TABLE@ENT' + CHAR(13)
SET @SQL = REPLACE(@SQL,'@ENT',CONVERT(VARCHAR(3),@pENTITY_ID))
SET @SQL = REPLACE(@SQL,'@TABLE',@ENTITY_TABLENAME)
EXEC sp_executesql @SQL
SET @SQL_BEGIN = 'CREATE TABLE @TABLE@ENT(' + CHAR(13) +
'[Record-ID] INT NOT NULL,' + CHAR(13) +
'ROW_COLOR VARCHAR(50) NOT NULL DEFAULT '''',' + CHAR(13)
SET @SQL_BEGIN = REPLACE(@SQL_BEGIN,'@ENT',CONVERT(VARCHAR(3),@pENTITY_ID))
SET @SQL_BEGIN = REPLACE(@SQL_BEGIN,'@TABLE',@ENTITY_TABLENAME)
--SET @SQL_END = ',T.ADDED_WHO as AddedWho,T.ADDED_WHEN as AddedWhen, T.CHANGED_WHO As ChangedWho, T.CHANGED_WHEN As ChangedWhen FROM TBPMO_RECORD T, TBPMO_FORM T1 WHERE T.FORM_ID = T1.GUID AND T.FORM_ID = @FORM_ID'
SET @SQL_END = '[file_exists] BIT NOT NULL DEFAULT 0,' + CHAR(13) + '[file_count] INT NOT NULL DEFAULT 0,' + CHAR(13) + 'AddedWho VARCHAR(50)' + CHAR(13) + ',AddedWhen DATETIME' + CHAR(13) + ', ChangedWho VARCHAR(50)' + CHAR(13) + ',ChangedWhen DATETIME,' + CHAR(13) + 'CONSTRAINT PK_@TABLE@ENT PRIMARY KEY([Record-ID]))' + CHAR(13)
SET @SQL_END = REPLACE(@SQL_END,'@ENT',CONVERT(VARCHAR(3),@pENTITY_ID))
SET @SQL_END = REPLACE(@SQL_END,'@TABLE',@ENTITY_TABLENAME)
OPEN c_SPALTENNAMEN
FETCH NEXT FROM c_SPALTENNAMEN INTO @CONTROL_ID,@COL_NAME,@TYPEID,@TABINDEX,@DEFAULT
WHILE @@FETCH_STATUS = 0
BEGIN
SET @ZAEHLER = @ZAEHLER + 1
BEGIN
IF @TYPEID IN(10,11) --CheckBox,RadioBox
BEGIN
IF @DEFAULT = 'False'
SET @DEFAULT = '0'
ELSE
SET @DEFAULT = '1'
SET @SQL_BEGIN = @SQL_BEGIN + @COL_NAME + ' BIT NOT NULL DEFAULT ' + @DEFAULT + ',' + CHAR(13)
END
ELSE IF @TYPEID = 6 --Picturebox
BEGIN
SET @SQL_BEGIN = @SQL_BEGIN + @COL_NAME + ' VARBINARY(MAX),' + CHAR(13)
ENd
ELSE IF @TYPEID IN(7,12,14) --GridView,CheckedListBox,GridViewCheckable
BEGIN
SET @SQL_BEGIN = @SQL_BEGIN + @COL_NAME + ' VARCHAR(MAX),' + CHAR(13)
END
ELSE IF @TYPEID = 1 --Label
BEGIN
SET @SQL_BEGIN = @SQL_BEGIN + @COL_NAME + ' VARCHAR(MAX),' + CHAR(13)
END
ELSE IF @TYPEID = 4 --DatePicker
BEGIN
SET @SQL_BEGIN = @SQL_BEGIN + @COL_NAME + ' VARCHAR(10),' + CHAR(13)
END
ELSE
BEGIN
SET @SQL_BEGIN = @SQL_BEGIN + @COL_NAME + ' VARCHAR(MAX),' + CHAR(13)
IF LEN(ISNULL(@DEFAULT,'')) > 0
BEGIN
DECLARE @TEMP_COL_NAME VARCHAR(50)
SET @TEMP_COL_NAME = REPLACE(@COL_NAME,' ','')
SET @TEMP_COL_NAME = REPLACE(@TEMP_COL_NAME,'[','')
SET @TEMP_COL_NAME = REPLACE(@TEMP_COL_NAME,']','')
IF LEN(@SQL_DEF_CONSTR) > 0
SET @SQL_DEF_CONSTR = @SQL_DEF_CONSTR + CHAR(13) + 'ALTER TABLE @TABLE@ENT ADD CONSTRAINT DEF@TABLE@ENT_@COL_NAME DEFAULT N''@DEFAULT_VALUE'' FOR ' + @COL_NAME + ';'
ELSE
SET @SQL_DEF_CONSTR = 'ALTER TABLE @TABLE@ENT ADD CONSTRAINT DEF@TABLE@ENT_@COL_NAME DEFAULT N''@DEFAULT_VALUE'' FOR ' + @COL_NAME + ';'
BEGIN
SET @SQL_DEF_CONSTR = REPLACE(@SQL_DEF_CONSTR,'@DEFAULT_VALUE',@DEFAULT)
SET @SQL_DEF_CONSTR = REPLACE(@SQL_DEF_CONSTR,'@COL_NAME',@TEMP_COL_NAME)
SET @SQL_DEF_CONSTR = REPLACE(@SQL_DEF_CONSTR,'@ENT',CONVERT(VARCHAR(3),@pENTITY_ID))
SET @SQL_DEF_CONSTR = REPLACE(@SQL_DEF_CONSTR,'@TABLE',@ENTITY_TABLENAME)
END
END
END
END
FETCH NEXT FROM c_SPALTENNAMEN INTO @CONTROL_ID,@COL_NAME,@TYPEID,@TABINDEX,@DEFAULT
END
CLOSE c_SPALTENNAMEN
DEALLOCATE c_SPALTENNAMEN
SET @RESULT = @SQL + @SQL_BEGIN + @SQL_END
--PRINT @RESULT
EXEC sp_executesql @RESULT
IF LEN(@SQL_DEF_CONSTR) > 0
BEGIN
--PRINT @SQL_DEF_CONSTR
EXEC sp_executesql @SQL_DEF_CONSTR
END
END
GO
-----------------------------------------------------------------------------------------
CREATE PROCEDURE PRPMO_DOC_RECORD_LINK_UPD_ENTITY_TABLE (@pRECID INT)
--ALTER PROCEDURE PRPMO_DOC_RECORD_LINK_UPD_ENTITY_TABLE (@pRECID INT)
AS
DECLARE @SQL NVARCHAR(MAX),
@COUNT_DOCS INT,
@DOC_EXISTS TINYINT,
@ENT_ID INT,
@ENTITY_TABLENAME VARCHAR(50)
BEGIN
SELECT @ENTITY_TABLENAME = ENTITY_TABLENAME FROM TBPMO_KONFIGURATION WHERE GUID = 1
SELECT @ENT_ID = FORM_ID FROM TBPMO_RECORD WHERE GUID = @pRECID
SELECT @COUNT_DOCS = COUNT(GUID) FROM TBPMO_DOC_RECORD_LINK WHERE RECORD_ID = @pRECID
IF @COUNT_DOCS > 0
SET @DOC_EXISTS = 1
ELSE
SET @DOC_EXISTS = 0
SET @SQL = 'UPDATE @TABLE@ENT_ID SET [file_exists] = @DOC_EXISTS, [file_count] = @COUNT_DOCS WHERE [Record-ID] = @pRECID'
SET @SQL = REPLACE(@SQL,'@pRECID',CONVERT(VARCHAR(10),@pRECID))
SET @SQL = REPLACE(@SQL,'@DOC_EXISTS',CONVERT(VARCHAR(1),@DOC_EXISTS))
SET @SQL = REPLACE(@SQL,'@COUNT_DOCS',CONVERT(VARCHAR(10),@COUNT_DOCS))
SET @SQL = REPLACE(@SQL,'@ENT_ID',CONVERT(VARCHAR(3),@ENT_ID))
SET @SQL = REPLACE(@SQL,'@TABLE',@ENTITY_TABLENAME)
EXEC sp_executesql @SQL
END
GO
-----------------------------------------------------------------------------------------
CREATE PROCEDURE PRPMO_ENTITY_TABLE_IMPORT_RECORDS(@pENTITY_ID INT)
--ALTER PROCEDURE PRPMO_ENTITY_TABLE_IMPORT_RECORDS(@pENTITY_ID INT)
AS
DECLARE @REC_ID INT,
@SQL_INSERT_REC NVARCHAR(MAX),
@SQL_DELETE NVARCHAR(MAX),
@SQL_UPDATE NVARCHAR(MAX),
@CONTROL_ID INT,
@INSERT_COMAMND NVARCHAR(MAX),
@TYPEID INT,
@TABINDEX INT,
@DEFAULT VARCHAR(50),
@COL_NAME VARCHAR(50),
@ENTITY_TABLENAME VARCHAR(50)
DECLARE cursor_Records CURSOR FOR SELECT GUID FROM TBPMO_RECORD WHERE FORM_ID = @pENTITY_ID
BEGIN
SELECT @ENTITY_TABLENAME = ENTITY_TABLENAME FROM TBPMO_KONFIGURATION WHERE GUID = 1
SET @SQL_DELETE = 'DELETE FROM @TABLE@ENT'
SET @SQL_DELETE = REPLACE(@SQL_DELETE,'@ENT',CONVERT(VARCHAR(3),@pENTITY_ID))
SET @SQL_DELETE = REPLACE(@SQL_DELETE,'@TABLE',@ENTITY_TABLENAME)
EXEC sp_executesql @SQL_DELETE
OPEN cursor_Records
FETCH NEXT FROM cursor_Records INTO @REC_ID
WHILE @@FETCH_STATUS = 0
BEGIN
SET @SQL_INSERT_REC = 'INSERT INTO @TABLE@ENT([Record-ID],ROW_COLOR, AddedWho, AddedWhen, ChangedWho, ChangedWhen) SELECT GUID,COLOR,ADDED_WHO,ADDED_WHEN,CHANGED_WHO,CHANGED_WHEN FROM TBPMO_RECORD WHERE GUID = @REC_ID'
SET @SQL_INSERT_REC = REPLACE(@SQL_INSERT_REC,'@ENT',CONVERT(VARCHAR(3),@pENTITY_ID))
SET @SQL_INSERT_REC = REPLACE(@SQL_INSERT_REC,'@TABLE',@ENTITY_TABLENAME)
SET @SQL_INSERT_REC = REPLACE(@SQL_INSERT_REC,'@REC_ID',CONVERT(VARCHAR(10),@REC_ID))
--PRINT @SQL_INSERT_REC
EXEC sp_executesql @SQL_INSERT_REC
EXEC dbo.PRPMO_DOC_RECORD_LINK_UPD_ENTITY_TABLE @REC_ID
DECLARE cursor_Columns CURSOR FOR SELECT T.GUID,'[' + T.COL_NAME + ']' AS 'COL_NAME',T2.GUID AS TYP_ID FROM TBPMO_CONTROL T,TBPMO_CONTROL_SCREEN T1,TBPMO_CONTROL_TYPE T2
WHERE T.SHOW_COLUMN = 1 AND T.GUID = T1.CONTROL_ID AND T.CONTROL_TYPE_ID = T2.GUID AND T.FORM_ID = @pENTITY_ID AND LEN(ISNULL(T.COL_NAME,'')) > 0 AND T.CONTROL_TYPE_ID NOT IN (1,5)
ORDER BY TAB_INDEX
BEGIN
OPEN cursor_Columns
FETCH NEXT FROM cursor_Columns INTO @CONTROL_ID,@COL_NAME,@TYPEID
WHILE @@FETCH_STATUS = 0
BEGIN
--PRINT 'CONTROL-ID: ' + CONVERT(VARCHAR(3),@CONTROL_ID) + ' - REC-ID: ' + CONVERT(VARCHAR(10),@REC_ID)
SET @SQL_UPDATE = 'UPDATE @TABLE@ENT SET @COL_NAME = ''@VALUE'' WHERE [Record-ID] = @REC_ID'
SET @SQL_UPDATE = REPLACE(@SQL_UPDATE,'@COL_NAME',@COL_NAME)
SET @SQL_UPDATE = REPLACE(@SQL_UPDATE,'@ENT',CONVERT(VARCHAR(3),@pENTITY_ID))
SET @SQL_UPDATE = REPLACE(@SQL_UPDATE,'@TABLE',@ENTITY_TABLENAME)
--
IF @TYPEID = 6 --Picturebox
BEGIN
DECLARE @VALUE_VBM VARBINARY(MAX)
IF EXISTS(SELECT GUID FROM TBPMO_CONTROL_IMAGE WHERE CONTROL_ID = @CONTROL_ID AND RECORD_ID = @REC_ID)
BEGIN
SET @SQL_UPDATE = REPLACE(@SQL_UPDATE,'''@VALUE''','(SELECT IMG FROM TBPMO_CONTROL_IMAGE WHERE CONTROL_ID = @CONTROL_ID AND RECORD_ID = @REC_ID)')
SET @SQL_UPDATE = REPLACE(@SQL_UPDATE,'@REC_ID',CONVERT(VARCHAR(10),@REC_ID))
SET @SQL_UPDATE = REPLACE(@SQL_UPDATE,'@CONTROL_ID',CONVERT(VARCHAR(10),@CONTROL_ID))
EXEC sp_executesql @SQL_UPDATE
END
END
ELSE
BEGIN
DECLARE @VALUE VARCHAR(MAX)
IF EXISTS(SELECT GUID FROM TBPMO_CONTROL_VALUE WHERE CONTROL_ID = @CONTROL_ID AND RECORD_ID = @REC_ID)
BEGIN
IF @TYPEID IN(10,11) --CheckBox,RadioBox
BEGIN
SELECT @VALUE = VALUE FROM TBPMO_CONTROL_VALUE WHERE CONTROL_ID = @CONTROL_ID AND RECORD_ID = @REC_ID
SET @SQL_UPDATE = REPLACE(@SQL_UPDATE,'@VALUE',@VALUE)
END
ELSE IF @TYPEID IN(7,12,14)
BEGIN
SELECT @VALUE = dbo.FNPMO_GET_CONTROL_VALUES(@CONTROL_ID, @REC_ID)
SET @SQL_UPDATE = REPLACE(@SQL_UPDATE,'@VALUE',@VALUE)
END
ELSE
SET @SQL_UPDATE = REPLACE(@SQL_UPDATE,'''@VALUE''','(SELECT VALUE FROM TBPMO_CONTROL_VALUE WHERE CONTROL_ID = @CONTROL_ID AND RECORD_ID = @REC_ID)')
SET @SQL_UPDATE = REPLACE(@SQL_UPDATE,'@REC_ID',CONVERT(VARCHAR(10),@REC_ID))
SET @SQL_UPDATE = REPLACE(@SQL_UPDATE,'@CONTROL_ID',CONVERT(VARCHAR(10),@CONTROL_ID))
--PRINT @SQL_UPDATE
EXEC sp_executesql @SQL_UPDATE
END
END
FETCH NEXT FROM cursor_Columns INTO @CONTROL_ID,@COL_NAME,@TYPEID
END
CLOSE cursor_Columns
DEALLOCATE cursor_Columns
END
FETCH NEXT FROM cursor_Records INTO @REC_ID
END
CLOSE cursor_Records
DEALLOCATE cursor_Records
END
GO
-----------------------------------------------------------------------------------------
CREATE PROCEDURE PRPMO_ENTITY_TABLE_UPDATE_COLUMN(@ENTITY_ID INT,@RECORD_ID INT, @CONTROL_ID INTEGER, @COL_NAME VARCHAR(50), @CHANGED_WHO VARCHAR(50),@VALUE_NEW VARCHAR(MAX) = NULL)
--ALTER PROCEDURE PRPMO_ENTITY_TABLE_UPDATE_COLUMN(@ENTITY_ID INT,@RECORD_ID INT, @COL_NAME VARCHAR(50),@CHANGED_WHO VARCHAR(50),@VALUE_NEW VARCHAR(MAX) = NULL)
AS
DECLARE @SQL_UPDATE NVARCHAR(MAX),
@ENTITY_TABLENAME VARCHAR(50),
@TYPE_ID INT
BEGIN
SELECT @ENTITY_TABLENAME = ENTITY_TABLENAME FROM TBPMO_KONFIGURATION WHERE GUID = 1
SELECT @TYPE_ID = CONTROL_TYPE_ID FROM TBPMO_CONTROL WHERE GUID = @CONTROL_ID
IF @TYPE_ID IN(7,12,14) --DGV,CheckedListBox,ListBox
SELECT @VALUE_NEW = dbo.FNPMO_GET_CONTROL_VALUES(@CONTROL_ID,@RECORD_ID)
IF @VALUE_NEW IS NULL
SET @SQL_UPDATE = 'UPDATE @TABLE@ENT_ID SET [@COL_NAME] = NULL,ChangedWho = ''@CHANGED_WHO'',ChangedWhen = ''@CHANGED_WHEN'' WHERE [Record-ID] = @RECORD_ID'
ELSE
SET @SQL_UPDATE = 'UPDATE @TABLE@ENT_ID SET [@COL_NAME] = ''@VALUE_NEW'',ChangedWho = ''@CHANGED_WHO'',ChangedWhen = ''@CHANGED_WHEN'' WHERE [Record-ID] = @RECORD_ID'
SET @SQL_UPDATE = REPLACE(@SQL_UPDATE,'@ENT_ID',CONVERT(VARCHAR(3),@ENTITY_ID))
SET @SQL_UPDATE = REPLACE(@SQL_UPDATE,'@TABLE',@ENTITY_TABLENAME)
SET @SQL_UPDATE = REPLACE(@SQL_UPDATE,'@VALUE_NEW',@VALUE_NEW)
SET @SQL_UPDATE = REPLACE(@SQL_UPDATE,'@COL_NAME',@COL_NAME)
SET @SQL_UPDATE = REPLACE(@SQL_UPDATE,'@RECORD_ID',CONVERT(VARCHAR(10),@RECORD_ID))
SET @SQL_UPDATE = REPLACE(@SQL_UPDATE,'@CHANGED_WHEN',CONVERT(VARCHAR(25),GETDATE()))
SET @SQL_UPDATE = REPLACE(@SQL_UPDATE,'@CHANGED_WHO',@CHANGED_WHO)
EXEC sp_executesql @SQL_UPDATE
END
GO
-----------------------------------------------------------------------------------------
--CREATE PROCEDURE PRPMO_ALTER_ENTITY_TABLE(@pENTITY_ID INT,@pCOL_NAME VARCHAR(50),@pCOL_NAME_OLD VARCHAR(50),@pTYP_ID INT,@pDEFAULT_VALUE VARCHAR(100),@pACTION TINYINT = 0)
CREATE PROCEDURE PRPMO_ALTER_ENTITY_TABLE(@pENTITY_ID INT,@pCOL_NAME VARCHAR(50),@pCOL_NAME_OLD VARCHAR(50),@pTYP_ID INT,@pDEFAULT_VALUE VARCHAR(100),@pACTION TINYINT = 0)
AS
DECLARE @SQL NVARCHAR(MAX),
@DEFAULT_VALUE VARCHAR(100),
@ENTITY_TABLENAME VARCHAR(50),
@TEMP_COL_NAME VARCHAR(50),
@SQL_DEF NVARCHAR(MAX),
@DFNAME VARCHAR(50),
@DROP NVARCHAR(500)
BEGIN
SELECT @ENTITY_TABLENAME = ENTITY_TABLENAME FROM TBPMO_KONFIGURATION WHERE GUID = 1
SET @DEFAULT_VALUE = @pDEFAULT_VALUE
IF @pACTION = 0 -- Für Insert
BEGIN
SET @SQL = 'ALTER TABLE @TABLE@ENT' + CHAR(13) + 'ADD [@COL_NAME]'
SET @SQL = REPLACE(@SQL,'@ENT',CONVERT(VARCHAR(3),@pENTITY_ID))
SET @SQL = REPLACE(@SQL,'@TABLE',@ENTITY_TABLENAME)
SET @SQL = REPLACE(@SQL,'@COL_NAME',@pCOL_NAME)
IF @pTYP_ID IN(10,11) --CheckBox,RadioBox
BEGIN
IF @DEFAULT_VALUE = 'False'
SET @DEFAULT_VALUE = '0'
ELSE
SET @DEFAULT_VALUE = '1'
SET @SQL = @SQL +' BIT NOT NULL DEFAULT ' + @DEFAULT_VALUE + CHAR(13)
END
ELSE IF @pTYP_ID = 6 --Picturebox
SET @SQL = @SQL +' VARBINARY(MAX)' + CHAR(13)
ELSE IF @pTYP_ID IN(7,12,14) --GridView,CheckedListBox,GridViewCheckable
SET @SQL = @SQL + ' VARCHAR(MAX)' + CHAR(13)
ELSE IF @pTYP_ID = 4 --DatePicker
SET @SQL = @SQL + ' VARCHAR(10)' + CHAR(13)
ELSE
BEGIN
IF LEN(ISNULL(@DEFAULT_VALUE,'')) > 0
BEGIN
SET @SQL = @SQL + ' VARCHAR(MAX) DEFAULT ''@DEFAULT''' + CHAR(13)
SET @SQL = REPLACE(@SQL,'@DEFAULT',@DEFAULT_VALUE)
END
ELSE
SET @SQL = @SQL + ' VARCHAR(MAX)' + CHAR(13)
END
--PRINT @SQL
EXEC sp_executesql @SQL
END
ELSE IF @pACTION = 1 -- Für Update
BEGIN
IF LEN(ISNULL(@pCOL_NAME_OLD,'')) > 0
BEGIN
SET @SQL = '@TABLE@ENT.[@OLDNAME]'
SET @SQL = REPLACE(@SQL,'@ENT',CONVERT(VARCHAR(3),@pENTITY_ID))
SET @SQL = REPLACE(@SQL,'@TABLE',@ENTITY_TABLENAME)
SET @SQL = REPLACE(@SQL,'@OLDNAME',@pCOL_NAME_OLD)
--PRINT @COL_NAME
--PRINT @TABLENAME_COL
--Update des Columnnames
EXEC sp_RENAME @SQL, @pCOL_NAME, 'COLUMN'
SET @SQL = 'ALTER TABLE @TABLE@ENT ALTER COLUMN '
SET @SQL = REPLACE(@SQL,'@ENT',CONVERT(VARCHAR(3),@pENTITY_ID))
SET @SQL = REPLACE(@SQL,'@TABLE',@ENTITY_TABLENAME)
SET @SQL = @SQL + '[' + @pCOL_NAME + '] '
IF @pTYP_ID IN(10,11) --CheckBox,RadioBox
BEGIN
IF @DEFAULT_VALUE = 'False'
SET @DEFAULT_VALUE = '0'
ELSE
SET @DEFAULT_VALUE = '1'
SET @SQL = @SQL +'BIT NOT NULL DEFAULT ' + @DEFAULT_VALUE
END
ELSE IF @pTYP_ID = 6 --Picturebox
SET @SQL = @SQL +'VARBINARY(MAX)'
ELSE IF @pTYP_ID IN(7,12,14) --GridView,CheckedListBox,GridViewCheckable
SET @SQL = @SQL + 'VARCHAR(MAX)'
ELSE IF @pTYP_ID = 4 --DatePicker
SET @SQL = @SQL + 'VARCHAR(10)'
ELSE
BEGIN
SET @SQL = @SQL + 'VARCHAR(MAX)'
IF @DEFAULT_VALUE IS NOT NULL
BEGIN
SET @TEMP_COL_NAME = REPLACE(@TEMP_COL_NAME,' ','')
SET @SQL_DEF = 'ALTER TABLE @TABLE@ENT ADD CONSTRAINT DEF@TABLE@ENT_@COL_NAME DEFAULT N''@DEFAULT_VALUE'' FOR [' + @pCOL_NAME + ']'
SET @SQL_DEF = REPLACE(@SQL_DEF,'@DEFAULT_VALUE',@DEFAULT_VALUE)
SET @SQL_DEF = REPLACE(@SQL_DEF,'@ENT',CONVERT(VARCHAR(3),@pENTITY_ID))
SET @SQL_DEF = REPLACE(@SQL_DEF,'@TABLE',@ENTITY_TABLENAME)
SET @SQL_DEF = REPLACE(@SQL_DEF,'@COL_NAME',@TEMP_COL_NAME)
END
END
--PRINT '@ALTER SQL-COMMAND: ' + @SQL
EXEC sp_executesql @SQL
SET @DFNAME = 'DEF@TABLE@ENT_@COL_NAME'
SET @DFNAME = REPLACE(@DFNAME,'@ENT',CONVERT(VARCHAR(3),@pENTITY_ID))
SET @DFNAME = REPLACE(@DFNAME,'@TABLE',@ENTITY_TABLENAME)
SET @DFNAME = REPLACE(@DFNAME,'@COL_NAME',@TEMP_COL_NAME)
--PRINT '@DFNAME: ' + @DFNAME
IF EXISTS(SELECT * FROM sys.default_constraints WHERE name = @DFNAME)
BEGIN
--PRINT 'DEFAULT KEY EXISTS'
SET @DROP = 'ALTER TABLE @TABLE@ENT DROP CONSTRAINT DEF@TABLE@ENT_@COL_NAME'
SET @DROP = REPLACE(@DROP,'@ENT',CONVERT(VARCHAR(3),@pENTITY_ID))
SET @DROP = REPLACE(@DROP,'@TABLE',@ENTITY_TABLENAME)
SET @DROP = REPLACE(@DROP,'@COL_NAME',@TEMP_COL_NAME)
--PRINT @DROP
EXEC sp_executesql @DROP
END
IF LEN(@SQL_DEF) > 0 AND LEN(@DEFAULT_VALUE) > 0
BEGIN
--PRINT '@SQL DEFAULT CONSTRAINT: ' + @SQL_DEF
EXEC sp_executesql @SQL_DEF
END
END
END
ELSE IF @pACTION = 2 -- Für Delete
BEGIN
SET @DFNAME = 'DEF@TABLE@ENT_@COL_NAME'
SET @DFNAME = REPLACE(@DFNAME,'@ENT',CONVERT(VARCHAR(3),@pENTITY_ID))
SET @DFNAME = REPLACE(@DFNAME,'@TABLE',@ENTITY_TABLENAME)
SET @DFNAME = REPLACE(@DFNAME,'@COL_NAME',@TEMP_COL_NAME)
--PRINT '@DFNAME: ' + @DFNAME
IF EXISTS(SELECT * FROM sys.default_constraints WHERE name = @DFNAME)
BEGIN
--PRINT 'DEFAULT KEY EXISTS'
SET @DROP = 'ALTER TABLE @TABLE@ENT DROP CONSTRAINT DEF@TABLE@ENT_@COL_NAME'
SET @DROP = REPLACE(@DROP,'@ENT',CONVERT(VARCHAR(3),@pENTITY_ID))
SET @DROP = REPLACE(@DROP,'@TABLE',@ENTITY_TABLENAME)
SET @DROP = REPLACE(@DROP,'@COL_NAME',@TEMP_COL_NAME)
--PRINT @DROP
EXEC sp_executesql @DROP
END
SET @SQL = 'ALTER TABLE @TABLE@ENT' + CHAR(13) + ' DROP COLUMN [@COL_NAME]'
SET @SQL = REPLACE(@SQL,'@ENT',CONVERT(VARCHAR(3),@pENTITY_ID))
SET @SQL = REPLACE(@SQL,'@TABLE',@ENTITY_TABLENAME)
SET @SQL = REPLACE(@SQL,'@COL_NAME',@pCOL_NAME)
EXEC sp_executesql @DROP
END
EXEC PRPMO_CREATE_ENTITY_TABLE_VIEW @pENTITY_ID
END
GO
ALTER TRIGGER [dbo].[TBPMO_CONTROL_VALUE_AFT_INS] ON [dbo].[TBPMO_CONTROL_VALUE]
FOR INSERT
AS
DECLARE
@RECORD_ID INTEGER,
@CONTROL_ID INTEGER,
@ADDED_WHO VARCHAR(50),
@VALUE_NEW VARCHAR(MAX),
@DOC_ID INTEGER,
@USER_ID INTEGER,
@USER_ID_ECM INTEGER,
@RIGHT INTEGER,
@COUNTER_CONTROL_UPDATE_ID INTEGER,
@ENTITY_ID INTEGER,
@COL_NAME VARCHAR(50)
SELECT
@RECORD_ID = INSERTED.RECORD_ID,
@CONTROL_ID = INSERTED.CONTROL_ID,
@ADDED_WHO = INSERTED.ADDED_WHO,
@VALUE_NEW = INSERTED.VALUE,
@ENTITY_ID = T.FORM_ID,
@COL_NAME = T1.COL_NAME
FROM INSERTED, TBPMO_RECORD T,TBPMO_CONTROL T1
WHERE INSERTED.RECORD_ID = T.GUID AND
INSERTED.CONTROL_ID = T1.GUID
EXEC PRPMO_ENTITY_TABLE_UPDATE_COLUMN @ENTITY_ID, @RECORD_ID,@CONTROL_ID, @COL_NAME,@ADDED_WHO,@VALUE_NEW
IF EXISTS(SELECT CONTROL_ID FROM TBPMO_APPOINTMENT_CONTROLS WHERE CONTROL_ID = @CONTROL_ID)
BEGIN
DECLARE @SUBJECT VARCHAR(100),
@LOCATION VARCHAR(100),
@DESCRIPTION VARCHAR(100)
SELECT @SUBJECT = APPT_SUBJECT, @LOCATION = APPT_LOCATION,@DESCRIPTION = APPT_DESCRIPTION FROM TBPMO_APPOINTMENT_CONTROLS WHERE CONTROL_ID = @CONTROL_ID
INSERT INTO TBPMO_APPOINTMENTS (Type,[StartDate],[EndDate],[AllDay],[Subject],[Location],[Description],Status,Label,[CustomField1],[CustomField2]) VALUES
(0,CONVERT(DATE,@VALUE_NEW),CONVERT(DATE,@VALUE_NEW),1,@SUBJECT,@LOCATION,@DESCRIPTION,0,2,@RECORD_ID,@CONTROL_ID)
END
/*###### KUNDEN-INDIVIDUELL - BEGIN ####################################################################*/
IF @CONTROL_ID = 346
BEGIN
SELECT @COUNTER_CONTROL_UPDATE_ID = COUNTER_CONTROL_UPDATE_ID + 1 FROM TBPMO_KONFIGURATION WHERE GUID = 1
UPDATE TBPMO_KONFIGURATION SET COUNTER_CONTROL_UPDATE_ID = @COUNTER_CONTROL_UPDATE_ID WHERE GUID = 1
DECLARE cursor_DOCS CURSOR FOR
select DocID from VWPMO_DOC_SEARCH T, TBPMO_DOC_RECORD_LINK TRL where T.DocID = TRL.DOC_ID AND
TRL.RECORD_ID = @RECORD_ID
--SELECT [USER_ID] FROM TBDD_GROUPS_USER WHERE GROUP_ID = (SELECT GUID FROM TBDD_USER_GROUPS WHERE NAME = @VALUE_NEW)
OPEN cursor_DOCS
FETCH NEXT FROM cursor_DOCS INTO @DOC_ID
WHILE @@FETCH_STATUS = 0
BEGIN
BEGIN
DECLARE cursor_User CURSOR FOR
SELECT [USER_ID] FROM TBDD_GROUPS_USER WHERE GROUP_ID = (SELECT GUID FROM TBDD_USER_GROUPS WHERE NAME = @VALUE_NEW)
--select DocID from VWPMO_DOC_SEARCH where RECORD_ID = @RECORD_ID
OPEN cursor_User
FETCH NEXT FROM cursor_User INTO @USER_ID
WHILE @@FETCH_STATUS = 0
BEGIN
SELECT @USER_ID_ECM = USERID_FK_INT_ECM FROM TBDD_USER WHERE GUID = @USER_ID
EXEC PRPMO_RIGHTS_CHECK_RIGHT @DOC_ID,@USER_ID,@USER_ID_ECM,1,'ADD RIGHT','LESEBERECHTIGUNG TEAM','TBPMO_CONTROL_VALUE_AFT_INS_346', @COUNTER_CONTROL_UPDATE_ID
FETCH NEXT FROM cursor_User INTO @USER_ID
END
CLOSE cursor_User
DEALLOCATE cursor_User
END
FETCH NEXT FROM cursor_DOCS INTO @DOC_ID
END
CLOSE cursor_DOCS
DEALLOCATE cursor_DOCS
END
/*###### KUNDEN-INDIVIDUELL - ENDE ####################################################################*/
GO
ALTER TRIGGER [dbo].[TBPMO_CONTROL_VALUE_AFT_UPD] ON [dbo].[TBPMO_CONTROL_VALUE]
FOR UPDATE
AS
BEGIN TRY
DECLARE
@CONTROL_ID INTEGER,
@RECORD_ID INTEGER,
@VALUE_NEW VARCHAR(MAX),
@VALUE_OLD VARCHAR(MAX),
@CHANGED_WHO VARCHAR(50),
@CHANGE_STEP INTEGER,
@REDO BIT,
@CHANGE_ID INTEGER,
@DOC_ID INTEGER,
@USER_ID INTEGER,
@USER_ID_ECM INTEGER,
@RIGHT INTEGER,
@COUNTER_CONTROL_UPDATE_ID INTEGER,
@UPDATE_SQL NVARCHAR(MAX),
@ENTITY_ID INTEGER,
@COL_NAME VARCHAR(50)
IF UPDATE (VALUE)
BEGIN
SELECT
@CONTROL_ID = DELETED.CONTROL_ID,
@RECORD_ID = DELETED.RECORD_ID,
@VALUE_OLD = DELETED.VALUE,
@ENTITY_ID = T.FORM_ID,
@COL_NAME = T1.COL_NAME
FROM DELETED, TBPMO_RECORD T,TBPMO_CONTROL T1
WHERE DELETED.RECORD_ID = T.GUID AND
DELETED.CONTROL_ID = T1.GUID
IF @CONTROL_ID in (29,14,346)
BEGIN
PRINT 'CHANGE OF RIGHT RELEVANT CONTROL'
SELECT @COUNTER_CONTROL_UPDATE_ID = COUNTER_CONTROL_UPDATE_ID + 1 FROM TBPMO_KONFIGURATION WHERE GUID = 1
UPDATE TBPMO_KONFIGURATION SET COUNTER_CONTROL_UPDATE_ID = @COUNTER_CONTROL_UPDATE_ID WHERE GUID = 1
END
--RAISERROR (@VALUE , 16, 1)
SELECT
@CHANGE_STEP = CHANGE_STEP,
@CHANGED_WHO = CHANGED_WHO,
@VALUE_NEW = VALUE,
@REDO = REDO
FROM INSERTED
--PRINT 'OLD VALUE: ' + @VALUE_OLD
--PRINT 'NEW VALUE: ' + @VALUE_NEW
IF @CHANGED_WHO IS NULL
BEGIN
SELECT @CHANGED_WHO = IN_WORK_WHO FROM TBPMO_RECORD WHERE GUID = @RECORD_ID
IF @CHANGED_WHO IS NULL
SET @CHANGED_WHO = 'TRIGGER DEFAULT'
END
IF NOT EXISTS(SELECT GUID FROM TBPMO_CONTROL_VALUE_CHANGE_HISTORY WHERE RECORD_ID = @RECORD_ID AND CONTROL_ID = @CONTROL_ID AND VALUE = @VALUE_OLD)
INSERT INTO TBPMO_CONTROL_VALUE_CHANGE_HISTORY (RECORD_ID,CONTROL_ID,VALUE,CHANGE_STEP,ADDED_WHO) VALUES
(@RECORD_ID,@CONTROL_ID,@VALUE_OLD,@CHANGE_STEP,@CHANGED_WHO)
ELSE
UPDATE TBPMO_CONTROL_VALUE_CHANGE_HISTORY SET ADDED_WHO = @CHANGED_WHO WHERE GUID = @CHANGE_ID
--IF @REDO = 0
-- IF @VALUE_OLD <> @VALUE_NEW AND NOT EXISTS(SELECT GUID FROM TBPMO_CONTROL_VALUE_CHANGE_HISTORY WHERE RECORD_ID = @RECORD_ID AND CONTROL_ID = @CONTROL_ID AND VALUE = @VALUE_OLD AND CHANGE_STEP = @CHANGE_STEP)
-- INSERT INTO TBPMO_CONTROL_VALUE_CHANGE_HISTORY (RECORD_ID,CONTROL_ID,VALUE,CHANGE_STEP,ADDED_WHO) VALUES
-- (@RECORD_ID,@CONTROL_ID,@VALUE_OLD,@CHANGE_STEP,@CHANGED_WHO)
--Update des Logs für loggen von Datensatzänderungen
IF EXISTS(SELECT LOG_UPDATE FROM TBPMO_RECORD_LOG_CONFIG WHERE CONTROL_ID = @CONTROL_ID AND LOG_UPDATE = 1)
If @VALUE_OLD <> @VALUE_NEW
BEGIN
DECLARE @LOG VARCHAR(1000)
SET @LOG = 'Update of Value - OLD-VALUE: ' + @VALUE_OLD + ' / NEW VALUE: ' + @VALUE_NEW
INSERT INTO TBPMO_RECORD_LOG (RECORD_ID,CONTROL_ID,LOG_DESCRIPTION,ADDED_WHO) VALUES
(@RECORD_ID,@CONTROL_ID,@LOG,@CHANGED_WHO)
END
ELSE
PRINT 'VALUES NOT DIFFERENT'
EXEC PRPMO_ENTITY_TABLE_UPDATE_COLUMN @ENTITY_ID, @RECORD_ID,@CONTROL_ID, @COL_NAME,@CHANGED_WHO,@VALUE_NEW
/*###### KUNDEN-INDIVIDUELL - BEGIN ####################################################################*/
IF @CONTROL_ID = 29 --Vertragseigner Person
BEGIN
--### Zuerst müssen die Rechte der geänderten Person gelöscht werden
select @USER_ID = dbo.FNPMO_GET_USERID_FORSTRING (@VALUE_OLD)
If @USER_ID IS NOT NULL AND @USER_ID <> 0
BEGIN
SELECT @USER_ID_ECM = USERID_FK_INT_ECM FROM TBDD_USER WHERE GUID = @USER_ID
DECLARE cursDOC_V1 CURSOR FOR
select DocID from VWPMO_DOC_SEARCH T, TBPMO_DOC_RECORD_LINK TRL where T.DocID = TRL.DOC_ID AND
TRL.RECORD_ID = @RECORD_ID
OPEN cursDOC_V1
FETCH NEXT FROM cursDOC_V1 INTO @DOC_ID
WHILE @@FETCH_STATUS = 0
BEGIN
EXEC PRPMO_RIGHTS_CHECK_RIGHT @DOC_ID,@USER_ID,@USER_ID_ECM,3,'DELETE RIGHT','ContractOwner',@CHANGED_WHO, @COUNTER_CONTROL_UPDATE_ID
FETCH NEXT FROM cursDOC_V1 INTO @DOC_ID
END
CLOSE cursDOC_V1
DEALLOCATE cursDOC_V1
END
SET @COUNTER_CONTROL_UPDATE_ID = @COUNTER_CONTROL_UPDATE_ID + 1
UPDATE TBPMO_KONFIGURATION SET COUNTER_CONTROL_UPDATE_ID = @COUNTER_CONTROL_UPDATE_ID WHERE GUID = 1
--### Jetzt prüfen der neuen Rechte
select @USER_ID = dbo.FNPMO_GET_USERID_FORSTRING (@VALUE_NEW)
If @USER_ID IS NOT NULL AND @USER_ID <> 0
BEGIN
SELECT @USER_ID_ECM = USERID_FK_INT_ECM FROM TBDD_USER WHERE GUID = @USER_ID
DECLARE cursDOC_V1 CURSOR FOR
select DocID from VWPMO_DOC_SEARCH T, TBPMO_DOC_RECORD_LINK TRL where T.DocID = TRL.DOC_ID AND
TRL.RECORD_ID = @RECORD_ID
OPEN cursDOC_V1
FETCH NEXT FROM cursDOC_V1 INTO @DOC_ID
WHILE @@FETCH_STATUS = 0
BEGIN
EXEC PRPMO_RIGHTS_CHECK_RIGHT @DOC_ID,@USER_ID,@USER_ID_ECM,3,'ADD RIGHT','VERTRAGSEIGNER USER',@CHANGED_WHO, @COUNTER_CONTROL_UPDATE_ID
FETCH NEXT FROM cursDOC_V1 INTO @DOC_ID
END
CLOSE cursDOC_V1
DEALLOCATE cursDOC_V1
END
END
-- ####### Vertragseigner Team ###############
ELSE IF @CONTROL_ID = 14
BEGIN
/*Die Rechte des des alten Vertragseigner-Teams löschen*/
DECLARE C_OLDUSER_CONTROWN CURSOR FOR
SELECT T.[USER_ID], T1.USERID_FK_INT_ECM FROM TBDD_GROUPS_USER T, TBDD_USER T1 WHERE T.USER_ID = T1.GUID AND T.GROUP_ID = (SELECT GUID FROM TBDD_USER_GROUPS WHERE UPPER(NAME) = UPPER(@VALUE_OLD))
OPEN C_OLDUSER_CONTROWN
FETCH NEXT FROM C_OLDUSER_CONTROWN INTO @USER_ID,@USER_ID_ECM
WHILE @@FETCH_STATUS = 0
BEGIN
DECLARE cursDOC_V2 CURSOR FOR
select DocID from VWPMO_DOC_SEARCH T, TBPMO_DOC_RECORD_LINK TRL where T.DocID = TRL.DOC_ID AND
TRL.RECORD_ID = @RECORD_ID
OPEN cursDOC_V2
FETCH NEXT FROM cursDOC_V2 INTO @DOC_ID
WHILE @@FETCH_STATUS = 0
BEGIN
EXEC PRPMO_RIGHTS_CHECK_RIGHT @DOC_ID,@USER_ID,@USER_ID_ECM,3,'DELETE RIGHT','CONTRACTOWNER',@CHANGED_WHO, @COUNTER_CONTROL_UPDATE_ID
FETCH NEXT FROM cursDOC_V2 INTO @DOC_ID
END
CLOSE cursDOC_V2
DEALLOCATE cursDOC_V2
FETCH NEXT FROM C_OLDUSER_CONTROWN INTO @USER_ID,@USER_ID_ECM
END
CLOSE C_OLDUSER_CONTROWN
DEALLOCATE C_OLDUSER_CONTROWN
SET @COUNTER_CONTROL_UPDATE_ID = @COUNTER_CONTROL_UPDATE_ID + 1
UPDATE TBPMO_KONFIGURATION SET COUNTER_CONTROL_UPDATE_ID = @COUNTER_CONTROL_UPDATE_ID WHERE GUID = 1
/*Die Rechte des Teams Vertragseigner hinzufügen*/
DECLARE c_USER CURSOR FOR
SELECT T.[USER_ID], T1.USERID_FK_INT_ECM FROM TBDD_GROUPS_USER T, TBDD_USER T1 WHERE T.USER_ID = T1.GUID AND T.GROUP_ID = (SELECT GUID FROM TBDD_USER_GROUPS WHERE UPPER(NAME) = UPPER(@VALUE_NEW))
OPEN c_USER
FETCH NEXT FROM c_USER INTO @USER_ID,@USER_ID_ECM
WHILE @@FETCH_STATUS = 0
BEGIN
DECLARE cursDOC_V2 CURSOR FOR
select DocID from VWPMO_DOC_SEARCH T, TBPMO_DOC_RECORD_LINK TRL where T.DocID = TRL.DOC_ID AND
TRL.RECORD_ID = @RECORD_ID
OPEN cursDOC_V2
FETCH NEXT FROM cursDOC_V2 INTO @DOC_ID
WHILE @@FETCH_STATUS = 0
BEGIN
EXEC PRPMO_RIGHTS_CHECK_RIGHT @DOC_ID,@USER_ID,@USER_ID_ECM,3,'ADD RIGHT','CONTRACTOWNER',@CHANGED_WHO,@COUNTER_CONTROL_UPDATE_ID
FETCH NEXT FROM cursDOC_V2 INTO @DOC_ID
END
CLOSE cursDOC_V2
DEALLOCATE cursDOC_V2
FETCH NEXT FROM c_USER INTO @USER_ID,@USER_ID_ECM
END
CLOSE c_USER
DEALLOCATE c_USER
END
END
/*###### KUNDEN-INDIVIDUELL - END ####################################################################*/
--Generelle Updates (Datum und Recor-Änderungen)
UPDATE TBPMO_CONTROL_VALUE SET CHANGED_WHEN = GETDATE() FROM INSERTED WHERE TBPMO_CONTROL_VALUE.GUID = INSERTED.GUID
UPDATE TBPMO_RECORD SET CHANGED_WHO = @CHANGED_WHO WHERE TBPMO_RECORD.GUID = @RECORD_ID
END TRY
BEGIN CATCH
PRINT 'ERROR IN PROCEDURE: ' + CONVERT(VARCHAR(30),ERROR_PROCEDURE())
+ ' - ERROR-MESSAGE: '
+ CONVERT(VARCHAR(500),ERROR_MESSAGE())
END CATCH
GO
ALTER TRIGGER [dbo].[TBPMO_CONTROL_VALUE_AFT_DEL] ON [dbo].[TBPMO_CONTROL_VALUE]
FOR DELETE
AS
BEGIN TRY
DECLARE
@RECORD_ID INTEGER,
@CONTROL_ID INTEGER,
@ADDED_WHO VARCHAR(50),
@VALUE_DEL VARCHAR(MAX),
@DOC_ID INTEGER,
@USER_ID INTEGER,
@USER_ID_ECM INTEGER,
@RIGHT INTEGER,
@ENTITY_ID INTEGER,
@COL_NAME VARCHAR(50),
@COUNTER_CONTROL_UPDATE_ID INTEGER
SELECT
@RECORD_ID = DELETED.RECORD_ID,
@CONTROL_ID = DELETED.CONTROL_ID,
@VALUE_DEL = DELETED.VALUE,
@ENTITY_ID = T1.FORM_ID,
@COL_NAME = T1.COL_NAME
FROM DELETED, TBPMO_RECORD T,TBPMO_CONTROL T1
WHERE DELETED.RECORD_ID = T.GUID AND
DELETED.CONTROL_ID = T1.GUID
IF EXISTS(SELECT CONTROL_ID FROM TBPMO_APPOINTMENT_CONTROLS WHERE CONTROL_ID = @CONTROL_ID)
DELETE FROM TBPMO_APPOINTMENTS WHERE [CustomField1] = @RECORD_ID AND [CustomField2] = @CONTROL_ID
EXEC PRPMO_ENTITY_TABLE_UPDATE_COLUMN @ENTITY_ID, @RECORD_ID,@CONTROL_ID, @COL_NAME,''
/*###### KUNDEN-INDIVIDUELL - BEGIN ####################################################################*/
IF @CONTROL_ID in (29,14,346)
BEGIN
SELECT @COUNTER_CONTROL_UPDATE_ID = COUNTER_CONTROL_UPDATE_ID + 1 FROM TBPMO_KONFIGURATION WHERE GUID = 1
UPDATE TBPMO_KONFIGURATION SET COUNTER_CONTROL_UPDATE_ID = @COUNTER_CONTROL_UPDATE_ID WHERE GUID = 1
END
IF @CONTROL_ID = 346
BEGIN
DECLARE cursor_DOCS CURSOR FOR
select DocID from VWPMO_DOC_SEARCH T, TBPMO_DOC_RECORD_LINK TRL where T.DocID = TRL.DOC_ID AND
TRL.RECORD_ID = @RECORD_ID
--SELECT [USER_ID] FROM TBDD_GROUPS_USER WHERE GROUP_ID = (SELECT GUID FROM TBDD_USER_GROUPS WHERE NAME = @VALUE_NEW)
OPEN cursor_DOCS
FETCH NEXT FROM cursor_DOCS INTO @DOC_ID
WHILE @@FETCH_STATUS = 0
BEGIN
BEGIN
DECLARE cursor_User CURSOR FOR
SELECT [USER_ID] FROM TBDD_GROUPS_USER WHERE GROUP_ID = (SELECT GUID FROM TBDD_USER_GROUPS WHERE NAME = @VALUE_DEL)
OPEN cursor_User
FETCH NEXT FROM cursor_User INTO @USER_ID
WHILE @@FETCH_STATUS = 0
BEGIN
SELECT @USER_ID_ECM = USERID_FK_INT_ECM FROM TBDD_USER WHERE GUID = @USER_ID
EXEC PRPMO_RIGHTS_CHECK_RIGHT @DOC_ID,@USER_ID,@USER_ID_ECM,1,'DELETE RIGHT','LESEBERECHTIGUNG TEAM','TBPMO_CONTROL_VALUE_AFT_DEL_346', @COUNTER_CONTROL_UPDATE_ID
FETCH NEXT FROM cursor_User INTO @USER_ID
END
CLOSE cursor_User
DEALLOCATE cursor_User
END
FETCH NEXT FROM cursor_DOCS INTO @DOC_ID
END
CLOSE cursor_DOCS
DEALLOCATE cursor_DOCS
END
/*###### KUNDEN-INDIVIDUELL - ENDE ####################################################################*/
END TRY
BEGIN CATCH
PRINT 'FEHLER IN TRIGGER: ' + CONVERT(VARCHAR(30),ERROR_PROCEDURE()) + ' - ZEILE: ' + CONVERT(VARCHAR(10),ERROR_LINE())
+ ' - FEHLER-MESSAGE: '
+ CONVERT(VARCHAR(500),ERROR_MESSAGE())
END CATCH
GO
ALTER PROCEDURE [dbo].[PRPMO_DELETE_RECORD](@pRECORD_ID INT, @WHO VARCHAR(30))
AS
DELETE FROM TBPMO_WORKFLOW_TASK_USER WHERE WF_TASK_ID IN (SELECT GUID FROM TBPMO_WORKFLOW_TASK WHERE RECORD_ID = @pRECORD_ID)
DELETE FROM TBPMO_WORKFLOW_TASK WHERE RECORD_ID = @pRECORD_ID
DELETE FROM TBPMO_RECORD_CONNECT WHERE RECORD1_ID = @pRECORD_ID OR RECORD2_ID = @pRECORD_ID
DELETE FROM TBPMO_WORKFLOW_TASK WHERE RECORD_ID = @pRECORD_ID
DELETE FROM TBPMO_CONTROL_VALUE WHERE RECORD_ID = @pRECORD_ID
DELETE FROM TBPMO_WORKFLOW_REMINDER WHERE RECORD_ID = @pRECORD_ID
DELETE FROM TBPMO_FOLLUPEMAIL_RECORD WHERE RECORD_ID = @pRECORD_ID
DELETE FROM TBPMO_RECORD_VARIANT WHERE RECORD_ID = @pRECORD_ID
DELETE FROM TBPMO_RECORD_GEODATA WHERE RECORD_ID = @pRECORD_ID
DELETE FROM TBPMO_DOC_VALUES WHERE RECORD_ID = @pRECORD_ID
DECLARE @DELETE_SQL NVARCHAR(MAX),@ENTITY_ID INT
SELECT @ENTITY_ID = FORM_ID FROM TBPMO_RECORD WHERE GUID = @pRECORD_ID
SET @DELETE_SQL = 'DELETE FROM TBPMO_ENTITY_TABLE@ENT_ID WHERE [Record-ID] = @RECORD_ID'
SET @DELETE_SQL = REPLACE(@DELETE_SQL,'@ENT_ID',@ENTITY_ID)
SET @DELETE_SQL = REPLACE(@DELETE_SQL,'@RECORD_ID',@pRECORD_ID)
EXEC sp_executesql @DELETE_SQL
DELETE FROM TBPMO_RECORD WHERE GUID = @pRECORD_ID
INSERT INTO TBPMO_LOG_ESSENTIALS (REFERENCE_KEY,REFERENCE_STRING,COMMENT,ADDED_WHO) VALUES (@pRECORD_ID,'RECORD-ID','RECORD DELETED BY USER',@WHO)
GO
CREATE TRIGGER [dbo].[TBPMO_CONTROL_AFT_INS] ON [dbo].[TBPMO_CONTROL]
FOR INSERT
AS
DECLARE
@CONTROL_ID INTEGER,
@ADDED_WHO VARCHAR(50),
@DEFAULT_VALUE VARCHAR(100),
@ENTITY_ID INTEGER,
@COL_NAME VARCHAR(50),
@TYP_ID INTEGER,
@SQL NVARCHAR(MAX)
SELECT
@CONTROL_ID = GUID,
@ADDED_WHO = ADDED_WHO,
@DEFAULT_VALUE = DEFAULT_VALUE,
@ENTITY_ID = FORM_ID,
@COL_NAME = COL_NAME
FROM INSERTED
--@pENTITY_ID INT,@pCOL_NAME VARCHAR(50),@pCOL_NAME_OLD VARCHAR(50),@pTYP_ID INT,@pDEFAULT_VALUE VARCHAR(100),@pACTION TINYINT = 0
EXEC PRPMO_ALTER_ENTITY_TABLE @ENTITY_ID, @COL_NAME, '' ,@TYP_ID,@DEFAULT_VALUE,0
GO
ALTER TRIGGER [dbo].[TBPMO_CONTROL_AFT_UPD] ON [dbo].[TBPMO_CONTROL]
FOR UPDATE
AS
BEGIN TRY
DECLARE
@CONTROL_ID INTEGER,
@TYP_ID INTEGER,
@TABLENAME_COL NVARCHAR(100),
@NEW_COL_NAME NVARCHAR(100),
@SQL NVARCHAR(MAX),
@ENTITY_ID INTEGER,
@COL_NAME VARCHAR(50),
@COL_NAME_OLD VARCHAR(50),
@DEFAULT_VALUE VARCHAR(MAX),
@SQL_DEF NVARCHAR(1000)
SELECT
@COL_NAME_OLD = COL_NAME
FROM DELETED
SELECT
@CONTROL_ID = GUID,
@TYP_ID = CONTROL_TYPE_ID,
@ENTITY_ID = FORM_ID,
@COL_NAME = COL_NAME,
@DEFAULT_VALUE = DEFAULT_VALUE
FROM INSERTED
--@pENTITY_ID INT,@pCOL_NAME VARCHAR(50),@pCOL_NAME_OLD VARCHAR(50),@pTYP_ID INT,@pDEFAULT_VALUE VARCHAR(100),@pACTION TINYINT = 0
EXEC PRPMO_ALTER_ENTITY_TABLE @ENTITY_ID, @COL_NAME, @COL_NAME_OLD ,@TYP_ID,@DEFAULT_VALUE,1
UPDATE TBPMO_CONTROL SET CHANGED_WHEN = GETDATE() FROM INSERTED WHERE TBPMO_CONTROL.GUID = INSERTED.GUID
END TRY
BEGIN CATCH
PRINT 'FEHLER IN PROCEDURE: ' + CONVERT(VARCHAR(30),ERROR_PROCEDURE()) + ' - ZEILE: ' + CONVERT(VARCHAR(10),ERROR_LINE())
+ ' - FEHLER-MESSAGE: '
+ CONVERT(VARCHAR(500),ERROR_MESSAGE())
END CATCH
GO
CREATE TRIGGER [dbo].[TBPMO_CONTROL_AFT_DEL] ON [dbo].[TBPMO_CONTROL]
FOR DELETE
AS
DECLARE
@CONTROL_ID INTEGER,
@TYP_ID INTEGER,
@TABLENAME_COL NVARCHAR(100),
@NEW_COL_NAME NVARCHAR(100),
@SQL NVARCHAR(MAX),
@ENTITY_ID INTEGER,
@COL_NAME VARCHAR(50),
@COL_NAME_OLD VARCHAR(50),
@DEFAULT_VALUE VARCHAR(MAX),
@SQL_DEF NVARCHAR(1000)
SELECT
@CONTROL_ID = GUID,
@COL_NAME_OLD = COL_NAME,
@TYP_ID = CONTROL_TYPE_ID,
@ENTITY_ID = FORM_ID,
@COL_NAME = COL_NAME,
@DEFAULT_VALUE = DEFAULT_VALUE
FROM DELETED
EXEC PRPMO_ALTER_ENTITY_TABLE @ENTITY_ID, @COL_NAME, @COL_NAME_OLD ,@TYP_ID,@DEFAULT_VALUE,2
GO
CREATE TRIGGER [dbo].[TBPMO_DOC_RECORD_LINK_AFT_DEL] ON [dbo].[TBPMO_DOC_RECORD_LINK]
WITH EXECUTE AS CALLER
FOR DELETE
AS
BEGIN TRY
DECLARE
@RECORD_ID INTEGER,
@DOC_ID INTEGER,
@ENTITY_ID INTEGER
SELECT
@RECORD_ID = RECORD_ID,
@DOC_ID = DOC_ID
FROM DELETED
SELECT @ENTITY_ID = FORM_ID FROM TBPMO_RECORD WHERE GUID = @RECORD_ID
DELETE FROM TBPMO_DOC_VALUES WHERE DocID = @DOC_ID AND RECORD_ID = @RECORD_ID
EXEC PRPMO_DOC_RECORD_LINK_UPD_ENTITY_TABLE @RECORD_ID
END TRY
BEGIN CATCH
PRINT 'ERROR IN TRIGGER: ' + CONVERT(VARCHAR(30),ERROR_PROCEDURE()) + ' - ROW: ' + CONVERT(VARCHAR(10),ERROR_LINE())
+ ' - ERROR-MESSAGE: '
+ CONVERT(VARCHAR(500),ERROR_MESSAGE())
END CATCH
GO
CREATE FUNCTION [dbo].[FNPMO_GETUSER_RECORDS_ENTITY_1] (@pUSER_ID INTEGER, @pENTITY_ID INTEGER)
RETURNS @Output TABLE (
RECORD_ID INTEGER,
WDRIGHT INTEGER
)
AS
BEGIN
INSERT INTO @Output(RECORD_ID,WDRIGHT)
SELECT [Record-ID], 1 FROM VWRENOLIT_CONTRACTS_DE where UNSICHTBAR = 0
INSERT INTO @Output(RECORD_ID,WDRIGHT)
SELECT [Record-ID], 3 FROM TBPMO_ENTITY_TABLE1 where Unsichtbar = 1 AND Team in
(SELECT T1.NAME FROM TBDD_GROUPS_USER T,TBDD_USER_GROUPS T1 WHERE T.GROUP_ID = T1.GUID AND USER_ID = @pUSER_ID AND T1.GUID IN (1,11))
RETURN
END
GO
CREATE PROCEDURE [dbo].[PRPMO_COPY_RECORD](@pRECORD_ID INT,@WHO VARCHAR(50))
AS
DECLARE @NEW_RECORD_ID INT
BEGIN TRY
INSERT INTO TBPMO_RECORD (
FORM_ID,ADDED_WHO,RECORD_ENTITY_ID)
SELECT FORM_ID,@WHO,4711 FROM TBPMO_RECORD WHERE GUID = @pRECORD_ID
SELECT @NEW_RECORD_ID = MAX(GUID) FROM TBPMO_RECORD
INSERT INTO TBPMO_RECORD_CONNECT(RECORD1_ID,RECORD2_ID,COMMENT) SELECT
RECORD1_ID,@NEW_RECORD_ID,COMMENT FROM TBPMO_RECORD_CONNECT WHERE RECORD2_ID = @pRECORD_ID
DECLARE @CONTROL_ID INT,
@REC_ID INT,
@VALUE VARCHAR(MAX),
@ADDED_WHO VARCHAR(50)
DECLARE cursorControlValues CURSOR LOCAL FOR
SELECT CONTROL_ID,@NEW_RECORD_ID,VALUE,@WHO FROM TBPMO_CONTROL_VALUE WHERE RECORD_ID = @pRECORD_ID
OPEN cursorControlValues
FETCH NEXT FROM cursorControlValues INTO @CONTROL_ID,@REC_ID,@VALUE,@ADDED_WHO
WHILE @@FETCH_STATUS = 0
BEGIN
INSERT INTO TBPMO_CONTROL_VALUE(CONTROL_ID,RECORD_ID,VALUE,ADDED_WHO) VALUES (
@CONTROL_ID,@REC_ID,@VALUE,@ADDED_WHO)
FETCH NEXT FROM cursorControlValues INTO @CONTROL_ID,@REC_ID,@VALUE,@ADDED_WHO
END
CLOSE cursorControlValues
DEALLOCATE cursorControlValues
INSERT INTO TBPMO_CONTROL_IMAGE(CONTROL_ID,RECORD_ID,IMG,ADDED_WHO) SELECT
CONTROL_ID,@NEW_RECORD_ID,IMG,@WHO FROM TBPMO_CONTROL_IMAGE WHERE RECORD_ID = @pRECORD_ID
END TRY
BEGIN CATCH
PRINT 'ERROR IN PROCEDURE: ' + CONVERT(VARCHAR(30),ERROR_PROCEDURE()) + ' - ROW: ' + CONVERT(VARCHAR(10),ERROR_LINE())
+ ' - ERROR-MESSAGE: '
+ CONVERT(VARCHAR(500),ERROR_MESSAGE())
END CATCH
GO
ALTER TRIGGER [dbo].[TBPMO_RECORD_AFT_INS] ON [dbo].[TBPMO_RECORD]
FOR INSERT
AS
BEGIN TRY
DECLARE
@RECORD_ID INTEGER,
@MAX_ID INTEGER,
@FORM_ID INTEGER,
@WF_ID INTEGER,
@PARENT_ID INTEGER,
@ADDED_WHO VARCHAR(50),
@INSERT_SQL NVARCHAR(MAX)
SELECT
@FORM_ID = FORM_ID,
@RECORD_ID = GUID
FROM INSERTED
SELECT @MAX_ID = ISNULL(MAX(RECORD_ENTITY_ID) + 1,0) FROM TBPMO_RECORD
WHERE FORM_ID = @FORM_ID AND GUID <> @RECORD_ID
SET @INSERT_SQL = 'INSERT INTO TBPMO_ENTITY_TABLE@ENT_ID ([Record-ID],AddedWho,AddedWhen) SELECT GUID,ADDED_WHO,ADDED_WHEN FROM TBPMO_RECORD WHERE GUID = @RECORD_ID'
SET @INSERT_SQL = REPLACE(@INSERT_SQL,'@ENT_ID',CONVERT(VARCHAR(10),@FORM_ID))
SET @INSERT_SQL = REPLACE(@INSERT_SQL,'@RECORD_ID',@RECORD_ID)
PRINT @INSERT_SQL
EXEC sp_executesql @INSERT_SQL
--RAISERROR(@INSERT_SQL, 16, 1);
-- ROLLBACK;
UPDATE TBPMO_RECORD SET RECORD_ENTITY_ID = @MAX_ID FROM INSERTED WHERE TBPMO_RECORD.GUID = INSERTED.GUID
----Überprüfen ob für die Entity_ID Workflows definiert sind?
IF EXISTS(
SELECT DISTINCT T.[ENTITY_ID] FROM TBPMO_WORKFLOW_ENTITY_STATE T,TBPMO_WORKFLOW T1 where T.WF_ID = T1.GUID AND T1.MANUALLY = 0 AND T.[ENTITY_ID] = @FORM_ID
AND T1.CREATE_ON_REC_CREATE = 1
)
BEGIN
EXECUTE dbo.PRPMO_CREATE_WF_TASKS @FORM_ID, @RECORD_ID
END
END TRY
BEGIN CATCH
PRINT 'FEHLER IN TRIGGER: ' + CONVERT(VARCHAR(30),ERROR_PROCEDURE()) + ' - ZEILE: ' + CONVERT(VARCHAR(10),ERROR_LINE())
+ ' - FEHLER-MESSAGE: '
+ CONVERT(VARCHAR(500),ERROR_MESSAGE())
END CATCH
GO
CREATE PROCEDURE [dbo].[PRPMO_CREATE_ENTITY_TABLE_VIEW](@pENTITY_ID INT)
AS
DECLARE @COL_NAME VARCHAR(50),
@SQL_BEGIN NVARCHAR(4000),
@SQL_END NVARCHAR(4000),
@SQL NVARCHAR(MAX),
@CONTROL_ID INT,
@RESULT NVARCHAR(MAX),
@TYPEID INT,
@TABINDEX INT,
@SQL_LBL VARCHAR(4000),
@ENTITY_TABLENAME VARCHAR(50),
@VWPMO_ENTITY_TABLE VARCHAR(100)
SELECT @ENTITY_TABLENAME = ENTITY_TABLENAME FROM TBPMO_KONFIGURATION WHERE GUID = 1
DECLARE c_SPALTENNAMEN CURSOR FOR SELECT T.GUID,'[' + T.COL_NAME + ']' AS 'COL_NAME',T2.GUID,T1.TAB_INDEX, '' FROM TBPMO_CONTROL T,TBPMO_CONTROL_SCREEN T1,TBPMO_CONTROL_TYPE T2
WHERE T.SHOW_COLUMN = 1 AND T.[COL_NAME] <> '' AND T.GUID = T1.CONTROL_ID AND T.CONTROL_TYPE_ID = T2.GUID AND T.FORM_ID = @pENTITY_ID AND LEN(ISNULL(T.COL_NAME,'')) > 0 AND T.CONTROL_TYPE_ID NOT IN (1,5)
UNION
SELECT T.GUID,'[' + T.NAME + ']' AS 'COL_NAME',T2.GUID,T1.TAB_INDEX, T.SQL_COMMAND_1 FROM TBPMO_CONTROL T,TBPMO_CONTROL_SCREEN T1,TBPMO_CONTROL_TYPE T2
WHERE T.GUID = T1.CONTROL_ID AND T.CONTROL_TYPE_ID = T2.GUID AND T.FORM_ID = @pENTITY_ID AND T.CONTROL_TYPE_ID = 1 AND LEN(ISNULL(T.SQL_COMMAND_1,'')) > 0
ORDER BY TAB_INDEX
BEGIN
SET @VWPMO_ENTITY_TABLE = 'VWPMO_ENTITY_TABLE@pENTITY_ID'
SET @SQL_BEGIN = 'CREATE VIEW @VIEW AS SELECT T.[Record-ID]' + CHAR(13) + ',T.ROW_COLOR' + CHAR(13) + ',@pENTITY_ID AS [Form-ID]' + CHAR(13) + ','
SET @SQL_BEGIN = REPLACE(@SQL_BEGIN,'@VIEW',@VWPMO_ENTITY_TABLE)
SET @SQL_BEGIN = REPLACE(@SQL_BEGIN,'@pENTITY_ID',CONVERT(VARCHAR(3),@pENTITY_ID))
SET @VWPMO_ENTITY_TABLE = REPLACE(@VWPMO_ENTITY_TABLE,'@pENTITY_ID',CONVERT(VARCHAR(3),@pENTITY_ID))
SET @SQL_END = 'T.file_exists as [files?],' + CHAR(13) + 'T.file_count as [file count],' + CHAR(13) + 'T.AddedWho,' + CHAR(13) + 'T.AddedWhen,' + CHAR(13) + 'T.ChangedWho,' + CHAR(13) + 'T.ChangedWhen FROM @TABLE@pENTITY_ID T'
SET @SQL_END = REPLACE(@SQL_END,'@pENTITY_ID',CONVERT(VARCHAR(3),@pENTITY_ID))
SET @SQL_END = REPLACE(@SQL_END,'@TABLE',@ENTITY_TABLENAME)
SET @SQL = ''
OPEN c_SPALTENNAMEN
FETCH NEXT FROM c_SPALTENNAMEN INTO @CONTROL_ID,@COL_NAME,@TYPEID,@TABINDEX,@SQL_LBL
WHILE @@FETCH_STATUS = 0
BEGIN
SET @COL_NAME = REPLACE(@COL_NAME,'lbl','')
--PRINT @COL_NAME
IF @TYPEID IN(10,11) -- CheckBox,RadioBox
SET @SQL = @SQL + 'ISNULL(CASE WHEN UPPER(RTRIM(LTRIM(T.@COL_NAME))) = ''TRUE'' THEN 1 ELSE 0 END,0) AS ' + @COL_NAME + ',' + CHAR(13)
ELSE IF @TYPEID = 6 --PictureBox
SET @SQL = @SQL + 'T.@COL_NAME AS ' + @COL_NAME + CHAR(13)
ELSE IF @TYPEID = 1 --Label mit SQL
BEGIN
SET @SQL_LBL = REPLACE(UPPER(@SQL_LBL),'@RECORD_ID','T.[Record-ID]')
SET @SQL = @SQL + '(' + @SQL_LBL + ') AS ' + @COL_NAME + ',' + CHAR(13)
END
--ELSE IF @TYPEID IN(7,12,14) --DGV,CheckedListBox,ListBox
-- SET @SQL = @SQL + 'dbo.FNPMO_GET_CONTROL_VALUES(' + CONVERT(VARCHAR(20),@CONTROL_ID) + ', T.[Record-ID]) AS ' + @COL_NAME + ',' + CHAR(13)
ELSE IF @TYPEID = 4 --Datepicker
SET @SQL = @SQL + 'T.@COL_NAME AS ' + @COL_NAME + ',' + CHAR(13)
ELSE
SET @SQL = @SQL + 'ISNULL(T.@COL_NAME,'''') AS ' + @COL_NAME + ',' + CHAR(13)
SET @SQL = REPLACE(@SQL,'@COL_NAME',@COL_NAME)
FETCH NEXT FROM c_SPALTENNAMEN INTO @CONTROL_ID,@COL_NAME,@TYPEID,@TABINDEX,@SQL_LBL
END
CLOSE c_SPALTENNAMEN
DEALLOCATE c_SPALTENNAMEN
SET @RESULT = @SQL_BEGIN + @SQL + @SQL_END
PRINT @RESULT
IF EXISTS (SELECT * FROM INFORMATION_SCHEMA.VIEWS WHERE TABLE_NAME = @VWPMO_ENTITY_TABLE)
BEGIN
SET @SQL = 'DROP VIEW [dbo].[@VIEW]'
SET @SQL = REPLACE(@SQL,'@VIEW',@VWPMO_ENTITY_TABLE)
PRINT @SQL
EXEC sp_executesql @SQL
END
EXEC sp_executesql @RESULT
UPDATE TBPMO_FORM_SQL SET SQL_COMMAND1 = @RESULT WHERE FORM_ID = @pENTITY_ID
END
GO
ALTER TRIGGER [dbo].[TBPMO_DOC_RECORD_LINK_AFT_INS] ON [dbo].[TBPMO_DOC_RECORD_LINK]
WITH EXECUTE AS CALLER
FOR INSERT
AS
BEGIN TRY
DECLARE
@RECORD_ID INTEGER,
@DOC_ID INTEGER,
@ADDED_WHO VARCHAR(50),
@ENTITY_ID INTEGER
SELECT
@RECORD_ID = RECORD_ID,
@DOC_ID = DOC_ID,
@ADDED_WHO = ADDED_WHO
FROM INSERTED
SELECT @ENTITY_ID = FORM_ID FROM TBPMO_RECORD WHERE GUID = @RECORD_ID
--Den Defaultvalue der DropdownListe eintragen
IF (SELECT COUNT(GUID) FROM TBPMO_DOCSEARCH_RESULTLIST_CONFIG WHERE ENTITY_ID = @ENTITY_ID AND TYPE_ID = 3 AND CONFIG_COLUMNS = 1) >= 1
BEGIN
INSERT INTO TBPMO_DOC_VALUES (DocID,RECORD_ID,CONFIG_ID,VALUE,ADDED_WHO)
SELECT @DOC_ID,@RECORD_ID,T.GUID,T1.VALUE,@ADDED_WHO FROM TBPMO_DOCSEARCH_RESULTLIST_CONFIG T, TBPMO_DOCRESULT_DROPDOWN_ITEMS T1 WHERE T.GUID = T1.CONFIG_ID AND T1.[DEFAULT] = 1 AND T.ENTITY_ID = @ENTITY_ID AND T.TYPE_ID = 3
--SELECT T.* FROM TBPMO_DOCSEARCH_RESULTLIST_CONFIG T, TBPMO_DOCRESULT_DROPDOWN_ITEMS T1 WHERE T.GUID = T1.CONFIG_ID AND T1.[DEFAULT] = 1 AND T.ENTITY_ID = 21 AND T.TYPE_ID = 3
END
IF (SELECT COUNT(GUID) FROM TBPMO_DOCSEARCH_RESULTLIST_CONFIG WHERE ENTITY_ID = @ENTITY_ID AND TYPE_ID <> 3 AND CONFIG_COLUMNS = 1) >= 1
INSERT INTO TBPMO_DOC_VALUES (DocID,RECORD_ID,CONFIG_ID,VALUE,ADDED_WHO)
SELECT @DOC_ID,@RECORD_ID,T.GUID,'',@ADDED_WHO FROM TBPMO_DOCSEARCH_RESULTLIST_CONFIG T WHERE T.ENTITY_ID = @ENTITY_ID AND T.TYPE_ID <> 4 AND T.CONFIG_COLUMNS = 1
--SELECT * FROM TBPMO_DOCSEARCH_RESULTLIST_CONFIG WHERE ENTITY_ID = 21 AND TYPE_ID <> 3 AND CONFIG_COLUMNS = 1
EXEC PRPMO_DOC_RECORD_LINK_UPD_ENTITY_TABLE @RECORD_ID
/*###### KUNDEN-INDIVIDUELL - BEGIN ####################################################################*/
DECLARE
@ENITTY_ID INTEGER,
@DOCTYPE VARCHAR(250),
@SUPPLIER VARCHAR(250)
SELECT @ENITTY_ID = FORM_ID FROM TBPMO_RECORD WHERE GUID = @RECORD_ID
IF @ENITTY_ID = 21
BEGIN
SELECT @SUPPLIER = VALUE FROM TBPMO_CONTROL_VALUE WHERE RECORD_ID = @RECORD_ID AND CONTROL_ID = 258
SELECT @DOCTYPE = T.Doctype FROM TBPMO_DOCRESULT_LIST T, TBPMO_DOC_RECORD_LINK T1 WHERE T.DocID = T1.DOC_ID AND T1.RECORD_ID = @RECORD_ID
IF @SUPPLIER <> '' and @DOCTYPE <> '' AND @DOCTYPE IN ('55.SA','23B.NDA/CA')
BEGIN
INSERT INTO TBPMO_DOC_RECORD_LINK (DOC_ID,RECORD_ID,ADDED_WHO) SELECT @DOC_ID,[Record-ID],'TBPMO_DOC_RECORD_LINK_AFT_INS' FROM VWTEMP_PMO_FORM19 where UPPER(Supplier_name) = UPPER(@SUPPLIER)
END
END
/*###### KUNDEN-INDIVIDUELL - ENDE ####################################################################*/
END TRY
BEGIN CATCH
PRINT 'ERROR IN TRIGGER: ' + CONVERT(VARCHAR(30),ERROR_PROCEDURE()) + ' - ROW: ' + CONVERT(VARCHAR(10),ERROR_LINE())
+ ' - ERROR-MESSAGE: '
+ CONVERT(VARCHAR(500),ERROR_MESSAGE())
END CATCH
GO
CREATE TRIGGER [dbo].[TBPMO_DOCSEARCH_RESULTLIST_CONFIG_AFT_INS] ON [dbo].[TBPMO_DOCSEARCH_RESULTLIST_CONFIG]
AFTER INSERT
AS
BEGIN
DECLARE
@CONFIG_ID INTEGER,
@ENTITY_ID INTEGER,
@ADDED_WHO VARCHAR(50),
@TYPE_ID INTEGER,
@CONFIG_COLUMNS INTEGER,
@DOC_ID INT,
@REC_ID INT,
@VALUE VARCHAR(100)
SELECT
@CONFIG_ID = GUID,
@ENTITY_ID = [ENTITY_ID],
@TYPE_ID = [TYPE_ID],
@ADDED_WHO = ADDED_WHO,
@CONFIG_COLUMNS = CONFIG_COLUMNS
FROM INSERTED
--Den Defaultvalue eintragen
IF @CONFIG_COLUMNS = 1
BEGIN
DECLARE cursorRecordDocs CURSOR LOCAL FOR
SELECT T.RECORD_ID, T.DOC_ID FROM TBPMO_DOC_RECORD_LINK T, TBPMO_RECORD T1 WHERE T.RECORD_ID = T1.GUID AND T1.FORM_ID = @ENTITY_ID
OPEN cursorRecordDocs
FETCH NEXT FROM cursorRecordDocs INTO @REC_ID,@DOC_ID
WHILE @@FETCH_STATUS = 0
BEGIN
INSERT INTO TBPMO_DOC_VALUES (DocID,RECORD_ID,CONFIG_ID,VALUE,ADDED_WHO) VALUES (
@DOC_ID,@REC_ID,@CONFIG_ID,'',@ADDED_WHO)
FETCH NEXT FROM cursorRecordDocs INTO @REC_ID,@DOC_ID
END
CLOSE cursorRecordDocs
DEALLOCATE cursorRecordDocs
END
END
GO