delete from versions delete from checks delete from revisions print 'old approval data purged' /****** Object: UserDefinedFunction [dbo].[vefn_GetVersionIDByItemID] Script Date: 02/03/2012 16:48:32 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vefn_GetVersionIDByItemID]') AND OBJECTPROPERTY(id,N'IsScalarFunction') = 1) DROP FUNCTION [vefn_GetVersionIDByItemID]; GO /* select dbo.vefn_GetVersionIDByItemID(41) */ /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ create function [dbo].[vefn_GetVersionIDByItemID] (@ItemID int) returns int as begin declare @VersionID int; with itemz ( itemid,previousid,versionid ) as ( select itemid,previousid,null from items ii join contents cc on ii.contentid = cc.contentid where itemid = @ItemID --siblins union all select ii.itemid,ii.previousid,null from items ii join contents cc on ii.contentid = cc.contentid join itemz zz on zz.previousid = ii.itemid where zz.versionid is null --chillins union all select ii.itemid,ii.previousid,null from parts pp join items ii on ii.contentid = pp.contentid join contents cc on ii.contentid = cc.contentid join itemz zz on zz.itemid = pp.itemid where zz.versionid is null --docversions union all select 0,0,dv.versionid from docversions dv join itemz zz on dv.itemid = zz.itemid where zz.versionid is null ) select @VersionID = versionid from itemz zz where versionid is not null OPTION (MAXRECURSION 10000) return @VersionID end GO -- Display the status of Func creation IF (@@Error = 0) PRINT 'Function Creation: vefn_GetVersionIDByItemID Succeeded' ELSE PRINT 'Function Creation: vefn_GetVersionIDByItemID Error on Creation' GO /****** Object: StoredProcedure [dbo].[getDocumentByLibDoc] Script Date: 01/30/2012 14:08:10 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[getDocumentByLibDoc]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) DROP PROCEDURE [getDocumentByLibDoc]; GO -- [dbo].[getDocumentByLibDoc] 'DOC_0000',4 -- [dbo].[getDocumentByLibDoc] 'DOC_0000',3 -- [dbo].[getDocumentByLibDoc] 'DOC_0000',2 -- [dbo].[getDocumentByLibDoc] 'DOC_0000',1 /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE Copyright 2012 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE PROCEDURE [dbo].[getDocumentByLibDoc] ( @LibDoc varchar(12), @VersionID int ) WITH EXECUTE AS OWNER AS DECLARE @DocID int select @DocID = docid from ( select distinct ah.docid,.dbo.vefn_GetVersionIDByItemID(ii.itemid) versionid from ( select dd.docid,ofn.value('@OriginalFileName','varchar(20)') origfilename,dts from (select docid,cast(config as xml) xconfig,dts from documents) dd cross apply xconfig.nodes('//History') t1(ofn) ) ah inner join entries ee on ah.docid = ee.docid inner join items ii on ee.contentid = ii.itemid where origfilename = @LibDoc + '.LIB' ) ah where versionid = @VersionID -- from (select docid,cast(config as xml) xconfig from documents) ah -- cross apply xconfig.nodes('//Config/History') t1(roc) -- where roc.value('@OriginalFileName','varchar(12)') = @LibDoc + '.LIB' SELECT [DocID], [LibTitle], [DocContent], [DocAscii], [Config], [DTS], [UserID], [LastChanged], [FileExtension], (SELECT COUNT(*) FROM [DROUsages] WHERE [DROUsages].[DocID]=[Documents].[DocID]) [DROUsageCount], (SELECT COUNT(*) FROM [Entries] WHERE [Entries].[DocID]=[Documents].[DocID]) [EntryCount], (SELECT COUNT(*) FROM [Pdfs] WHERE [Pdfs].[DocID]=[Documents].[DocID]) [PdfCount] FROM [Documents] WHERE [DocID]=@DocID SELECT [DROUsages].[DROUsageID], [DROUsages].[DocID], [DROUsages].[ROID], [DROUsages].[Config], [DROUsages].[DTS], [DROUsages].[UserID], [DROUsages].[LastChanged], [DROUsages].[RODbID], [RODbs].[ROName] [RODb_ROName], [RODbs].[FolderPath] [RODb_FolderPath], [RODbs].[DBConnectionString] [RODb_DBConnectionString], [RODbs].[Config] [RODb_Config], [RODbs].[DTS] [RODb_DTS], [RODbs].[UserID] [RODb_UserID] FROM [DROUsages] JOIN [RODbs] ON [RODbs].[RODbID]=[DROUsages].[RODbID] WHERE [DROUsages].[DocID]=@DocID SELECT [Entries].[ContentID], [Entries].[DocID], [Entries].[DTS], [Entries].[UserID], [Entries].[LastChanged], [Contents].[Number] [Content_Number], [Contents].[Text] [Content_Text], [Contents].[Type] [Content_Type], [Contents].[FormatID] [Content_FormatID], [Contents].[Config] [Content_Config], [Contents].[DTS] [Content_DTS], [Contents].[UserID] [Content_UserID] FROM [Entries] JOIN [Contents] ON [Contents].[ContentID]=[Entries].[ContentID] WHERE [Entries].[DocID]=@DocID SELECT [Pdfs].[DocID], [Pdfs].[DebugStatus], [Pdfs].[TopRow], [Pdfs].[PageLength], [Pdfs].[LeftMargin], [Pdfs].[PageWidth], [Pdfs].[PageCount], [Pdfs].[DocPdf], [Pdfs].[DTS], [Pdfs].[UserID], [Pdfs].[LastChanged] FROM [Pdfs] WHERE [Pdfs].[DocID]=@DocID RETURN GO -- Display the status of Proc creation IF (@@Error = 0) PRINT 'Procedure Creation: getDocumentByLibDoc Succeeded' ELSE PRINT 'Procedure Creation: getDocumentByLibDoc Error on Creation' GO SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO /* select [dbo].[vefn_CheckAllXML](1) */ ALTER function [dbo].[vefn_CheckAllXML](@DocVersionID int) returns xml begin --temp table for max checkid declare @tChecks table (CheckID int) insert into @tChecks select max(cc.checkid) checkid from checks cc inner join stages ss on cc.stageid = ss.stageid inner join revisions rr on cc.revisionid = rr.revisionid where ss.isapproved = 1 group by rr.itemid --temp table for sibling itemid declare @tItems table (ItemID int) insert into @tItems select itemid from vefn_siblingitems((select itemid from docversions where versionid = @docversionid),0) --temp table for multi valued roids declare @mvROIDS table (ROID varchar(max)) insert into @mvROIDS select roid from (select distinct r1.value('@ROID','varchar(max)') roid,r1.value('@ROValue','varchar(max)') rovalue from checks cc cross apply cc.consistencychecks.nodes('//ROCheck') t1(r1)) t1 group by roid having count(*) > 1 --temp table for multi valued transitionids declare @mvTransitions table (TransitionID int) insert into @mvTransitions select transitionid from (select distinct r1.value('@TransitionID','int') transitionid,r1.value('@TransitionValue','varchar(max)') transitionvalue from checks cc cross apply cc.consistencychecks.nodes('//TransitionCheck') t1(r1)) t1 group by transitionid having count(*) > 1 --temp table for multi valued docids declare @mvLibDocs table (DocID int) insert into @mvLibDocs select docid from (select distinct r1.value('@DocID','int') docid,r1.value('@DocDate','datetime') docdate from checks cc cross apply cc.consistencychecks.nodes('//LibDocCheck') t1(r1)) t1 group by docid having count(*) > 1 --temp table for roids declare @tROIDS table (ItemID int,ROID varchar(max),ROValue varchar(max),CheckID int) insert into @tROIDS select rr.itemid,r1.value('@ROID','varchar(max)') roid,r1.value('@ROValue','varchar(max)') rovalue, cc.checkid from checks cc inner join revisions rr on cc.revisionid = rr.revisionid cross apply cc.consistencychecks.nodes('//ROCheck') t1(r1) --temp table for transitions declare @tTransitions table (ItemID int,TransitionID int,TransitionValue varchar(max),CheckID int) insert into @tTransitions select rr.itemid,r1.value('@TransitionID','int') transitionid,r1.value('@TransitionValue','varchar(max)') transitionvalue,cc.checkid from checks cc inner join revisions rr on cc.revisionid = rr.revisionid cross apply cc.consistencychecks.nodes('//TransitionCheck') t1(r1) --temp table for libdocs declare @tLibDocs table (ItemID int, DocID int, DocDate datetime,CheckID int) insert into @tLibDocs select rr.itemid,r1.value('@DocID','int') docid,r1.value('@DocDate','datetime') docdate,cc.checkid from checks cc inner join revisions rr on cc.revisionid = rr.revisionid cross apply cc.consistencychecks.nodes('//LibDocCheck') t1(r1) --get all inconsitencies accross set declare @ChkXML xml set @ChkXML = ( select (--ro inconsistencies accross set select ROCheck.ItemID,ROCheck.ROID,ROCheck.ROValue from @tROIDS ROCheck inner join @tChecks tc on ROCheck.checkid = tc.checkid inner join @tItems ti on ROCheck.itemid = ti.itemid inner join @mvROIDS mv on ROCheck.roid = mv.roid order by ROCheck.itemid for xml auto,root('ROChecks'),type ), (--transition inconsistencies accross set select TransitionCheck.ItemID,TransitionCheck.TransitionID,TransitionCheck.TransitionValue from @tTransitions TransitionCheck inner join @tChecks tc on TransitionCheck.checkid = tc.checkid inner join @tItems ti on TransitionCheck.itemid = ti.itemid inner join @mvTransitions mv on TransitionCheck.TransitionID = mv.TransitionID order by TransitionCheck.itemid for xml auto,root('TransitionChecks'),type ), (--libdoc inconsistencies accross set select LibDocCheck.ItemID,LibDocCheck.DocID,LibDocCheck.DocDate from @tLibDocs LibDocCheck inner join @tChecks tc on LibDocCheck.checkid = tc.checkid inner join @tItems ti on LibDocCheck.itemid = ti.itemid inner join @mvLibDocs mv on LibDocCheck.docid = mv.docid order by LibDocCheck.itemid for xml auto,root('LibDocChecks'),type ) for xml path(''),ROOT ('ConsistencyChecks'),type ) return @ChkXML end GO -- Display the status of Func creation IF (@@Error = 0) PRINT 'Function Alteration: vefn_CheckAllXML Succeeded' ELSE PRINT 'Function Alteration: vefn_CheckAllXML Error on Alteration' GO