mirror of
https://github.com/helpsystems/EFTScriptSamples.git
synced 2025-07-02 13:42:01 -05:00
created folder structure
This commit is contained in:
Binary file not shown.
11
sql/7.4 purge with cascade deletes/ProlificUsers.sql
Normal file
11
sql/7.4 purge with cascade deletes/ProlificUsers.sql
Normal file
@ -0,0 +1,11 @@
|
||||
SELECT TOP 3 UserName, Count(*) As SuccessConnections
|
||||
FROM tbl_Authentications
|
||||
WHERE resultID = 0 AND protocol <> 'Administration' AND Time_stamp >= DATEADD(minute,-1440,GetDate())
|
||||
GROUP BY UserName
|
||||
ORDER BY SuccessConnections DESC
|
||||
|
||||
SELECT TOP 3 UserName, Count(*) As FailedConnections
|
||||
FROM tbl_Authentications
|
||||
WHERE resultID = 1 AND protocol <> 'Administration' AND Time_stamp >= DATEADD(minute,-1440,GetDate())
|
||||
GROUP BY UserName
|
||||
ORDER BY FailedConnections DESC
|
278
sql/7.4 purge with cascade deletes/PurgeSQLEFTData.sql
Normal file
278
sql/7.4 purge with cascade deletes/PurgeSQLEFTData.sql
Normal file
@ -0,0 +1,278 @@
|
||||
-- EFT Purging Script
|
||||
-- Goal: Allow customers to purge data from EFT's ARM database
|
||||
|
||||
--USAGE
|
||||
/*
|
||||
1. Run recreate_foreign_keys.sql next, as it will fix any problems if present (see notes in that script)
|
||||
2. Run index_foreign_keys_and_time_stamps.sql first, as that will improve purge performance
|
||||
3. Modify the purge date if desired. -30 means purge all records older than 30 days
|
||||
3a. To change: search for "SET @stopTime = DATEADD(DAY, -30, GETDATE())"
|
||||
3b. A value of -0 means ALL records
|
||||
3c. Alternatively, you can pass in an exact date range:
|
||||
3ci. Search for EXEC sp_PurgeEFTTransactions NULL, NULL, 1000000, 1
|
||||
3cii. Enter date and times in quotes as such: EXEC sp_PurgeEFTTransactions '2019-01-20 18:11:00', '2019-04-01 07:50:00', 1000000, 1
|
||||
4. Modify "USE EFTDB" below if your database name is different
|
||||
5. Make sure you database isn't actively recording data (disable ARM reporting in EFT temporarily)
|
||||
6. Execute the script (it can take several hours for databases with hundreds of millions of records)
|
||||
*/
|
||||
|
||||
-- Change Log:
|
||||
-- 0.1: Set batch size at 100,000
|
||||
-- Removed SELECT and extra PRINT statements.
|
||||
-- 0.2: Changed to purge up to records greater than 30 days old
|
||||
-- 0.3: Modified script to not assume cascading deletes and to
|
||||
-- explicitly delete from all tables
|
||||
-- Modified script to default 'purgesize' to 10,000
|
||||
-- instead of 1,000
|
||||
-- 0.4 Added AS2 and SAT purging
|
||||
-- 0.5 Subset table wasn't being dropped.
|
||||
-- 0.6 Changed to all static calls instead of dynamic.
|
||||
-- 0.7 Changed purge size to 1,000,000
|
||||
-- 0.8 Brought back cascade deletes to speed up performance
|
||||
|
||||
--USE EFTDB
|
||||
|
||||
-- Include minutes/seconds
|
||||
PRINT 'Script started at: ' + CONVERT(varchar(30),CURRENT_TIMESTAMP,109)
|
||||
-- PRINT 'Script started at: ' + CAST(CURRENT_TIMESTAMP AS NVARCHAR)
|
||||
-- USE EFTDB741315
|
||||
|
||||
-- This procedure will print the version of this script
|
||||
IF OBJECT_ID('dbo.sp_PurgeEFTTransactionsVersion') IS NOT NULL
|
||||
DROP PROC dbo.sp_PurgeEFTTransactionsVersion
|
||||
GO
|
||||
|
||||
CREATE PROCEDURE sp_PurgeEFTTransactionsVersion
|
||||
AS
|
||||
PRINT 'GlobalSCAPE, Inc. Purge Script Version 0.6'
|
||||
GO
|
||||
|
||||
-- This procedure will delete EFT transactions from a all tables.
|
||||
IF OBJECT_ID('dbo.sp_PurgeEFTTransactions') IS NOT NULL BEGIN
|
||||
DROP PROC dbo.sp_PurgeEFTTransactions
|
||||
END
|
||||
GO
|
||||
|
||||
-- By default, this procedure will purge data from 1970 to 60 days ago.
|
||||
CREATE PROCEDURE sp_PurgeEFTTransactions @startTime datetime = NULL,
|
||||
@stopTime datetime = NULL,
|
||||
@purgeSize int = NULL,
|
||||
@debug bit = 0
|
||||
AS
|
||||
BEGIN
|
||||
DECLARE @r INT;
|
||||
DECLARE @ErrMsg nvarchar(4000);
|
||||
DECLARE @ErrSeverity int;
|
||||
DECLARE @deletedTransactions TABLE(ParentTransactionID numeric(18,0));
|
||||
|
||||
EXEC sp_PurgeEFTTransactionsVersion
|
||||
|
||||
-- Delete tblTransactions records and sub-tables
|
||||
SET NOCOUNT ON
|
||||
|
||||
IF @startTime IS NULL BEGIN
|
||||
set @startTime = '19700101 00:00:00'
|
||||
END
|
||||
|
||||
IF @stopTime IS NULL BEGIN
|
||||
SET @stopTime = DATEADD(DAY, -60, GETDATE())
|
||||
END
|
||||
|
||||
IF @purgeSize IS NULL BEGIN
|
||||
set @purgeSize = 1000000
|
||||
END
|
||||
|
||||
-- Temporarily remove the ParentTransactionID -> TransactionID constraint
|
||||
ALTER TABLE tbl_Transactions DROP CONSTRAINT FK_tbl_Transactions_ParentTransID;
|
||||
|
||||
-- First, delete from tbl_Actions separately since potential circular cascade delete with tbl_EventRules
|
||||
IF @debug=1 PRINT 'Deleting from tbl_Actions: ' + CONVERT(varchar(30),CURRENT_TIMESTAMP,109);
|
||||
BEGIN TRY
|
||||
BEGIN TRANSACTION
|
||||
|
||||
-- Clear the temp table
|
||||
DELETE @deletedTransactions
|
||||
|
||||
-- First, drop constraint
|
||||
ALTER TABLE tbl_Actions DROP CONSTRAINT FK_tbl_Actions_TransID;
|
||||
|
||||
-- First delete the related transactions
|
||||
DELETE FROM tbl_Transactions
|
||||
OUTPUT deleted.ParentTransactionID INTO @deletedTransactions
|
||||
WHERE transactionID IN
|
||||
(SELECT transactionID FROM tbl_Actions WHERE Time_stamp BETWEEN @startTime AND @stopTime)
|
||||
-- Now delete the Actions
|
||||
DELETE FROM tbl_Actions WHERE Time_stamp BETWEEN @startTime AND @stopTime
|
||||
|
||||
-- Make sure no orphans remaining
|
||||
DELETE FROM tbl_Actions WHERE transactionID NOT IN
|
||||
(SELECT transactionID FROM tbl_Transactions);
|
||||
-- Now, add it back with cascade delete enabled
|
||||
ALTER TABLE tbl_Actions ADD CONSTRAINT FK_tbl_Actions_TransID
|
||||
FOREIGN KEY (TransactionID)
|
||||
REFERENCES tbl_Transactions (TransactionID)
|
||||
ON DELETE NO ACTION;
|
||||
|
||||
-- Delete any parent transactions
|
||||
DELETE FROM tbl_Transactions WHERE transactionID IN (SELECT ParentTransactionID FROM @deletedTransactions WHERE ParentTransactionID IS NOT NULL)
|
||||
|
||||
COMMIT TRANSACTION;
|
||||
|
||||
END TRY
|
||||
|
||||
BEGIN CATCH
|
||||
-- Whoops, there was an error
|
||||
IF @@TRANCOUNT > 0 ROLLBACK
|
||||
-- Raise an error with the details of the exception
|
||||
SELECT @ErrMsg = ERROR_MESSAGE(), @ErrSeverity = ERROR_SEVERITY()
|
||||
RAISERROR(@ErrMsg, @ErrSeverity, 1)
|
||||
END CATCH
|
||||
|
||||
BEGIN TRY
|
||||
|
||||
|
||||
SET @r = 1;
|
||||
WHILE @r > 0
|
||||
BEGIN
|
||||
IF @debug=1 PRINT 'Deleting from tbl_Transactions: ' + CONVERT(varchar(30),CURRENT_TIMESTAMP,109);
|
||||
BEGIN TRANSACTION
|
||||
|
||||
-- Clear the temp table
|
||||
DELETE @deletedTransactions
|
||||
|
||||
-- Delete from tbl_Transactions and cascade delete of multiple tables,
|
||||
-- copy deleted transactions' ParentTransactionIDs so can delete any parents after
|
||||
DELETE TOP (@purgeSize) FROM tbl_Transactions
|
||||
OUTPUT deleted.ParentTransactionID INTO @deletedTransactions
|
||||
WHERE
|
||||
-- See code above to delete tbl_Actions separately
|
||||
-- TransactionID IN (SELECT transactionID FROM tbl_Actions WHERE Time_stamp BETWEEN @startTime AND @stopTime) OR
|
||||
TransactionID IN (SELECT transactionID FROM tbl_AdminActions WHERE Timestamp BETWEEN @startTime AND @stopTime) OR
|
||||
TransactionID IN (SELECT transactionID FROM tbl_Authentications WHERE Time_stamp BETWEEN @startTime AND @stopTime) OR
|
||||
TransactionID IN (SELECT transactionID FROM tbl_ClientOperations WHERE Time_stamp BETWEEN @startTime AND @stopTime) OR
|
||||
TransactionID IN (SELECT transactionID FROM tbl_CustomCommands WHERE Time_stamp BETWEEN @startTime AND @stopTime) OR
|
||||
TransactionID IN (SELECT transactionID FROM tbl_EventRules WHERE Time_stamp BETWEEN @startTime AND @stopTime) OR
|
||||
-- EventRuleTransfers do not contain a time_stamp, but will cascade delete from Transactions
|
||||
-- TransactionID IN (SELECT transactionID FROM tbl_EventRuleTransfers WHERE Time_stamp BETWEEN @startTime AND @stopTime) OR
|
||||
TransactionID IN (SELECT transactionID FROM tbl_ProtocolCommands WHERE Time_stamp BETWEEN @startTime AND @stopTime) OR
|
||||
TransactionID IN (SELECT transactionID FROM tbl_SocketConnections WHERE Time_stamp BETWEEN @startTime AND @stopTime) OR
|
||||
TransactionID IN (SELECT transactionID FROM tbl_WorkspaceActions WHERE Time_stamp BETWEEN @startTime AND @stopTime)
|
||||
|
||||
SET @r = @@ROWCOUNT
|
||||
|
||||
-- Now delete the parents
|
||||
DELETE FROM tbl_Transactions WHERE transactionID IN (SELECT ParentTransactionID FROM @deletedTransactions WHERE ParentTransactionID IS NOT NULL)
|
||||
|
||||
COMMIT TRANSACTION;
|
||||
|
||||
DBCC SHRINKFILE (2) WITH NO_INFOMSGS; -- Truncate the log after each iteration to its original creation size
|
||||
END
|
||||
|
||||
END TRY
|
||||
|
||||
BEGIN CATCH
|
||||
-- Whoops, there was an error
|
||||
IF @@TRANCOUNT > 0 ROLLBACK
|
||||
-- Raise an error with the details of the exception
|
||||
SELECT @ErrMsg = ERROR_MESSAGE(), @ErrSeverity = ERROR_SEVERITY()
|
||||
RAISERROR(@ErrMsg, @ErrSeverity, 1)
|
||||
END CATCH
|
||||
|
||||
-- Delete SAT Transactions and sub-tables tbl_SAT_Files, tbl_SAT_Emails (Cascading Delete)
|
||||
IF @debug=1 PRINT 'Deleting from tbl_SAT_Transactions: ' + CONVERT(varchar(30),CURRENT_TIMESTAMP,109);
|
||||
BEGIN TRY
|
||||
BEGIN TRANSACTION
|
||||
|
||||
DELETE FROM tbl_SAT_Transactions
|
||||
WHERE time_stamp BETWEEN @startTime AND @stopTime
|
||||
|
||||
COMMIT TRANSACTION;
|
||||
|
||||
END TRY
|
||||
|
||||
BEGIN CATCH
|
||||
-- Whoops, there was an error
|
||||
IF @@TRANCOUNT > 0 ROLLBACK
|
||||
-- Raise an error with the details of the exception
|
||||
SELECT @ErrMsg = ERROR_MESSAGE(), @ErrSeverity = ERROR_SEVERITY()
|
||||
RAISERROR(@ErrMsg, @ErrSeverity, 1)
|
||||
END CATCH
|
||||
|
||||
-- Delete AS2 Transactions and sub-tables tbl_AS2Actions, tbl_AS2Files (non-Cascading Delete)
|
||||
IF @debug=1 PRINT 'Deleting from tbl_AS2Transactions: ' + CONVERT(varchar(30),CURRENT_TIMESTAMP,109);
|
||||
BEGIN TRY
|
||||
BEGIN TRANSACTION
|
||||
|
||||
-- First delete records in sub-tables
|
||||
-- tbl_AS2Actions
|
||||
DELETE FROM tbl_AS2Actions WHERE transactionID IN
|
||||
(SELECT transactionID FROM tbl_AS2Transactions
|
||||
WHERE CompleteTime BETWEEN @startTime AND @stopTime) OR
|
||||
FileID IN (SELECT FileID FROM tbl_AS2Files WHERE transactionID IN
|
||||
(SELECT transactionID FROM tbl_AS2Transactions
|
||||
WHERE CompleteTime BETWEEN @startTime AND @stopTime))
|
||||
-- tbl_AS2Files
|
||||
DELETE FROM tbl_AS2Files WHERE transactionID IN
|
||||
(SELECT transactionID FROM tbl_AS2Transactions
|
||||
WHERE CompleteTime BETWEEN @startTime AND @stopTime)
|
||||
-- tbl_AS2Transactions
|
||||
DELETE FROM tbl_AS2Transactions
|
||||
WHERE CompleteTime BETWEEN @startTime AND @stopTime
|
||||
|
||||
COMMIT TRANSACTION;
|
||||
|
||||
END TRY
|
||||
|
||||
BEGIN CATCH
|
||||
-- Whoops, there was an error
|
||||
IF @@TRANCOUNT > 0 ROLLBACK
|
||||
-- Raise an error with the details of the exception
|
||||
SELECT @ErrMsg = ERROR_MESSAGE(), @ErrSeverity = ERROR_SEVERITY()
|
||||
RAISERROR(@ErrMsg, @ErrSeverity, 1)
|
||||
END CATCH
|
||||
|
||||
-- Delete from remaining tables (stand-alone)
|
||||
/*
|
||||
IF @debug=1 PRINT 'Deleting from tbl_ScanDataActions, etc.: ' + CONVERT(varchar(30),CURRENT_TIMESTAMP,109);
|
||||
BEGIN TRY
|
||||
BEGIN TRANSACTION
|
||||
DELETE FROM tbl_ScanDataActions WHERE Time_stamp BETWEEN @startTime AND @stopTime
|
||||
DELETE FROM tbl_PrivacyTermsEUStatus WHERE Setdate BETWEEN @startTime AND @stopTime
|
||||
DELETE FROM tbl_PersonalDataActions WHERE Setdate BETWEEN @startTime AND @stopTime
|
||||
COMMIT TRANSACTION;
|
||||
END TRY
|
||||
BEGIN CATCH
|
||||
-- Whoops, there was an error
|
||||
IF @@TRANCOUNT > 0 ROLLBACK
|
||||
-- Raise an error with the details of the exception
|
||||
SELECT @ErrMsg = ERROR_MESSAGE(), @ErrSeverity = ERROR_SEVERITY()
|
||||
RAISERROR(@ErrMsg, @ErrSeverity, 1)
|
||||
END CATCH
|
||||
*/
|
||||
|
||||
-- Re-establish the ParentTransactionID -> TransactionID constraint
|
||||
-- Make sure no orphans remaining
|
||||
DELETE FROM tbl_Transactions WHERE ParentTransactionID IS NOT NULL AND ParentTransactionID NOT IN
|
||||
(SELECT transactionID FROM tbl_Transactions);
|
||||
-- Now, add it back without cascade delete enabled
|
||||
ALTER TABLE tbl_Transactions ADD CONSTRAINT FK_tbl_Transactions_ParentTransID
|
||||
FOREIGN KEY (ParentTransactionID)
|
||||
REFERENCES tbl_Transactions (TransactionID)
|
||||
ON DELETE NO ACTION;
|
||||
|
||||
DBCC SHRINKFILE (2) WITH NO_INFOMSGS; -- Truncate the log to its original creation size
|
||||
END
|
||||
GO
|
||||
|
||||
-- Using 1,000,000 batch for now. Creates larger log, but moves quicker.
|
||||
SET STATISTICS TIME OFF
|
||||
EXEC sp_PurgeEFTTransactions NULL, NULL, 10000000, 1
|
||||
SET STATISTICS TIME OFF
|
||||
|
||||
|
||||
PRINT ''
|
||||
-- PRINT 'Script completed at: ' + CAST(CURRENT_TIMESTAMP AS NVARCHAR)
|
||||
PRINT 'Script completed at: ' + CONVERT(varchar(30),CURRENT_TIMESTAMP,109)
|
||||
|
||||
|
||||
GO
|
20
sql/7.4 purge with cascade deletes/README.txt
Normal file
20
sql/7.4 purge with cascade deletes/README.txt
Normal file
@ -0,0 +1,20 @@
|
||||
|
||||
|
||||
1. Run recreate_foreign_keys.sql first, as it will fix any problems with FK associations if present (see notes in that script)
|
||||
|
||||
2. Run index_foreign_keys_and_time_stamps.sql next, as that will signficantly improve purge performance.
|
||||
|
||||
3. Open PurgeSQLEFTData.sql
|
||||
|
||||
3. Modify the purge date if desired. -30 means purge all records older than 30 days
|
||||
3a. To change: search for "SET @stopTime = DATEADD(DAY, -60, GETDATE())"
|
||||
3b. A value of -0 means ALL records
|
||||
3c. Alternatively, you can pass in an exact date range:
|
||||
3ci. Search for EXEC sp_PurgeEFTTransactions NULL, NULL, 1000000, 1
|
||||
3cii. Enter date and times in quotes as such: EXEC sp_PurgeEFTTransactions '2019-01-20 18:11:00', '2019-04-01 07:50:00', 1000000, 1
|
||||
|
||||
4. Modify "USE EFTDB" below if your database name is different
|
||||
|
||||
5. Make sure you database is NOT actively recording data (disable ARM reporting in EFT temporarily)
|
||||
|
||||
6. Execute the script (it may take several hours if your databases has hundreds of millions of records)
|
12
sql/7.4 purge with cascade deletes/RowCount.sql
Normal file
12
sql/7.4 purge with cascade deletes/RowCount.sql
Normal file
@ -0,0 +1,12 @@
|
||||
|
||||
declare @count int
|
||||
print 'Row counts before purge'
|
||||
select @count = count(*) from [dbo].[tbl_AdminActions] print 'tbl_AdminActions count = ' +CAST(@count AS NVARCHAR)
|
||||
select @count = count(*) from tbl_ProtocolCommands print 'tbl_ProtocolCommands count = ' +CAST(@count AS NVARCHAR)
|
||||
select @count = count(*) from tbl_Actions print 'tbl_Actions count = ' +CAST(@count AS NVARCHAR)
|
||||
select @count = count(*) from tbl_ClientOperations print 'tbl_ClientOperations count = ' +CAST(@count AS NVARCHAR)
|
||||
select @count = count(*) from tbl_SocketConnections print 'tbl_SocketConnections count = ' +CAST(@count AS NVARCHAR)
|
||||
select @count = count(*) from tbl_Authentications print 'tbl_Authentications count = ' +CAST(@count AS NVARCHAR)
|
||||
select @count = count(*) from tbl_CustomCommands print 'tbl_CustomCommands count = ' +CAST(@count AS NVARCHAR)
|
||||
select @count = count(*) from tbl_EventRules print 'tbl_EventRules count = ' +CAST(@count AS NVARCHAR)
|
||||
select @count = count(*) from tbl_Transactions print 'tbl_Transactions count = ' +CAST(@count AS NVARCHAR)
|
@ -0,0 +1,81 @@
|
||||
|
||||
IF NOT EXISTS (SELECT * FROM sys.indexes WHERE name = 'IX_tbl_Actions_TransactionID' AND object_id = OBJECT_ID('tbl_Actions'))
|
||||
CREATE NONCLUSTERED INDEX [IX_tbl_Actions_TransactionID] ON [tbl_Actions] ([TransactionID] ASC) WITH (IGNORE_DUP_KEY = OFF) ON [PRIMARY]
|
||||
GO
|
||||
IF NOT EXISTS (SELECT * FROM sys.indexes WHERE name = 'IX_tbl_AdminActions_TransactionID' AND object_id = OBJECT_ID('tbl_AdminActions'))
|
||||
CREATE NONCLUSTERED INDEX [IX_tbl_AdminActions_TransactionID] ON [tbl_AdminActions] ([TransactionID] ASC) WITH (IGNORE_DUP_KEY = OFF) ON [PRIMARY]
|
||||
GO
|
||||
IF NOT EXISTS (SELECT * FROM sys.indexes WHERE name = 'IX_tbl_AS2Actions_FileID' AND object_id = OBJECT_ID('tbl_AS2Actions'))
|
||||
CREATE NONCLUSTERED INDEX [IX_tbl_AS2Actions_FileID] ON [tbl_AS2Actions] ([FileID] ASC) WITH (IGNORE_DUP_KEY = OFF) ON [PRIMARY]
|
||||
GO
|
||||
IF NOT EXISTS (SELECT * FROM sys.indexes WHERE name = 'IX_tbl_AS2Actions_TransactionID' AND object_id = OBJECT_ID('tbl_AS2Actions'))
|
||||
CREATE NONCLUSTERED INDEX [IX_tbl_AS2Actions_TransactionID] ON [tbl_AS2Actions] ([TransactionID] ASC) WITH (IGNORE_DUP_KEY = OFF) ON [PRIMARY]
|
||||
GO
|
||||
IF NOT EXISTS (SELECT * FROM sys.indexes WHERE name = 'IX_tbl_AS2Files_TransactionID' AND object_id = OBJECT_ID('tbl_AS2Files'))
|
||||
CREATE NONCLUSTERED INDEX [IX_tbl_AS2Files_TransactionID] ON [tbl_AS2Files] ([TransactionID] ASC) WITH (IGNORE_DUP_KEY = OFF) ON [PRIMARY]
|
||||
GO
|
||||
IF NOT EXISTS (SELECT * FROM sys.indexes WHERE name = 'IX_tbl_CustomCommands_TransactionID' AND object_id = OBJECT_ID('tbl_CustomCommands'))
|
||||
CREATE NONCLUSTERED INDEX [IX_tbl_CustomCommands_TransactionID] ON [tbl_CustomCommands] ([TransactionID] ASC) WITH (IGNORE_DUP_KEY = OFF) ON [PRIMARY]
|
||||
GO
|
||||
IF NOT EXISTS (SELECT * FROM sys.indexes WHERE name = 'IX_tbl_Groups_AuthenticationID' AND object_id = OBJECT_ID('tbl_Groups'))
|
||||
CREATE NONCLUSTERED INDEX [IX_tbl_Groups_AuthenticationID] ON [tbl_Groups] ([AuthenticationID] ASC) WITH (IGNORE_DUP_KEY = OFF) ON [PRIMARY]
|
||||
GO
|
||||
IF NOT EXISTS (SELECT * FROM sys.indexes WHERE name = 'IX_tbl_ProtocolCommands_TransactionID' AND object_id = OBJECT_ID('tbl_ProtocolCommands'))
|
||||
CREATE NONCLUSTERED INDEX [IX_tbl_ProtocolCommands_TransactionID] ON [tbl_ProtocolCommands] ([TransactionID] ASC) WITH (IGNORE_DUP_KEY = OFF) ON [PRIMARY]
|
||||
GO
|
||||
IF NOT EXISTS (SELECT * FROM sys.indexes WHERE name = 'IX_tbl_SAT_Emails_txid' AND object_id = OBJECT_ID('tbl_SAT_Emails'))
|
||||
CREATE NONCLUSTERED INDEX [IX_tbl_SAT_Emails_txid] ON [tbl_SAT_Emails] ([txid] ASC) WITH (IGNORE_DUP_KEY = OFF) ON [PRIMARY]
|
||||
GO
|
||||
IF NOT EXISTS (SELECT * FROM sys.indexes WHERE name = 'IX_tbl_SAT_Files_txid' AND object_id = OBJECT_ID('tbl_SAT_Files'))
|
||||
CREATE NONCLUSTERED INDEX [IX_tbl_SAT_Files_txid] ON [tbl_SAT_Files] ([txid] ASC) WITH (IGNORE_DUP_KEY = OFF) ON [PRIMARY]
|
||||
GO
|
||||
IF NOT EXISTS (SELECT * FROM sys.indexes WHERE name = 'IX_tbl_SocketConnections_TransactionID' AND object_id = OBJECT_ID('tbl_SocketConnections'))
|
||||
CREATE NONCLUSTERED INDEX [IX_tbl_SocketConnections_TransactionID] ON [tbl_SocketConnections] ([TransactionID] ASC) WITH (IGNORE_DUP_KEY = OFF) ON [PRIMARY]
|
||||
GO
|
||||
IF NOT EXISTS (SELECT * FROM sys.indexes WHERE name = 'IX_tbl_Transactions_ParentTransactionID' AND object_id = OBJECT_ID('tbl_Transactions'))
|
||||
CREATE NONCLUSTERED INDEX [IX_tbl_Transactions_ParentTransactionID] ON [tbl_Transactions] ([ParentTransactionID] ASC) WITH (IGNORE_DUP_KEY = OFF) ON [PRIMARY]
|
||||
GO
|
||||
IF NOT EXISTS (SELECT * FROM sys.indexes WHERE name = 'IX_tbl_WorkspaceActions_TransactionID' AND object_id = OBJECT_ID('tbl_WorkspaceActions'))
|
||||
CREATE NONCLUSTERED INDEX [IX_tbl_WorkspaceActions_TransactionID] ON [tbl_WorkspaceActions] ([TransactionID] ASC) WITH (IGNORE_DUP_KEY = OFF) ON [PRIMARY]
|
||||
GO
|
||||
IF NOT EXISTS (SELECT * FROM sys.indexes WHERE name = 'IX_tbl_WorkspaceActions_TransactionID' AND object_id = OBJECT_ID('tbl_WorkspaceParticipants'))
|
||||
CREATE NONCLUSTERED INDEX [IX_tbl_WorkspaceActions_TransactionID] ON [tbl_WorkspaceParticipants] ([WorkspaceActionID] ASC) WITH (IGNORE_DUP_KEY = OFF) ON [PRIMARY]
|
||||
GO
|
||||
|
||||
-- Add indexes on time_stamps
|
||||
|
||||
-- tbl_SAT_Transactions
|
||||
IF NOT EXISTS (SELECT * FROM sys.indexes WHERE name = 'IX_tbl_SAT_Transactions_Time_Stamp' AND object_id = OBJECT_ID('tbl_SAT_Transactions'))
|
||||
CREATE NONCLUSTERED INDEX [IX_tbl_SAT_Transactions_Time_Stamp] ON [tbl_SAT_Transactions] ([time_stamp] ASC) WITH (IGNORE_DUP_KEY = OFF) ON [PRIMARY]
|
||||
GO
|
||||
|
||||
-- tbl_ProtocolCommands (index existed, but adding INCLUDE TransactionID)
|
||||
IF EXISTS (SELECT * FROM sys.indexes WHERE name = 'IX_tbl_ProtocolCommands_Time_stamp' AND object_id = OBJECT_ID('tbl_ProtocolCommands'))
|
||||
DROP INDEX [IX_tbl_ProtocolCommands_Time_stamp] ON [tbl_ProtocolCommands]
|
||||
GO
|
||||
CREATE NONCLUSTERED INDEX [IX_tbl_ProtocolCommands_Time_stamp] ON [tbl_ProtocolCommands] ([time_stamp]) INCLUDE ([TransactionID]) WITH (IGNORE_DUP_KEY = OFF) ON [PRIMARY]
|
||||
GO
|
||||
|
||||
-- tbl_SocketConnections (index existed, but adding INCLUDE TransactionID)
|
||||
IF EXISTS (SELECT * FROM sys.indexes WHERE name = 'IX_tbl_SocketConnections_Time_stamp' AND object_id = OBJECT_ID('tbl_SocketConnections'))
|
||||
DROP INDEX [IX_tbl_SocketConnections_Time_stamp] ON [tbl_SocketConnections]
|
||||
GO
|
||||
CREATE NONCLUSTERED INDEX [IX_tbl_SocketConnections_Time_stamp] ON [tbl_SocketConnections] ([Time_stamp]) INCLUDE ([TransactionID]) WITH (IGNORE_DUP_KEY = OFF) ON [PRIMARY]
|
||||
GO
|
||||
|
||||
-- tbl_Authentications (index existed, but adding Time_stamp)
|
||||
IF EXISTS (SELECT * FROM sys.indexes WHERE name = 'IX_tbl_Authentications_User_Name' AND object_id = OBJECT_ID('tbl_Authentications'))
|
||||
DROP INDEX [IX_tbl_Authentications_User_Name] ON [tbl_Authentications]
|
||||
GO
|
||||
CREATE NONCLUSTERED INDEX [IX_tbl_Authentications_User_Name] ON [tbl_Authentications] ([UserName],[Time_stamp]) INCLUDE ([TransactionID]) WITH (IGNORE_DUP_KEY = OFF) ON [PRIMARY]
|
||||
GO
|
||||
|
||||
-- tbl_ScanDataActions
|
||||
/*
|
||||
IF EXISTS (SELECT * FROM sys.indexes WHERE name = 'IX_tbl_ScanDataActions_Time_Stamp' AND object_id = OBJECT_ID('tbl_ScanDataActions'))
|
||||
DROP INDEX [IX_tbl_ScanDataActions_Time_Stamp] ON [tbl_ScanDataActions]
|
||||
GO
|
||||
CREATE NONCLUSTERED INDEX [IX_tbl_ScanDataActions_Time_Stamp] ON [tbl_ScanDataActions] ([Time_stamp]) INCLUDE ([ActionID]) WITH (IGNORE_DUP_KEY = OFF) ON [PRIMARY]
|
||||
GO
|
||||
*/
|
||||
|
275
sql/7.4 purge with cascade deletes/recreate_foreign_keys.sql
Normal file
275
sql/7.4 purge with cascade deletes/recreate_foreign_keys.sql
Normal file
@ -0,0 +1,275 @@
|
||||
-- recreate_foreign_keys.sql
|
||||
-- Delete orphan records for any cascade delete foreign key constraints
|
||||
-- 1. Test to see if any orphan records in sub-tables
|
||||
-- 2. If orphan records exist
|
||||
-- a. Drop the constraint between the table and parent table
|
||||
-- b. Delete the orphan records
|
||||
-- c. Recreate the constraint with the cascade delete
|
||||
|
||||
-- ****************************
|
||||
-- tbl_Transactions constraints
|
||||
-- ****************************
|
||||
|
||||
-- tbl_AdminActions
|
||||
-- IF EXISTS (SELECT * FROM tbl_AdminActions WHERE transactionID NOT IN (SELECT transactionID FROM tbl_Transactions))
|
||||
BEGIN
|
||||
-- Drop constraint
|
||||
ALTER TABLE tbl_AdminActions DROP CONSTRAINT FK_tbl_AdminActions_TransID;
|
||||
-- Make sure no orphans remaining
|
||||
DELETE FROM tbl_AdminActions WHERE transactionID NOT IN
|
||||
(SELECT transactionID FROM tbl_Transactions);
|
||||
-- Now, add it back with cascade delete enabled
|
||||
ALTER TABLE tbl_AdminActions ADD CONSTRAINT FK_tbl_AdminActions_TransID
|
||||
FOREIGN KEY (TransactionID)
|
||||
REFERENCES tbl_Transactions (TransactionID)
|
||||
ON DELETE CASCADE;
|
||||
END
|
||||
-- tbl_Authentications
|
||||
-- IF EXISTS (SELECT * FROM tbl_Authentications WHERE transactionID NOT IN (SELECT transactionID FROM tbl_Transactions))
|
||||
BEGIN
|
||||
-- Drop constraint
|
||||
ALTER TABLE tbl_Authentications DROP CONSTRAINT FK_tbl_Auth_TransID;
|
||||
-- Make sure no orphans remaining
|
||||
DELETE FROM tbl_Authentications WHERE transactionID NOT IN
|
||||
(SELECT transactionID FROM tbl_Transactions);
|
||||
-- Now, add it back with cascade delete enabled
|
||||
ALTER TABLE tbl_Authentications ADD CONSTRAINT FK_tbl_Auth_TransID
|
||||
FOREIGN KEY (TransactionID)
|
||||
REFERENCES tbl_Transactions (TransactionID)
|
||||
ON DELETE CASCADE;
|
||||
END
|
||||
-- tbl_ClientOperations
|
||||
-- IF EXISTS (SELECT * FROM tbl_ClientOperations WHERE transactionID NOT IN (SELECT transactionID FROM tbl_Transactions))
|
||||
BEGIN
|
||||
-- Drop constraint
|
||||
ALTER TABLE tbl_ClientOperations DROP CONSTRAINT FK_tbl_ClientOperations_TransID;
|
||||
-- Make sure no orphans remaining
|
||||
DELETE FROM tbl_ClientOperations WHERE transactionID NOT IN
|
||||
(SELECT transactionID FROM tbl_Transactions);
|
||||
-- Now, add it back with cascade delete enabled
|
||||
ALTER TABLE tbl_ClientOperations ADD CONSTRAINT FK_tbl_ClientOperations_TransID
|
||||
FOREIGN KEY (TransactionID)
|
||||
REFERENCES tbl_Transactions (TransactionID)
|
||||
ON DELETE CASCADE;
|
||||
END
|
||||
-- tbl_CustomCommands
|
||||
-- IF EXISTS (SELECT * FROM tbl_CustomCommands WHERE transactionID NOT IN (SELECT transactionID FROM tbl_Transactions))
|
||||
BEGIN
|
||||
-- Drop constraint
|
||||
ALTER TABLE tbl_CustomCommands DROP CONSTRAINT FK_tbl_CustomCommands_TransID;
|
||||
-- Make sure no orphans remaining
|
||||
DELETE FROM tbl_CustomCommands WHERE transactionID NOT IN
|
||||
(SELECT transactionID FROM tbl_Transactions);
|
||||
-- Now, add it back with cascade delete enabled
|
||||
ALTER TABLE tbl_CustomCommands ADD CONSTRAINT FK_tbl_CustomCommands_TransID
|
||||
FOREIGN KEY (TransactionID)
|
||||
REFERENCES tbl_Transactions (TransactionID)
|
||||
ON DELETE CASCADE;
|
||||
END
|
||||
-- tbl_EventRules
|
||||
-- IF EXISTS (SELECT * FROM tbl_EventRules WHERE transactionID NOT IN (SELECT transactionID FROM tbl_Transactions))
|
||||
BEGIN
|
||||
-- Drop constraint
|
||||
ALTER TABLE tbl_EventRules DROP CONSTRAINT FK_tbl_EventRules_TransID;
|
||||
-- Make sure no orphans remaining
|
||||
DELETE FROM tbl_EventRules WHERE transactionID NOT IN
|
||||
(SELECT transactionID FROM tbl_Transactions);
|
||||
-- Now, add it back with cascade delete enabled
|
||||
ALTER TABLE tbl_EventRules ADD CONSTRAINT FK_tbl_EventRules_TransID
|
||||
FOREIGN KEY (TransactionID)
|
||||
REFERENCES tbl_Transactions (TransactionID)
|
||||
ON DELETE CASCADE;
|
||||
END
|
||||
-- tbl_EventRuleTransfers
|
||||
/*
|
||||
-- IF EXISTS (SELECT * FROM tbl_EventRuleTransfers WHERE transactionID NOT IN (SELECT transactionID FROM tbl_Transactions))
|
||||
BEGIN
|
||||
-- Drop constraint
|
||||
ALTER TABLE tbl_EventRuleTransfers DROP CONSTRAINT FK_tbl_EventRuleTransfers_TransactionID;
|
||||
-- Make sure no orphans remaining
|
||||
DELETE FROM tbl_EventRuleTransfers WHERE transactionID NOT IN
|
||||
(SELECT transactionID FROM tbl_Transactions);
|
||||
-- Now, add it back with cascade delete enabled
|
||||
ALTER TABLE tbl_EventRuleTransfers ADD CONSTRAINT FK_tbl_EventRuleTransfers_TransactionID
|
||||
FOREIGN KEY (TransactionID)
|
||||
REFERENCES tbl_Transactions (TransactionID)
|
||||
ON DELETE CASCADE;
|
||||
END
|
||||
*/
|
||||
-- tbl_ProtocolCommands
|
||||
-- IF EXISTS (SELECT * FROM tbl_ProtocolCommands WHERE transactionID NOT IN (SELECT transactionID FROM tbl_Transactions))
|
||||
BEGIN
|
||||
-- Drop constraint
|
||||
ALTER TABLE tbl_ProtocolCommands DROP CONSTRAINT FK_tbl_ProtocolCommands_TransID;
|
||||
-- Make sure no orphans remaining
|
||||
DELETE FROM tbl_ProtocolCommands WHERE transactionID NOT IN
|
||||
(SELECT transactionID FROM tbl_Transactions);
|
||||
-- Now, add it back with cascade delete enabled
|
||||
ALTER TABLE tbl_ProtocolCommands ADD CONSTRAINT FK_tbl_ProtocolCommands_TransID
|
||||
FOREIGN KEY (TransactionID)
|
||||
REFERENCES tbl_Transactions (TransactionID)
|
||||
ON DELETE CASCADE;
|
||||
END
|
||||
-- tbl_SocketConnections
|
||||
-- IF EXISTS (SELECT * FROM tbl_SocketConnections WHERE transactionID NOT IN (SELECT transactionID FROM tbl_Transactions))
|
||||
BEGIN
|
||||
-- Drop constraint
|
||||
ALTER TABLE tbl_SocketConnections DROP CONSTRAINT FK_tbl_SocketConnections_TransID;
|
||||
-- Make sure no orphans remaining
|
||||
DELETE FROM tbl_SocketConnections WHERE transactionID NOT IN
|
||||
(SELECT transactionID FROM tbl_Transactions);
|
||||
-- Now, add it back with cascade delete enabled
|
||||
ALTER TABLE tbl_SocketConnections ADD CONSTRAINT FK_tbl_SocketConnections_TransID
|
||||
FOREIGN KEY (TransactionID)
|
||||
REFERENCES tbl_Transactions (TransactionID)
|
||||
ON DELETE CASCADE;
|
||||
END
|
||||
-- tbl_WorkspaceActions
|
||||
/*
|
||||
-- IF EXISTS (SELECT * FROM tbl_WorkspaceActions WHERE transactionID NOT IN (SELECT transactionID FROM tbl_Transactions))
|
||||
BEGIN
|
||||
-- Drop constraint
|
||||
ALTER TABLE tbl_WorkspaceActions DROP CONSTRAINT FK_tbl_WorkspaceActions_TransID;
|
||||
-- Make sure no orphans remaining
|
||||
DELETE FROM tbl_WorkspaceActions WHERE transactionID NOT IN
|
||||
(SELECT transactionID FROM tbl_Transactions);
|
||||
-- Now, add it back with cascade delete enabled
|
||||
ALTER TABLE tbl_WorkspaceActions ADD CONSTRAINT FK_tbl_WorkspaceActions_TransID
|
||||
FOREIGN KEY (TransactionID)
|
||||
REFERENCES tbl_Transactions (TransactionID)
|
||||
ON DELETE CASCADE;
|
||||
END
|
||||
*/
|
||||
-- *****************
|
||||
-- Other constraints
|
||||
-- *****************
|
||||
|
||||
-- tbl_ScanDataActions -> tbl_Actions
|
||||
/*
|
||||
IF EXISTS (SELECT * FROM tbl_ScanDataActions WHERE ActionID NOT IN
|
||||
(SELECT ActionID FROM tbl_Actions))
|
||||
BEGIN
|
||||
-- Drop constraint
|
||||
ALTER TABLE tbl_ScanDataActions DROP CONSTRAINT FK_tbl_ScanDataActions_ActionID;
|
||||
-- Make sure no orphans remaining
|
||||
DELETE FROM tbl_ScanDataActions WHERE ActionID NOT IN
|
||||
(SELECT ActionID FROM tbl_Actions);
|
||||
-- Now, add it back with cascade delete enabled
|
||||
ALTER TABLE tbl_ScanDataActions ADD CONSTRAINT FK_tbl_ScanDataActions_ActionID
|
||||
FOREIGN KEY (ActionID)
|
||||
REFERENCES tbl_Actions (ActionID)
|
||||
ON DELETE CASCADE;
|
||||
END
|
||||
*/
|
||||
-- tbl_Groups -> tbl_Authentications
|
||||
-- IF EXISTS (SELECT * FROM tbl_Groups WHERE AuthenticationID NOT IN (SELECT AuthenticationID FROM tbl_Authentications))
|
||||
BEGIN
|
||||
-- Drop constraint
|
||||
ALTER TABLE tbl_Groups DROP CONSTRAINT FK_tbl_Groups_AuthID;
|
||||
-- Make sure no orphans remaining
|
||||
DELETE FROM tbl_Groups WHERE AuthenticationID NOT IN
|
||||
(SELECT AuthenticationID FROM tbl_Authentications);
|
||||
-- Now, add it back with cascade delete enabled
|
||||
ALTER TABLE tbl_Groups ADD CONSTRAINT FK_tbl_Groups_AuthID
|
||||
FOREIGN KEY (AuthenticationID)
|
||||
REFERENCES tbl_Authentications (AuthenticationID)
|
||||
ON DELETE CASCADE;
|
||||
END
|
||||
-- tbl_Actions -> tbl_EventRules
|
||||
-- IF EXISTS (SELECT * FROM tbl_Actions WHERE EventID NOT IN (SELECT EventID FROM tbl_EventRules))
|
||||
BEGIN
|
||||
-- Drop constraint
|
||||
ALTER TABLE tbl_Actions DROP CONSTRAINT FK_tbl_Actions_EventId;
|
||||
-- Make sure no orphans remaining
|
||||
DELETE FROM tbl_Actions WHERE EventID NOT IN
|
||||
(SELECT EventID FROM tbl_EventRules);
|
||||
-- Now, add it back with cascade delete enabled
|
||||
ALTER TABLE tbl_Actions ADD CONSTRAINT FK_tbl_Actions_EventId
|
||||
FOREIGN KEY (EventID)
|
||||
REFERENCES tbl_EventRules (EventID)
|
||||
ON DELETE CASCADE;
|
||||
END
|
||||
-- tbl_Groups -> tbl_Authentications
|
||||
-- IF EXISTS (SELECT * FROM tbl_Groups WHERE AuthenticationID NOT IN (SELECT AuthenticationID FROM tbl_Authentications))
|
||||
BEGIN
|
||||
-- Drop constraint
|
||||
ALTER TABLE tbl_Groups DROP CONSTRAINT FK_tbl_Groups_AuthID;
|
||||
-- Make sure no orphans remaining
|
||||
DELETE FROM tbl_Groups WHERE AuthenticationID NOT IN
|
||||
(SELECT AuthenticationID FROM tbl_Authentications);
|
||||
-- Now, add it back with cascade delete enabled
|
||||
ALTER TABLE tbl_Groups ADD CONSTRAINT FK_tbl_Groups_AuthID
|
||||
FOREIGN KEY (AuthenticationID)
|
||||
REFERENCES tbl_Authentications (AuthenticationID)
|
||||
ON DELETE CASCADE;
|
||||
END
|
||||
-- tbl_SAT_Emails -> tbl_SAT_Transactions
|
||||
-- IF EXISTS (SELECT * FROM tbl_SAT_Emails WHERE txid NOT IN (SELECT ID FROM tbl_SAT_Transactions))
|
||||
BEGIN
|
||||
-- Drop constraint
|
||||
ALTER TABLE tbl_SAT_Emails DROP CONSTRAINT FK_tbl_SAT_Emails_TxID;
|
||||
-- Make sure no orphans remaining
|
||||
DELETE FROM tbl_SAT_Emails WHERE txid NOT IN
|
||||
(SELECT ID FROM tbl_SAT_Transactions);
|
||||
-- Now, add it back with cascade delete enabled
|
||||
ALTER TABLE tbl_SAT_Emails ADD CONSTRAINT FK_tbl_SAT_Emails_TxID
|
||||
FOREIGN KEY (txid)
|
||||
REFERENCES tbl_SAT_Transactions (ID)
|
||||
ON DELETE CASCADE;
|
||||
END
|
||||
-- tbl_SAT_Emails -> tbl_SAT_Transactions
|
||||
-- IF EXISTS (SELECT * FROM tbl_SAT_Emails WHERE txid NOT IN (SELECT ID FROM tbl_SAT_Transactions))
|
||||
BEGIN
|
||||
-- Drop constraint
|
||||
ALTER TABLE tbl_SAT_Emails DROP CONSTRAINT FK_tbl_SAT_Emails_TxID;
|
||||
-- Make sure no orphans remaining
|
||||
DELETE FROM tbl_SAT_Emails WHERE txid NOT IN
|
||||
(SELECT ID FROM tbl_SAT_Transactions);
|
||||
-- Now, add it back with cascade delete enabled
|
||||
ALTER TABLE tbl_SAT_Emails ADD CONSTRAINT FK_tbl_SAT_Emails_TxID
|
||||
FOREIGN KEY (txid)
|
||||
REFERENCES tbl_SAT_Transactions (ID)
|
||||
ON DELETE CASCADE;
|
||||
END
|
||||
-- tbl_SAT_Files -> tbl_SAT_Transactions
|
||||
-- IF EXISTS (SELECT * FROM tbl_SAT_Files WHERE txid NOT IN (SELECT ID FROM tbl_SAT_Transactions))
|
||||
BEGIN
|
||||
-- Drop constraint
|
||||
ALTER TABLE tbl_SAT_Files DROP CONSTRAINT FK_tbl_SAT_Files_TxID;
|
||||
-- Make sure no orphans remaining
|
||||
DELETE FROM tbl_SAT_Files WHERE txid NOT IN
|
||||
(SELECT ID FROM tbl_SAT_Transactions);
|
||||
-- Now, add it back with cascade delete enabled
|
||||
ALTER TABLE tbl_SAT_Files ADD CONSTRAINT FK_tbl_SAT_Files_TxID
|
||||
FOREIGN KEY (txid)
|
||||
REFERENCES tbl_SAT_Transactions (ID)
|
||||
ON DELETE CASCADE;
|
||||
END
|
||||
-- tbl_WorkspaceParticipants -> tbl_WorkspaceActions
|
||||
-- IF EXISTS (SELECT * FROM tbl_WorkspaceParticipants WHERE WorkspaceActionID NOT IN (SELECT ID FROM tbl_WorkspaceActions))
|
||||
/*
|
||||
BEGIN
|
||||
-- Drop constraint
|
||||
ALTER TABLE tbl_WorkspaceParticipants DROP CONSTRAINT FK_tbl_WorkspaceParticipants_WorkspaceActionID;
|
||||
-- Make sure no orphans remaining
|
||||
DELETE FROM tbl_WorkspaceParticipants WHERE WorkspaceActionID NOT IN
|
||||
(SELECT ID FROM tbl_WorkspaceActions);
|
||||
-- Now, add it back with cascade delete enabled
|
||||
ALTER TABLE tbl_WorkspaceParticipants ADD CONSTRAINT FK_tbl_WorkspaceParticipants_WorkspaceActionID
|
||||
FOREIGN KEY (WorkspaceActionID)
|
||||
REFERENCES tbl_WorkspaceActions (ID)
|
||||
ON DELETE CASCADE;
|
||||
END
|
||||
*/
|
||||
|
||||
-- Re-create FK constraint between ParentTransactionID and TransactionID
|
||||
-- Drop constraint
|
||||
ALTER TABLE tbl_Transactions DROP CONSTRAINT FK_tbl_Transactions_ParentTransID;
|
||||
-- Make sure no orphans remaining
|
||||
DELETE FROM tbl_Transactions WHERE ParentTransactionID IS NOT NULL AND ParentTransactionID NOT IN
|
||||
(SELECT transactionID FROM tbl_Transactions);
|
||||
-- Now, add it back without cascade delete enabled
|
||||
ALTER TABLE tbl_Transactions ADD CONSTRAINT FK_tbl_Transactions_ParentTransID
|
||||
FOREIGN KEY (ParentTransactionID)
|
||||
REFERENCES tbl_Transactions (TransactionID)
|
||||
ON DELETE NO ACTION;
|
@ -0,0 +1,295 @@
|
||||
-- recreate_foreign_keys.sql
|
||||
-- Delete orphan records for any cascade delete foreign key constraints
|
||||
-- 1. Test to see if any orphan records in sub-tables
|
||||
-- 2. If orphan records exist
|
||||
-- a. Drop the constraint between the table and parent table
|
||||
-- b. Delete the orphan records
|
||||
-- c. Recreate the constraint with the cascade delete
|
||||
|
||||
-- ****************************
|
||||
-- tbl_Transactions constraints
|
||||
-- ****************************
|
||||
|
||||
-- tbl_AdminActions
|
||||
-- IF EXISTS (SELECT * FROM tbl_AdminActions WHERE transactionID NOT IN (SELECT transactionID FROM tbl_Transactions))
|
||||
BEGIN
|
||||
-- Drop constraint
|
||||
IF EXISTS (SELECT * FROM sys.foreign_keys
|
||||
WHERE object_id = OBJECT_ID(N'FK_tbl_AdminActions_TransID') AND parent_object_id = OBJECT_ID(N'tbl_AdminActions'))
|
||||
ALTER TABLE tbl_AdminActions DROP CONSTRAINT FK_tbl_AdminActions_TransID;
|
||||
-- Make sure no orphans remaining
|
||||
DELETE FROM tbl_AdminActions WHERE transactionID NOT IN
|
||||
(SELECT transactionID FROM tbl_Transactions);
|
||||
-- Now, add it back with cascade delete enabled
|
||||
ALTER TABLE tbl_AdminActions ADD CONSTRAINT FK_tbl_AdminActions_TransID
|
||||
FOREIGN KEY (TransactionID)
|
||||
REFERENCES tbl_Transactions (TransactionID)
|
||||
ON DELETE CASCADE;
|
||||
END
|
||||
-- tbl_Authentications
|
||||
-- IF EXISTS (SELECT * FROM tbl_Authentications WHERE transactionID NOT IN (SELECT transactionID FROM tbl_Transactions))
|
||||
BEGIN
|
||||
-- Drop constraint
|
||||
IF EXISTS (SELECT * FROM sys.foreign_keys
|
||||
WHERE object_id = OBJECT_ID(N'FK_tbl_Auth_TransID') AND parent_object_id = OBJECT_ID(N'tbl_Authentications'))
|
||||
ALTER TABLE tbl_Authentications DROP CONSTRAINT FK_tbl_Auth_TransID;
|
||||
-- Make sure no orphans remaining
|
||||
DELETE FROM tbl_Authentications WHERE transactionID NOT IN
|
||||
(SELECT transactionID FROM tbl_Transactions);
|
||||
-- Now, add it back with cascade delete enabled
|
||||
ALTER TABLE tbl_Authentications ADD CONSTRAINT FK_tbl_Auth_TransID
|
||||
FOREIGN KEY (TransactionID)
|
||||
REFERENCES tbl_Transactions (TransactionID)
|
||||
ON DELETE CASCADE;
|
||||
END
|
||||
-- tbl_ClientOperations
|
||||
-- IF EXISTS (SELECT * FROM tbl_ClientOperations WHERE transactionID NOT IN (SELECT transactionID FROM tbl_Transactions))
|
||||
BEGIN
|
||||
-- Drop constraint
|
||||
IF EXISTS (SELECT * FROM sys.foreign_keys
|
||||
WHERE object_id = OBJECT_ID(N'FK_tbl_ClientOperations_TransID') AND parent_object_id = OBJECT_ID(N'tbl_ClientOperations'))
|
||||
ALTER TABLE tbl_ClientOperations DROP CONSTRAINT FK_tbl_ClientOperations_TransID;
|
||||
-- Make sure no orphans remaining
|
||||
DELETE FROM tbl_ClientOperations WHERE transactionID NOT IN
|
||||
(SELECT transactionID FROM tbl_Transactions);
|
||||
-- Now, add it back with cascade delete enabled
|
||||
ALTER TABLE tbl_ClientOperations ADD CONSTRAINT FK_tbl_ClientOperations_TransID
|
||||
FOREIGN KEY (TransactionID)
|
||||
REFERENCES tbl_Transactions (TransactionID)
|
||||
ON DELETE CASCADE;
|
||||
END
|
||||
-- tbl_CustomCommands
|
||||
-- IF EXISTS (SELECT * FROM tbl_CustomCommands WHERE transactionID NOT IN (SELECT transactionID FROM tbl_Transactions))
|
||||
BEGIN
|
||||
-- Drop constraint
|
||||
IF EXISTS (SELECT * FROM sys.foreign_keys
|
||||
WHERE object_id = OBJECT_ID(N'FK_tbl_CustomCommands_TransID') AND parent_object_id = OBJECT_ID(N'tbl_CustomCommands'))
|
||||
ALTER TABLE tbl_CustomCommands DROP CONSTRAINT FK_tbl_CustomCommands_TransID;
|
||||
-- Make sure no orphans remaining
|
||||
DELETE FROM tbl_CustomCommands WHERE transactionID NOT IN
|
||||
(SELECT transactionID FROM tbl_Transactions);
|
||||
-- Now, add it back with cascade delete enabled
|
||||
ALTER TABLE tbl_CustomCommands ADD CONSTRAINT FK_tbl_CustomCommands_TransID
|
||||
FOREIGN KEY (TransactionID)
|
||||
REFERENCES tbl_Transactions (TransactionID)
|
||||
ON DELETE CASCADE;
|
||||
END
|
||||
-- tbl_EventRules
|
||||
-- IF EXISTS (SELECT * FROM tbl_EventRules WHERE transactionID NOT IN (SELECT transactionID FROM tbl_Transactions))
|
||||
BEGIN
|
||||
-- Drop constraint
|
||||
IF EXISTS (SELECT * FROM sys.foreign_keys
|
||||
WHERE object_id = OBJECT_ID(N'FK_tbl_EventRules_TransID') AND parent_object_id = OBJECT_ID(N'tbl_EventRules'))
|
||||
ALTER TABLE tbl_EventRules DROP CONSTRAINT FK_tbl_EventRules_TransID;
|
||||
-- Make sure no orphans remaining
|
||||
DELETE FROM tbl_EventRules WHERE transactionID NOT IN
|
||||
(SELECT transactionID FROM tbl_Transactions);
|
||||
-- Now, add it back with cascade delete enabled
|
||||
ALTER TABLE tbl_EventRules ADD CONSTRAINT FK_tbl_EventRules_TransID
|
||||
FOREIGN KEY (TransactionID)
|
||||
REFERENCES tbl_Transactions (TransactionID)
|
||||
ON DELETE CASCADE;
|
||||
END
|
||||
-- tbl_EventRuleTransfers
|
||||
/*
|
||||
-- IF EXISTS (SELECT * FROM tbl_EventRuleTransfers WHERE transactionID NOT IN (SELECT transactionID FROM tbl_Transactions))
|
||||
BEGIN
|
||||
-- Drop constraint
|
||||
IF EXISTS (SELECT * FROM sys.foreign_keys
|
||||
WHERE object_id = OBJECT_ID(N'FK_tbl_EventRuleTransfers_TransactionID') AND parent_object_id = OBJECT_ID(N'tbl_EventRuleTransfers'))
|
||||
ALTER TABLE tbl_EventRuleTransfers DROP CONSTRAINT FK_tbl_EventRuleTransfers_TransactionID;
|
||||
-- Make sure no orphans remaining
|
||||
DELETE FROM tbl_EventRuleTransfers WHERE transactionID NOT IN
|
||||
(SELECT transactionID FROM tbl_Transactions);
|
||||
-- Now, add it back with cascade delete enabled
|
||||
ALTER TABLE tbl_EventRuleTransfers ADD CONSTRAINT FK_tbl_EventRuleTransfers_TransactionID
|
||||
FOREIGN KEY (TransactionID)
|
||||
REFERENCES tbl_Transactions (TransactionID)
|
||||
ON DELETE CASCADE;
|
||||
END
|
||||
*/
|
||||
-- tbl_ProtocolCommands
|
||||
-- IF EXISTS (SELECT * FROM tbl_ProtocolCommands WHERE transactionID NOT IN (SELECT transactionID FROM tbl_Transactions))
|
||||
BEGIN
|
||||
-- Drop constraint
|
||||
IF EXISTS (SELECT * FROM sys.foreign_keys
|
||||
WHERE object_id = OBJECT_ID(N'FK_tbl_ProtocolCommands_TransID') AND parent_object_id = OBJECT_ID(N'tbl_ProtocolCommands'))
|
||||
ALTER TABLE tbl_ProtocolCommands DROP CONSTRAINT FK_tbl_ProtocolCommands_TransID;
|
||||
-- Make sure no orphans remaining
|
||||
DELETE FROM tbl_ProtocolCommands WHERE transactionID NOT IN
|
||||
(SELECT transactionID FROM tbl_Transactions);
|
||||
-- Now, add it back with cascade delete enabled
|
||||
ALTER TABLE tbl_ProtocolCommands ADD CONSTRAINT FK_tbl_ProtocolCommands_TransID
|
||||
FOREIGN KEY (TransactionID)
|
||||
REFERENCES tbl_Transactions (TransactionID)
|
||||
ON DELETE CASCADE;
|
||||
END
|
||||
-- tbl_SocketConnections
|
||||
-- IF EXISTS (SELECT * FROM tbl_SocketConnections WHERE transactionID NOT IN (SELECT transactionID FROM tbl_Transactions))
|
||||
BEGIN
|
||||
-- Drop constraint
|
||||
IF EXISTS (SELECT * FROM sys.foreign_keys
|
||||
WHERE object_id = OBJECT_ID(N'FK_tbl_SocketConnections_TransID') AND parent_object_id = OBJECT_ID(N'tbl_SocketConnections'))
|
||||
ALTER TABLE tbl_SocketConnections DROP CONSTRAINT FK_tbl_SocketConnections_TransID;
|
||||
-- Make sure no orphans remaining
|
||||
DELETE FROM tbl_SocketConnections WHERE transactionID NOT IN
|
||||
(SELECT transactionID FROM tbl_Transactions);
|
||||
-- Now, add it back with cascade delete enabled
|
||||
ALTER TABLE tbl_SocketConnections ADD CONSTRAINT FK_tbl_SocketConnections_TransID
|
||||
FOREIGN KEY (TransactionID)
|
||||
REFERENCES tbl_Transactions (TransactionID)
|
||||
ON DELETE CASCADE;
|
||||
END
|
||||
-- tbl_WorkspaceActions
|
||||
/*
|
||||
-- IF EXISTS (SELECT * FROM tbl_WorkspaceActions WHERE transactionID NOT IN (SELECT transactionID FROM tbl_Transactions))
|
||||
BEGIN
|
||||
-- Drop constraint
|
||||
IF EXISTS (SELECT * FROM sys.foreign_keys
|
||||
WHERE object_id = OBJECT_ID(N'FK_tbl_WorkspaceActions_TransID') AND parent_object_id = OBJECT_ID(N'tbl_WorkspaceActions'))
|
||||
ALTER TABLE tbl_WorkspaceActions DROP CONSTRAINT FK_tbl_WorkspaceActions_TransID;
|
||||
-- Make sure no orphans remaining
|
||||
DELETE FROM tbl_WorkspaceActions WHERE transactionID NOT IN
|
||||
(SELECT transactionID FROM tbl_Transactions);
|
||||
-- Now, add it back with cascade delete enabled
|
||||
ALTER TABLE tbl_WorkspaceActions ADD CONSTRAINT FK_tbl_WorkspaceActions_TransID
|
||||
FOREIGN KEY (TransactionID)
|
||||
REFERENCES tbl_Transactions (TransactionID)
|
||||
ON DELETE CASCADE;
|
||||
END
|
||||
*/
|
||||
-- *****************
|
||||
-- Other constraints
|
||||
-- *****************
|
||||
|
||||
-- tbl_ScanDataActions -> tbl_Actions
|
||||
/*
|
||||
IF EXISTS (SELECT * FROM tbl_ScanDataActions WHERE ActionID NOT IN
|
||||
(SELECT ActionID FROM tbl_Actions))
|
||||
BEGIN
|
||||
-- Drop constraint
|
||||
IF EXISTS (SELECT * FROM sys.foreign_keys
|
||||
WHERE object_id = OBJECT_ID(N'FK_tbl_ScanDataActions_ActionID') AND parent_object_id = OBJECT_ID(N'tbl_ScanDataActions'))
|
||||
ALTER TABLE tbl_ScanDataActions DROP CONSTRAINT FK_tbl_ScanDataActions_ActionID;
|
||||
-- Make sure no orphans remaining
|
||||
DELETE FROM tbl_ScanDataActions WHERE ActionID NOT IN
|
||||
(SELECT ActionID FROM tbl_Actions);
|
||||
-- Now, add it back with cascade delete enabled
|
||||
ALTER TABLE tbl_ScanDataActions ADD CONSTRAINT FK_tbl_ScanDataActions_ActionID
|
||||
FOREIGN KEY (ActionID)
|
||||
REFERENCES tbl_Actions (ActionID)
|
||||
ON DELETE CASCADE;
|
||||
END
|
||||
*/
|
||||
-- tbl_Groups -> tbl_Authentications
|
||||
-- IF EXISTS (SELECT * FROM tbl_Groups WHERE AuthenticationID NOT IN (SELECT AuthenticationID FROM tbl_Authentications))
|
||||
BEGIN
|
||||
-- Drop constraint
|
||||
IF EXISTS (SELECT * FROM sys.foreign_keys
|
||||
WHERE object_id = OBJECT_ID(N'FK_tbl_Groups_AuthID') AND parent_object_id = OBJECT_ID(N'tbl_Groups'))
|
||||
ALTER TABLE tbl_Groups DROP CONSTRAINT FK_tbl_Groups_AuthID;
|
||||
-- Make sure no orphans remaining
|
||||
DELETE FROM tbl_Groups WHERE AuthenticationID NOT IN
|
||||
(SELECT AuthenticationID FROM tbl_Authentications);
|
||||
-- Now, add it back with cascade delete enabled
|
||||
ALTER TABLE tbl_Groups ADD CONSTRAINT FK_tbl_Groups_AuthID
|
||||
FOREIGN KEY (AuthenticationID)
|
||||
REFERENCES tbl_Authentications (AuthenticationID)
|
||||
ON DELETE CASCADE;
|
||||
END
|
||||
-- tbl_Actions -> tbl_EventRules
|
||||
-- IF EXISTS (SELECT * FROM tbl_Actions WHERE EventID NOT IN (SELECT EventID FROM tbl_EventRules))
|
||||
BEGIN
|
||||
-- Drop constraint
|
||||
IF EXISTS (SELECT * FROM sys.foreign_keys
|
||||
WHERE object_id = OBJECT_ID(N'FK_tbl_Actions_EventId') AND parent_object_id = OBJECT_ID(N'tbl_Actions'))
|
||||
ALTER TABLE tbl_Actions DROP CONSTRAINT FK_tbl_Actions_EventId;
|
||||
-- Make sure no orphans remaining
|
||||
DELETE FROM tbl_Actions WHERE EventID NOT IN
|
||||
(SELECT EventID FROM tbl_EventRules);
|
||||
-- Now, add it back with cascade delete enabled
|
||||
ALTER TABLE tbl_Actions ADD CONSTRAINT FK_tbl_Actions_EventId
|
||||
FOREIGN KEY (EventID)
|
||||
REFERENCES tbl_EventRules (EventID)
|
||||
ON DELETE CASCADE;
|
||||
END
|
||||
-- tbl_Groups -> tbl_Authentications
|
||||
-- IF EXISTS (SELECT * FROM tbl_Groups WHERE AuthenticationID NOT IN (SELECT AuthenticationID FROM tbl_Authentications))
|
||||
BEGIN
|
||||
-- Drop constraint
|
||||
IF EXISTS (SELECT * FROM sys.foreign_keys
|
||||
WHERE object_id = OBJECT_ID(N'FK_tbl_Groups_AuthID') AND parent_object_id = OBJECT_ID(N'tbl_Groups'))
|
||||
ALTER TABLE tbl_Groups DROP CONSTRAINT FK_tbl_Groups_AuthID;
|
||||
-- Make sure no orphans remaining
|
||||
DELETE FROM tbl_Groups WHERE AuthenticationID NOT IN
|
||||
(SELECT AuthenticationID FROM tbl_Authentications);
|
||||
-- Now, add it back with cascade delete enabled
|
||||
ALTER TABLE tbl_Groups ADD CONSTRAINT FK_tbl_Groups_AuthID
|
||||
FOREIGN KEY (AuthenticationID)
|
||||
REFERENCES tbl_Authentications (AuthenticationID)
|
||||
ON DELETE CASCADE;
|
||||
END
|
||||
-- tbl_SAT_Emails -> tbl_SAT_Transactions
|
||||
-- IF EXISTS (SELECT * FROM tbl_SAT_Emails WHERE txid NOT IN (SELECT ID FROM tbl_SAT_Transactions))
|
||||
BEGIN
|
||||
-- Drop constraint
|
||||
IF EXISTS (SELECT * FROM sys.foreign_keys
|
||||
WHERE object_id = OBJECT_ID(N'FK_tbl_SAT_Emails_TxID') AND parent_object_id = OBJECT_ID(N'tbl_SAT_Emails'))
|
||||
ALTER TABLE tbl_SAT_Emails DROP CONSTRAINT FK_tbl_SAT_Emails_TxID;
|
||||
-- Make sure no orphans remaining
|
||||
DELETE FROM tbl_SAT_Emails WHERE txid NOT IN
|
||||
(SELECT ID FROM tbl_SAT_Transactions);
|
||||
-- Now, add it back with cascade delete enabled
|
||||
ALTER TABLE tbl_SAT_Emails ADD CONSTRAINT FK_tbl_SAT_Emails_TxID
|
||||
FOREIGN KEY (txid)
|
||||
REFERENCES tbl_SAT_Transactions (ID)
|
||||
ON DELETE CASCADE;
|
||||
END
|
||||
-- tbl_SAT_Files -> tbl_SAT_Transactions
|
||||
-- IF EXISTS (SELECT * FROM tbl_SAT_Files WHERE txid NOT IN (SELECT ID FROM tbl_SAT_Transactions))
|
||||
BEGIN
|
||||
-- Drop constraint
|
||||
IF EXISTS (SELECT * FROM sys.foreign_keys
|
||||
WHERE object_id = OBJECT_ID(N'FK_tbl_SAT_Files_TxID') AND parent_object_id = OBJECT_ID(N'tbl_SAT_Files'))
|
||||
ALTER TABLE tbl_SAT_Files DROP CONSTRAINT FK_tbl_SAT_Files_TxID;
|
||||
-- Make sure no orphans remaining
|
||||
DELETE FROM tbl_SAT_Files WHERE txid NOT IN
|
||||
(SELECT ID FROM tbl_SAT_Transactions);
|
||||
-- Now, add it back with cascade delete enabled
|
||||
ALTER TABLE tbl_SAT_Files ADD CONSTRAINT FK_tbl_SAT_Files_TxID
|
||||
FOREIGN KEY (txid)
|
||||
REFERENCES tbl_SAT_Transactions (ID)
|
||||
ON DELETE CASCADE;
|
||||
END
|
||||
-- tbl_WorkspaceParticipants -> tbl_WorkspaceActions
|
||||
-- IF EXISTS (SELECT * FROM tbl_WorkspaceParticipants WHERE WorkspaceActionID NOT IN (SELECT ID FROM tbl_WorkspaceActions))
|
||||
/*
|
||||
BEGIN
|
||||
-- Drop constraint
|
||||
IF EXISTS (SELECT * FROM sys.foreign_keys
|
||||
WHERE object_id = OBJECT_ID(N'FK_tbl_WorkspaceParticipants_WorkspaceActionID') AND parent_object_id = OBJECT_ID(N'tbl_WorkspaceParticipants'))
|
||||
ALTER TABLE tbl_WorkspaceParticipants DROP CONSTRAINT FK_tbl_WorkspaceParticipants_WorkspaceActionID;
|
||||
-- Make sure no orphans remaining
|
||||
DELETE FROM tbl_WorkspaceParticipants WHERE WorkspaceActionID NOT IN
|
||||
(SELECT ID FROM tbl_WorkspaceActions);
|
||||
-- Now, add it back with cascade delete enabled
|
||||
ALTER TABLE tbl_WorkspaceParticipants ADD CONSTRAINT FK_tbl_WorkspaceParticipants_WorkspaceActionID
|
||||
FOREIGN KEY (WorkspaceActionID)
|
||||
REFERENCES tbl_WorkspaceActions (ID)
|
||||
ON DELETE CASCADE;
|
||||
END
|
||||
*/
|
||||
|
||||
-- Re-create FK constraint between ParentTransactionID and TransactionID
|
||||
-- Drop constraint
|
||||
IF EXISTS (SELECT * FROM sys.foreign_keys
|
||||
WHERE object_id = OBJECT_ID(N'FK_tbl_Transactions_ParentTransID') AND parent_object_id = OBJECT_ID(N'tbl_Transactions'))
|
||||
ALTER TABLE tbl_Transactions DROP CONSTRAINT FK_tbl_Transactions_ParentTransID;
|
||||
-- Make sure no orphans remaining
|
||||
DELETE FROM tbl_Transactions WHERE ParentTransactionID IS NOT NULL AND ParentTransactionID NOT IN
|
||||
(SELECT transactionID FROM tbl_Transactions);
|
||||
-- Now, add it back without cascade delete enabled
|
||||
ALTER TABLE tbl_Transactions ADD CONSTRAINT FK_tbl_Transactions_ParentTransID
|
||||
FOREIGN KEY (ParentTransactionID)
|
||||
REFERENCES tbl_Transactions (TransactionID)
|
||||
ON DELETE NO ACTION;
|
Reference in New Issue
Block a user