diff --git a/PROMS/DataLoader/PROMSFixes.Sql b/PROMS/DataLoader/PROMSFixes.Sql index c5386327..d62510a2 100644 --- a/PROMS/DataLoader/PROMSFixes.Sql +++ b/PROMS/DataLoader/PROMSFixes.Sql @@ -9760,4 +9760,606 @@ then 'matches' else 'different' end ContentMatchesRangeTrans from Contents cc join transitions tt on tt.fromid = cc.contentid) mm where ContentMatchesTrans = 'different') mm -return @Count END \ No newline at end of file +return @Count +END +GO +-- Display the status of Proc creation +IF (@@Error = 0) PRINT 'ScalarFunction Creation: ve_GetTransitionErrorCount Succeeded' +ELSE PRINT 'ScalarFunction Creation: ve_GetTransitionErrorCount Error on Creation' +GO + +--added by JCB for storing procedure xml for approved version +--ALTER TABLE Versions add ApprovedXML if it does not exist +IF COL_LENGTH('Versions','ApprovedXML') IS NULL + ALTER TABLE Versions ADD [ApprovedXML] [NVARCHAR](MAX) NULL; +GO + +/****** Object: StoredProcedure [addVersion] ******/ +IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[addVersion]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) + DROP PROCEDURE [addVersion]; +GO + +/***************************************************************************** + Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE + Copyright 2012 - Volian Enterprises, Inc. All rights reserved. +*****************************************************************************/ +CREATE PROCEDURE [dbo].[addVersion] + +( + @RevisionID int, + @StageID int, + @PDF varbinary(MAX)=null, + @SummaryPDF varbinary(MAX)=null, + @ApprovedXML nvarchar(MAX)=null, + @DTS datetime, + @UserID nvarchar(200), + @newVersionID int output, + @newLastChanged timestamp output +) +WITH EXECUTE AS OWNER +AS +BEGIN TRY -- Try Block + BEGIN TRANSACTION + INSERT INTO [Versions] + ( + [RevisionID], + [StageID], + [PDF], + [SummaryPDF], + [ApprovedXML], + [DTS], + [UserID] + ) + VALUES + ( + @RevisionID, + @StageID, + @PDF, + @SummaryPDF, + @ApprovedXML, + @DTS, + @UserID + ) + SELECT @newVersionID= SCOPE_IDENTITY() + SELECT @newLastChanged=[LastChanged] + FROM [Versions] WHERE [VersionID]=@newVersionID + IF( @@TRANCOUNT > 0 ) COMMIT +END TRY +BEGIN CATCH -- Catch Block + IF( @@TRANCOUNT = 1 ) ROLLBACK -- Only rollback if top level + ELSE IF( @@TRANCOUNT > 1 ) COMMIT -- Otherwise commit. Top level will rollback + EXEC vlnErrorHandler +END CATCH +GO +-- Display the status of Proc creation +IF (@@Error = 0) PRINT 'Procedure Creation: addVersion Succeeded' +ELSE PRINT 'Procedure Creation: addVersion Error on Creation' +GO + +/****** Object: StoredProcedure [getVersion] ******/ +IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[getVersion]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) + DROP PROCEDURE [getVersion]; +GO + +/***************************************************************************** + Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE + Copyright 2012 - Volian Enterprises, Inc. All rights reserved. +*****************************************************************************/ +CREATE PROCEDURE [dbo].[getVersion] + +( + @VersionID int +) +WITH EXECUTE AS OWNER +AS + SELECT + [VersionID], + [RevisionID], + [StageID], + [PDF], + [SummaryPDF], + [ApprovedXML], + [DTS], + [UserID], + [LastChanged] + FROM [Versions] + WHERE [VersionID]=@VersionID + RETURN +GO +-- Display the status of Proc creation +IF (@@Error = 0) PRINT 'Procedure Creation: getVersion Succeeded' +ELSE PRINT 'Procedure Creation: getVersion Error on Creation' +GO + +/****** Object: StoredProcedure [getVersions] ******/ +IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[getVersions]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) + DROP PROCEDURE [getVersions]; +GO + +/***************************************************************************** + Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE + Copyright 2012 - Volian Enterprises, Inc. All rights reserved. +*****************************************************************************/ +CREATE PROCEDURE [dbo].[getVersions] + +WITH EXECUTE AS OWNER +AS + SELECT + [VersionID], + [RevisionID], + [StageID], + [PDF], + [SummaryPDF], + [ApprovedXML], + [DTS], + [UserID], + [LastChanged] + FROM [Versions] + RETURN +GO +-- Display the status of Proc creation +IF (@@Error = 0) PRINT 'Procedure Creation: getVersions Succeeded' +ELSE PRINT 'Procedure Creation: getVersions Error on Creation' +GO + +/****** Object: StoredProcedure [getVersionsByRevisionID] ******/ +IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[getVersionsByRevisionID]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) + DROP PROCEDURE [getVersionsByRevisionID]; +GO + +/***************************************************************************** + Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE + Copyright 2012 - Volian Enterprises, Inc. All rights reserved. +*****************************************************************************/ +CREATE PROCEDURE [dbo].[getVersionsByRevisionID] + +( + @RevisionID int +) +WITH EXECUTE AS OWNER +AS + + SELECT + [Versions].[VersionID], + [Versions].[RevisionID], + [Versions].[StageID], + [Versions].[PDF], + [Versions].[SummaryPDF], + [Versions].[ApprovedXML], + [Versions].[DTS], + [Versions].[UserID], + [Versions].[LastChanged], + [Stages].[Name] [Stage_Name], + [Stages].[Description] [Stage_Description], + [Stages].[IsApproved] [Stage_IsApproved], + [Stages].[DTS] [Stage_DTS], + [Stages].[UserID] [Stage_UserID] + FROM [Versions] + JOIN [Stages] ON + [Stages].[StageID]=[Versions].[StageID] + WHERE + [Versions].[RevisionID]=@RevisionID + + RETURN +GO +-- Display the status of Proc creation +IF (@@Error = 0) PRINT 'Procedure Creation: getVersionsByRevisionID Succeeded' +ELSE PRINT 'Procedure Creation: getVersionsByRevisionID Error on Creation' +GO + +/****** Object: StoredProcedure [getVersionsByStageID] ******/ +IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[getVersionsByStageID]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) + DROP PROCEDURE [getVersionsByStageID]; +GO + +/***************************************************************************** + Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE + Copyright 2012 - Volian Enterprises, Inc. All rights reserved. +*****************************************************************************/ +CREATE PROCEDURE [dbo].[getVersionsByStageID] + +( + @StageID int +) +WITH EXECUTE AS OWNER +AS + + SELECT + [Versions].[VersionID], + [Versions].[RevisionID], + [Versions].[StageID], + [Versions].[PDF], + [Versions].[SummaryPDF], + [Versions].[ApprovedXML], + [Versions].[DTS], + [Versions].[UserID], + [Versions].[LastChanged], + [Revisions].[ItemID] [Revision_ItemID], + [Revisions].[TypeID] [Revision_TypeID], + [Revisions].[RevisionNumber] [Revision_RevisionNumber], + [Revisions].[RevisionDate] [Revision_RevisionDate], + [Revisions].[Notes] [Revision_Notes], + [Revisions].[Config] [Revision_Config], + [Revisions].[DTS] [Revision_DTS], + [Revisions].[UserID] [Revision_UserID] + FROM [Versions] + JOIN [Revisions] ON + [Revisions].[RevisionID]=[Versions].[RevisionID] + WHERE + [Versions].[StageID]=@StageID + + RETURN +GO +-- Display the status of Proc creation +IF (@@Error = 0) PRINT 'Procedure Creation: getVersionsByStageID Succeeded' +ELSE PRINT 'Procedure Creation: getVersionsByStageID Error on Creation' +GO + +/****** Object: StoredProcedure [updateVersion] ******/ +IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[updateVersion]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) + DROP PROCEDURE [updateVersion]; +GO + +/***************************************************************************** + Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE + Copyright 2012 - Volian Enterprises, Inc. All rights reserved. +*****************************************************************************/ +CREATE PROCEDURE [dbo].[updateVersion] + +( + @VersionID int, + @RevisionID int, + @StageID int, + @PDF varbinary(MAX)=null, + @SummaryPDF varbinary(MAX)=null, + @ApprovedXML nvarchar(MAX)=null, + @DTS datetime, + @UserID nvarchar(200), + @LastChanged timestamp, + @newLastChanged timestamp output +) +WITH EXECUTE AS OWNER +AS +BEGIN TRY -- Try Block + BEGIN TRANSACTION + UPDATE [Versions] + SET + [RevisionID]=@RevisionID, + [StageID]=@StageID, + [PDF]=@PDF, + [SummaryPDF]=@SummaryPDF, + [ApprovedXML]=@ApprovedXML, + [DTS]=@DTS, + [UserID]=@UserID + WHERE [VersionID]=@VersionID AND [LastChanged]=@LastChanged + IF @@ROWCOUNT = 0 + BEGIN + IF NOT exists(select * from [Versions] WHERE [VersionID]=@VersionID) + RAISERROR('Version record has been deleted by another user', 16, 1) + ELSE + RAISERROR('Version has been edited by another user', 16, 1) + END + + SELECT @newLastChanged=[LastChanged] + FROM [Versions] WHERE [VersionID]=@VersionID + + IF( @@TRANCOUNT > 0 ) COMMIT +END TRY +BEGIN CATCH -- Catch Block + IF( @@TRANCOUNT = 1 ) ROLLBACK -- Only rollback if top level + ELSE IF( @@TRANCOUNT > 1 ) COMMIT -- Otherwise commit. Top level will rollback + EXEC vlnErrorHandler +END CATCH +GO +-- Display the status of Proc creation +IF (@@Error = 0) PRINT 'Procedure Creation: updateVersion Succeeded' +ELSE PRINT 'Procedure Creation: updateVersion Error on Creation' +GO + +IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vefn_GetDisconnectedItems]') AND OBJECTPROPERTY(id,N'IsTableFunction') = 1) + DROP FUNCTION [vefn_GetDisconnectedItems]; +GO +/****** Object: UserDefinedFunction [dbo].[vefn_GetDisconnectedItems] ******/ +SET ANSI_NULLS ON +GO +SET QUOTED_IDENTIFIER ON +GO + +-- select * from vefn_GetDisconnectedItems() + +/***************************************************************************** + Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE + Copyright 2013 - Volian Enterprises, Inc. All rights reserved. +*****************************************************************************/ + +CREATE FUNCTION [dbo].[vefn_GetDisconnectedItems]() +RETURNS @DiscItems TABLE +( + ItemID int primary Key, + ContentID int, + UNIQUE (ContentID) +) +WITH EXECUTE AS OWNER +AS +BEGIN + declare @UsedItems Table + ( itemid int primary key, contentid int) + insert into @UsedItems + Select ItemID, ContentID from vefn_GetVersionItems('') + insert into @DiscItems + select itemid,ii.contentid from ( + Select ItemID,ii.ContentID from Items II + where ItemID not in(select ItemID from @UsedItems)) ii + Join Contents CC ON CC.ContentID = II.ContentID + And CC.Type is not null + RETURN +END +GO +IF (@@Error = 0) PRINT 'TableFunction [vefn_GetDisconnectedItems] Succeeded' +ELSE PRINT 'TableFunction [vefn_GetDisconnectedItems] Error on Creation' +GO + +IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vefn_TransitionsToDisconnected]') AND OBJECTPROPERTY(id,N'IsTableFunction') = 1) + DROP FUNCTION [vefn_TransitionsToDisconnected]; +GO +/****** Object: UserDefinedFunction [dbo].[vefn_TransitionsToDisconnected] ******/ +SET ANSI_NULLS ON +GO +SET QUOTED_IDENTIFIER ON +GO + +-- select * from vefn_TransitionsToDisconnected('1') + +/***************************************************************************** + Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE + Copyright 2013 - Volian Enterprises, Inc. All rights reserved. +*****************************************************************************/ + +CREATE FUNCTION dbo.vefn_TransitionsToDisconnected(@DocVersionList nvarchar(MAX)) +RETURNS @Transitions TABLE +( + [TransitionID] int primary key + ,[FromID] int + ,[ToID] int + ,[RangeID] int + ,[IsRange] int + ,[TranType] int + ,[Config] nvarchar(max) + ,[DTS] datetime + ,[UserID] nvarchar(100) + ,UNIQUE(FromID,TransitionID) + ,UNIQUE(ToID,TransitionID) +) +WITH EXECUTE AS OWNER +AS +BEGIN + insert into @Transitions + select [TransitionID],[FromID],[ToID],[RangeID],[IsRange],[TranType],[Config],[DTS],[UserID] + from Transitions tt + join vefn_GetVersionItems(@DocVersionList) vi on tt.FromID = vi.ContentID + join vefn_GetDisconnectedItems() di on tt.ToID = di.ItemID + RETURN +END +GO +IF (@@Error = 0) PRINT 'TableFunction [vefn_TransitionsToDisconnected] Succeeded' +ELSE PRINT 'TableFunction [vefn_TransitionsToDisconnected] Error on Creation' +GO + +/****** Object: StoredProcedure [getTransitionsToDisconnected] ******/ +IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[getTransitionsToDisconnected]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) + DROP PROCEDURE [getTransitionsToDisconnected]; +GO + +/* +exec getTransitionsToDisconnected +*/ + +/***************************************************************************** + Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE + Copyright 2012 - Volian Enterprises, Inc. All rights reserved. +*****************************************************************************/ +CREATE PROCEDURE [dbo].[getTransitionsToDisconnected] +( + @DocVersionList nvarchar(MAX) +) +WITH EXECUTE AS OWNER +AS + SELECT + TT.[TransitionID], + TT.[FromID], + TT.[ToID], + TT.[RangeID], + TT.[IsRange], + TT.[TranType], + TT.[Config], + TT.[DTS], + TT.[UserID], + TT.[LastChanged], + (SELECT COUNT(*) FROM [ZTransitions] WHERE [ZTransitions].[TransitionID]=TT.[TransitionID]) [ZTransitionCount] + from transitions tt + join vefn_TransitionsToDisconnected(@DocVersionList) td on tt.TransitionID = td.TransitionID + RETURN +GO +-- Display the status of Proc creation +IF (@@Error = 0) PRINT 'Procedure Creation: getTransitionsToDisconnected Succeeded' +ELSE PRINT 'Procedure Creation: getTransitionsToDisconnected Error on Creation' +GO + +IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vefn_GetNonEditableItems]') AND OBJECTPROPERTY(id,N'IsTableFunction') = 1) + DROP FUNCTION [vefn_GetNonEditableItems]; +GO +/****** Object: UserDefinedFunction [dbo].[vefn_GetNonEditableItems] ******/ +SET ANSI_NULLS ON +GO +SET QUOTED_IDENTIFIER ON +GO + +-- select * from vefn_GetNonEditableItems() + +/***************************************************************************** + Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE + Copyright 2013 - Volian Enterprises, Inc. All rights reserved. +*****************************************************************************/ + +CREATE FUNCTION vefn_GetNonEditableItems() +RETURNS @NonEditItems TABLE +( + ItemID int primary Key, + ContentID int, + UNIQUE (ContentID) +) +WITH EXECUTE AS OWNER +AS +BEGIN + insert into @NonEditItems + select ii.ItemID,ah.ContentID + from + ( + select cast(Config as xml) xconfig,ContentID from Contents where ContentID in + ( + select p1.ContentID from Parts p1 + join Parts p2 on p1.ContentID = p2.ContentID + where p1.FromType = 2 and p2.FromType = 6 + ) + and Config like '%edit%' + ) ah + cross apply xconfig.nodes('//SubSection') tSubsection(xSubsection) + join Items ii on ah.ContentID = ii.ContentID + where isnull(xSubsection.value('@Edit','varchar(1)'),'N') = 'N' + RETURN +END +GO +IF (@@Error = 0) PRINT 'TableFunction [vefn_GetNonEditableItems] Succeeded' +ELSE PRINT 'TableFunction [vefn_GetNonEditableItems] Error on Creation' +GO + +IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vefn_TransitionsToNonEditable]') AND OBJECTPROPERTY(id,N'IsTableFunction') = 1) + DROP FUNCTION [vefn_TransitionsToNonEditable]; +GO +/****** Object: UserDefinedFunction [dbo].[vefn_TransitionsToNonEditable] ******/ +SET ANSI_NULLS ON +GO +SET QUOTED_IDENTIFIER ON +GO + +-- select * from vefn_TransitionsToNonEditable('1') + +/***************************************************************************** + Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE + Copyright 2013 - Volian Enterprises, Inc. All rights reserved. +*****************************************************************************/ + +CREATE FUNCTION dbo.vefn_TransitionsToNonEditable(@DocVersionList nvarchar(MAX)) +RETURNS @Transitions TABLE +( + [TransitionID] int primary key + ,[FromID] int + ,[ToID] int + ,[RangeID] int + ,[IsRange] int + ,[TranType] int + ,[Config] nvarchar(max) + ,[DTS] datetime + ,[UserID] nvarchar(100) + ,UNIQUE(FromID,TransitionID) + ,UNIQUE(ToID,TransitionID) +) +WITH EXECUTE AS OWNER +AS +BEGIN + insert into @Transitions + select [TransitionID],[FromID],[ToID],[RangeID],[IsRange],[TranType],[Config],[DTS],[UserID] + from Transitions tt + join vefn_GetVersionItems(@DocVersionList) vi on tt.FromID = vi.ContentID + join vefn_GetNonEditableItems() di on tt.ToID in (select ItemID from vefn_StepChildItems(di.ItemID)) + RETURN +END +GO +IF (@@Error = 0) PRINT 'TableFunction [vefn_TransitionsToNonEditable] Succeeded' +ELSE PRINT 'TableFunction [vefn_TransitionsToNonEditable] Error on Creation' +GO + +/****** Object: StoredProcedure [getTransitionsToNonEditable] ******/ +IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[getTransitionsToNonEditable]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) + DROP PROCEDURE [getTransitionsToNonEditable]; +GO + +/* +exec getTransitionsToNonEditable '8' +*/ + +/***************************************************************************** + Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE + Copyright 2012 - Volian Enterprises, Inc. All rights reserved. +*****************************************************************************/ +CREATE PROCEDURE [dbo].[getTransitionsToNonEditable] +( + @DocVersionList nvarchar(MAX) +) +WITH EXECUTE AS OWNER +AS + SELECT + TT.[TransitionID], + TT.[FromID], + TT.[ToID], + TT.[RangeID], + TT.[IsRange], + TT.[TranType], + TT.[Config], + TT.[DTS], + TT.[UserID], + TT.[LastChanged], + (SELECT COUNT(*) FROM [ZTransitions] WHERE [ZTransitions].[TransitionID]=TT.[TransitionID]) [ZTransitionCount] + from transitions tt + join vefn_TransitionsToNonEditable(@DocVersionList) td on tt.TransitionID = td.TransitionID + RETURN +GO +-- Display the status of Proc creation +IF (@@Error = 0) PRINT 'Procedure Creation: getTransitionsToNonEditable Succeeded' +ELSE PRINT 'Procedure Creation: getTransitionsToNonEditable Error on Creation' +GO + +/****** Object: StoredProcedure [vefn_StepChildItems] ******/ +IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vefn_StepChildItems]') AND OBJECTPROPERTY(id,N'IsTableFunction') = 1) + DROP FUNCTION [vefn_StepChildItems]; +GO + +/***************************************************************************** + Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE + Copyright 2012 - Volian Enterprises, Inc. All rights reserved. +*****************************************************************************/ +CREATE FUNCTION [dbo].[vefn_StepChildItems](@ItemID int) +RETURNS @Children TABLE +( + ItemID int PRIMARY KEY, + ContentID int +) +WITH EXECUTE AS OWNER +AS +BEGIN +with Itemz([Level], [ItemID], [ContentID]) as ( + Select 0 [Level], [ItemID], [ContentID] + FROM [Items] + where [ItemID]=@ItemID +Union All +-- Children + select [Level] + 1, I.[ItemID], I.[ContentID] + from Itemz Z + join Parts P on P.ContentID = Z.ContentID and (Z.Level > 0 or p.FromType = 6) + join Items I on I.ItemID = P.ItemID +-- Siblings +Union All + select [Level] , I.[ItemID], I.[ContentID] + from Itemz Z + join Items I on I.PreviousID = Z.ItemID + where Z.[Level] > 0 +) +insert into @Children select ItemID, ContentID from Itemz +OPTION (MAXRECURSION 10000) +RETURN +END +GO +-- Display the status of Proc creation +IF (@@Error = 0) PRINT 'TableFunction Creation: vefn_StepChildItems Succeeded' +ELSE PRINT 'TableFunction Creation: vefn_StepChildItems Error on Creation' +GO