Changed the getContentAuditsSummaryByItemIDandUnitID to run faster
This commit is contained in:
parent
2c3c5fc9e0
commit
3d6d75e04d
@ -4694,6 +4694,59 @@ create PROCEDURE [dbo].[getContentAuditsSummaryByItemIDandUnitID]
|
||||
WITH EXECUTE AS OWNER
|
||||
AS
|
||||
begin
|
||||
DECLARE @ProcId Int
|
||||
Set @ProcID = @ProcedureItemID
|
||||
DECLARE @Apples TABLE
|
||||
(
|
||||
ProcID int,
|
||||
ItemId int,
|
||||
ContentID int Primary Key,
|
||||
Apple nvarchar(255),
|
||||
DerApple nvarchar(255)
|
||||
)
|
||||
--Build Applicabilty table for the specified Procedure ID
|
||||
BEGIN
|
||||
with Itemz([Level],[Apple],[DerApple],[ParApple],[ItemID], [ContentID]) as
|
||||
(Select 0
|
||||
,xMasterSlave.value('@Applicability','nvarchar(255)') Apple
|
||||
,IsNull(xMasterSlave.value('@Applicability','nvarchar(255)'),dbo.ve_getItemDerivedApplicability(@ProcID)) DerApple
|
||||
,cast(dbo.ve_getItemDerivedApplicability(@ProcID) as nvarchar(255)) ParApple
|
||||
,[II].[ItemID], [II].[ContentID]
|
||||
FROM [Items] II
|
||||
JOIN (Select ContentID, cast(config as XML) xConfig FROM Contents) CC ON II.ContentID = CC.ContentID
|
||||
outer apply xConfig.nodes('//MasterSlave') tMasterSlave(xMasterSlave)
|
||||
Where II.[ItemID] = @ProcID
|
||||
Union All
|
||||
-- Children
|
||||
select ZZ.Level + 1 Level
|
||||
,xMasterSlave.value('@Applicability','nvarchar(255)') Apple
|
||||
,IsNull(xMasterSlave.value('@Applicability','nvarchar(255)'),ZZ.DerApple) DerApple
|
||||
,ZZ.DerApple ParApple
|
||||
, II.[ItemID], II.[ContentID]
|
||||
from Itemz ZZ
|
||||
join Parts PP on PP.ContentID = ZZ.ContentID
|
||||
join Items II on II.ItemID = PP.ItemID
|
||||
JOIN (Select ContentID, cast(config as XML) xConfig FROM Contents) CC ON II.ContentID = CC.ContentID
|
||||
outer apply xConfig.nodes('//MasterSlave') tMasterSlave(xMasterSlave)
|
||||
Union All
|
||||
-- Siblings
|
||||
select ZZ.Level
|
||||
,xMasterSlave.value('@Applicability','nvarchar(255)') Apple
|
||||
,IsNull(xMasterSlave.value('@Applicability','nvarchar(255)'),ZZ.ParApple) DerApple
|
||||
,ZZ.ParApple
|
||||
, II.[ItemID], II.[ContentID]
|
||||
from Itemz ZZ
|
||||
join Items II on II.PreviousID = ZZ.ItemID
|
||||
JOIN (Select ContentID, cast(config as XML) xConfig FROM Contents) CC ON II.ContentID = CC.ContentID
|
||||
outer apply xConfig.nodes('//MasterSlave') tMasterSlave(xMasterSlave)
|
||||
Where Level >= 1
|
||||
)
|
||||
insert into @Apples
|
||||
select @ProcID ProcID, ItemID, ContentID, Apple, DerApple--, [ItemID], [ContentID]
|
||||
from ItemZ II
|
||||
OPTION (MAXRECURSION 10000)
|
||||
END
|
||||
|
||||
|
||||
DECLARE @Chrono TABLE
|
||||
(
|
||||
@ -4715,153 +4768,25 @@ ItemID int,
|
||||
TypeName nvarchar(max),
|
||||
ordinalpath nvarchar(max)
|
||||
)
|
||||
|
||||
-- Use the Applicability Table to limit Items included in the list of changes
|
||||
insert into @Chrono
|
||||
select * from vefn_GetMyChronology(@ProcedureItemID,@SelectedItemID,@IncludeDeletedChildren,@DTS)
|
||||
where dbo.ve_GetItemDerivedApplicability(ItemID) = '-1' or ',' + dbo.ve_GetItemDerivedApplicability(ItemID) + ',' like '%,' + cast(@UnitID as varchar(10)) + ',%'
|
||||
select Distinct VC.* from vefn_GetMyChronology(@ProcedureItemID,@SelectedItemID,@IncludeDeletedChildren,@DTS) VC
|
||||
Left JOIN @Apples AA ON AA.ContentID = VC.ContentID
|
||||
Where aa.ContentID is null or AA.DerApple = '-1' or ',' + AA.DerApple + ',' like '%,' + cast(@UnitID as varchar(10)) + ',%'
|
||||
|
||||
Declare @Audits TABLE
|
||||
(
|
||||
AuditID int primary key
|
||||
)
|
||||
-- Create a Unique list of Minimum and Maximum AuditIDs for Each ContentID
|
||||
insert into @Audits
|
||||
select min(auditID) from @Chrono group by contentid UNION select max(auditID) from @Chrono group by contentid
|
||||
-- Return the List Of Changes with the first Audit Record and the Last Audit Record
|
||||
select * from @Chrono
|
||||
where AuditID is null OR AuditID in (select min(auditID) from @Chrono group by contentid UNION select max(auditID) from @Chrono group by contentid)
|
||||
where AuditID is null OR AuditID in (select AuditID from @Audits)
|
||||
order by OrdinalPath, contentid,auditid
|
||||
|
||||
--select xyz.* from
|
||||
--(
|
||||
--select z.* from
|
||||
--(
|
||||
--select contentid,min(auditid) auditid from
|
||||
--(
|
||||
-- select [AuditID],[ContentID],[Number],[Text],[Type],[FormatID],[Config],[DTS],[UserID],[DeleteStatus],[ActionDTS],[ActionWhat],[ActionWhen],[Path],ItemID,TypeName
|
||||
-- from
|
||||
-- (
|
||||
-- select
|
||||
-- case
|
||||
-- when lastauditid is null then 'Added'
|
||||
-- when r.deletestatus > 0 then 'Deleted'
|
||||
-- when lastauditid = -1 then 'Changed'
|
||||
-- when DeletedAuditID is not null then 'Restored'
|
||||
---- when DeletedAuditID is not null and lastauditid = deletedauditid then 'Restored'
|
||||
-- else 'Changed'
|
||||
-- end actionwhat
|
||||
--,actiondts actionwhen
|
||||
---- ,case
|
||||
---- when lastauditid is null then dts
|
||||
---- when r.deletestatus > 0 then ActionDTS
|
||||
---- when lastauditid = -1 then dts
|
||||
---- when DeletedAuditID is not null then ActionDTS
|
||||
---- else dts
|
||||
---- end actionwhen
|
||||
--,(select dbo.vefn_GetStepTypeNameByItemIDandTypeID(t.itemid,r.type)) TypeName
|
||||
-- ,*
|
||||
-- from vefn_tblchilditems (@ProcedureItemID,@SelectedItemID,@IncludeDeletedChildren) t
|
||||
-- inner join vefn_chronologyreport(@ProcedureItemID) r
|
||||
-- on t.icontentid = r.contentid
|
||||
---- where dbo.ve_GetItemApplicability(ItemID) = '-1' or ',' + dbo.ve_GetItemApplicability(ItemID) + ',' like '%,' + cast(@UnitID as varchar(10)) + ',%'
|
||||
---- where ActionDTS > procdts or dts > procdts
|
||||
-- ) ah
|
||||
--) x
|
||||
--group by contentid
|
||||
--) y
|
||||
--inner join
|
||||
--(
|
||||
-- select [AuditID],[ContentID],[Number],[Text],[Type],[FormatID],[Config],[DTS],[UserID],[DeleteStatus],[ActionDTS],[ActionWhat],[ActionWhen],[Path],ItemID,TypeName,appl,ordinalpath
|
||||
-- from
|
||||
-- (
|
||||
-- select
|
||||
-- case
|
||||
-- when lastauditid is null then 'Added'
|
||||
-- when r.deletestatus > 0 then 'Deleted'
|
||||
-- when lastauditid = -1 then 'Changed'
|
||||
-- when DeletedAuditID is not null then 'Restored'
|
||||
---- when DeletedAuditID is not null and lastauditid = deletedauditid then 'Restored'
|
||||
-- else 'Changed'
|
||||
-- end actionwhat
|
||||
--,actiondts actionwhen
|
||||
---- ,case
|
||||
---- when lastauditid is null then dts
|
||||
---- when r.deletestatus > 0 then ActionDTS
|
||||
---- when lastauditid = -1 then dts
|
||||
---- when DeletedAuditID is not null then ActionDTS
|
||||
---- else dts
|
||||
---- end actionwhen
|
||||
--,(select dbo.vefn_GetStepTypeNameByItemIDandTypeID(t.itemid,r.type)) TypeName
|
||||
--,dbo.ve_GetItemApplicability(ItemID) appl
|
||||
-- ,*
|
||||
-- from vefn_tblchilditems (@ProcedureItemID,@SelectedItemID,@IncludeDeletedChildren) t
|
||||
-- inner join vefn_chronologyreport(@ProcedureItemID) r
|
||||
-- on t.icontentid = r.contentid
|
||||
---- where dbo.ve_GetItemApplicability(ItemID) = '-1' or ',' + dbo.ve_GetItemApplicability(ItemID) + ',' like '%,' + cast(@UnitID as varchar(10)) + ',%'
|
||||
---- where ActionDTS > procdts or dts > procdts
|
||||
-- ) ah
|
||||
--) z on y.contentid = z.contentid and y.auditid = z.auditid
|
||||
--union
|
||||
--select z.* from
|
||||
--(
|
||||
--select contentid,max(auditid) auditid from
|
||||
--(
|
||||
-- select [AuditID],[ContentID],[Number],[Text],[Type],[FormatID],[Config],[DTS],[UserID],[DeleteStatus],[ActionDTS],[ActionWhat],[ActionWhen],[Path],ItemID,TypeName
|
||||
-- from
|
||||
-- (
|
||||
-- select
|
||||
-- case
|
||||
-- when lastauditid is null then 'Added'
|
||||
-- when r.deletestatus > 0 then 'Deleted'
|
||||
-- when lastauditid = -1 then 'Changed'
|
||||
-- when DeletedAuditID is not null then 'Restored'
|
||||
---- when DeletedAuditID is not null and lastauditid = deletedauditid then 'Restored'
|
||||
-- else 'Changed'
|
||||
-- end actionwhat
|
||||
--,actiondts actionwhen
|
||||
---- ,case
|
||||
---- when lastauditid is null then dts
|
||||
---- when r.deletestatus > 0 then ActionDTS
|
||||
---- when lastauditid = -1 then dts
|
||||
---- when DeletedAuditID is not null then ActionDTS
|
||||
---- else dts
|
||||
---- end actionwhen
|
||||
--,(select dbo.vefn_GetStepTypeNameByItemIDandTypeID(t.itemid,r.type)) TypeName
|
||||
-- ,*
|
||||
-- from vefn_tblchilditems (@ProcedureItemID,@SelectedItemID,@IncludeDeletedChildren) t
|
||||
-- inner join vefn_chronologyreport(@ProcedureItemID) r
|
||||
-- on t.icontentid = r.contentid
|
||||
---- where dbo.ve_GetItemApplicability(ItemID) = '-1' or ',' + dbo.ve_GetItemApplicability(ItemID) + ',' like '%,' + cast(@UnitID as varchar(10)) + ',%'
|
||||
---- where ActionDTS > procdts or dts > procdts
|
||||
-- ) ah
|
||||
--) x
|
||||
--group by contentid
|
||||
--) y
|
||||
--inner join
|
||||
--(
|
||||
-- select [AuditID],[ContentID],[Number],[Text],[Type],[FormatID],[Config],[DTS],[UserID],[DeleteStatus],[ActionDTS],[ActionWhat],[ActionWhen],[Path],ItemID,TypeName,appl,ordinalpath
|
||||
-- from
|
||||
-- (
|
||||
-- select
|
||||
-- case
|
||||
-- when lastauditid is null then 'Added'
|
||||
-- when r.deletestatus > 0 then 'Deleted'
|
||||
-- when lastauditid = -1 then 'Changed'
|
||||
-- when DeletedAuditID is not null then 'Restored'
|
||||
---- when DeletedAuditID is not null and lastauditid = deletedauditid then 'Restored'
|
||||
-- else 'Changed'
|
||||
-- end actionwhat
|
||||
--,actiondts actionwhen
|
||||
---- ,case
|
||||
---- when lastauditid is null then dts
|
||||
---- when r.deletestatus > 0 then ActionDTS
|
||||
---- when lastauditid = -1 then dts
|
||||
---- when DeletedAuditID is not null then ActionDTS
|
||||
---- else dts
|
||||
---- end actionwhen
|
||||
--,(select dbo.vefn_GetStepTypeNameByItemIDandTypeID(t.itemid,r.type)) TypeName
|
||||
--,dbo.ve_GetItemApplicability(ItemID) appl
|
||||
-- ,*
|
||||
-- from vefn_tblchilditems (@ProcedureItemID,@SelectedItemID,@IncludeDeletedChildren) t
|
||||
-- inner join vefn_chronologyreport(@ProcedureItemID) r
|
||||
-- on t.icontentid = r.contentid
|
||||
---- where dbo.ve_GetItemApplicability(ItemID) = '-1' or ',' + dbo.ve_GetItemApplicability(ItemID) + ',' like '%,' + cast(@UnitID as varchar(10)) + ',%'
|
||||
---- where ActionDTS > procdts or dts > procdts
|
||||
-- ) ah
|
||||
--) z on y.contentid = z.contentid and y.auditid = z.auditid
|
||||
--) xyz
|
||||
-- where appl = '-1' or ',' + appl + ',' like '%,' + cast(@UnitID as varchar(10)) + ',%'
|
||||
-- order by OrdinalPath, contentid,auditid--actionwhen
|
||||
RETURN
|
||||
end
|
||||
GO
|
||||
@ -13143,8 +13068,8 @@ BEGIN TRY -- Try Block
|
||||
set nocount on
|
||||
DECLARE @RevDate varchar(255)
|
||||
DECLARE @RevDescription varchar(255)
|
||||
set @RevDate = '1/9/2017 4:45 PM'
|
||||
set @RevDescription = 'Fixed vesp_SessionBegin'
|
||||
set @RevDate = '2/27/2017 9:30AM'
|
||||
set @RevDescription = 'Update getContentAuditsSummaryByItemIDandUnitID'
|
||||
Select cast(@RevDate as datetime) RevDate, @RevDescription RevDescription
|
||||
PRINT 'SQL Code Revision ' + @RevDate + ' - ' + @RevDescription
|
||||
IF( @@TRANCOUNT > 0 ) COMMIT
|
||||
|
Loading…
x
Reference in New Issue
Block a user