C2025-043 Admin Tool - Data Check - Tool to identify and report RO's that are not used in any of the PROMS data.
Performance Improvement
This commit is contained in:
@@ -24448,7 +24448,8 @@ CREATE PROCEDURE [dbo].[vesp_GetROsNotUsed]
|
||||
AS
|
||||
BEGIN
|
||||
|
||||
DECLARE @notused table (RofstChildID int NULL, roid [varchar](50) NULL, ID int NOT NULL, ParentID int NOT NULL, dbID int NOT NULL, title varchar(max) not null)
|
||||
Create table #notused (RofstChildID int NULL, roid [varchar](50) NULL, ID int NOT NULL, ParentID int NOT NULL, dbID int NOT NULL, title varchar(max) not null);
|
||||
|
||||
|
||||
DECLARE @FSTs table (RofstID int primary key NOT NULL, RODbID int NOT NULL)
|
||||
|
||||
@@ -24457,38 +24458,43 @@ BEGIN
|
||||
GROUP BY RODbID
|
||||
|
||||
--insert the not used ROs
|
||||
INSERT INTO @notused
|
||||
INSERT INTO #notused
|
||||
SELECT RofstChild.RofstChildID, RofstChild.roid, RofstChild.ID, RofstChild.ParentID, RofstChild.dbiID,
|
||||
RofstChild.title + Case When (Not RofstChild.[value] is null) Then ' (' + fstdb.dbiAP + '-' + RofstChild.appid + ')' Else '' End --Add in Accessory Page ID if it exists
|
||||
FROM RofstChild
|
||||
INNER JOIN RofstDatabase fstdb on fstdb.RofstID = RofstChild.RofstID and fstdb.dbiID = RofstChild.dbiID
|
||||
INNER JOIN @FSTs fst on fst.RofstID = fstdb.RofstID AND RofstChild.RofstID = fst.RofstID
|
||||
LEFT OUTER JOIN RofstChild subchild ON subChild.ParentID = RofstChild.ID --make sure it is not a parent of something else
|
||||
LEFT OUTER JOIN DRoUsages ON [DRoUsages].[ROID] like RofstChild.[ROID] + '%' AND fst.RODbID = DROUsages.RODbID --not used in documents
|
||||
LEFT OUTER JOIN RoUsages ON [RoUsages].[ROID] like RofstChild.[ROID] + '%' AND fst.RODbID = ROUsages.RODbID --not used in regular ROs
|
||||
where
|
||||
NOT EXISTS(Select 1 FROM RofstChild subchild where subChild.ParentID = RofstChild.ID) --make sure it is not a parent of something else
|
||||
AND NOT EXISTS(Select 1 FROM DRoUsages where [DRoUsages].[ROID] like RofstChild.[ROID] + '%' AND fst.RODbID = DROUsages.RODbID) --not used in documents
|
||||
AND NOT EXISTS(Select 1 FROM RoUsages where [RoUsages].[ROID] like RofstChild.[ROID] + '%' AND fst.RODbID = ROUsages.RODbID) --not used in regular ROs
|
||||
subchild.RofstChildID IS NULL --make sure it is not a parent of something else
|
||||
AND DRoUsages.DROUsageID IS NULL --not used in documents
|
||||
AND RoUsages.ROUsageID IS NULL --not used in regular ROs
|
||||
|
||||
--insert thier parents
|
||||
--if they are not already in @notused
|
||||
INSERT INTO @notused
|
||||
INSERT INTO #notused
|
||||
SELECT DISTINCT RofstChild.RofstChildID, RofstChild.roid, RofstChild.ID, RofstChild.ParentID, RofstChild.dbiID, RofstChild.title
|
||||
FROM RofstChild
|
||||
INNER JOIN @notused notusedgetparents on notusedgetparents.ParentID = RofstChild.ID AND RofstChild.dbiID = notusedgetparents.dbID
|
||||
INNER JOIN #notused notusedgetparents on notusedgetparents.ParentID = RofstChild.ID AND RofstChild.dbiID = notusedgetparents.dbID
|
||||
INNER JOIN @FSTs fst on RofstChild.RofstID = fst.RofstID
|
||||
LEFT OUTER JOIN @notused notused on notused.RofstChildID = RofstChild.RofstChildID
|
||||
LEFT OUTER JOIN #notused notused on notused.RofstChildID = RofstChild.RofstChildID
|
||||
WHERE notused.RofstChildID IS NULL
|
||||
|
||||
--insert parent dbs
|
||||
--if they are not already in @notused
|
||||
INSERT INTO @notused
|
||||
INSERT INTO #notused
|
||||
SELECT DISTINCT NULL, NULL, RofstDatabase.ID, RofstDatabase.ParentID, RofstDatabase.dbiID, RofstDatabase.dbiTitle
|
||||
FROM RofstDatabase
|
||||
INNER JOIN @FSTs fst on fst.RofstID = RofstDatabase.RofstID
|
||||
|
||||
select *
|
||||
FROM @notused notused
|
||||
FROM #notused notused
|
||||
order by RofstChildID, dbID
|
||||
|
||||
drop table #notused
|
||||
|
||||
RETURN
|
||||
END
|
||||
|
||||
@@ -24497,6 +24503,18 @@ ELSE PRINT 'Procedure Creation: [vesp_GetROsNotUsed] Error on Creation'
|
||||
GO
|
||||
|
||||
|
||||
IF EXISTS (SELECT * FROM dbo.sysIndexes WHERE name like 'IX_tblROUsagesRODbIDDeleteStatusROID')
|
||||
DROP INDEX [IX_tblROUsagesRODbIDDeleteStatusROID] ON [dbo].[tblROUsages];
|
||||
GO
|
||||
|
||||
CREATE NONCLUSTERED INDEX IX_tblROUsagesRODbIDDeleteStatusROID
|
||||
ON [dbo].[tblROUsages] ([RODbID],[DeleteStatus],[ROID])
|
||||
INCLUDE([ROUsageID],[ContentID],[Config],[DTS],[UserID],[LastChanged]) WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = OFF, DROP_EXISTING = OFF, ONLINE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, OPTIMIZE_FOR_SEQUENTIAL_KEY = OFF) ON [PRIMARY]
|
||||
GO
|
||||
|
||||
PRINT 'Added IX_tblROUsagesRODbIDDeleteStatusROID Index. Speeds up RO queries'
|
||||
GO
|
||||
|
||||
/*
|
||||
---------------------------------------------------------------------------
|
||||
| ADD New Code Before this Block |
|
||||
@@ -24530,7 +24548,7 @@ BEGIN TRY -- Try Block
|
||||
DECLARE @RevDate varchar(255)
|
||||
DECLARE @RevDescription varchar(255)
|
||||
|
||||
set @RevDate = '1/5/2026 7:00 AM'
|
||||
set @RevDate = '1/12/2026 2:00 PM'
|
||||
set @RevDescription = 'Added Method to get ROs that are not used in PROMS'
|
||||
|
||||
Select cast(@RevDate as datetime) RevDate, @RevDescription RevDescription
|
||||
|
||||
@@ -21,7 +21,7 @@ namespace VEPROMS.CSLA.Library
|
||||
{
|
||||
cm.CommandType = CommandType.StoredProcedure;
|
||||
cm.CommandText = "vesp_GetROsNotUsed";
|
||||
cm.CommandTimeout = Database.DefaultTimeout;
|
||||
cm.CommandTimeout = 0;
|
||||
using (SqlDataAdapter da = new SqlDataAdapter(cm))
|
||||
{
|
||||
DataTable dt = new DataTable();
|
||||
|
||||
Reference in New Issue
Block a user