Compare commits
3 Commits
Developmen
...
B2026-001-
| Author | SHA1 | Date | |
|---|---|---|---|
| 66600f8d15 | |||
| 90d79dfc54 | |||
| 4c9cc724b9 |
@@ -19134,7 +19134,7 @@ GO
|
||||
rd.ParentID
|
||||
From vwRofstData_RofstDatabases rd
|
||||
Where rd.RofstID = @RofstID
|
||||
Order By rd.dbiID Asc;
|
||||
Order By rd.dbiTitle Asc;
|
||||
|
||||
Return;
|
||||
End
|
||||
@@ -19320,7 +19320,7 @@ GO
|
||||
rc.AccPageID
|
||||
From RoParent rp
|
||||
inner join vwRofstData_RofstChildren rc on rc.RofstID = rp.RofstID and rc.dbiID = rp.dbiID and rc.ParentID = rp.ID
|
||||
Order By rc.ID Asc;
|
||||
Order By rc.title Asc;
|
||||
|
||||
|
||||
Return;
|
||||
@@ -20588,11 +20588,6 @@ GO
|
||||
GO
|
||||
|
||||
|
||||
|
||||
-- Delete All Existing Rofst Table Data
|
||||
Delete From RofstHeader;
|
||||
|
||||
|
||||
/*
|
||||
==========================================================================================================
|
||||
End: B2022-083: Support Conditional RO Values (v2.1)
|
||||
@@ -24264,6 +24259,276 @@ BEGIN
|
||||
RETURN
|
||||
END
|
||||
|
||||
IF (@@Error = 0) PRINT 'Procedure Creation: [getUserAcessControl] Succeeded'
|
||||
ELSE PRINT 'Procedure Creation: [getUserAcessControl] Error on Creation'
|
||||
GO
|
||||
|
||||
-- C2021-058 Admin Tool Purge Change History / C2025-052 Admin Tool Index Maintenance
|
||||
IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vesp_PurgeChangeHistory]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1)
|
||||
DROP PROCEDURE [vesp_PurgeChangeHistory];
|
||||
|
||||
GO
|
||||
|
||||
/****** Object: StoredProcedure [dbo].[vesp_PurgeChangeHistory] Script Date: 9/9/2025 6:51:42 AM ******/
|
||||
|
||||
-- =============================================
|
||||
-- Author: Matthew Schill
|
||||
-- Create date: 09/09/2025
|
||||
-- Description: Admin Tool Purge Change History. Add the ability to remove audit records from Admin Tools.
|
||||
-- =============================================
|
||||
CREATE PROCEDURE [dbo].[vesp_PurgeChangeHistory]
|
||||
(
|
||||
@dte AS datetime
|
||||
)
|
||||
AS
|
||||
BEGIN
|
||||
Delete from Versions where DTS < @dte
|
||||
Delete from DocumentAudits where DTS < @dte
|
||||
delete from Figures where ROFSTID not in(select rofstid from Associations) and DTS < @dte
|
||||
Delete from ROFSTs where ROFSTID not in(select rofstid from Associations) and DTS < @dte
|
||||
delete from roimages where rodbid not in(select rodbid from rofsts) and DTS < @dte
|
||||
delete from documents where docid not in(select docid from entries) and DTS < @dte
|
||||
PRINT 'Temporarally storing Items to delete'
|
||||
declare @Items table (ItemID bigint PRIMARY KEY, deletestatus int)
|
||||
INSERT INTO @Items
|
||||
Select Child.ItemID, Child.deletestatus
|
||||
FROM tblItems AS Child
|
||||
INNER JOIN tblContents AS parent
|
||||
ON Parent.ContentID = Child.ContentID
|
||||
AND Parent.deletestatus = Child.deletestatus
|
||||
Where
|
||||
parent.deletestatus != 0 and parent.ActionDTS < @dte
|
||||
PRINT 'Phase 1'
|
||||
delete from tblAnnotations where deletestatus != 0 and DTS < @dte
|
||||
delete tblAnnotations
|
||||
from tblAnnotations
|
||||
INNER JOIN @Items Itms
|
||||
ON Itms.ItemID = tblAnnotations.ItemID AND tblAnnotations.deletestatus != 0
|
||||
|
||||
delete from drousages where docid in(select docid from tbldocuments where deletestatus != 0) and DTS < @dte
|
||||
delete from tblEntries where deletestatus != 0 and DTS < @dte
|
||||
delete from tblDocuments where deletestatus != 0 and DTS < @dte
|
||||
delete from tblGrids where deletestatus != 0 and DTS < @dte
|
||||
delete from tblImages where deletestatus != 0 and DTS < @dte
|
||||
PRINT 'Phase 2'
|
||||
delete from tblROUsages where deletestatus != 0 and DTS < @dte
|
||||
delete tblROUsages
|
||||
from tblROUsages
|
||||
INNER JOIN tblContents ON tblContents.ContentID = tblROUsages.ContentID
|
||||
AND tblContents.deletestatus = tblROUsages.deletestatus
|
||||
where tblContents.deletestatus != 0 and tblContents.ActionDTS < @dte
|
||||
PRINT 'Deleting Transitions'
|
||||
delete from tblTransitions where deletestatus != 0 and
|
||||
(DTS < @dte
|
||||
OR RangeID in (Select ItemID FROM @Items)
|
||||
OR ToID in (Select ItemID FROM @Items)
|
||||
OR FromID in (Select ContentID from tblContents where deletestatus != 0 and ActionDTS < @dte)
|
||||
)
|
||||
PRINT 'Deleting Items and Parts'
|
||||
delete from tblItems where deletestatus != 0 and DTS < @dte
|
||||
delete from tblParts where deletestatus != 0 and ItemID Not IN (Select ItemID from Items) and DTS < @dte
|
||||
PRINT 'Purging Parts with deleted Contents'
|
||||
DELETE from Child
|
||||
FROM tblParts AS Child
|
||||
INNER JOIN tblItems
|
||||
ON tblItems.ItemID = Child.ItemID
|
||||
AND tblItems.deletestatus = Child.deletestatus
|
||||
INNER JOIN tblContents AS parent
|
||||
ON parent.ContentID = tblItems.ContentID
|
||||
AND parent.deletestatus = tblItems.deletestatus
|
||||
Where
|
||||
parent.deletestatus != 0 and parent.ActionDTS < @dte
|
||||
DELETE FROM tblParts
|
||||
where deletestatus != 0 AND
|
||||
ContentID in
|
||||
(Select ContentID from tblContents where deletestatus != 0 and ActionDTS < @dte)
|
||||
|
||||
PRINT 'Purging Items with deleted Contents'
|
||||
alter table tblItems nocheck constraint FK_Items_Items
|
||||
DELETE tblItems
|
||||
FROM tblItems
|
||||
INNER JOIN @Items Itms
|
||||
ON Itms.ItemID = tblItems.ItemID AND Itms.deletestatus = tblItems.deletestatus
|
||||
alter table tblItems check constraint FK_Items_Items
|
||||
PRINT 'Purging Contents'
|
||||
delete from tblContents where deletestatus != 0 and ActionDTS < @dte
|
||||
PRINT 'Phase 3'
|
||||
delete from AnnotationAudits where DTS < @dte
|
||||
delete from ContentAudits where DTS < @dte
|
||||
delete from EntryAudits where DTS < @dte
|
||||
delete from DocumentAudits where DTS < @dte
|
||||
delete from GridAudits where DTS < @dte
|
||||
delete from ImageAudits where DTS < @dte
|
||||
PRINT 'Phase 4'
|
||||
delete from ItemAudits where DTS < @dte
|
||||
delete from PartAudits where DTS < @dte
|
||||
delete from ROUsageAudits where DTS < @dte
|
||||
delete from TransitionAudits where DTS < @dte
|
||||
|
||||
RETURN
|
||||
END
|
||||
|
||||
IF (@@Error = 0) PRINT 'Procedure Creation: [vesp_PurgeChangeHistory] Succeeded'
|
||||
ELSE PRINT 'Procedure Creation: [vesp_PurgeChangeHistory] Error on Creation'
|
||||
GO
|
||||
|
||||
IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vesp_IndexMaintenance]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1)
|
||||
DROP PROCEDURE [vesp_IndexMaintenance];
|
||||
|
||||
GO
|
||||
|
||||
/****** Object: StoredProcedure [dbo].[vesp_IndexMaintenance] Script Date: 9/9/2025 7:54:42 AM ******/
|
||||
|
||||
-- =============================================
|
||||
-- Author: Matthew Schill
|
||||
-- Create date: 09/09/2025
|
||||
-- Description: Rebuild all indexes in the db
|
||||
-- =============================================
|
||||
CREATE PROCEDURE [dbo].[vesp_IndexMaintenance]
|
||||
With Execute as Owner
|
||||
AS
|
||||
BEGIN
|
||||
|
||||
Exec sp_msforeachtable 'SET QUOTED_IDENTIFIER ON; ALTER INDEX ALL ON ? REBUILD'
|
||||
|
||||
RETURN
|
||||
END
|
||||
|
||||
IF (@@Error = 0) PRINT 'Procedure Creation: [vesp_IndexMaintenance] Succeeded'
|
||||
ELSE PRINT 'Procedure Creation: [vesp_IndexMaintenance] Error on Creation'
|
||||
GO
|
||||
|
||||
IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vesp_GetOtherActiveSessions]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1)
|
||||
DROP PROCEDURE [vesp_GetOtherActiveSessions];
|
||||
|
||||
GO
|
||||
|
||||
/****** Object: StoredProcedure [dbo].[vesp_GetOtherActiveSessions] Script Date: 9/10/2025 7:54:42 AM ******/
|
||||
|
||||
-- =============================================
|
||||
-- Author: Matthew Schill
|
||||
-- Create date: 09/10/2025
|
||||
-- Description: Get active sessions by users other than the current user
|
||||
-- =============================================
|
||||
CREATE PROCEDURE [dbo].[vesp_GetOtherActiveSessions]
|
||||
(
|
||||
@UsrID AS varchar(100)
|
||||
)
|
||||
AS
|
||||
BEGIN
|
||||
|
||||
SELECT
|
||||
[UserID],
|
||||
[DTSDtart],
|
||||
[MachineName]
|
||||
FROM [Sessions]
|
||||
WHERE DTSEnd IS NULL AND UserID != @UsrID
|
||||
|
||||
RETURN
|
||||
END
|
||||
|
||||
IF (@@Error = 0) PRINT 'Procedure Creation: [vesp_GetOtherActiveSessions] Succeeded'
|
||||
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
|
||||
-- Need to drop vesp_GetROsNotUsed SP first so script can drop and recreate the TableValID table type
|
||||
IF EXISTS( SELECT * FROM INFORMATION_SCHEMA.DOMAINS WHERE Domain_Name = 'TableValID' )
|
||||
DROP TYPE [dbo].[TableValID]
|
||||
|
||||
CREATE TYPE [dbo].[TableValID] AS TABLE(
|
||||
[ID] [bigint] NOT NULL
|
||||
|
||||
)
|
||||
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]
|
||||
(
|
||||
@dbIDs AS dbo.TableValID READONLY
|
||||
)
|
||||
AS
|
||||
BEGIN
|
||||
|
||||
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)
|
||||
|
||||
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
|
||||
INNER JOIN @dbIDs dbIDs on dbIDs.ID = RofstChild.dbiID --downbase to only dbs included
|
||||
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
|
||||
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
|
||||
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
|
||||
INNER JOIN @dbIDs dbIDs on RofstDatabase.dbiID = dbIDs.ID --downbase to only dbs included
|
||||
|
||||
select *
|
||||
FROM #notused notused
|
||||
order by RofstChildID, dbID
|
||||
|
||||
drop table #notused
|
||||
|
||||
RETURN
|
||||
END
|
||||
|
||||
IF (@@Error = 0) PRINT 'Procedure Creation: [vesp_GetROsNotUsed] Succeeded'
|
||||
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) ON [PRIMARY]
|
||||
GO
|
||||
|
||||
PRINT 'Added IX_tblROUsagesRODbIDDeleteStatusROID Index. Speeds up RO queries'
|
||||
GO
|
||||
|
||||
/*
|
||||
---------------------------------------------------------------------------
|
||||
| ADD New Code Before this Block |
|
||||
@@ -24297,8 +24562,8 @@ BEGIN TRY -- Try Block
|
||||
DECLARE @RevDate varchar(255)
|
||||
DECLARE @RevDescription varchar(255)
|
||||
|
||||
set @RevDate = '09/05/2025 7:00 AM'
|
||||
set @RevDescription = 'Added stored procedure for User Access Control Report'
|
||||
set @RevDate = '01/19/2026 2:40 PM'
|
||||
set @RevDescription = 'Sync tree list Sort order between in RO Editor and PROMS'
|
||||
|
||||
Select cast(@RevDate as datetime) RevDate, @RevDescription RevDescription
|
||||
PRINT 'SQL Code Revision ' + @RevDate + ' - ' + @RevDescription
|
||||
|
||||
Reference in New Issue
Block a user