From e14f62728e2d41fb39964e7654f4508a4a3f1b10 Mon Sep 17 00:00:00 2001 From: Rich Date: Wed, 28 Mar 2012 21:56:23 +0000 Subject: [PATCH] Fixed logic to get data for Chronology and Summary of Changes reports --- PROMS/DataLoader/PROMSFixes.Sql | 204 ++++++++++++++++++++++++++++++++ 1 file changed, 204 insertions(+) diff --git a/PROMS/DataLoader/PROMSFixes.Sql b/PROMS/DataLoader/PROMSFixes.Sql index 7c2a0deb..5eedf0d9 100644 --- a/PROMS/DataLoader/PROMSFixes.Sql +++ b/PROMS/DataLoader/PROMSFixes.Sql @@ -748,3 +748,207 @@ go IF (@@Error = 0) PRINT 'Procedure Creation: restoreDeletedItem Succeeded' ELSE PRINT 'Procedure Creation: restoreDeletedItem Error on Creation' GO + +/****** Object: UserDefinedFunction [dbo].[vefn_GetLastDelim] Script Date: 03/28/2012 17:58:48 ******/ +IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vefn_GetLastDelim]') AND OBJECTPROPERTY(id,N'IsScalarFunction') = 1) + DROP FUNCTION [vefn_GetLastDelim]; +GO +SET ANSI_NULLS ON +GO +SET QUOTED_IDENTIFIER ON +GO +/* +select .dbo.vefn_GetLastDelim(bozo) delim,bozo +from +( +select 'ES\u8209?3.1Post\u8209?SGTR Cooldown Using Backfill' bozo union +select 'ES\u8209?3.1Post\u8209?SGTR Cooldown Using BackfillProcedure Steps' bozo union +select 'ES\u8209?3.1Post\u8209?SGTR Cooldown Using BackfillProcedure Steps1' bozo union +select 'ES\u8209?3.1Post\u8209?SGTR Cooldown Using BackfillProcedure Steps1.1' bozo union +select 'ES\u8209?3.1Post\u8209?SGTR Cooldown Using BackfillProcedure Steps1.1.RNO..1' bozo union +select 'ES\u8209?3.1Post\u8209?SGTR Cooldown Using BackfillProcedure Steps1.1.RNO..1.3' bozo +) ah +*/ + +CREATE FUNCTION [dbo].[vefn_GetLastDelim](@SearchString nvarchar(MAX)) +RETURNS nvarchar(1) +WITH EXECUTE AS OWNER +AS +BEGIN + declare @patstr nvarchar(7) + set @patstr = '%[' + char(7) + char(17) + '.]%' + declare @patidx bigint + set @patidx = patindex(@patstr,Reverse(@SearchString)) + if @patidx = 0 return ' ' + return substring(@SearchString,1 + len(@SearchString) - @patidx,1) +END +GO +IF (@@Error = 0) PRINT 'ScalerFunction [vefn_GetLastDelim] Succeeded' +ELSE PRINT 'ScalerFunction [vefn_GetLastDelim] Error on Creation' +go + +/****** Object: UserDefinedFunction [dbo].[vefn_tblChildItems] Script Date: 03/28/2012 17:43:20 ******/ +SET ANSI_NULLS ON +GO +SET QUOTED_IDENTIFIER ON +GO + +/* +declare @PreviousID as int +declare @ItemID as int +set @ItemID = 450 +select @PreviousID = PreviousID from items where ItemID = @ItemID + +Select * from Items where ItemID = @ItemID + +select * from Transitions +where FromID in (Select ContentID from vefn_ChildItems(@PreviousID)) +AND (ToID = @ItemID or RangeID = @ItemID) + +select CC.Text from Transitions TT +join contents CC on TT.FromID = CC.ContentID +where FromID in (Select ContentID from vefn_ChildItems(@PreviousID)) +AND (ToID = @ItemID or RangeID = @ItemID) + +*/ +ALTER FUNCTION [dbo].[vefn_tblChildItems](@ProcItemID int, @ItemID int, @IncludeDeletedChildren int) +RETURNS @Children TABLE +( + ItemID int PRIMARY KEY, + IContentID int, + IDeleteStatus int, + ProcDTS datetime, + Path nvarchar(max), + OrdinalPath nvarchar(max) +) +WITH EXECUTE AS OWNER +AS +BEGIN + declare @path nvarchar(max) + declare @ppath nvarchar(max) + declare @ordinalpath nvarchar(max) + declare @pordinalpath nvarchar(max) + declare @ordinal int + declare @pitemid int + select @path = path,@ordinalpath = ordinalpath,@ordinal = ordinal,@pitemid = parentid from vefn_ProcedureByProcID(@ProcItemID) where itemid = @ItemID + if @pitemid = 0 begin + set @pordinalpath = '' + set @ppath = '' + end + else begin + select @ppath = path,@pordinalpath = ordinalpath from vefn_ProcedureByProcID(@ProcItemID) where itemid = @pitemID + end + declare @procdts datetime + select @procdts = dts from items where itemid = @ProcItemID + 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([Level], [ItemID], [ContentID], DeleteStatus, ProcDTS, PPath, [Path], [POrdinalPath], [OrdinalPath], [FromType], [Ordinal]) as ( + Select 0 [Level], [ItemID], I.[ContentID], I.DeleteStatus, @procdts procdts, + @ppath [PPath], + @path [Path], + @pordinalpath [POrdinalPath], + @ordinalpath [OrdinalPath], + 0 [FromType],@ordinal [Ordinal] + FROM [tblItems] I + --inner join tblContents C on C.ContentID=I.ContentID + where I.[ItemID]=@ItemID + Union All + -- Children + select [Level] + 1, I.[ItemID], I.[ContentID], I.DeleteStatus, @procdts procdts, + 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 C.Type/10000 + when 0 then @Delim +C.Number + @DelimNumber + C.Text + when 1 then @Delim +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 + + case when I.deletestatus != 0 then 'Old ' else '' end + cast(1 as varchar(3)) + end end Path, + OrdinalPath + '.' + Right('000' + Cast(P.FromType as varchar(4)), 4) + '-' , + OrdinalPath + '.' + Right('000' + Cast(P.FromType as varchar(4)), 4) + '-00001', + P.[FromType],0 + from Itemz Z + join tblParts P on P.ContentID = Z.ContentID + join tblItems I on I.ItemID = P.ItemID + inner join tblContents C on C.ContentID=I.ContentID + where @IncludeDeletedChildren = 1 or z.DeleteStatus = 0 + Union All + -- Children2 + select [Level] + 1, I.[ItemID], I.[ContentID], I.DeleteStatus, @procdts procdts, + 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 C.Type/10000 + when 0 then @Delim +C.Number + @DelimNumber + C.Text + when 1 then @Delim +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 + + case when I.deletestatus != 0 then 'Old ' else '' end + cast(1 as varchar(3)) + end end Path, + OrdinalPath + '.' + Right('000' + Cast(P.FromType as varchar(4)), 4) + '-' , + OrdinalPath + '.' + Right('000' + Cast(P.FromType as varchar(4)), 4) + '-00001', + P.[FromType],0 + from Itemz Z + join PartAudits P on P.ContentID = Z.ContentID + join tblItems I on I.ItemID = P.ItemID and i.PreviousID is null + inner join tblContents C on C.ContentID=I.ContentID + where @IncludeDeletedChildren = 1 or z.DeleteStatus >= 0 + -- Siblings + Union All + select [Level] , I.[ItemID], I.[ContentID], I.DeleteStatus, @procdts procdts, + PPath, + --'1' + + PPath + case C.Type/10000 + when 0 then @Delim + C.Number + @DelimNumber + C.Text + when 1 then @Delim + C.Number + @DelimNumber + C.Text + else case when .dbo.vefn_GetLastDelim(Path) = '.' then @DelimStep else @Delim end + + case when I.deletestatus != 0 then 'Old ' else '' end + cast(Ordinal + 2 as varchar(3)) + end Path, + POrdinalPath, + POrdinalPath + right('00000' + cast(Z.[Ordinal] + 2 as varchar(5)), 5), + FromType,Z.[Ordinal] +1 + from Itemz Z + join tblItems I on I.PreviousID = Z.ItemID + inner join tblContents C on C.ContentID=I.ContentID + where Z.[Level] > 0 + ) + insert into @Children select distinct ItemID, ContentID, DeleteStatus, ProcDTS, Path, OrdinalPath from Itemz + END + RETURN +end +go +IF (@@Error = 0) PRINT 'TableFunction [vefn_tblChildItems] Succeeded' +ELSE PRINT 'TableFunction [vefn_tblChildItems] Error on Creation' +go