C2025-043 Admin Tool - Data Check - Tool to identify and report RO's that are not used in any of the PROMS data.

This commit is contained in:
2026-01-09 09:12:00 -05:00
parent 862cf67375
commit ac88add40b
8 changed files with 480 additions and 161 deletions

View File

@@ -24432,6 +24432,71 @@ ELSE PRINT 'Procedure Creation: [vesp_GetOtherActiveSessions] Error on Creation'
GO
IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vesp_GetROsNotUsed]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1)
DROP PROCEDURE [vesp_GetROsNotUsed];
GO
/****** Object: StoredProcedure [dbo].[vesp_GetROsNotUsed] ******/
-- =============================================
-- Author: Matthew Schill
-- Create date: 1/5/2026
-- Description: Returns ROs that are not Used in PROMS
-- =============================================
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)
DECLARE @FSTs table (RofstID int primary key NOT NULL, RODbID int NOT NULL)
INSERT INTO @FSTs
Select max(RoFSTID), RODbID from ROFsts
GROUP BY RODbID
--insert the not used ROs
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
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
--insert thier parents
--if they are not already in @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 @FSTs fst on RofstChild.RofstID = fst.RofstID
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
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
order by RofstChildID, dbID
RETURN
END
IF (@@Error = 0) PRINT 'Procedure Creation: [vesp_GetROsNotUsed] Succeeded'
ELSE PRINT 'Procedure Creation: [vesp_GetROsNotUsed] Error on Creation'
GO
/*
---------------------------------------------------------------------------
| ADD New Code Before this Block |
@@ -24465,8 +24530,8 @@ BEGIN TRY -- Try Block
DECLARE @RevDate varchar(255)
DECLARE @RevDescription varchar(255)
set @RevDate = '09/16/2025 7:00 AM'
set @RevDescription = 'Added Purge Change History and Index Maintenance functions to Admin Tools'
set @RevDate = '1/5/2026 7:00 AM'
set @RevDescription = 'Added Method to get ROs that are not used in PROMS'
Select cast(@RevDate as datetime) RevDate, @RevDescription RevDescription
PRINT 'SQL Code Revision ' + @RevDate + ' - ' + @RevDescription