1113 lines
48 KiB
Transact-SQL

UPDATE TBIDB_BASE SET CONFIG_VALUE = '1.0.5' where CONFIG_NAME = 'DB_VERSION'
GO
DECLARE @INITIAL_TERM_ID VARCHAR(100)
EXEC PRIDB_NEW_TERM 'VARCHAR','SchreiberM','DD Initial',@TERM_ID = @INITIAL_TERM_ID OUTPUT;
SELECT @INITIAL_TERM_ID
GO
CREATE FUNCTION [dbo].[FNIDB_GET_FILE_PATH] (@pIDB_OBJ_ID BIGINT)
RETURNS VARCHAR(500)
AS
BEGIN
DECLARE @RELPATH VARCHAR(500),@FILEPATH VARCHAR(500),@NAVPATH as VARCHAR(500)
SELECT @RELPATH = [CAT_STRING] FROM [TBIDB_CATALOG] where CAT_TITLE = 'FILESTORE_PRAEFIX'
SELECT @NAVPATH = RELATIVE_PATH FROM TBIDB_DOC_INFO WHERE IDB_OBJ_ID = @pIDB_OBJ_ID
RETURN @NAVPATH
END
GO
CREATE NONCLUSTERED INDEX [IDXTBIDB_OBJECT_METADATA4]
ON [dbo].[TBIDB_OBJECT_METADATA] ([ATTR_ID])
INCLUDE ([IDB_OBJ_ID],[DEC_TERM_ID],[ADDED_WHO],[ADDED_WHEN])
GO
CREATE NONCLUSTERED INDEX [IDXTBIDB_OBJECT_METADATA5]
ON [dbo].[TBIDB_OBJECT_METADATA] ([ATTR_ID],[DEC_TERM_ID])
INCLUDE ([IDB_OBJ_ID],[ADDED_WHO],[ADDED_WHEN])
GO
-- =============================================
-- Author: DD MS
-- Change date: 25.08.2020 @TERM_TYPE_ID = 7 AND UPPER(@TERM)
-- =============================================
ALTER PROCEDURE [dbo].[PRIDB_NEW_TERM] @MD_TYPE VARCHAR(100),@TERM VARCHAR(MAX), @WHO VARCHAR(100), @TERM_ID BIGINT OUTPUT
AS
BEGIN
DECLARE @TERM_TYPE_ID TINYINT
SELECT @TERM_TYPE_ID = GUID FROM TBIDB_ATTRIBUTE_TYPE WHERE UPPER(NAME_TYPE) = UPPER(@MD_TYPE)
IF @TERM_TYPE_ID = 7 AND UPPER(@TERM) = 'TRUE'
SET @TERM = 1
ELSE IF @TERM_TYPE_ID = 7 AND UPPER(@TERM) = 'FALSE'
SET @TERM = 0
--PRINT 'PRIDB_NEW_TERM: TERM_TYPE_ID IS: ' + CONVERT(VARCHAR(2),@TERM_TYPE_ID) + ' # TERM: ' + @TERM
IF @TERM_TYPE_ID IN (1,8) --VARCHAR
IF NOT EXISTS(SELECT GUID FROM TBIDB_TERM_VALUE_VARCHAR WHERE UPPER(TERM_VALUE) = UPPER(@TERM))
BEGIN
INSERT INTO TBIDB_TERM_VALUE_VARCHAR (TERM_VALUE,ADDED_WHO) VALUES (@TERM,@WHO)
SELECT @TERM_ID = MAX(GUID) FROM TBIDB_TERM_VALUE_VARCHAR
END
ELSE
SELECT @TERM_ID = GUID FROM TBIDB_TERM_VALUE_VARCHAR WHERE UPPER(TERM_VALUE) = UPPER(@TERM)
ELSE IF @TERM_TYPE_ID IN (2,7,9) --BIGINT
IF NOT EXISTS(SELECT GUID FROM TBIDB_TERM_VALUE_INTEGER WHERE TERM_VALUE = CONVERT(BIGINT,@TERM))
BEGIN
INSERT INTO TBIDB_TERM_VALUE_INTEGER (TERM_VALUE,ADDED_WHO) VALUES (CONVERT(BIGINT,@TERM),@WHO)
SELECT @TERM_ID = MAX(GUID) FROM TBIDB_TERM_VALUE_INTEGER
END
ELSE
SELECT @TERM_ID = GUID FROM TBIDB_TERM_VALUE_INTEGER WHERE TERM_VALUE = CONVERT(BIGINT,@TERM)
ELSE IF @TERM_TYPE_ID = 3 --FLOAT
IF NOT EXISTS(SELECT GUID FROM TBIDB_TERM_VALUE_FLOAT WHERE TERM_VALUE = CONVERT(FLOAT,@TERM))
BEGIN
INSERT INTO TBIDB_TERM_VALUE_FLOAT (TERM_VALUE,ADDED_WHO) VALUES (CONVERT(FLOAT,@TERM),@WHO)
SELECT @TERM_ID = MAX(GUID) FROM TBIDB_TERM_VALUE_FLOAT
END
ELSE
SELECT @TERM_ID = GUID FROM TBIDB_TERM_VALUE_FLOAT WHERE TERM_VALUE = CONVERT(FLOAT,@TERM)
ELSE IF @TERM_TYPE_ID = 4 --DECIMAL
IF NOT EXISTS(SELECT GUID FROM TBIDB_TERM_VALUE_DECIMAL WHERE TERM_VALUE = CONVERT(DECIMAL(19,0),@TERM))
BEGIN
INSERT INTO TBIDB_TERM_VALUE_DECIMAL (TERM_VALUE,ADDED_WHO) VALUES (CONVERT(DECIMAL(19,0),@TERM),@WHO)
SELECT @TERM_ID = MAX(GUID) FROM TBIDB_TERM_VALUE_DECIMAL
END
ELSE
SELECT @TERM_ID = GUID FROM TBIDB_TERM_VALUE_DECIMAL WHERE TERM_VALUE = CONVERT(DECIMAL(19,0),@TERM)
ELSE IF @TERM_TYPE_ID = 5 --DATE
IF NOT EXISTS(SELECT GUID FROM TBIDB_TERM_VALUE_DATE WHERE TERM_VALUE = CONVERT(DATE,@TERM))
BEGIN
INSERT INTO TBIDB_TERM_VALUE_DATE (TERM_VALUE,ADDED_WHO) VALUES (CONVERT(DATE,@TERM),@WHO)
SELECT @TERM_ID = MAX(GUID) FROM TBIDB_TERM_VALUE_DATE
END
ELSE
SELECT @TERM_ID = GUID FROM TBIDB_TERM_VALUE_DATE WHERE TERM_VALUE = CONVERT(DATE,@TERM)
PRINT '### PRIDB_NEW_TERM: TERM-ID: ' + CONVERT(VARCHAR(10),@TERM_ID) + '###'
END
GO
ALTER TABLE TBIDB_TERM_VALUE_VARCHAR ALTER COLUMN ADDED_WHO VARCHAR (100);
ALTER TABLE TBIDB_TERM_VALUE_VARCHAR ALTER COLUMN CHANGED_WHO VARCHAR (100);
ALTER TABLE TBIDB_TERM_VALUE_INTEGER ALTER COLUMN ADDED_WHO VARCHAR (100);
ALTER TABLE TBIDB_TERM_VALUE_INTEGER ALTER COLUMN CHANGED_WHO VARCHAR (100);
ALTER TABLE TBIDB_TERM_VALUE_FLOAT ALTER COLUMN ADDED_WHO VARCHAR (100);
ALTER TABLE TBIDB_TERM_VALUE_FLOAT ALTER COLUMN CHANGED_WHO VARCHAR (100);
ALTER TABLE TBIDB_TERM_VALUE_DECIMAL ALTER COLUMN ADDED_WHO VARCHAR (100);
ALTER TABLE TBIDB_TERM_VALUE_DECIMAL ALTER COLUMN CHANGED_WHO VARCHAR (100);
ALTER TABLE TBIDB_TERM_VALUE_DATE ALTER COLUMN ADDED_WHO VARCHAR (100);
ALTER TABLE TBIDB_TERM_VALUE_DATE ALTER COLUMN CHANGED_WHO VARCHAR (100);
ALTER TABLE TBIDB_TERM_LANGUAGE ALTER COLUMN ADDED_WHO VARCHAR (100);
ALTER TABLE TBIDB_TERM_LANGUAGE ALTER COLUMN CHANGED_WHO VARCHAR (100);
ALTER TABLE TBIDB_OBJECT_METADATA ALTER COLUMN ADDED_WHO VARCHAR (100);
ALTER TABLE TBIDB_OBJECT_METADATA ALTER COLUMN CHANGED_WHO VARCHAR (100);
CREATE FUNCTION [dbo].[FNIDB_GET_TERM_FOR_TERM_ID] (@pTERMGUID BIGINT)
RETURNS VARCHAR(900)
AS
BEGIN
DECLARE @TERM_ID BIGINT, @RESULT VARCHAR(900)
SELECT @RESULT = T.TERM_VALUE
FROM TBIDB_TERM_VALUE_VARCHAR T WHERE T.GUID = @pTERMGUID
RETURN @RESULT
END
GO
-- =============================================
-- Author: DD MS
-- Craeation date: 17.08.2020 MS [TBIDB_LANGUAGE_TERM_METADATA]
-- =============================================
CREATE FUNCTION [dbo].[FNIDB_GET_TERM_FOR_LANGUAGE_TERM_METADATA_GUID] (@pTBIDB_LANGUAGE_TERM_METADATA_GUID BIGINT,@pLANG_CODE VARCHAR(5) = 'de-DE')
RETURNS VARCHAR(900)
AS
BEGIN
DECLARE @TERM_ID BIGINT, @RESULT VARCHAR(900),@LANG_ID INTEGER
SELECT @LANG_ID = GUID FROM TBIDB_LANGUAGE WHERE LANG_CODE = @pLANG_CODE
SELECT @RESULT = T3.TERM_VALUE -- @TERM_ID = T1.TEXT_TERM_ID
FROM TBIDB_LANGUAGE_TERM_METADATA T2
INNER JOIN TBIDB_TERM_LANGUAGE T1 ON T2.LANG_TERM_ID = T1.GUID
INNER JOIN TBIDB_TERM_VALUE_VARCHAR T3 ON T1.TEXT_TERM_ID = T3.GUID
WHERE
T2.GUID = @pTBIDB_LANGUAGE_TERM_METADATA_GUID
AND T1.LANGUAGE_ID = @LANG_ID
--SELECT @RESULT = TERM_VALUE FROM TBIDB_TERM_VALUE_VARCHAR WHERE GUID = @TERM_ID
RETURN @RESULT
END
GO
-- =============================================
-- Author: DD MS
-- Creation date: 17.08.2020
-- =============================================
CREATE FUNCTION [dbo].[FNIDB_GET_TERM_FOR_ATTRIBUTE_ID] (@pATTRIBUTE_ID INTEGER,@pLANG_CODE VARCHAR(10), @pUSERID INTEGER)
RETURNS @Output TABLE (IDB_OBJECT_ID BIGINT, TERM_VALUE VARCHAR(900),TERM_ID BIGINT,IDB_CREATED_WHEN DATETIME,IDB_CREATED_WHO VARCHAR(100))
AS
BEGIN
DECLARE
@TYP_ID TINYINT,
@TYP_DESCR VARCHAR(100),
@MULTI BIT,
@LANG_ID INT,
@TERM_RESULT VARCHAR(900),
@CREATED_WHEN DATETIME,
@CREATED_WHO VARCHAR(100)
BEGIN
SELECT @LANG_ID = GUID FROM TBIDB_LANGUAGE WHERE LANG_CODE = @pLANG_CODE
SELECT @TYP_ID = T.TYP_ID, @MULTI = T.MULTI_CONTEXT,@TYP_DESCR = T1.NAME_TYPE FROM TBIDB_ATTRIBUTE T, TBIDB_ATTRIBUTE_TYPE T1
WHERE T.TYP_ID = T1.GUID AND T.GUID = @pATTRIBUTE_ID
IF @TYP_ID IN (1,8) --VARCHAR
BEGIN
DECLARE @TL_ID BIGINT
INSERT INTO @Output (IDB_OBJECT_ID,TERM_VALUE,TERM_ID,IDB_CREATED_WHEN,IDB_CREATED_WHO)
SELECT MD.IDB_OBJ_ID, TERM.TERM_VALUE,TERM.GUID, MD.ADDED_WHEN,MD.ADDED_WHO
FROM
TBIDB_TERM_VALUE_VARCHAR TERM INNER JOIN TBIDB_TERM_LANGUAGE TLANG ON TERM.GUID = TLANG.TEXT_TERM_ID
INNER JOIN TBIDB_LANGUAGE_TERM_METADATA T1 ON TLANG.GUID = T1.LANG_TERM_ID
INNER JOIN TBIDB_OBJECT_METADATA MD ON T1.GUID = MD.TEXT_TERM_LANG_ID
WHERE MD.ATTR_ID = @pATTRIBUTE_ID
AND TLANG.LANGUAGE_ID = @LANG_ID
END
ELSE IF @TYP_ID IN (2,7,9) --BIGINT
BEGIN
INSERT INTO @Output (IDB_OBJECT_ID,TERM_VALUE,TERM_ID,IDB_CREATED_WHEN,IDB_CREATED_WHO)
SELECT MD.IDB_OBJ_ID, TERM.TERM_VALUE,TERM.GUID, MD.ADDED_WHEN,MD.ADDED_WHO
FROM
TBIDB_TERM_VALUE_INTEGER TERM, TBIDB_OBJECT_METADATA MD WHERE MD.INT_TERM_ID = TERM.GUID
AND MD.ATTR_ID = @pATTRIBUTE_ID
END
ELSE IF @TYP_ID = 3 --FLOAT
BEGIN
INSERT INTO @Output (IDB_OBJECT_ID,TERM_VALUE,TERM_ID,IDB_CREATED_WHEN,IDB_CREATED_WHO)
SELECT MD.IDB_OBJ_ID, TERM.TERM_VALUE,TERM.GUID, MD.ADDED_WHEN,MD.ADDED_WHO
FROM TBIDB_TERM_VALUE_FLOAT TERM, TBIDB_OBJECT_METADATA MD WHERE MD.FLOAT_TERM_ID = TERM.GUID
AND MD.ATTR_ID = @pATTRIBUTE_ID
END
ELSE IF @TYP_ID = 4
BEGIN
INSERT INTO @Output (IDB_OBJECT_ID,TERM_VALUE,TERM_ID,IDB_CREATED_WHEN,IDB_CREATED_WHO)
SELECT MD.IDB_OBJ_ID, TERM.TERM_VALUE, TERM.GUID, MD.ADDED_WHEN,MD.ADDED_WHO
FROM TBIDB_TERM_VALUE_DECIMAL TERM, TBIDB_OBJECT_METADATA MD WHERE MD.DEC_TERM_ID = TERM.GUID
AND MD.ATTR_ID = @pATTRIBUTE_ID
END
ELSE IF @TYP_ID = 5
BEGIN
INSERT INTO @Output (IDB_OBJECT_ID,TERM_VALUE,TERM_ID,IDB_CREATED_WHEN,IDB_CREATED_WHO)
SELECT MD.IDB_OBJ_ID, TERM.TERM_VALUE,TERM.GUID, MD.ADDED_WHEN,MD.ADDED_WHO
FROM TBIDB_TERM_VALUE_DATE TERM, TBIDB_OBJECT_METADATA MD WHERE MD.DATE_TERM_ID = TERM.GUID
AND MD.ATTR_ID = @pATTRIBUTE_ID
END
END
RETURN
END
CREATE TABLE TBIDB_SEARCH_PROFILE
(
GUID INTEGER NOT NULL IDENTITY (1, 1),
TITLE_ID BIGINT NOT NULL,
COMMENT VARCHAR(900),
ACTIVE BIT NOT NULL DEFAULT 1,
ADDED_WHO BIGINT,
ADDED_WHEN DATETIME NOT NULL DEFAULT GETDATE(),
CHANGED_WHO BIGINT,
CHANGED_WHEN DATETIME,
CONSTRAINT PK_TBIDB_SEARCH_PROFILE PRIMARY KEY (GUID),
CONSTRAINT FK_TBIDB_SEARCH_PROFILE_ADDED_WHO_T_ID FOREIGN KEY (ADDED_WHO) REFERENCES TBIDB_TERM_VALUE_VARCHAR (GUID),
CONSTRAINT FK_TBIDB_SEARCH_PROFILE_CHANGED_WHO_T_ID FOREIGN KEY (CHANGED_WHO) REFERENCES TBIDB_TERM_VALUE_VARCHAR (GUID),
)
GO
CREATE TRIGGER TBIDB_SEARCH_PROFILE_AFT_UPD ON TBIDB_SEARCH_PROFILE
FOR UPDATE
AS
UPDATE TBIDB_SEARCH_PROFILE SET CHANGED_WHEN = GETDATE()
FROM INSERTED
WHERE TBIDB_SEARCH_PROFILE.GUID = INSERTED.GUID
GO
CREATE TABLE TBIDB_SEARCH_RESULT_ATTRIBUTES
(
GUID INTEGER NOT NULL IDENTITY (1, 1),
SEARCH_PROFIL_ID INTEGER NOT NULL,
ATTRIBUTE_ID INTEGER NOT NULL,
SEQUENCE INTEGER DEFAULT 0,
ADDED_WHO BIGINT,
ADDED_WHEN DATETIME NOT NULL DEFAULT GETDATE(),
CONSTRAINT PK_TBIDB_SEARCH_RESULT_ATTRIBUTES_GUID PRIMARY KEY (GUID),
CONSTRAINT FK_TBIDB_SEARCH_RESULT_ATTRIBUTES_SPID FOREIGN KEY (SEARCH_PROFIL_ID) REFERENCES TBIDB_SEARCH_PROFILE (GUID),
CONSTRAINT FK_TBIDB_SEARCH_RESULT_ATTRIBUTES_ADDED_WHO FOREIGN KEY (ADDED_WHO) REFERENCES TBIDB_TERM_VALUE_VARCHAR (GUID),
CONSTRAINT UQ_TBIDB_SEARCH_RESULT_ATTRIBUTES UNIQUE(SEARCH_PROFIL_ID,ATTRIBUTE_ID)
)
GO
CREATE PROCEDURE [dbo].[PRIDB_NEW_SEARCH_RESULT_ATTRIBUTE] @pSEARCHID INTEGER,@pATTRIBUTE_ID INTEGER,@pWHO_TERM_ID BIGINT,@pSequence INTEGER = 0
AS
BEGIN
IF @pSequence = 0
SELECT @pSEQUENCE = COALESCE(MAX([SEQUENCE]),0) + 1 FROM TBIDB_SEARCH_RESULT_ATTRIBUTES
WHERE SEARCH_PROFIL_ID = @pSEARCHID
IF NOT EXISTS(SELECT GUID FROM TBIDB_SEARCH_RESULT_ATTRIBUTES WHERE ATTRIBUTE_ID = @pATTRIBUTE_ID AND SEARCH_PROFIL_ID = @pSEARCHID)
BEGIN
INSERT INTO TBIDB_SEARCH_RESULT_ATTRIBUTES (SEARCH_PROFIL_ID,ATTRIBUTE_ID,SEQUENCE,ADDED_WHO) VALUES (@pSEARCHID,@pATTRIBUTE_ID,@pSequence, @pWHO_TERM_ID)
EXEC [dbo].[PRIDB_NEW_SEARCH_ATTRIBUTE] @pSEARCHID,@pATTRIBUTE_ID,@pWHO_TERM_ID,0
END
ELSE
UPDATE TBIDB_SEARCH_RESULT_ATTRIBUTES SET SEQUENCE = @pSequence
WHERE ATTRIBUTE_ID = @pATTRIBUTE_ID AND SEARCH_PROFIL_ID = @pSEARCHID
--SELECT
-- T.GUID,
-- T.ATTRIBUTE_ID,
-- T1.TITLE
-- ,[dbo].[FNIDB_GET_TERM_FOR_TERM_ID] (T.ADDED_WHO) AS ADDED_WHO
-- ,T.ADDED_WHEN
--FROM TBIDB_SEARCH_RESULT_ATTRIBUTES T INNER JOIN TBIDB_ATTRIBUTE T1 ON T.ATTRIBUTE_ID = T1.GUID
--WHERE SEARCH_PROFIL_ID = @pSEARCHID
END
GO
CREATE PROCEDURE [dbo].[PRIDB_NEW_SEARCH_PROFILE] @BE_ID INT, @pTITLE VARCHAR(512),@pWHO_TERMID BIGINT,@pCOMMENT VARCHAR(900) = NULL, @pLANG_CODE VARCHAR(5) = 'de-DE'
AS
BEGIN
DECLARE
@LANG_ID INTEGER, @SQL_RESULT VARCHAR(912),
@SEARCH_ID INTEGER,
@WHO_TERM VARCHAR(100)
SELECT @WHO_TERM = TERM_VALUE FROM TBIDB_TERM_VALUE_VARCHAR WHERE GUID = @pWHO_TERMID
SELECT @LANG_ID = GUID FROM TBIDB_LANGUAGE WHERE LANG_CODE = @pLANG_CODE
DECLARE @MY_TITLE_TERM_ID BIGINT,@MY_LANG_TERM_ID BIGINT,@oLANGUAGE_TERM_METADATA_GUID BIGINT,@MY_RESULT_SQL_TERM_ID BIGINT
EXEC PRIDB_NEW_TERM 'VARCHAR',@pTITLE,@WHO_TERM,@TERM_ID = @MY_TITLE_TERM_ID OUTPUT;
EXEC PRIDB_NEW_TERM_LANGUAGE @LANG_ID,@MY_TITLE_TERM_ID,@WHO_TERM,@TERM_LANGUAGE_GUID = @MY_LANG_TERM_ID OUTPUT
EXEC PRIDB_NEW_LANGUAGE_TERM_METADATA_GUID @MY_LANG_TERM_ID,@pWHO_TERMID,@oLANG_TERM_GUID = @oLANGUAGE_TERM_METADATA_GUID OUTPUT
IF NOT EXISTS(SELECT GUID FROM TBIDB_SEARCH_PROFILE WHERE TITLE_ID = @oLANGUAGE_TERM_METADATA_GUID)
INSERT INTO TBIDB_SEARCH_PROFILE (TITLE_ID,ADDED_WHO,COMMENT) VALUES (@oLANGUAGE_TERM_METADATA_GUID,@pWHO_TERMID,@pCOMMENT)
ELSE
UPDATE TBIDB_SEARCH_PROFILE SET
COMMENT = @pCOMMENT,CHANGED_WHO = @pWHO_TERMID WHERE TITLE_ID = @oLANGUAGE_TERM_METADATA_GUID AND COMMENT <> @pCOMMENT
SELECT @SEARCH_ID = MAX(GUID) FROM TBIDB_SEARCH_PROFILE T
WHERE T.TITLE_ID = @oLANGUAGE_TERM_METADATA_GUID
SET @SQL_RESULT = 'SELECT T.IDB_OBJ_ID as DocID, [dbo].[FNIDB_GET_FILE_PATH] (T.IDB_OBJ_ID) as FULL_FILENAME, T.DocName as Filename, * FROM VWIDB_DOC_DATA WHERE '
DECLARE @ATTR_ID INT,@SEQUENCE TINYINT
SET @SEQUENCE = 0
DECLARE cursorDefaultAttributes CURSOR FOR
SELECT
T1.GUID
FROM TBIDB_ATTRIBUTE T1 INNER JOIN TBIDB_BE_ATTRIBUTE T2 ON T1.GUID = T2.ATTR_ID
WHERE T2.BE_ID = @BE_ID AND DEFAULT_SEARCH_ATTRIBUTE = 1
ORDER BY T1.VIEW_SEQUENCE
OPEN cursorDefaultAttributes
FETCH NEXT FROM cursorDefaultAttributes INTO @ATTR_ID
WHILE @@FETCH_STATUS = 0
BEGIN
IF NOT EXISTS (SELECT GUID FROM TBIDB_SEARCH_RESULT_ATTRIBUTES WHERE SEARCH_PROFIL_ID = @SEARCH_ID AND ATTRIBUTE_ID = @ATTR_ID)
EXEC PRIDB_NEW_SEARCH_RESULT_ATTRIBUTE @SEARCH_ID,@ATTR_ID,@pWHO_TERMID,@SEQUENCE
SET @SEQUENCE += 1
FETCH NEXT FROM cursorDefaultAttributes INTO @ATTR_ID
END
CLOSE cursorDefaultAttributes
DEALLOCATE cursorDefaultAttributes
SELECT
T.GUID,T.TITLE_ID
,dbo.[FNIDB_GET_TERM_FOR_LANGUAGE_TERM_METADATA_GUID ] (T.TITLE_ID,@pLANG_CODE) AS TITLE
--,[dbo].[FNIDB_GET_TERM_FOR_TERM_ID] (T.RESULT_SQL) AS RESULT_SQL
,[dbo].[FNIDB_GET_TERM_FOR_TERM_ID] (T.ADDED_WHO) AS ADDED_WHO
,T.ADDED_WHEN
,[dbo].[FNIDB_GET_TERM_FOR_TERM_ID] (T.CHANGED_WHO) AS CHANGED_WHO
,T.CHANGED_WHEN
FROM TBIDB_SEARCH_PROFILE T
WHERE GUID = @SEARCH_ID
END
GO
--DROP TABLE TBIDB_SEARCH_LANGUAGE_SQL_RESULT
CREATE TABLE TBIDB_SEARCH_LANGUAGE_SQL_RESULT
(
GUID INTEGER NOT NULL IDENTITY (1, 1),
SEARCH_PROFIL_ID INTEGER NOT NULL,
LANGUAGE_ID TINYINT NOT NULL,
SEARCH_TERM_ID BIGINT NOT NULL,
ADDED_WHO BIGINT,
ADDED_WHEN DATETIME NOT NULL DEFAULT GETDATE(),
CHANGED_WHO BIGINT,
CHANGED_WHEN DATETIME,
CONSTRAINT PK_TBIDB_SEARCH_LANGUAGE_SQL_RESULT_GUID PRIMARY KEY (GUID),
CONSTRAINT FK_TBIDB_SEARCH_LANGUAGE_SQL_RESULT_P_ID FOREIGN KEY (SEARCH_PROFIL_ID) REFERENCES TBIDB_SEARCH_PROFILE (GUID),
CONSTRAINT FK_TBIDB_SEARCH_LANGUAGE_SQL_RESULT_LID FOREIGN KEY (LANGUAGE_ID) REFERENCES TBIDB_LANGUAGE (GUID),
CONSTRAINT FK_TBIDB_SEARCH_LANGUAGE_SQL_RESULT_STID FOREIGN KEY (SEARCH_TERM_ID) REFERENCES TBIDB_TERM_VALUE_VARCHAR (GUID),
CONSTRAINT FK_TBIDB_SEARCH_LANGUAGE_SQL_RESULT_ADDED_WHO FOREIGN KEY (ADDED_WHO) REFERENCES TBIDB_TERM_VALUE_VARCHAR (GUID),
CONSTRAINT FK_TBIDB_SEARCH_LANGUAGE_SQL_RESULT_CHANGED_WHO FOREIGN KEY (CHANGED_WHO) REFERENCES TBIDB_TERM_VALUE_VARCHAR (GUID),
--CONSTRAINT FK_TBIDB_SEARCH_PROFILE_USER_USER_ID FOREIGN KEY (USER_ID) REFERENCES DD_ECM_TEST.dbo.TBDD_USER (GUID),
CONSTRAINT UQ_TBIDB_SEARCH_LANGUAGE_SQL_RESULT UNIQUE(SEARCH_PROFIL_ID,LANGUAGE_ID)
)
GO
CREATE TRIGGER TBIDB_SEARCH_LANGUAGE_SQL_RESULT_AFT_UPD ON TBIDB_SEARCH_LANGUAGE_SQL_RESULT
FOR UPDATE
AS
UPDATE TBIDB_SEARCH_LANGUAGE_SQL_RESULT SET CHANGED_WHEN = GETDATE()
FROM INSERTED
WHERE TBIDB_SEARCH_LANGUAGE_SQL_RESULT .GUID = INSERTED.GUID
GO
CREATE PROCEDURE [dbo].[PRIDB_NEW_SEARCH_SQL_RESULT] @SEARCH_ID INT,@pWHO_TERMID BIGINT
AS
BEGIN
DECLARE
@LANG_ID TINYINT,
@SQL_RESULT VARCHAR(912),
@WHO_TERM VARCHAR(100),
@MY_RESULT_SQL_TERM_ID BIGINT
SELECT @WHO_TERM = TERM_VALUE FROM TBIDB_TERM_VALUE_VARCHAR WHERE GUID = @pWHO_TERMID
DECLARE cursorLang CURSOR FOR
select GUID from TBIDB_LANGUAGE WHERE CREATE_DEFAULT_ENTRY = 1
OPEN cursorLang
FETCH NEXT FROM cursorLang INTO @LANG_ID
WHILE @@FETCH_STATUS = 0
BEGIN
SET @SQL_RESULT = 'SELECT T.IDB_OBJ_ID as DocID, [dbo].[FNIDB_GET_FILE_PATH] (T.IDB_OBJ_ID) as FULL_FILENAME, T.DocName as Filename'
DECLARE @ATTR_TITLE VARCHAR(100)
DECLARE cursorSRA CURSOR FOR
SELECT T3.TERM_VALUE
FROM TBIDB_SEARCH_RESULT_ATTRIBUTES T INNER JOIN TBIDB_ATTRIBUTE T1 ON T.ATTRIBUTE_ID = T1.GUID
INNER JOIN TBIDB_ATTRIBUTE_LANGUAGE T2 ON T1.GUID = T2.ATTRIBUTE_ID
INNER JOIN TBIDB_TERM_VALUE_VARCHAR T3 ON T2.TERM_ID = T3.GUID
WHERE T.SEARCH_PROFIL_ID = @SEARCH_ID --@SEARCH_ID
AND T2.LANGUAGE_ID = @LANG_ID
ORDER BY T.SEQUENCE
OPEN cursorSRA
FETCH NEXT FROM cursorSRA INTO @ATTR_TITLE
WHILE @@FETCH_STATUS = 0
BEGIN
SET @SQL_RESULT += ', T.[' + @ATTR_TITLE + ']'
FETCH NEXT FROM cursorSRA INTO @ATTR_TITLE
END
CLOSE cursorSRA
DEALLOCATE cursorSRA
SET @SQL_RESULT += ' FROM VWIDB_DOC_DATA T INNER JOIN [dbo].[FNIDB_SEARCH_RESULT_GET_OBJECTS] (@UserID,@SearchID) T1 ON T.IDB_OBJ_ID = T1.IDB_OBJ_ID '
EXEC PRIDB_NEW_TERM 'VARCHAR',@SQL_RESULT,@WHO_TERM,@TERM_ID = @MY_RESULT_SQL_TERM_ID OUTPUT;
PRINT @SQL_RESULT
IF NOT EXISTS(SELECT GUID FROM TBIDB_SEARCH_LANGUAGE_SQL_RESULT WHERE SEARCH_PROFIL_ID = @SEARCH_ID AND LANGUAGE_ID = @LANG_ID)
INSERT INTO TBIDB_SEARCH_LANGUAGE_SQL_RESULT (SEARCH_PROFIL_ID,LANGUAGE_ID,SEARCH_TERM_ID,ADDED_WHO) VALUES
(@SEARCH_ID,@LANG_ID,@MY_RESULT_SQL_TERM_ID,@pWHO_TERMID)
ELSE
UPDATE TBIDB_SEARCH_LANGUAGE_SQL_RESULT SET SEARCH_TERM_ID = @MY_RESULT_SQL_TERM_ID,CHANGED_WHO = @pWHO_TERMID WHERE SEARCH_PROFIL_ID = @SEARCH_ID AND LANGUAGE_ID = @LANG_ID
FETCH NEXT FROM cursorLang INTO @LANG_ID
END
CLOSE cursorLang
DEALLOCATE cursorLang
END
GO
CREATE TABLE TBIDB_SEARCH_PROFILE_USER
(
GUID INTEGER NOT NULL IDENTITY (1, 1),
SEARCH_PROFIL_ID INTEGER NOT NULL,
USER_ID INTEGER NOT NULL,
ADDED_WHO BIGINT,
ADDED_WHEN DATETIME NOT NULL DEFAULT GETDATE(),
CONSTRAINT PK_TBIDB_SEARCH_PROFILE_USER_GUID PRIMARY KEY (GUID),
CONSTRAINT FK_TBIDB_SEARCH_PROFILE_USER_P_ID FOREIGN KEY (SEARCH_PROFIL_ID) REFERENCES TBIDB_SEARCH_PROFILE (GUID),
CONSTRAINT FK_TBIDB_SEARCH_PROFILE_USER_ADDED_WHO FOREIGN KEY (ADDED_WHO) REFERENCES TBIDB_TERM_VALUE_VARCHAR (GUID),
--CONSTRAINT FK_TBIDB_SEARCH_PROFILE_USER_USER_ID FOREIGN KEY (USER_ID) REFERENCES DD_ECM_TEST.dbo.TBDD_USER (GUID),
CONSTRAINT UQ_TBIDB_SEARCH_PROFILE_USER UNIQUE(SEARCH_PROFIL_ID,USER_ID)
)
GO
CREATE PROCEDURE [dbo].[PRIDB_NEW_RELATION_SEARCH_USER] @pSEARCHID INTEGER,@pUSER_ID INTEGER,@pWHO_TERM_ID BIGINT
AS
BEGIN
IF NOT EXISTS(SELECT GUID FROM TBIDB_SEARCH_PROFILE_USER WHERE USER_ID = @pUSER_ID AND SEARCH_PROFIL_ID = @pSEARCHID)
INSERT INTO TBIDB_SEARCH_PROFILE_USER (USER_ID,ADDED_WHO,SEARCH_PROFIL_ID) VALUES (@pUSER_ID,@pWHO_TERM_ID,@pSEARCHID)
SELECT
GUID,USER_ID,SEARCH_PROFIL_ID
,[dbo].[FNIDB_GET_TERM_FOR_TERM_ID] (ADDED_WHO) AS ADDED_WHO
,ADDED_WHEN
FROM TBIDB_SEARCH_PROFILE_USER
WHERE SEARCH_PROFIL_ID = @pSEARCHID
END
GO
CREATE TABLE TBIDB_SEARCH_PROFILE_GROUP
(
GUID INTEGER NOT NULL IDENTITY (1, 1),
SEARCH_PROFIL_ID INTEGER NOT NULL,
GROUP_ID INTEGER NOT NULL,
ADDED_WHO BIGINT,
ADDED_WHEN DATETIME NOT NULL DEFAULT GETDATE(),
CONSTRAINT PK_TBIDB_SEARCH_PROFILE_GROUP_GUID PRIMARY KEY (GUID),
CONSTRAINT FK_TBIDB_SEARCH_PROFILE_GROUP_P_ID FOREIGN KEY (SEARCH_PROFIL_ID) REFERENCES TBIDB_SEARCH_PROFILE (GUID),
CONSTRAINT FK_TBIDB_SEARCH_PROFILE_GROUP_ADDED_WHO FOREIGN KEY (ADDED_WHO) REFERENCES TBIDB_TERM_VALUE_VARCHAR (GUID),
--CONSTRAINT FK_TBIDB_SEARCH_PROFILE_USER_USER_ID FOREIGN KEY (USER_ID) REFERENCES DD_ECM_TEST.dbo.TBDD_USER (GUID),
CONSTRAINT UQ_TBIDB_SEARCH_PROFILE_GROUP UNIQUE(SEARCH_PROFIL_ID,GROUP_ID)
)
GO
CREATE PROCEDURE [dbo].[PRIDB_NEW_RELATION_SEARCH_GROUP] @pSEARCHID INTEGER,@pGROUP_ID INTEGER,@pWHO_TERM_ID BIGINT
AS
BEGIN
IF NOT EXISTS(SELECT GUID FROM TBIDB_SEARCH_PROFILE_GROUP WHERE GROUP_ID = @pGROUP_ID AND SEARCH_PROFIL_ID = @pSEARCHID)
INSERT INTO TBIDB_SEARCH_PROFILE_GROUP (GROUP_ID,ADDED_WHO,SEARCH_PROFIL_ID) VALUES (@pGROUP_ID,@pWHO_TERM_ID,@pSEARCHID)
SELECT
GUID,GROUP_ID,SEARCH_PROFIL_ID
,[dbo].[FNIDB_GET_TERM_FOR_TERM_ID] (ADDED_WHO) AS ADDED_WHO
,ADDED_WHEN
FROM TBIDB_SEARCH_PROFILE_GROUP
WHERE SEARCH_PROFIL_ID = @pSEARCHID
END
GO
--DROP TABLE TBIDB_SEARCH_PROFILE_ATTRIBUTES
CREATE TABLE TBIDB_SEARCH_PROFILE_ATTRIBUTES
(
GUID INTEGER NOT NULL IDENTITY (1, 1),
SEARCH_PROFIL_ID INTEGER NOT NULL,
ATTRIBUTE_ID INTEGER NOT NULL,
X_LOC FLOAT NOT NULL DEFAULT 0,
Y_LOC FLOAT NOT NULL DEFAULT 0,
[SEQUENCE] INTEGER NOT NULL DEFAULT 0,
HEIGHT SMALLINT NOT NULL DEFAULT 25,
WIDTH SMALLINT NOT NULL DEFAULT 200,
MULTISELECT BIT NOT NULL DEFAULT 0,
SOURCE_SQL BIGINT,
ENABLE_SQL BIGINT,
ENABLE_CONID SMALLINT,
--DEPENDING_ATTRIBUTE1 INTEGER NOT NULL DEFAULT 0,
ADDED_WHO BIGINT,
ADDED_WHEN DATETIME NOT NULL DEFAULT GETDATE(),
CHANGED_WHO BIGINT,
CHANGED_WHEN DATETIME,
CONSTRAINT PK_TBIDB_SEARCH_PROFILE_ATTRIBUTES_GUID PRIMARY KEY (GUID),
CONSTRAINT FK_TBIDB_SEARCH_PROFILE_ATTRIBUTES_P_ID FOREIGN KEY (SEARCH_PROFIL_ID) REFERENCES TBIDB_SEARCH_PROFILE (GUID),
CONSTRAINT FK_TBIDB_SEARCH_PROFILE_ATTRIBUTES_ADDED_WHO FOREIGN KEY (ADDED_WHO) REFERENCES TBIDB_TERM_VALUE_VARCHAR (GUID),
CONSTRAINT FK_TBIDB_SEARCH_PROFILE_ATTRIBUTES_CHANGED_WHO FOREIGN KEY (CHANGED_WHO) REFERENCES TBIDB_TERM_VALUE_VARCHAR (GUID),
CONSTRAINT FK_TBIDB_SEARCH_PROFILE_ATTRIBUTES_SOURCE_SQL FOREIGN KEY (SOURCE_SQL) REFERENCES TBIDB_TERM_VALUE_VARCHAR (GUID),
CONSTRAINT FK_TBIDB_SEARCH_PROFILE_ATTRIBUTES_ENABLE_SQL FOREIGN KEY (ENABLE_SQL) REFERENCES TBIDB_TERM_VALUE_VARCHAR (GUID),
CONSTRAINT UQ_TBIDB_SEARCH_PROFILE_ATTRIBUTES UNIQUE(SEARCH_PROFIL_ID,ATTRIBUTE_ID)
)
GO
CREATE TRIGGER TBIDB_SEARCH_PROFILE_ATTRIBUTES_AFT_UPD ON TBIDB_SEARCH_PROFILE_ATTRIBUTES
FOR UPDATE
AS
UPDATE TBIDB_SEARCH_PROFILE_ATTRIBUTES SET CHANGED_WHEN = GETDATE()
FROM INSERTED
WHERE TBIDB_SEARCH_PROFILE_ATTRIBUTES .GUID = INSERTED.GUID
GO
CREATE PROCEDURE [dbo].[PRIDB_NEW_SEARCH_ATTRIBUTE] @pSEARCH_PROFIL_ID INTEGER,@pATTRIBUTE_ID INTEGER,@MULTISELECT BIT, @WHO_TERM_ID INTEGER, @pSEQUENCE INTEGER,@pHEIGHT SMALLINT = 0,@pWIDTH SMALLINT = 0
AS
BEGIN
DECLARE @pWHO_USERNAME VARCHAR(100),@USER_LANGUAGE VARCHAR(5),@USER_LANGUAGE_ID INT, @ATTRTYPE as VARCHAR(20)--,@USER_ID INTEGER
SELECT @pWHO_USERNAME = TERM_VALUE FROM TBIDB_TERM_VALUE_VARCHAR WHERE GUID = @WHO_TERM_ID
SELECT @USER_LANGUAGE = LANGUAGE,@USER_LANGUAGE_ID = T1.GUID FROM DD_ECM_TEST.dbo.TBDD_USER T INNER JOIN IDB_TEST.dbo.TBIDB_LANGUAGE T1 ON T.LANGUAGE = T1.LANG_CODE WHERE UPPER(USERNAME) = UPPER(@pWHO_USERNAME)
SELECT @ATTRTYPE = T1.NAME_TYPE FROM TBIDB_ATTRIBUTE T INNER JOIN TBIDB_ATTRIBUTE_TYPE T1 ON T.TYP_ID = T1.GUID WHERE T.GUID = @pATTRIBUTE_ID
IF @ATTRTYPE IN ('VARCHAR','BIG INTEGER')
BEGIN
IF @pHEIGHT = 0
SET @pHEIGHT = 200
IF @pWIDTH = 0
SET @pWIDTH = 200
END
ELSE IF @ATTRTYPE ='DATE'
BEGIN
IF @pHEIGHT = 0
SET @pHEIGHT = 20
IF @pWIDTH = 0
SET @pWIDTH = 100
END
ELSE IF @ATTRTYPE ='BIT'
BEGIN
IF @pHEIGHT = 0
SET @pHEIGHT = 20
IF @pWIDTH = 0
SET @pWIDTH = 200
END
DECLARE @SOURCE_TERM_ID BIGINT,@SOURCE_DEFAULT_SQL VARCHAR(900)
SET @SOURCE_DEFAULT_SQL = 'select DISTINCT TERM.TERM_VALUE AS @RESULT_TITLE
FROM
TBIDB_TERM_VALUE_VARCHAR TERM INNER JOIN TBIDB_TERM_LANGUAGE TLANG ON TERM.GUID = TLANG.TEXT_TERM_ID
INNER JOIN TBIDB_LANGUAGE_TERM_METADATA T1 ON TLANG.GUID = T1.LANG_TERM_ID
INNER JOIN TBIDB_OBJECT_METADATA MD ON T1.GUID = MD.TEXT_TERM_LANG_ID
INNER JOIN TBIDB_OBJECT OBJ ON MD.IDB_OBJ_ID = OBJ.IDB_OBJ_ID
WHERE
MD.ATTR_ID = ' + CONVERT(VARCHAR(3),@pATTRIBUTE_ID) + ' AND TLANG.LANGUAGE_ID = ' + CONVERT(VARCHAR(3),@USER_LANGUAGE_ID) + '
AND OBJ.DELETED = 0 AND ACTIVE = 1'
--IF @pDEPENDING_ATTRIBUTE1 <> 0
-- SET @SOURCE_DEFAULT_SQL = REPLACE(@SOURCE_DEFAULT_SQL,'@pUSER_ID) ','@pUSER_ID) where IDB_OBJECT_ID = @DEPENDING_IDB_OBJECT ')
--ELSE
-- SET @SOURCE_DEFAULT_SQL = REPLACE(@SOURCE_DEFAULT_SQL,'@JOIN ','')
IF @ATTRTYPE = 'DATE'
SET @SOURCE_DEFAULT_SQL = 'select DISTINCT TERM.TERM_VALUE AS @RESULT_TITLE
FROM
TBIDB_TERM_VALUE_DATE TERM INNER JOIN TBIDB_OBJECT_METADATA MD ON TERM.GUID = MD.DATE_TERM_ID
INNER JOIN TBIDB_OBJECT OBJ ON MD.IDB_OBJ_ID = OBJ.IDB_OBJ_ID
WHERE
MD.ATTR_ID = ' + CONVERT(VARCHAR(3),@pATTRIBUTE_ID) + '
AND OBJ.DELETED = 0 AND ACTIVE = 1'
ELSE IF @ATTRTYPE = 'BIG INTEGER'
SET @SOURCE_DEFAULT_SQL = 'select DISTINCT TERM.TERM_VALUE AS @RESULT_TITLE
FROM
TBIDB_TERM_VALUE_INTEGER TERM INNER JOIN TBIDB_OBJECT_METADATA MD ON TERM.GUID = MD.INT_TERM_ID
INNER JOIN TBIDB_OBJECT OBJ ON MD.IDB_OBJ_ID = OBJ.IDB_OBJ_ID
WHERE
MD.ATTR_ID = ' + CONVERT(VARCHAR(3),@pATTRIBUTE_ID) + '
AND OBJ.DELETED = 0 AND ACTIVE = 1'
ELSE IF @ATTRTYPE = 'BIT'
SET @SOURCE_DEFAULT_SQL = 'select DISTINCT CONVERT(BIT,TERM.TERM_VALUE) AS @RESULT_TITLE
FROM
TBIDB_TERM_VALUE_INTEGER TERM INNER JOIN TBIDB_OBJECT_METADATA MD ON TERM.GUID = MD.INT_TERM_ID
INNER JOIN TBIDB_OBJECT OBJ ON MD.IDB_OBJ_ID = OBJ.IDB_OBJ_ID
WHERE
MD.ATTR_ID = ' + CONVERT(VARCHAR(3),@pATTRIBUTE_ID) + '
AND OBJ.DELETED = 0 AND ACTIVE = 1'
EXEC PRIDB_NEW_TERM 'VARCHAR',@SOURCE_DEFAULT_SQL,@pWHO_USERNAME,@TERM_ID = @SOURCE_TERM_ID OUTPUT;
IF @pSEQUENCE = 0
SELECT @pSEQUENCE = COALESCE(MAX([SEQUENCE]),0) + 1 FROM TBIDB_SEARCH_PROFILE_ATTRIBUTES WHERE SEARCH_PROFIL_ID = @pSEARCH_PROFIL_ID
IF NOT EXISTS(SELECT GUID FROM TBIDB_SEARCH_PROFILE_ATTRIBUTES WHERE SEARCH_PROFIL_ID = @pSEARCH_PROFIL_ID AND ATTRIBUTE_ID = @pATTRIBUTE_ID)
INSERT INTO TBIDB_SEARCH_PROFILE_ATTRIBUTES (SEARCH_PROFIL_ID,ATTRIBUTE_ID,SOURCE_SQL, [SEQUENCE], ADDED_WHO,HEIGHT,WIDTH,MULTISELECT)
VALUES (@pSEARCH_PROFIL_ID,@pATTRIBUTE_ID,@SOURCE_TERM_ID,@pSEQUENCE, @WHO_TERM_ID,@pHEIGHT,@pWIDTH,@MULTISELECT)
ELSE
BEGIN
UPDATE TBIDB_SEARCH_PROFILE_ATTRIBUTES SET
SOURCE_SQL = @SOURCE_TERM_ID
,[SEQUENCE] = @pSEQUENCE
,HEIGHT = @pHEIGHT
,WIDTH = @pWIDTH
,MULTISELECT = @MULTISELECT
WHERE SEARCH_PROFIL_ID = @pSEARCH_PROFIL_ID AND ATTRIBUTE_ID = @pATTRIBUTE_ID
END
SELECT
T.SEARCH_PROFIL_ID,
T.GUID,
T.ATTRIBUTE_ID,
T1.TITLE AS ATTRIBUTE_TITLE,
T.MULTISELECT,
T.HEIGHT,
T.WIDTH,
T2.NAME_TYPE AS ATTRIBUTE_TYPE
,[dbo].[FNIDB_GET_TERM_FOR_TERM_ID] (T.SOURCE_SQL) AS SOURCE_SQL
,[dbo].[FNIDB_GET_TERM_FOR_TERM_ID] (T.ADDED_WHO) AS ADDED_WHO
,T.ADDED_WHEN
,[dbo].[FNIDB_GET_TERM_FOR_TERM_ID] (T.CHANGED_WHO) AS CHANGED_WHO
,T.CHANGED_WHEN
FROM TBIDB_SEARCH_PROFILE_ATTRIBUTES T INNER JOIN TBIDB_ATTRIBUTE T1 ON T.ATTRIBUTE_ID = T1.GUID
INNER JOIN TBIDB_ATTRIBUTE_TYPE T2 ON T1.TYP_ID = T2.GUID
WHERE T.SEARCH_PROFIL_ID = @pSEARCH_PROFIL_ID --AND ATTRIBUTE_ID = @pATTRIBUTE_ID
ORDER BY [SEQUENCE]
END
GO
--drop table TBIDB_SEARCH_ATTRIBUTES_LINKS;
CREATE TABLE TBIDB_SEARCH_ATTRIBUTES_LINKS
(
GUID INTEGER NOT NULL IDENTITY (1, 1),
DEP_ATTR_ID INTEGER NOT NULL,
LINKED_ATTR_ID INTEGER NOT NULL,
ADDED_WHO BIGINT,
ADDED_WHEN DATETIME NOT NULL DEFAULT GETDATE(),
CHANGED_WHO BIGINT,
CHANGED_WHEN DATETIME,
CONSTRAINT PK_TBIDB_SEARCH_ATTRIBUTES_LINKS_GUID PRIMARY KEY (GUID),
CONSTRAINT FK_TBIDB_SEARCH_ATTRIBUTES_LINKS_DA_ID FOREIGN KEY (DEP_ATTR_ID) REFERENCES TBIDB_SEARCH_PROFILE_ATTRIBUTES (GUID),
CONSTRAINT FK_TBIDB_SEARCH_ATTRIBUTES_LINKS_LA_ID FOREIGN KEY (LINKED_ATTR_ID) REFERENCES TBIDB_SEARCH_PROFILE_ATTRIBUTES (GUID),
CONSTRAINT FK_TBIDB_SEARCH_ATTRIBUTES_LINKS_ADDED_WHO FOREIGN KEY (ADDED_WHO) REFERENCES TBIDB_TERM_VALUE_VARCHAR (GUID),
CONSTRAINT FK_TBIDB_SEARCH_ATTRIBUTES_LINKS_CHANGED_WHO FOREIGN KEY (CHANGED_WHO) REFERENCES TBIDB_TERM_VALUE_VARCHAR (GUID)
)
GO
--DROP TABLE TBIDB_SEARCH_RESTRICTIONS_INPUT
CREATE TABLE TBIDB_SEARCH_RESTRICTIONS_INPUT
(
GUID INTEGER NOT NULL IDENTITY (1, 1),
SEARCH_ID INTEGER NOT NULL,
RESTR_ATTR_ID INTEGER NOT NULL,
SOURCE_ATTR_ID INTEGER NOT NULL,
TERM VARCHAR(900) NOT NULL,
USR_ID INTEGER NOT NULL,
ADDED_WHEN DATETIME NOT NULL DEFAULT GETDATE(),
CONSTRAINT PK_TBIDB_SEARCH_RESTRICTIONS_INPUT_GUID PRIMARY KEY (GUID),
CONSTRAINT FK_TBIDB_SEARCH_RESTRICTIONS_INPUT_SID FOREIGN KEY (SEARCH_ID) REFERENCES TBIDB_SEARCH_PROFILE (GUID),
CONSTRAINT FK_TBIDB_SEARCH_RESTRICTIONS_INPUT_RA_ID FOREIGN KEY (RESTR_ATTR_ID) REFERENCES TBIDB_SEARCH_PROFILE_ATTRIBUTES (GUID),
CONSTRAINT FK_TBIDB_SEARCH_RESTRICTIONS_INPUT_SA_ID FOREIGN KEY (SOURCE_ATTR_ID) REFERENCES TBIDB_SEARCH_PROFILE_ATTRIBUTES (GUID),
)
GO
CREATE TABLE TBIDB_SEARCH_RESTRICTIONS_OBJECTS
(
GUID INTEGER NOT NULL IDENTITY (1, 1),
SEARCH_ID INTEGER NOT NULL,
RESTR_ATTR_ID INTEGER NOT NULL,
SOURCE_ATTR_ID INTEGER NOT NULL,
IDB_OBJ_ID BIGINT NOT NULL,
USR_ID INTEGER NOT NULL,
ADDED_WHEN DATETIME NOT NULL DEFAULT GETDATE(),
CONSTRAINT PK_TBIDB_SEARCH_RESTRICTIONS_OBJECTS_GUID PRIMARY KEY (GUID),
CONSTRAINT FK_TBIDB_SEARCH_RESTRICTIONS_OBJECTS_SID FOREIGN KEY (SEARCH_ID) REFERENCES TBIDB_SEARCH_PROFILE (GUID),
CONSTRAINT FK_TBIDB_SEARCH_RESTRICTIONS_OBJECTS_RA_ID FOREIGN KEY (RESTR_ATTR_ID) REFERENCES TBIDB_SEARCH_PROFILE_ATTRIBUTES (GUID),
CONSTRAINT FK_TBIDB_SEARCH_RESTRICTIONS_OBJECTS_SA_ID FOREIGN KEY (SOURCE_ATTR_ID) REFERENCES TBIDB_SEARCH_PROFILE_ATTRIBUTES (GUID),
CONSTRAINT FK_TBIDB_SEARCH_RESTRICTIONS_OBJECTS_IOBJ_ID FOREIGN KEY (IDB_OBJ_ID) REFERENCES TBIDB_OBJECT (IDB_OBJ_ID)
)
GO
CREATE TRIGGER [dbo].[TBIDB_SEARCH_RESTRICTIONS_INPUT_AFT_INS] ON [dbo].[TBIDB_SEARCH_RESTRICTIONS_INPUT]
WITH EXECUTE AS CALLER
FOR INSERT
AS
BEGIN TRY
DECLARE
@SEARCH_ID INTEGER,
@RESTR_ATTR_ID INTEGER,
@SOURCE_ATTR_ID INTEGER,
@TERM VARCHAR(900),
@USR_ID INTEGER,
@pLANG_CODE VARCHAR(5)
SELECT
@SEARCH_ID = SEARCH_ID,
@RESTR_ATTR_ID = RESTR_ATTR_ID,
@SOURCE_ATTR_ID = SOURCE_ATTR_ID,
@TERM = TERM,
@USR_ID = USR_ID
FROM INSERTED
--DELETE FROM TBIDB_SEARCH_RESTRICTIONS_OBJECTS
--WHERE
-- SEARCH_ID = @SEARCH_ID AND
-- RESTR_ATTR_ID = @RESTR_ATTR_ID AND
-- SOURCE_ATTR_ID = @SOURCE_ATTR_ID AND
-- USR_ID = @USR_ID;
SELECT @pLANG_CODE = [LANGUAGE] FROM DD_ECM_TEST.dbo.TBDD_USER WHERE GUID = @USR_ID
INSERT INTO TBIDB_SEARCH_RESTRICTIONS_OBJECTS (SEARCH_ID,RESTR_ATTR_ID, SOURCE_ATTR_ID, IDB_OBJ_ID, USR_ID)
SELECT @SEARCH_ID,@RESTR_ATTR_ID, @SOURCE_ATTR_ID,T.IDB_OBJECT_ID,@USR_ID
FROM [dbo].[FNIDB_GET_TERM_FOR_ATTRIBUTE_ID] (@SOURCE_ATTR_ID,@pLANG_CODE,@USR_ID) T LEFT JOIN TBIDB_SEARCH_RESTRICTIONS_OBJECTS T1
ON T.IDB_OBJECT_ID = T1.IDB_OBJ_ID
where T.TERM_VALUE = @TERM AND T1.IDB_OBJ_ID IS NULL
--where TERM_VALUE = @TERM
END TRY
BEGIN CATCH
PRINT 'ERROR IN TRIGGER: ' + CONVERT(VARCHAR(30),ERROR_PROCEDURE())
+ ' - ERROR-MESSAGE: '
+ CONVERT(VARCHAR(500),ERROR_MESSAGE())
END CATCH
GO
CREATE NONCLUSTERED INDEX [IDXTBIDB_OBJECT_METADATA_ATTR_ID1]
ON [dbo].[TBIDB_OBJECT_METADATA] ([ATTR_ID])
INCLUDE ([IDB_OBJ_ID],[TEXT_TERM_LANG_ID],[ADDED_WHO],[ADDED_WHEN])
GO
CREATE NONCLUSTERED INDEX [TBIDB_LANGUAGE_TERM_METADATA_LANG_TERM_ID]
ON [dbo].[TBIDB_LANGUAGE_TERM_METADATA] ([LANG_TERM_ID])
GO
CREATE NONCLUSTERED INDEX [IDXTBIDB_OBJECT_METADATA2]
ON [dbo].[TBIDB_OBJECT_METADATA] ([ATTR_ID])
INCLUDE ([IDB_OBJ_ID],[INT_TERM_ID],[ADDED_WHO],[ADDED_WHEN])
GO
CREATE NONCLUSTERED INDEX [IDXTBIDB_OBJECT_METADATA_ATTR_ID_TEXT_TERM_LANG_ID]
ON [dbo].[TBIDB_OBJECT_METADATA] ([ATTR_ID],[TEXT_TERM_LANG_ID])
INCLUDE ([IDB_OBJ_ID],[ADDED_WHO],[ADDED_WHEN])
GO
CREATE NONCLUSTERED INDEX [IDXTBIDB_OBJECT_METADATA3]
ON [dbo].[TBIDB_OBJECT_METADATA] ([ATTR_ID])
INCLUDE ([IDB_OBJ_ID],[FLOAT_TERM_ID],[ADDED_WHO],[ADDED_WHEN])
GO
CREATE NONCLUSTERED INDEX [IDXTBIDB_OBJECT_METADATA_ATTR_ID_[FLOAT_TERM_ID]
ON [dbo].[TBIDB_OBJECT_METADATA] ([ATTR_ID],[FLOAT_TERM_ID])
INCLUDE ([IDB_OBJ_ID],[ADDED_WHO],[ADDED_WHEN])
GO
CREATE VIEW VWIDB_SEARCH_PROFILE_ATTRIBUTES AS
SELECT
T.SEARCH_PROFIL_ID,
T.GUID,
T.ATTRIBUTE_ID,
--T.DEPENDING_ATTRIBUTE1,
T1.TITLE AS ATTRIBUTE_TITLE,
T.HEIGHT,
T.WIDTH,
T.MULTISELECT,
T2.NAME_TYPE AS ATTRIBUTE_TYPE
,[dbo].[FNIDB_GET_TERM_FOR_TERM_ID] (T.SOURCE_SQL) AS SOURCE_SQL
,[dbo].[FNIDB_GET_TERM_FOR_TERM_ID] (T.ADDED_WHO) AS ADDED_WHO
,T.ADDED_WHEN
,[dbo].[FNIDB_GET_TERM_FOR_TERM_ID] (T.CHANGED_WHO) AS CHANGED_WHO
,T.CHANGED_WHEN
,T.[SEQUENCE]
FROM
TBIDB_SEARCH_PROFILE_ATTRIBUTES T INNER JOIN TBIDB_ATTRIBUTE T1 ON T.ATTRIBUTE_ID = T1.GUID
INNER JOIN TBIDB_ATTRIBUTE_TYPE T2 ON T1.TYP_ID = T2.GUID
GO
CREATE VIEW VWIDB_SEARCH_ATTRIBUTES_LINKS AS
SELECT
T1.SEARCH_PROFIL_ID,
T.GUID,
T.DEP_ATTR_ID,
--T.DEPENDING_ATTRIBUTE1,
T3.TITLE AS DEP_ATTRIBUTE_TITLE,
[dbo].[FNIDB_GET_TERM_FOR_TERM_ID] (T1.SOURCE_SQL) DEP_SOURCE_SQL,
T.LINKED_ATTR_ID
--T.DEPENDING_ATTRIBUTE1,
,T5.TITLE AS LINK_ATTRIBUTE_TITLE
,T.ADDED_WHEN
,[dbo].[FNIDB_GET_TERM_FOR_TERM_ID] (T.CHANGED_WHO) AS CHANGED_WHO
,T.CHANGED_WHEN
FROM
TBIDB_SEARCH_ATTRIBUTES_LINKS T INNER JOIN TBIDB_SEARCH_PROFILE_ATTRIBUTES T1 ON T.DEP_ATTR_ID = T1.ATTRIBUTE_ID
--INNER JOIN TBIDB_SEARCH_PROFILE_ATTRIBUTES T2 ON T.LINKED_ATTR_ID = T2.ATTRIBUTE_ID
INNER JOIN TBIDB_ATTRIBUTE T3 ON T.DEP_ATTR_ID = T3.GUID
INNER JOIN TBIDB_ATTRIBUTE T5 ON T.LINKED_ATTR_ID = T5.GUID
GO
-- =============================================
-- Author: Digital Data MS
-- Creation date: 22.10.2020
-- =============================================
CREATE FUNCTION [dbo].[FNIDB_GET_SEARCH_PROFILES] (@pUSERID INT, @pLANGCODE VARCHAR(5))
RETURNS @Output TABLE (SEARCH_PROFILE_ID INTEGER,TITLE VARCHAR(100),RESULT_SQL VARCHAR(915),PSOURCE VARCHAR(50))
AS
BEGIN
DECLARE
@ATTR_ID INTEGER,
@TYP_ID TINYINT,
@TYP_DESCR VARCHAR(100),
@MULTI BIT,
@LANG_ID INT,
@TERM_RESULT VARCHAR(900),
@IDB_CREATED_WHEN DATETIME,
@IDB_CREATED_WHO VARCHAR(100),
@IDB_CHANGED_WHEN DATETIME,
@IDB_CHANGED_WHO VARCHAR(100)
INSERT INTO @Output (SEARCH_PROFILE_ID,TITLE,RESULT_SQL,PSOURCE)
SELECT
T.GUID
,dbo.[FNIDB_GET_TERM_FOR_LANGUAGE_TERM_METADATA_GUID ] (T.TITLE_ID,@pLANGCODE) AS TITLE
,[dbo].[FNIDB_GET_TERM_FOR_TERM_ID] (T2.SEARCH_TERM_ID) AS RESULT_SQL
,'TBIDB_SEARCH_PROFILE_USER'
FROM TBIDB_SEARCH_PROFILE T INNER JOIN TBIDB_SEARCH_PROFILE_USER T1 ON T.GUID = T1.SEARCH_PROFIL_ID
INNER JOIN TBIDB_SEARCH_LANGUAGE_SQL_RESULT T2 ON T.GUID = T2.SEARCH_PROFIL_ID
INNER JOIN TBIDB_LANGUAGE T3 ON T2.LANGUAGE_ID = T3.GUID
WHERE T1.USER_ID = @pUSERID AND UPPER(T3.LANG_CODE) = UPPER(@pLANGCODE)
INSERT INTO @Output (SEARCH_PROFILE_ID,TITLE,RESULT_SQL,PSOURCE)
SELECT
T.GUID
,dbo.[FNIDB_GET_TERM_FOR_LANGUAGE_TERM_METADATA_GUID ] (T.TITLE_ID,@pLANGCODE) AS TITLE
,[dbo].[FNIDB_GET_TERM_FOR_TERM_ID] (T4.SEARCH_TERM_ID) AS RESULT_SQL
,'TBIDB_SEARCH_PROFILE_GROUP'
FROM TBIDB_SEARCH_PROFILE T INNER JOIN TBIDB_SEARCH_PROFILE_GROUP T1 ON T.GUID = T1.SEARCH_PROFIL_ID
INNER JOIN DD_ECM_TEST.dbo.TBDD_GROUPS T2 ON T1.GROUP_ID = T2.GUID
INNER JOIN DD_ECM_TEST.dbo.TBDD_GROUPS_USER T3 ON T2.GUID = T3.GROUP_ID
INNER JOIN TBIDB_SEARCH_LANGUAGE_SQL_RESULT T4 ON T.GUID = T4.SEARCH_PROFIL_ID
INNER JOIN TBIDB_LANGUAGE T5 ON T4.LANGUAGE_ID = T3.GUID
WHERE T3.USER_ID = @pUSERID AND UPPER(T5.LANG_CODE) = UPPER(@pLANGCODE)
RETURN
END
GO
-- =============================================
-- Author: DD MS
-- Create date 05.11.2020
-- =============================================
CREATE PROCEDURE [dbo].[PRIDB_NEW_TERM_FOR_ATTRIBUTE] @ATTRIBUTE VARCHAR(100),@TERM VARCHAR(MAX), @WHO VARCHAR(100), @TERM_ID BIGINT OUTPUT
AS
BEGIN
DECLARE @TERM_TYPE_ID TINYINT
SELECT @TERM_TYPE_ID = TYP_ID FROM TBIDB_ATTRIBUTE WHERE UPPER(TITLE) = UPPER(@ATTRIBUTE)
IF @TERM_TYPE_ID = 7 AND UPPER(@TERM) = 'TRUE'
SET @TERM = 1
ELSE IF @TERM_TYPE_ID = 7 AND UPPER(@TERM) = 'FALSE'
SET @TERM = 0
--PRINT 'PRIDB_NEW_TERM: TERM_TYPE_ID IS: ' + CONVERT(VARCHAR(2),@TERM_TYPE_ID) + ' # TERM: ' + @TERM
IF @TERM_TYPE_ID IN (1,8) --VARCHAR
IF NOT EXISTS(SELECT GUID FROM TBIDB_TERM_VALUE_VARCHAR WHERE UPPER(TERM_VALUE) = UPPER(@TERM))
BEGIN
INSERT INTO TBIDB_TERM_VALUE_VARCHAR (TERM_VALUE,ADDED_WHO) VALUES (@TERM,@WHO)
SELECT @TERM_ID = GUID FROM TBIDB_TERM_VALUE_VARCHAR where TERM_VALUE = @TERM
END
ELSE
SELECT @TERM_ID = GUID FROM TBIDB_TERM_VALUE_VARCHAR WHERE UPPER(TERM_VALUE) = UPPER(@TERM)
ELSE IF @TERM_TYPE_ID IN (2,7,9) --BIGINT
IF NOT EXISTS(SELECT GUID FROM TBIDB_TERM_VALUE_INTEGER WHERE TERM_VALUE = CONVERT(BIGINT,@TERM))
BEGIN
INSERT INTO TBIDB_TERM_VALUE_INTEGER (TERM_VALUE,ADDED_WHO) VALUES (CONVERT(BIGINT,@TERM),@WHO)
SELECT @TERM_ID =GUID FROM TBIDB_TERM_VALUE_INTEGER where TERM_VALUE = @TERM
END
ELSE
SELECT @TERM_ID = GUID FROM TBIDB_TERM_VALUE_INTEGER WHERE TERM_VALUE = CONVERT(BIGINT,@TERM)
ELSE IF @TERM_TYPE_ID = 3 --FLOAT
IF NOT EXISTS(SELECT GUID FROM TBIDB_TERM_VALUE_FLOAT WHERE TERM_VALUE = CONVERT(FLOAT,@TERM))
BEGIN
INSERT INTO TBIDB_TERM_VALUE_FLOAT (TERM_VALUE,ADDED_WHO) VALUES (CONVERT(FLOAT,@TERM),@WHO)
SELECT @TERM_ID =GUID FROM TBIDB_TERM_VALUE_FLOAT where TERM_VALUE = @TERM
END
ELSE
SELECT @TERM_ID = GUID FROM TBIDB_TERM_VALUE_FLOAT WHERE TERM_VALUE = CONVERT(FLOAT,@TERM)
ELSE IF @TERM_TYPE_ID = 4 --DECIMAL
IF NOT EXISTS(SELECT GUID FROM TBIDB_TERM_VALUE_DECIMAL WHERE TERM_VALUE = CONVERT(DECIMAL(19,0),@TERM))
BEGIN
INSERT INTO TBIDB_TERM_VALUE_DECIMAL (TERM_VALUE,ADDED_WHO) VALUES (CONVERT(DECIMAL(19,0),@TERM),@WHO)
SELECT @TERM_ID =GUID FROM TBIDB_TERM_VALUE_DECIMAL where TERM_VALUE = @TERM
END
ELSE
SELECT @TERM_ID = GUID FROM TBIDB_TERM_VALUE_DECIMAL WHERE TERM_VALUE = CONVERT(DECIMAL(19,0),@TERM)
ELSE IF @TERM_TYPE_ID = 5 --DATE
IF NOT EXISTS(SELECT GUID FROM TBIDB_TERM_VALUE_DATE WHERE TERM_VALUE = CONVERT(DATE,@TERM))
BEGIN
INSERT INTO TBIDB_TERM_VALUE_DATE (TERM_VALUE,ADDED_WHO) VALUES (CONVERT(DATE,@TERM),@WHO)
SELECT @TERM_ID =GUID FROM TBIDB_TERM_VALUE_DATE where TERM_VALUE = @TERM
END
ELSE
SELECT @TERM_ID = GUID FROM TBIDB_TERM_VALUE_DATE WHERE TERM_VALUE = CONVERT(DATE,@TERM)
PRINT '### PRIDB_NEW_TERM: TERM-ID: ' + CONVERT(VARCHAR(10),@TERM_ID) + '###'
END
GO
CREATE TABLE TBIDB_USER_SEARCH_CRITERIA
(
GUID BIGINT NOT NULL IDENTITY (1, 1),
SEARCH_PROFIL_ID INTEGER NOT NULL,
USERID INTEGER NOT NULL,
ATTRIBUTE_ID INTEGER NOT NULL,
TERM_TEXT VARCHAR(900),
--TERM_DATE DATE,
--TERM_FLOAT FLOAT,
--TERM_DEC DECIMAL(19,2),
TERM_ID BIGINT,
ADDED_WHO BIGINT,
ADDED_WHEN DATETIME NOT NULL DEFAULT GETDATE(),
CONSTRAINT PK_TBIDB_USER_SEARCH_CRITERIA_GUID PRIMARY KEY (GUID),
CONSTRAINT FK_TBIDB_USER_SEARCH_CRITERIA_SPID FOREIGN KEY (SEARCH_PROFIL_ID) REFERENCES TBIDB_SEARCH_PROFILE (GUID),
CONSTRAINT FK_TBIDB_USER_SEARCH_CRITERIA_ADDED_WHO FOREIGN KEY (ADDED_WHO) REFERENCES TBIDB_TERM_VALUE_VARCHAR (GUID)
)
GO
CREATE PROCEDURE [dbo].[PRIDB_NEW_USER_SEARCH_CRITERIA] @pSEARCHID INTEGER,@pUSER_ID INTEGER,@pATTRIBUTE_ID INTEGER,@pTERM VARCHAR(900), @pWHO VARCHAR(100)
AS
BEGIN
DECLARE @WHO_TERM_ID BIGINT,@ATTR_TYPE INT, @ATTR_TERM_ID BIGINT,@ATTRIBUTE VARCHAR(100)
SELECT @ATTR_TYPE = TYP_ID,@ATTRIBUTE = TITLE FROM TBIDB_ATTRIBUTE WHERE GUID = @pATTRIBUTE_ID
EXEC PRIDB_NEW_TERM 'VARCHAR',@pWHO,@pWHO,@TERM_ID = @WHO_TERM_ID OUTPUT;
EXEC PRIDB_NEW_TERM_FOR_ATTRIBUTE @ATTRIBUTE,@pTERM,@pWHO,@TERM_ID = @ATTR_TERM_ID OUTPUT;
-- GUID NAME_TYPE
--3 FLOAT
--4 DECIMAL
--5 DATE
--6 DATETIME
--9 VECTOR INTEGER
INSERT INTO TBIDB_USER_SEARCH_CRITERIA (SEARCH_PROFIL_ID, USERID, ATTRIBUTE_ID, ADDED_WHO, TERM_TEXT, TERM_ID) VALUES
(@pSEARCHID, @pUSER_ID, @pATTRIBUTE_ID, @WHO_TERM_ID, @pTERM, @ATTR_TERM_ID)
/*IF @ATTR_TYPE IN (1,2,7,8)
BEGIN
INSERT INTO TBIDB_USER_SEARCH_CRITERIA ( SEARCH_PROFIL_ID, USERID, ATTRIBUTE_ID, TERM_TEXT, ADDED_WHO,TERM_ID) VALUES
( @pSEARCHID, @pUSER_ID, @pATTRIBUTE_ID, @pTERM, @WHO_TERM_ID,@ATTR_TERM_ID)
END
ELSE IF @ATTR_TYPE = 5
INSERT INTO TBIDB_USER_SEARCH_CRITERIA ( SEARCH_PROFIL_ID, USERID, ATTRIBUTE_ID, TERM_DATE, ADDED_WHO,TERM_ID) VALUES
( @pSEARCHID, @pUSER_ID, @pATTRIBUTE_ID, Convert(Date,@pTERM), @WHO_TERM_ID,@ATTR_TERM_ID)
ELSE IF @ATTR_TYPE = 3
INSERT INTO TBIDB_USER_SEARCH_CRITERIA ( SEARCH_PROFIL_ID, USERID, ATTRIBUTE_ID, TERM_FLOAT, ADDED_WHO,TERM_ID) VALUES
( @pSEARCHID, @pUSER_ID, @pATTRIBUTE_ID, Convert(float,@pTERM), @WHO_TERM_ID,@ATTR_TERM_ID)
*/
END
GO
CREATE TABLE TBIDB_SEARCH_CRITERIA_SAVE
(
GUID BIGINT NOT NULL IDENTITY (1, 1),
SEARCH_PROFIL_ID INTEGER NOT NULL,
ATTRIBUTE_ID INTEGER NOT NULL,
TERM_TEXT VARCHAR(900),
--TERM_DATE DATE,
--TERM_FLOAT FLOAT,
--TERM_DEC DECIMAL(19,2),
TERM_ID BIGINT,
ADDED_WHO BIGINT,
ADDED_WHEN DATETIME NOT NULL DEFAULT GETDATE(),
CONSTRAINT PK_TBIDB_SEARCH_CRITERIA_SAVE_GUID PRIMARY KEY (GUID),
CONSTRAINT FK_TBIDB_SEARCH_CRITERIA_SAVE_SPID FOREIGN KEY (SEARCH_PROFIL_ID) REFERENCES TBIDB_SEARCH_PROFILE (GUID),
CONSTRAINT FK_TBIDB_SEARCH_CRITERIA_SAVE_ADDED_WHO FOREIGN KEY (ADDED_WHO) REFERENCES TBIDB_TERM_VALUE_VARCHAR (GUID)
)
GO
CREATE PROCEDURE [dbo].[PRIDB_SEARCH_CRITERIA_SAVE] @pSEARCHID INTEGER,@pUserID INT, @pWHO VARCHAR(100)
AS
BEGIN
DECLARE @WHO_TERM_ID BIGINT
EXEC PRIDB_NEW_TERM 'VARCHAR',@pWHO,@pWHO,@TERM_ID = @WHO_TERM_ID OUTPUT;
DELETE FROM TBIDB_SEARCH_CRITERIA_SAVE WHERE SEARCH_PROFIL_ID = @pSEARCHID
INSERT INTO [dbo].[TBIDB_SEARCH_CRITERIA_SAVE]
([SEARCH_PROFIL_ID]
,[ATTRIBUTE_ID]
,[TERM_TEXT]
,TERM_ID
--,[TERM_DATE]
--,[TERM_FLOAT]
--,[TERM_DEC]
,[ADDED_WHO])
SELECT [SEARCH_PROFIL_ID]
,[ATTRIBUTE_ID]
,[TERM_TEXT]
,TERM_ID
--,[TERM_DATE]
--,[TERM_FLOAT]
--,[TERM_DEC]
,@WHO_TERM_ID FROM TBIDB_USER_SEARCH_CRITERIA WHERE USERID = @pUserID AND SEARCH_PROFIL_ID = @pSEARCHID
END
GO
CREATE VIEW VWIDB_SEARCH_ATTRIBUTES_USER
AS
select TOP 100 PERCENT
T.USERID,T.SEARCH_PROFIL_ID, T.ATTRIBUTE_ID,T1.TITLE,T2.SEQUENCE
from
TBIDB_USER_SEARCH_CRITERIA T INNER JOIN TBIDB_ATTRIBUTE T1 ON T.ATTRIBUTE_ID = T1.GUID
INNER JOIN TBIDB_SEARCH_PROFILE_ATTRIBUTES T2 ON T.SEARCH_PROFIL_ID = T2.SEARCH_PROFIL_ID AND T.ATTRIBUTE_ID = T2.ATTRIBUTE_ID
GROUP BY T.USERID,T.SEARCH_PROFIL_ID, T.ATTRIBUTE_ID,T1.TITLE,T2.SEQUENCE
ORDER BY T.USERID, T.SEARCH_PROFIL_ID, T2.SEQUENCE
GO
CREATE FUNCTION [dbo].[FNIDB_SEARCH_RESULT_GET_OBJECTS] (@pUSERID INT,@PSEARCHID INT)
--DECLARE @pUSERID INT,@PSEARCHID INT
--SET @pUSERID =1
--SET @PSEARCHID = 7
RETURNS @TBRESULT TABLE (RUN INT, IDB_OBJ_ID BIGINT, ATTR_ID INT,ATTR_TITLE VARCHAR(100), COMMENT VARCHAR(200))
AS
BEGIN
DECLARE
@GUID BIGINT,@ATTR_ID INT,@LASTATTR_ID INT ,@ATTR_TITLE VARCHAR(100),@RUN TINYINT,@COUNT_ATTRIBUTES TINYINT
,@RESTRICTIONSYN BIT
SET @LASTATTR_ID = 0
DECLARE @TBRESULT_RESTRICTION TABLE (RUN INT, IDB_OBJ_ID BIGINT, ATTR_ID INT,ATTR_TITLE VARCHAR(100), COMMENT VARCHAR(200))
select @COUNT_ATTRIBUTES = COUNT(T.USERID)
from
VWIDB_SEARCH_ATTRIBUTES_USER T
WHERE
T.SEARCH_PROFIL_ID = @PSEARCHID AND T.USERID = @pUSERID
SET @RUN = 1
DECLARE cursorSearchAttributes CURSOR FOR
select
T.ATTRIBUTE_ID,T.TITLE
from
VWIDB_SEARCH_ATTRIBUTES_USER T
WHERE
T.SEARCH_PROFIL_ID = @PSEARCHID AND T.USERID = @pUSERID
ORDER BY T.SEQUENCE
OPEN cursorSearchAttributes
FETCH NEXT FROM cursorSearchAttributes INTO @ATTR_ID,@ATTR_TITLE
WHILE @@FETCH_STATUS = 0
BEGIN
DECLARE @SEARCH_DEF_ID BIGINT, @TERM_ID BIGINT
DECLARE cursorDetailAttribute CURSOR FOR
select
T.GUID,T.TERM_ID
from
TBIDB_USER_SEARCH_CRITERIA T
WHERE
T.SEARCH_PROFIL_ID = 7 AND T.USERID = 1 AND T.ATTRIBUTE_ID = @ATTR_ID
OPEN cursorDetailAttribute
FETCH NEXT FROM cursorDetailAttribute INTO @SEARCH_DEF_ID,@TERM_ID
WHILE @@FETCH_STATUS = 0
BEGIN
INSERT INTO @TBRESULT_RESTRICTION ( RUN, IDB_OBJ_ID, ATTR_ID, ATTR_TITLE)
SELECT @SEARCH_DEF_ID, IDB_OBJECT_ID, @ATTR_ID, @ATTR_TITLE
FROM
FNIDB_GET_TERM_FOR_ATTRIBUTE_ID (@ATTR_ID,'de-DE',@pUSERID)
WHERE
TERM_ID = @TERM_ID
--SELECT * FROM @TBRESULT_RESTRICTION
FETCH NEXT FROM cursorDetailAttribute INTO @SEARCH_DEF_ID,@TERM_ID
END
CLOSE cursorDetailAttribute
DEALLOCATE cursorDetailAttribute
--PRINT 'FIRST SEARCH ROW'
--PRINT @TBRESULT_RESTRICTION
--PRINT '@COUNT_ATTRIBUTES: ' + CONVERT(VARCHAR(2),@COUNT_ATTRIBUTES)
--PRINT '@RUN: ' + CONVERT(VARCHAR(2),@RUN)
IF @RUN = 1
INSERT INTO @TBRESULT ( RUN, IDB_OBJ_ID, ATTR_ID, ATTR_TITLE, COMMENT)
SELECT * FROM @TBRESULT_RESTRICTION
ELSE
IF @COUNT_ATTRIBUTES = @RUN
BEGIN
-- --#### Now deleting the Results which are not part of the restriction
--PRINT 'DELETE AS THIS IS THE LAST RUN PER ATTRIBUTE'
DELETE FROM @TBRESULT WHERE IDB_OBJ_ID NOT IN (
SELECT IDB_OBJ_ID FROM @TBRESULT_RESTRICTION)
-- UPDATE T
-- SET
-- T.RUN = T1.RUN
-- FROM
-- @TBRESULT T INNER JOIN
-- @TBRESULT_RESTRICTION T1 ON T.IDB_OBJ_ID = T1.IDB_OBJ_ID
END
SET @RUN +=1
SET @LASTATTR_ID = @ATTR_ID
DELETE FROM @TBRESULT_RESTRICTION
FETCH NEXT FROM cursorSearchAttributes INTO @ATTR_ID,@ATTR_TITLE
END
CLOSE cursorSearchAttributes
DEALLOCATE cursorSearchAttributes
RETURN
--select DISTINCT IDB_OBJ_ID from @TBRESULT ORDER BY IDB_OBJ_ID
END
GO
CREATE FUNCTION [dbo].[FNIDB_SEARCH_GET_FILTER_SQL] (@pSEARCH_ID INTEGER, @pUSERID INTEGER, @pLANG_CODE VARCHAR(5))
RETURNS NVARCHAR(MAX)
AS
BEGIN
DECLARE @ATTR_ID INTEGER, @ATTR_TITLE AS VARCHAR(100), @RUN TINYINT, @RESULT NVARCHAR(MAX), @RUN_ALIAS VARCHAR(2), @RUN_SELECT VARCHAR(500)
,@RUN_FROM VARCHAR(500), @SELECT_PART NVARCHAR(MAX), @FROM_PART NVARCHAR(MAX),@SEPARATOR VARCHAR(1)
SET @RUN = 0
SET @RUN_ALIAS = 'T'
SET @SELECT_PART = 'SELECT '
SET @FROM_PART = ''
DECLARE cursAttribute CURSOR LOCAL FOR
SELECT ATTRIBUTE_ID,ATTRIBUTE_TITLE
FROM VWIDB_SEARCH_PROFILE_ATTRIBUTES WHERE SEARCH_PROFIL_ID = @pSEARCH_ID ORDER BY SEQUENCE
OPEN cursAttribute
FETCH NEXT FROM cursAttribute INTO @ATTR_ID,@ATTR_TITLE
WHILE @@FETCH_STATUS = 0
BEGIN
SET @RUN_SELECT = ''
SET @RUN_FROM = ''
IF @RUN = 0
BEGIN
SET @RUN_SELECT = 'T.IDB_OBJECT_ID, T.TERM_VALUE AS [' + @ATTR_TITLE + ']'
SET @RUN_FROM = CHAR(10) + 'FROM [dbo].[FNIDB_GET_TERM_FOR_ATTRIBUTE_ID] (' + CONVERT(VARCHAR(10),@ATTR_ID) + ',''' + @pLANG_CODE + ''',' + CONVERT(VARCHAR(10),@pUSERID) + ') T'
END
ELSE
BEGIN
SET @RUN_SELECT = ', ' + @RUN_ALIAS + CONVERT(VARCHAR(2), @RUN) + '.TERM_VALUE AS [' + @ATTR_TITLE + ']'
SET @RUN_FROM = CHAR(10) + 'INNER JOIN [dbo].[FNIDB_GET_TERM_FOR_ATTRIBUTE_ID] (' + CONVERT(VARCHAR(10),@ATTR_ID) + ',''' + @pLANG_CODE + ''',' + CONVERT(VARCHAR(10),@pUSERID) + ') ' + @RUN_ALIAS + CONVERT(VARCHAR(2), @RUN)
SET @RUN_FROM += ' ON T.IDB_OBJECT_ID = T' + CONVERT(VARCHAR(2), @RUN) + '.IDB_OBJECT_ID'
END
SET @SELECT_PART += @RUN_SELECT
SET @FROM_PART += @RUN_FROM
SET @RUN += 1
FETCH NEXT FROM cursAttribute INTO @ATTR_ID,@ATTR_TITLE
END
CLOSE cursAttribute
DEALLOCATE cursAttribute
SET @RESULT = @SELECT_PART + @FROM_PART
RETURN @RESULT
END
GO