diff --git a/PROMS/DataLoader/PROMSFixes.Sql b/PROMS/DataLoader/PROMSFixes.Sql index 765e7f45..46128e07 100644 --- a/PROMS/DataLoader/PROMSFixes.Sql +++ b/PROMS/DataLoader/PROMSFixes.Sql @@ -1701,3 +1701,135 @@ GO IF (@@Error = 0) PRINT 'Trigger alteration: tr_tblItems_Update Succeeded' ELSE PRINT 'Trigger alteration: tr_tblItems_Update Error on Alteration' GO +/****** Object: StoredProcedure [vesp_GetROUsagesByProcedure] ******/ +IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vesp_GetROUsagesByProcedure]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1) + DROP PROCEDURE [vesp_GetROUsagesByProcedure]; +GO + +/* +exec vesp_GetROUsagesByProcedure '1,2,4','20007','1:00010000019C,0001000002AE' +exec vesp_GetROUsagesByProcedure '1,2,4','','1:00010000019C,0001000002AE' +exec vesp_GetROUsagesByProcedure '1,2,4','20007','1:0001' +exec vesp_GetROUsagesByProcedure '1,2,4','20006','1' +exec vesp_GetROUsagesByProcedure '1,2,4','20006','' +exec vesp_GetROUsagesByProcedure '1,2,4',Null,Null +exec vesp_GetROUsagesByProcedure '1','','1:000700000124','' +exec vesp_GetROUsagesByProcedure '','','1:0007000001C9,000700000124', '' +exec vesp_SearchROItemAndChildren '1','','1:000700000124','' +*/ + +CREATE PROCEDURE [dbo].[vesp_GetROUsagesByProcedure] (@DocVersionList varchar(MAX), @StepTypeList varchar(MAX), @ROSearchString varchar(MAX), @UnitPrefix as varchar(MAX)) +WITH EXECUTE AS OWNER +AS +BEGIN +Declare @Delim char(1) +Set @Delim=char(7) +Declare @DelimNumber char(1) +Set @DelimNumber=char(17) +Declare @DelimStep char(1) +Set @DelimStep='.' +begin +with Itemz(DVPath, [Level], [ParentID], [Ordinal], [ItemID], [PreviousID], [FromType], [ContentID], [DTS], [UserID], [LastChanged],[pContentID], + [pDTS],[pUserID],[pLastChanged],PPath, Path, IsRNO, POrdinalPath, OrdinalPath, FoundROID) as ( + Select DVPath, 0 [Level], 0 [ParentID], 0 [Ordinal], [I].[ItemID], [PreviousID],0 [FromType],[I].[ContentID],[I].[DTS],[I].[UserID],[I].[LastChanged] + ,0 [pContentID],[I].[DTS] [pDTS], [I].[UserID] [pUserID], [I].[LastChanged] [pLastChanged], + Cast('' as nvarchar(max)) PPath, + Cast(Case when C.Type < 20000 then @Delim + @UnitPrefix + C.Number + @DelimNumber + C.Text else '1' end as nvarchar(max)) Path, + 0 IsRNO, Cast('' as nvarchar(max)) POrdinalPath, Cast('0001' as nvarchar(max)) OrdinalPath, null + + FROM [Items] I + Join Contents C on C.ContentID=I.ContentID + JOIN vefn_DocVersionSplit(@DocVersionList) DV + ON I.[ItemID] = DV.[ItemID] +Union All +-- Children + select DVPath, [Level] + 1,Z.ItemID,0, I.[ItemID], I.[PreviousID], P.[FromType],I.[ContentID],I.[DTS],I.[UserID],I.[LastChanged] + ,P.[ContentID] [pContentID],P.[DTS] [pDTS],P.[UserID] [pUserID],P.[LastChanged] [pLastChanged] + ,PATH + --'' + case C.Type/10000 + when 2 then + case P.FromType + when 3 then @DelimStep + 'Caution' + when 4 then @DelimStep + 'Note' + else '' end + else '' end + PPath, + --Path + case when Z.FromType < 3 then @Delim else @DelimStep end + case C.Type/10000 + Path + case C.Type/10000 + when 0 then @Delim + @UnitPrefix + C.Number + @DelimNumber + C.Text + when 1 then @Delim + @UnitPrefix + C.Number + @DelimNumber + C.Text + else + case P.FromType + --when 1 then 'PRC' + @Delim + cast(1 as varchar(3)) + --when 2 then 'SEC' + @Delim + cast(1 as varchar(3)) + when 3 then @DelimStep +'Caution' + @DelimStep + cast(1 as varchar(3)) + when 4 then @DelimStep +'Note' + @DelimStep + cast(1 as varchar(3)) + when 5 then @DelimStep +'RNO' + @DelimStep + when 7 then @DelimStep +'Table' + @DelimStep + else case when Z.FromType < 3 then @Delim else @DelimStep end + cast(1 as varchar(3)) + end end Path, + case when P.FromType = 5 then -1 else 0 end IsRNO, + OrdinalPath + '.' + Right('0000' + Cast(P.FromType as varchar(4)), 4) + '-' , + OrdinalPath + '.' + Right('0000' + Cast(P.FromType as varchar(4)), 4) + '-0001', + null + from Itemz Z + join Parts P on P.ContentID = Z.ContentID + join Items I on I.ItemID = P.ItemID + join Contents C on C.ContentID = I.ContentID +Union All +-- Siblings + select DVPath, [Level] ,Z.[ParentID],Z.[Ordinal] +1, I.[ItemID], I.[PreviousID], [FromType],I.[ContentID],I.[DTS],I.[UserID],I.[LastChanged] + ,null,null,null,null + ,PPath, + --'1' + + PPath + case C.Type/10000 + when 0 then @Delim + @UnitPrefix + C.Number + @DelimNumber + C.Text + when 1 then @Delim + @UnitPrefix + C.Number + @DelimNumber + C.Text + else case when Path like '%.%' then @DelimStep else @Delim end + cast(Ordinal + 2 as varchar(3)) + end Path, 0, + POrdinalPath, + POrdinalPath + right('0000' + cast(Z.[Ordinal] + 2 as varchar(4)), 4), + null + from Itemz Z + join Items I on I.PreviousID = Z.ItemID + join Contents C on C.ContentID = I.ContentID + --where Z.[Level] > 0 +) +select DvPath, Path, I.[Level],I.[FromType],I.[Ordinal], I.[ParentID], I.[ItemID],I.[PreviousID],I.[ContentID],I.[DTS],I.[UserID],I.[LastChanged], + C.[Number],C.[Text],C.[Type],C.[FormatID],C.[Config],C.[DTS] [cDTS],C.[UserID] [cUserID],C.[LastChanged] [cLastChanged], + [pContentID],[pDTS],[pUserID],[pLastChanged], + (SELECT COUNT(*) FROM [Annotations] WHERE [Annotations].[ItemID]=[I].[ItemID]) [AnnotationCount], + (SELECT COUNT(*) FROM [DocVersions] WHERE [DocVersions].[ItemID]=[I].[ItemID]) [DocVersionCount], + (SELECT COUNT(*) FROM [Items] [Next] WHERE [Next].[PreviousID]=[I].[ItemID]) [NextCount], + (SELECT COUNT(*) FROM [Parts] WHERE [Parts].[ItemID]=[I].[ItemID]) [PartCount], + (SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[RangeID]=[I].[ItemID]) [Transition_RangeIDCount], + (SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[ToID]=[I].[ItemID]) [Transition_ToIDCount], + (SELECT COUNT(*) FROM [Details] WHERE [Details].[ContentID]=[C].[ContentID]) [DetailCount], + (SELECT COUNT(*) FROM [Entries] WHERE [Entries].[ContentID]=[C].[ContentID]) [EntryCount], + (SELECT COUNT(*) FROM [Grids] WHERE [Grids].[ContentID]=[C].[ContentID]) [GridCount], + (SELECT COUNT(*) FROM [Images] WHERE [Images].[ContentID]=[C].[ContentID]) [ImageCount], + (SELECT COUNT(*) FROM [Items] WHERE [Items].[ContentID]=[C].[ContentID]) [ItemCount], + (SELECT COUNT(*) FROM [Parts] WHERE [Parts].[ContentID]=[C].[ContentID]) [cPartCount], + (SELECT COUNT(*) FROM [RoUsages] WHERE [RoUsages].[ContentID]=[C].[ContentID]) [RoUsageCount], + (SELECT COUNT(*) FROM [Transitions] WHERE [Transitions].[FromID]=[C].[ContentID]) [TransitionCount], + (SELECT COUNT(*) FROM [ZContents] WHERE [ZContents].[ContentID]=[C].[ContentID]) [ZContentCount], + RRU.ROID FoundROID + from ItemZ I + join Contents C on C.ContentID = I.ContentID +join (select contentid, ru.roid from ROusages RU +join vefn_SplitROSearch(@ROSearchString) RR on RU.roid like RR.roid + '%' +union +select contentid, du.roid from DROusages DU +join entries ee on DU.DOCID = EE.DOCID +join vefn_SplitROSearch(@ROSearchString) RR on DU.roid like RR.roid + '%') RRU on RRU.ContentID = I.ContentID + AND + ((isnull(@StepTypeList,'') = '' and dbo.vefn_AllSections(C.Type)>=10000) + or + ((dbo.vefn_AllSections(C.Type) in (Select ID from vefn_SplitInt(@StepTypeList,','))) + or + (@StepTypeList like '%20040%' AND IsRNO = -1))) + order by DvPath,OrdinalPath /*having foundroid in ( select roid from vefn_SplitROSearch(@ROSearchString))*/ +OPTION (MAXRECURSION 10000) +END +END +GO