DROP TABLE TBIDB_STRUCTURE_NODES_IDB_OBJ DROP TABLE TBIDB_STRUCTURE_NODES CREATE TABLE TBIDB_STRUCTURE_NODES ( GUID BIGINT NOT NULL IDENTITY (1, 1), PARENT_ID BIGINT NOT NULL DEFAULT 0, NODE_CAPTION VARCHAR(250) NOT NULL, ADDED_WHO VARCHAR(100), ADDED_WHEN DATETIME DEFAULT GETDATE(), CHANGED_WHO VARCHAR(100), CHANGED_WHEN DATETIME, CONSTRAINT PK_TBIDB_STRUCTURE_NODES PRIMARY KEY (GUID), CONSTRAINT UQ_TBIDB_STRUCTURE_NODES UNIQUE(PARENT_ID,NODE_CAPTION) ) GO CREATE TRIGGER TBIDB_STRUCTURE_NODES_AFT_UPD ON TBIDB_STRUCTURE_NODES FOR UPDATE AS UPDATE TBIDB_STRUCTURE_NODES SET CHANGED_WHEN = GETDATE() FROM INSERTED WHERE TBIDB_STRUCTURE_NODES .GUID = INSERTED.GUID GO CREATE TABLE TBIDB_STRUCTURE_NODES_IDB_OBJ ( GUID BIGINT NOT NULL IDENTITY (1, 1), SN_ID BIGINT NOT NULL, IDB_OBJ_ID BIGINT NOT NULL, ADDED_WHO VARCHAR(100), ADDED_WHEN DATETIME DEFAULT GETDATE(), CONSTRAINT PK_TBIDB_SN_IDB_OBJ PRIMARY KEY (GUID), CONSTRAINT FK_TBIDB_SN_IDB_OBJ_SN_ID FOREIGN KEY (SN_ID) REFERENCES TBIDB_STRUCTURE_NODES (GUID), CONSTRAINT FK_TBIDB_SN_IDB_OBJ_ID FOREIGN KEY (IDB_OBJ_ID) REFERENCES TBIDB_OBJECT (IDB_OBJ_ID), CONSTRAINT UQ_TBIDB_SN_IDB_OBJ UNIQUE(SN_ID,IDB_OBJ_ID) ) GO CREATE TABLE TBIDB_STRUCTURE_NODES_RELATIONS ( GUID BIGINT NOT NULL IDENTITY (1, 1), SN_ID BIGINT NOT NULL, USR_ID INT, GRP_ID INT, ADDED_WHO VARCHAR(100), ADDED_WHEN DATETIME DEFAULT GETDATE(), CONSTRAINT PK_TBIDB_STRUCTURE_NODES_RELATIONS PRIMARY KEY (GUID), CONSTRAINT FK_TBIDB_STRUCTURE_NODES_RELATIONS_SN_ID FOREIGN KEY (SN_ID) REFERENCES TBIDB_STRUCTURE_NODES (GUID), CONSTRAINT UQ_TBIDB_STRUCTURE_NODES_RELATIONS UNIQUE(SN_ID,USR_ID,GRP_ID) ) GO CREATE OR ALTER VIEW VWIDB_SN_RELATIONS AS SELECT SNR.GUID as REL_ID, SNR.SN_ID, SN.NODE_CAPTION, USR.EMAIL as Identification, 'USR' as Scope, USR.GUID ScopeID FROM TBIDB_STRUCTURE_NODES_RELATIONS SNR INNER JOIN DD_ECM.dbo.TBDD_USER USR ON SNR.USR_ID = USR.GUID INNER JOIN TBIDB_STRUCTURE_NODES SN ON SNR.SN_ID = SN.GUID UNION SELECT SNR.GUID as REL_ID, SNR.SN_ID,SN.NODE_CAPTION, GRP.NAME as Identification, 'GRP' as Scope, GRP.GUID ScopeID FROM TBIDB_STRUCTURE_NODES_RELATIONS SNR INNER JOIN DD_ECM.dbo.TBDD_GROUPS GRP ON SNR.GRP_ID = GRP.GUID INNER JOIN TBIDB_STRUCTURE_NODES SN ON SNR.SN_ID = SN.GUID GO CREATE VIEW VWIDB_LANGAGE_TERM_KIND_NODE AS SELECT LTERM.GUID ,LTERM.TERM_ID ,TERM.TERM_VALUE ,LTERM.LANG_ID ,LANG.LANG_CODE FROM TBIDB_LANGUAGE_TERM LTERM INNER JOIN TBIDB_LANGUAGE LANG ON LTERM.LANG_ID = LANG.GUID INNER JOIN TBIDB_TERM_VALUE_VARCHAR TERM ON LTERM.TERM_ID = TERM.GUID WHERE LTERM.KIND_TYPE = 4 GO CREATE OR ALTER PROCEDURE [dbo].[PRIDB_NEW_LANGUAGE_TERM] @pOBJ_ID BIGINT, @pTERM_ID BIGINT,@pWHO_TERM_ID BIGINT,@pKIND_TYPE INT,@pLANG_ID TINYINT, @OUT_LANG_TERM_GUID BIGINT OUTPUT AS BEGIN IF NOT EXISTS(SELECT GUID FROM TBIDB_LANGUAGE_TERM WHERE OBJECT_ID = @pOBJ_ID AND LANG_ID = @pLANG_ID AND KIND_TYPE = @pKIND_TYPE ) INSERT INTO TBIDB_LANGUAGE_TERM (OBJECT_ID,TERM_ID,LANG_ID,ADDED_WHO,KIND_TYPE) VALUES (@pOBJ_ID,@pTERM_ID,@pLANG_ID,@pWHO_TERM_ID,@pKIND_TYPE) ELSE BEGIN UPDATE TBIDB_LANGUAGE_TERM SET TERM_ID = @pTERM_ID,CHANGED_WHO = @pWHO_TERM_ID WHERE OBJECT_ID = @pOBJ_ID AND LANG_ID = @pLANG_ID AND KIND_TYPE = @pKIND_TYPE AND TERM_ID <> @pTERM_ID PRINT 'NEW LANG TERM ALREADY EXISTING' END SELECT @OUT_LANG_TERM_GUID = GUID FROM TBIDB_LANGUAGE_TERM WHERE OBJECT_ID = @pOBJ_ID AND LANG_ID = @pLANG_ID AND TERM_ID = @pTERM_ID AND KIND_TYPE = @pKIND_TYPE PRINT 'NEW LANGTERMID: ' + CONVERT(VARCHAR(10),@OUT_LANG_TERM_GUID) END GO -- ============================================= -- Author: DD MS -- Changed: -- ============================================= CREATE OR ALTER PROCEDURE PRIDB_NEW_DYNAMIC_FOLDER @pDYNAMIC_FOLDER VARCHAR(900),@pWHO VARCHAR(100),@pLANG_ID TINYINT, @LAST_SN_ID BIGINT OUTPUT AS BEGIN DECLARE @FOLDER_DEPTH TINYINT,@FOLD_PART VARCHAR(250),@FOLD_PATH_SO_FAR VARCHAR(900) SET @FOLDER_DEPTH = 0 DECLARE @PARENT_NODE_GUID BIGINT,@SN_ID BIGINT --SPLIT FOR FOLDER PARTS DECLARE cursSplitFolder CURSOR FOR SELECT Item FROM [dbo].[FN_SPLIT_STRING] (@pDYNAMIC_FOLDER,'\') OPEN cursSplitFolder FETCH NEXT FROM cursSplitFolder INTO @FOLD_PART WHILE @@FETCH_STATUS = 0 BEGIN --EACH FOLDER PART WORKED SEPERATELY IF @FOLDER_DEPTH = 0 BEGIN SET @PARENT_NODE_GUID = 0 SET @FOLD_PATH_SO_FAR = @FOLD_PART END ELSE BEGIN SET @FOLD_PATH_SO_FAR += '\' + @FOLD_PART END PRINT '##############################' PRINT 'WORKING ON @FOLD_PATH_SO_FAR: ' + @FOLD_PATH_SO_FAR EXEC PRIDB_NEW_STRUCTURE_NODE @PARENT_NODE_GUID, @FOLD_PART,@pWHO, @pLANG_ID, @LAST_SN_ID OUTPUT SET @PARENT_NODE_GUID = @LAST_SN_ID SET @FOLDER_DEPTH += 1 FETCH NEXT FROM cursSplitFolder INTO @FOLD_PART END CLOSE cursSplitFolder DEALLOCATE cursSplitFolder END GO CREATE OR ALTER PROCEDURE [dbo].[PRIDB_NEW_STRUCTURE_NODE] @pNODE_PARENT_ID BIGINT, @pNODECAPTION VARCHAR(200),@pWHO VARCHAR(100), @pLANG_ID TINYINT, @OUT_SN_ID BIGINT OUTPUT AS BEGIN DECLARE @WHO_TERM_ID BIGINT, @NODECAPTION_TERM_ID BIGINT EXEC PRIDB_NEW_TERM 'VARCHAR',@pWHO,@pWHO, @TERM_ID = @WHO_TERM_ID OUTPUT; EXEC PRIDB_NEW_TERM 'VARCHAR',@pNODECAPTION,@pWHO, @TERM_ID = @NODECAPTION_TERM_ID OUTPUT; IF NOT EXISTS(SELECT SN_ID FROM VWIDB_STRUCTURE_NODES_STRUCTURE WHERE SN_PARENT_ID = @pNODE_PARENT_ID AND LANG_ID = @pLANG_ID) INSERT INTO TBIDB_STRUCTURE_NODES (PARENT_ID,NODE_CAPTION,ADDED_WHO) VALUES (@pNODE_PARENT_ID,@pNODECAPTION,@pWHO); ELSE IF NOT EXISTS(SELECT SN_ID FROM VWIDB_STRUCTURE_NODES_STRUCTURE WHERE SN_PARENT_ID = @pNODE_PARENT_ID AND LTERM_TERMID = @NODECAPTION_TERM_ID AND LANG_ID = @pLANG_ID) INSERT INTO TBIDB_STRUCTURE_NODES (PARENT_ID,NODE_CAPTION,ADDED_WHO) VALUES (@pNODE_PARENT_ID,@pNODECAPTION,@pWHO); BEGIN SELECT @OUT_SN_ID = MAX(GUID) FROM TBIDB_STRUCTURE_NODES WHERE PARENT_ID = @pNODE_PARENT_ID AND NODE_CAPTION = @pNODECAPTION END DECLARE @OUT_LANG_TERM_GUID BIGINT EXEC [PRIDB_NEW_LANGUAGE_TERM] @OUT_SN_ID, @NODECAPTION_TERM_ID,@WHO_TERM_ID,4,@pLANG_ID,@OUT_LANG_TERM_GUID OUTPUT END GO -- ============================================= -- Author: DD MS -- Changed: -- ============================================= CREATE OR ALTER PROCEDURE PRIDB_NEW_STUCTURE_NODE_FOR_OBJECT @pIDB_OBJ_ID BIGINT, @pSN_ID BIGINT,@pWHO VARCHAR(100),@pLANG_ID TINYINT, @LAST_SN_ID BIGINT OUTPUT AS BEGIN IF NOT EXISTS(SELECT GUID FROM TBIDB_STRUCTURE_NODES_IDB_OBJ WHERE IDB_OBJ_ID = @pIDB_OBJ_ID AND SN_ID = @pSN_ID) INSERT INTO TBIDB_STRUCTURE_NODES_IDB_OBJ (IDB_OBJ_ID,SN_ID,ADDED_WHO) VALUES (@pIDB_OBJ_ID,@pSN_ID,@pWHO); END GO CREATE VIEW VWIDB_LANGAGE_TERM_KIND_NODE AS SELECT SN.GUID NODE_ID ,SN.PARENT_ID NODE_PARENT_ID ,LTERM.TERM_ID ,LTERM.OBJECT_ID OBJ_ID ,TERM.TERM_VALUE AS NODE_CAPTION ,LTERM.LANG_ID ,LANG.LANG_CODE FROM TBIDB_STRUCTURE_NODES SN INNER JOIN TBIDB_LANGUAGE_TERM LTERM ON SN.TERM_LANG_ID = LTERM.GUID INNER JOIN TBIDB_LANGUAGE LANG ON LTERM.LANG_ID = LANG.GUID INNER JOIN TBIDB_TERM_VALUE_VARCHAR TERM ON LTERM.TERM_ID = TERM.GUID WHERE LTERM.KIND_TYPE = 4 GO CREATE OR ALTER VIEW [dbo].[VWIDB_STRUCTURE_NODES_STRUCTURE] AS select SN.GUID SN_ID ,SN.PARENT_ID SN_PARENT_ID ,SN.NODE_CAPTION SN_NODE_CAPTION ,T2.TERM_ID LTERM_TERMID ,T3.TERM_VALUE ,T4.LANG_CODE ,T4.GUID as LANG_ID ,SN.ADDED_WHO SN_ADDED_WHO ,SN.ADDED_WHEN SN_ADDED_WHEN ,T2.CHANGED_WHO TERM_CHANGED_WHO ,T2.CHANGED_WHEN TERM_CHANGED_WHEN from TBIDB_STRUCTURE_NODES SN INNER JOIN TBIDB_LANGUAGE_TERM T2 ON SN.GUID = T2.[OBJECT_ID] INNER JOIN TBIDB_TERM_VALUE_VARCHAR T3 ON T2.TERM_ID = T3.GUID INNER JOIN TBIDB_LANGUAGE T4 ON T2.LANG_ID = T4.GUID WHERE T2.KIND_TYPE = 4 GO CREATE VIEW [dbo].[VWIDB_SN_DYNAMIC_FOLDER_OBJECT] AS select SN_OBJ.GUID AS SN_REL_ID, SN_OBJ.IDB_OBJ_ID, SN.GUID SN_ID, SN.PARENT_ID SN_PARENT_ID, OBJ.PARENT_OBJ_ID, T3.TERM_VALUE AS LANG_NODE_CAPTION , LTERM.LANG_ID, T4.LANG_CODE, SN_OBJ.ADDED_WHO, SN_OBJ.ADDED_WHEN from TBIDB_STRUCTURE_NODES_IDB_OBJ SN_OBJ INNER JOIN TBIDB_STRUCTURE_NODES SN ON SN_OBJ.SN_ID = SN.GUID INNER JOIN TBIDB_LANGUAGE_TERM LTERM ON SN_OBJ.SN_ID = LTERM.OBJECT_ID INNER JOIN TBIDB_OBJECT OBJ ON SN_OBJ.IDB_OBJ_ID = OBJ.IDB_OBJ_ID INNER JOIN TBIDB_TERM_VALUE_VARCHAR T3 ON LTERM.TERM_ID = T3.GUID INNER JOIN TBIDB_LANGUAGE T4 ON LTERM.LANG_ID = T4.GUID WHERE OBJ.ACTIVE = 1 AND LTERM.KIND_TYPE = 4 GO