created folder structure

This commit is contained in:
2022-09-13 11:37:49 -05:00
commit 251dbfb0eb
112 changed files with 16067 additions and 0 deletions

View File

@ -0,0 +1,277 @@
-- EFT Purging Script
-- Goal: General script to purge data from EFT's ARM database by date
--USAGE
/*
1. Run index_foreign_keys_and_time_stamps.sql first, as that will improve purge performance
2. Run repair_foreign_keys.sql next, as it will fix any problems if present (see notes in that script)
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
PRINT CONVERT(varchar(30),CURRENT_TIMESTAMP, 8) + ' Script started'
-- 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.8'
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 tbl_Transactions records and sub-tables
SET NOCOUNT ON
IF @startTime IS NULL BEGIN
set @startTime = '1970-01-01'
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 CONVERT(varchar(30), CURRENT_TIMESTAMP, 8) + ' Deleting from tbl_Actions';
BEGIN TRY
BEGIN TRANSACTION
-- Clear the temp table
DELETE @deletedTransactions
-- 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);
-- 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
-- First, drop constraint
IF (OBJECT_ID('FK_tbl_OutlookReport_ParentTransID', 'F') IS NOT NULL)
BEGIN
ALTER TABLE tbl_OutlookReport DROP CONSTRAINT FK_tbl_OutlookReport_ParentTransID;
END
SET @r = 1;
WHILE @r > 0
BEGIN
IF @debug=1 PRINT CONVERT(varchar(30),CURRENT_TIMESTAMP, 8) + ' Deleting from tbl_Transactions';
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
-- Tables cascade deleted are:
-- tbl_AdminActions, tbl_Authentications, tbl_ClientOperations, tbl_CustomCommands, tbl_EventRules,
-- tbl_EventRuleTransfers, tbl_ProtocolCommands, tbl_SocketConnections, tbl_WorkspaceActions
DELETE TOP (@purgeSize) FROM tbl_Transactions
OUTPUT deleted.ParentTransactionID INTO @deletedTransactions
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
DELETE FROM dbo.tbl_OutlookReport WHERE TransactionID NOT IN (SELECT TransactionID FROM tbl_Transactions);
ALTER TABLE tbl_OutlookReport ADD CONSTRAINT FK_tbl_OutlookReport_ParentTransID
FOREIGN KEY(TransactionID)
REFERENCES tbl_Transactions (TransactionID)
ON DELETE NO ACTION;
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)
BEGIN TRY
IF @debug=1 PRINT CONVERT(varchar(30), CURRENT_TIMESTAMP, 8) + ' Deleting from tbl_SAT_Transactions';
BEGIN TRANSACTION
DELETE FROM tbl_SAT_Transactions
WHERE time_stamp BETWEEN @startTime AND @stopTime
COMMIT TRANSACTION;
IF @debug=1 PRINT CONVERT(varchar(30), CURRENT_TIMESTAMP, 8) + ' Deleting from tbl_AWESteps';
BEGIN TRANSACTION
DELETE FROM tbl_AWESteps
WHERE time_stamp BETWEEN @startTime AND @stopTime
COMMIT TRANSACTION;
IF @debug=1 PRINT CONVERT(varchar(30), CURRENT_TIMESTAMP, 8) + ' Deleting from tbl_PCIViolations';
BEGIN TRANSACTION
DELETE FROM tbl_PCIViolations
WHERE time_stamp BETWEEN @startTime AND @stopTime
COMMIT TRANSACTION;
IF @debug=1 PRINT CONVERT(varchar(30), CURRENT_TIMESTAMP, 8) + ' Deleting from tbl_ServerInternalEvents';
BEGIN TRANSACTION
DELETE FROM tbl_ServerInternalEvents
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-table tbl_AS2Actions (non-Cascading Delete)
IF @debug=1 PRINT CONVERT(varchar(30), CURRENT_TIMESTAMP, 8) + ' Deleting from tbl_AS2Transactions';
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)
-- 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 CONVERT(varchar(30), CURRENT_TIMESTAMP, 8) + ' Deleting from tbl_ScanDataActions, etc.';
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 10,000,000 batch for now. Creates larger log, but moves quicker.
SET STATISTICS TIME OFF
EXEC sp_PurgeEFTTransactions NULL, NULL, 10000000, 1
--EXEC sp_PurgeEFTTransactions '2018-01-01', '2018-12-31', 10000000, 1
SET STATISTICS TIME OFF
PRINT ''
PRINT CONVERT(varchar(30),CURRENT_TIMESTAMP, 8) + ' Script completed'
GO

View File

@ -0,0 +1,107 @@
-- EFT Purging script: tbl_Authentications
-- Goal: Purge tbl_Authentications table of garbage logon attempts using non-existing usernames.
-- USAGE
-- Config: By default, the script will search for user account authentications attempts using 'root' or 'administrator'
-- You can edit those terms or add your own by modifying the appropriate areas of this script (search for root or administrator)
-- You can also specify a start and end range or use NULL, NULL which will dafault to deleting records back 60 days
-- Change Log:
-- 0.1: Initial version
-- [NOTE: Added to upgrade_17.0.0.0-18.0.0.0 script to modify tbl_Authentications index IX_tbl_Authentications_User_Name to include Time_stamp]
PRINT CONVERT(varchar(30), CURRENT_TIMESTAMP, 8) + ' Script started'
-- USE EFTDB
-- This procedure will print the version of this script
IF OBJECT_ID('dbo.sp_PurgeEFT_AuthenticationsVersion') IS NOT NULL
DROP PROC dbo.sp_PurgeEFT_AuthenticationsVersion
GO
CREATE PROCEDURE sp_PurgeEFT_AuthenticationsVersion
AS
PRINT 'GlobalSCAPE, Inc. Purge Authentication Script Version 0.1'
GO
-- This procedure deletes Authentications based on username and date range
IF OBJECT_ID('dbo.sp_PurgeEFT_Authentications') IS NOT NULL
DROP PROC dbo.sp_PurgeEFT_Authentications
GO
CREATE PROCEDURE sp_PurgeEFT_Authentications
@startTime datetime = NULL,
@stopTime datetime = NULL,
@UserName nvarchar(50) = NULL,
@debug bit = 0
AS
EXEC dbo.sp_PurgeEFT_AuthenticationsVersion
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
-- Temporarily remove the ParentTransactionID -> TransactionID constraint
ALTER TABLE tbl_Transactions DROP CONSTRAINT FK_tbl_Transactions_ParentTransID;
BEGIN TRY
BEGIN TRANSACTION
IF @debug = 1 PRINT CONVERT(varchar(30), CURRENT_TIMESTAMP, 8) + ' Deleting transactions for authentications';
-- Deleting the transactions should cascade delete to other tables if any associated transactions exist
IF @UserName IS NULL -- Use default usernames
DELETE FROM tbl_Transactions WHERE TransactionID IN
(SELECT transactionID FROM tbl_Authentications WHERE (UserName = 'Administrator' OR UserName = 'root') AND Time_stamp BETWEEN @startTime AND @stopTime)
ELSE
DELETE FROM tbl_Transactions WHERE TransactionID IN
(SELECT transactionID FROM tbl_Authentications WHERE UserName = @UserName AND Time_stamp BETWEEN @startTime AND @stopTime)
-- Should be zero transactions to purge here, since cascade delete above should have handled them
IF @debug = 1 PRINT CONVERT(varchar(30), CURRENT_TIMESTAMP, 8) + ' Deleting rows from tbl_Authentications with UserNames: ' + ISNULL(@UserName, 'Adminitrator, root');
IF @UserName IS NULL -- Use default usernames
DELETE FROM tbl_Authentications WHERE (UserName = 'Administrator' OR UserName = 'root') AND Time_stamp BETWEEN @startTime AND @stopTime
ELSE
DELETE FROM tbl_Authentications WHERE UserName = @UserName AND Time_stamp BETWEEN @startTime AND @stopTime
COMMIT TRANSACTION
END TRY
BEGIN CATCH
-- If error, roll back
IF @@TRANCOUNT > 0
ROLLBACK
-- Raise an error with the details of the exception
DECLARE @ErrMsg nvarchar(4000),
@ErrSeverity int
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;
GO
EXEC sp_PurgeEFT_Authentications NULL, NULL, NULL, 1
-- EXEC sp_PurgeEFT_Authentications '2018-01-01', '2018-12-31', NULL, 1
PRINT ''
PRINT CONVERT(varchar(30), CURRENT_TIMESTAMP, 8) + ' Script completed'

View File

@ -0,0 +1,93 @@
-- EFT Purging Script - tbl_ProtocolCommands
-- Goal: Special script to purge internal transaction data from tbl_ProtocolCommands
-- USAGE
-- 1. Configure (bottom of script) then run.
-- to purge all ProtocolCommands with IsInternal = 1:
-- EXEC sp_PurgeEFT_ProtocolCommands NULL, NULL
-- to purge date range ProtocolCommands with IsInternal = 1 - e.g.:
-- EXEC sp_PurgeEFT_ProtocolCommands '2019-01-01', '2019-05-18'
--
-- leaving begin date as NULL will default to earliest date
-- leaving end date as NULL will default to current date
-- Change Log:
-- 0.1: Original version
-- USE EFTDB
-- This procedure will print the version of this script
IF OBJECT_ID('dbo.sp_PurgeEFT_ProtocolCommandsVersion') IS NOT NULL
DROP PROC dbo.sp_PurgeEFT_ProtocolCommandsVersion
GO
CREATE PROCEDURE sp_PurgeEFT_ProtocolCommandsVersion
AS
PRINT 'GlobalSCAPE, Inc. Purge Protocol Commands Script Version 0.1'
GO
-- This procedure will delete EFT transactions from a all tables.
IF OBJECT_ID('dbo.sp_PurgeEFT_ProtocolCommands') IS NOT NULL BEGIN
DROP PROC dbo.sp_PurgeEFT_ProtocolCommands
END
GO
-- By default, with no parameters, this procedure will purge all Protocol connections
CREATE PROCEDURE sp_PurgeEFT_ProtocolCommands
@startTime datetime = NULL,
@stopTime datetime = NULL,
@debug bit = 0
AS
BEGIN
DECLARE @ErrMsg nvarchar(4000);
DECLARE @ErrSeverity int;
EXEC dbo.sp_PurgeEFT_ProtocolCommandsVersion
SET NOCOUNT ON
IF @startTime IS NULL
BEGIN
SET @startTime = '1970-01-01 00:00:00'
END
IF @stopTime IS NULL
BEGIN
SET @stopTime = DATEADD(DAY, 1, GETDATE())
END
ELSE
BEGIN
SET @stopTime = DATEADD(DAY, 1, @stopTime) -- Add 1 to selected date to get all records before that
END
IF @debug=1 PRINT CONVERT(varchar(30), CURRENT_TIMESTAMP, 8) + ' Deleting from tbl_ProtocolCommands';
BEGIN TRY
DELETE FROM tbl_ProtocolCommands WHERE IsInternal=1 AND Time_stamp >= @startTime AND Time_stamp < @stopTime
END TRY
BEGIN CATCH
-- 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
DBCC SHRINKFILE (2) WITH NO_INFOMSGS; -- Truncate the log to its original creation size
IF @debug=1 PRINT CONVERT(varchar(30),CURRENT_TIMESTAMP, 8) + ' Done deleting from tbl_ProtocolCommands';
PRINT 'Procedure Complete'
END
GO
-- Default to purge entire table
-- SET STATISTICS TIME OFF
-- EXEC sp_PurgeEFT_ProtocolCommands NULL, NULL, 1
EXEC sp_PurgeEFT_ProtocolCommands '2018-01-01', '2018-12-31', 1
-- SET STATISTICS TIME OFF

View File

@ -0,0 +1,95 @@
-- EFT Purging Script - tbl_ProtocolCommands
-- Goal: Special script to purge data from tbl_ProtocolCommands with unimportant verbs
-- USAGE
-- 1. Run this script, then
-- to purge all ProtocolCommands which are not relevant to main operations (upload, download, rename, delete, mkd)
-- EXEC sp_PurgeEFT_ProtocolCommands NULL, NULL
-- to purge date range:
-- EXEC sp_PurgeEFT_ProtocolCommands '2019-01-01', '2019-05-18'
--
-- leaving begin date as NULL will default to earliest date
-- leaving end date as NULL will default to current date
-- Change Log:
-- 0.1: Original version
-- 0.2: Changed to remove based on certain commands. the is internal flag wasn't a sufficient qualifier.
-- USE EFTDB
-- This procedure will print the version of this script
IF OBJECT_ID('dbo.sp_PurgeEFT_ProtocolCommands2Version') IS NOT NULL
DROP PROC dbo.sp_PurgeEFT_ProtocolCommands2Version
GO
CREATE PROCEDURE sp_PurgeEFT_ProtocolCommands2Version
AS
PRINT 'GlobalSCAPE, Inc. Purge Protocol Commands Script 2 Version 0.2'
GO
-- This procedure will delete EFT transactions from a all tables.
IF OBJECT_ID('dbo.sp_PurgeEFT_ProtocolCommands2') IS NOT NULL BEGIN
DROP PROC dbo.sp_PurgeEFT_ProtocolCommands2
END
GO
-- By default, with no parameters, this procedure will purge all Protocol connections
CREATE PROCEDURE sp_PurgeEFT_ProtocolCommands2
@startTime datetime = NULL,
@stopTime datetime = NULL,
@debug bit = 0
AS
BEGIN
DECLARE @ErrMsg nvarchar(4000);
DECLARE @ErrSeverity int;
EXEC dbo.sp_PurgeEFT_ProtocolCommands2Version
SET NOCOUNT ON
IF @startTime IS NULL
BEGIN
SET @startTime = '1970-01-01 00:00:00'
END
IF @stopTime IS NULL
BEGIN
SET @stopTime = DATEADD(DAY, 1, GETDATE())
END
ELSE
BEGIN
SET @stopTime = DATEADD(DAY, 1, @stopTime) -- Add 1 to selected date to get all records before that
END
IF @debug=1 PRINT CONVERT(varchar(30), CURRENT_TIMESTAMP, 8) + ' Deleting from tbl_ProtocolCommands';
BEGIN TRY
DELETE FROM tbl_ProtocolCommands
WHERE Time_stamp >= @startTime AND Time_stamp < @stopTime AND
Command NOT IN ('sent', 'created', 'mkd', 'rmd', 'dele', 'rnfr', 'rnto', 'DELETE', 'retr', 'POST', 'patch', 'copy')
END TRY
BEGIN CATCH
-- 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
DBCC SHRINKFILE (2) WITH NO_INFOMSGS; -- Truncate the log to its original creation size
IF @debug=1 PRINT CONVERT(varchar(30),CURRENT_TIMESTAMP, 8) + ' Done deleting from tbl_ProtocolCommands';
PRINT 'Procedure Complete'
END
GO
SET STATISTICS TIME OFF
/* EXEC sp_PurgeEFT_ProtocolCommands2 NULL, NULL -- Default to purge entire table */
EXEC sp_PurgeEFT_ProtocolCommands2 '2018-01-01', '2018-12-31', 1

View File

@ -0,0 +1,119 @@
-- EFT Purging Script - tbl_SocketConnections
-- Goal: Special script to purge data from tbl_SocketConnections by date
-- USAGE
-- 1. Configure the purge (bottom of script)
-- To perform a complete purge, just run the command at the bottom of the script: EXEC sp_PurgeEFT_SocketConnections NULL, NULL, NULL
-- If you want to purge a specific date range, then specify a start and end date: EXEC sp_PurgeEFT_SocketConnections '2019-01-01', '2019-05-18', NULL
-- If you want to purge a specific error code, for example error code 0: EXEC sp_PurgeEFT_SocketConnections '2019-01-01', '2019-05-18', 0
-- Note: Leaving begin date as NULL will default to earliest date.
-- Leaving end date as NULL will default to current date.
-- Leaving errorCode as NULL will purge all error codes.
-- Change Log:
-- 0.1: Original version
-- 0.2: Updated comments
-- USE EFTDB
-- This procedure will print the version of this script
IF OBJECT_ID('dbo.sp_PurgeEFT_SocketConnectionsVersion') IS NOT NULL
DROP PROC dbo.sp_PurgeEFT_SocketConnectionsVersion
GO
CREATE PROCEDURE sp_PurgeEFT_SocketConnectionsVersion
AS
PRINT 'GlobalSCAPE, Inc. Purge Script Version 0.2'
GO
-- This procedure will delete EFT transactions from a all tables.
IF OBJECT_ID('dbo.sp_PurgeEFT_SocketConnections') IS NOT NULL BEGIN
DROP PROC dbo.sp_PurgeEFT_SocketConnections
END
GO
-- By default, with no parameters, this procedure will purge all socket connections
CREATE PROCEDURE sp_PurgeEFT_SocketConnections
@startTime datetime = NULL,
@stopTime datetime = NULL,
@errorCode int = NULL,
@debug bit = 0
AS
BEGIN
DECLARE @ErrMsg nvarchar(4000);
DECLARE @ErrSeverity int;
EXEC dbo.sp_PurgeEFT_SocketConnectionsVersion
SET NOCOUNT ON
IF @startTime IS NULL AND @stopTime IS NULL AND @errorCode IS NULL
BEGIN
--This will remove everything, regardless of ResultID code
TRUNCATE TABLE tbl_SocketConnections
END
ELSE
BEGIN
IF @startTime IS NULL
BEGIN
SET @startTime = '1970-01-01 00:00:00'
END
IF @stopTime IS NULL
BEGIN
SET @stopTime = DATEADD(DAY, 1, GETDATE())
END
ELSE
BEGIN
SET @stopTime = DATEADD(DAY, 1, @stopTime)
END
IF @debug=1 PRINT CONVERT(varchar(30),CURRENT_TIMESTAMP, 8) + ' Deleting from tbl_SocketConnections';
BEGIN TRY
IF @errorCode IS NULL
BEGIN
DELETE FROM tbl_SocketConnections WHERE Time_stamp >= @startTime AND Time_stamp < @stopTime
END
ELSE
BEGIN
DELETE FROM tbl_SocketConnections WHERE Time_stamp >= @startTime AND Time_stamp < @stopTime AND ResultID = @errorCode
END
END TRY
BEGIN CATCH
-- 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
DBCC SHRINKFILE (2) WITH NO_INFOMSGS; -- Truncate the log to its original creation size
IF @debug=1 PRINT CONVERT(varchar(30),CURRENT_TIMESTAMP, 8) + ' Done deleting from tbl_SocketConnections';
END
PRINT 'Procedure Complete'
END
GO
-- sp_PurgeEFT_SocketConnections parameters
--
-- startTime: set the time to purge from. If set to NULL it will default to January 1970.
-- stopTime : set the time to purge to. If set to NULL it will default to todays date.
-- errorCode: set the resultID to purge. If set to NULL it will purge all resultIDs.
-- The errorCodes are as follows:
-- - TOO_MANY_CONNECTIONS_PER_SITE = 8
-- - TOO_MANY_CONNECTIONS_PER_IP = 9
-- - RESTRICTED_IP = 10
-- - BANNED_IP = 11
-- - EFT_IN_DEV_MODE = 12
-- - INTERNAL_SERVER_ERROR = 13
-- - OK = 0
-- Default to purge entire table
-- SET STATISTICS TIME OFF
EXEC sp_PurgeEFT_SocketConnections NULL, NULL, NULL, 1
-- EXEC sp_PurgeEFT_SocketConnections '2018-01-01', '2018-12-31', NULL, 1
-- SET STATISTICS TIME OFF

View File

@ -0,0 +1,34 @@
/*
WHAT:
Detects superfluous indexes
WHY:
These can hurt performance, since the DB must update them during Inserts, Updates and Deletes. And if theyre never used, then thats a waste of resources.
WHEN:
Created in April of 2019
WHO:
Created by Globalscape, Inc.
HOW:
Its best run on one of the larger, well-used databases, since it then has more info to work with. Otherwise stats won't be available to determine whether indexes are unused or not. Indexes that are identified as seldom used should be deleted by your db admin.
*/
SELECT TOP 10 o.name AS TableName, i.name AS IndexName, u.user_seeks As Seeks, u.user_scans As Scans, u.user_lookups As Lookups,
u.user_updates As UserUpdates, u.last_user_seek As LastUserSeek, u.last_user_scan As LastUserScan,
(SELECT SUM(s.[used_page_count]) * 8 FROM sys.dm_db_partition_stats s WHERE s.[object_id] = i.[object_id] AND s.[index_id] = i.[index_id]) As IndexSizeKB,
'Drop index ' + i.name + ' on ' + o.name as DropIndexStatement
FROM sys.indexes i
JOIN sys.objects o ON i.object_id = o.object_id
LEFT JOIN sys.dm_db_index_usage_stats u ON i.object_id = u.object_id
AND i.index_id = u.index_id
AND u.database_id = DB_ID()
WHERE o.type <> 'S'
and isnull(u.user_updates,0) > 0
and i.type_desc <> 'HEAP'
and i.type_desc <> 'CLUSTERED'
and u.user_seeks < 5 and u.user_scans < 5 and u.user_lookups < 5
ORDER BY IndexSizeKB DESC, UserUpdates DESC

View File

@ -0,0 +1,98 @@
/*
WHAT:
Records the number of rows in each table
WHY:
Can be useful to count rows before and after a purge.
WHEN:
Created in April of 2019
WHO:
Created by Globalscape, Inc.
HOW:
Row count can take several minutes depending on the size of the database
*/
declare @count int
select @count = count(*) from tbl_Actions
print 'tbl_Actions count = ' +CAST(@count AS NVARCHAR)
select @count = count(*) from tbl_AdminActions
print 'tbl_AdminActions count = ' +CAST(@count AS NVARCHAR)
select @count = count(*) from tbl_AS2Actions
print 'tbl_AS2Actions count = ' +CAST(@count AS NVARCHAR)
select @count = count(*) from tbl_AS2Transactions
print 'tbl_AS2Transactions count = ' +CAST(@count AS NVARCHAR)
select @count = count(*) from tbl_Authentications
print 'tbl_Authentications count = ' +CAST(@count AS NVARCHAR)
select @count = count(*) from tbl_AuthenticationsExpired
print 'tbl_AuthenticationsExpired count = ' +CAST(@count AS NVARCHAR)
select @count = count(*) from tbl_AWESteps
print 'tbl_AWESteps count = ' +CAST(@count AS NVARCHAR)
select @count = count(*) from tbl_ClientOperations
print 'tbl_ClientOperations 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_EventRuleTransfers
print 'tbl_EventRuleTransfers count = ' +CAST(@count AS NVARCHAR)
select @count = count(*) from tbl_Groups
print 'tbl_Groups count = ' +CAST(@count AS NVARCHAR)
select @count = count(*) from tbl_NegotiatedCiphersSSH
print 'tbl_NegotiatedCiphersSSH count = ' +CAST(@count AS NVARCHAR)
select @count = count(*) from tbl_NegotiatedCiphersSSL
print 'tbl_NegotiatedCiphersSSL count = ' +CAST(@count AS NVARCHAR)
select @count = count(*) from tbl_OutlookReport
print 'tbl_OutlookReport count = ' +CAST(@count AS NVARCHAR)
select @count = count(*) from tbl_PCIViolations
print 'tbl_PCIViolations count = ' +CAST(@count AS NVARCHAR)
select @count = count(*) from tbl_PersonalDataActions
print 'tbl_PersonalDataActions count = ' +CAST(@count AS NVARCHAR)
select @count = count(*) from tbl_PrivacyTermsEUStatus
print 'tbl_PrivacyTermsEUStatus count = ' +CAST(@count AS NVARCHAR)
select @count = count(*) from tbl_ProtocolCommands
print 'tbl_ProtocolCommands count = ' +CAST(@count AS NVARCHAR)
select @count = count(*) from tbl_PrivacyRightExercised
print 'tbl_PrivacyRightExercised count = ' +CAST(@count AS NVARCHAR)
select @count = count(*) from tbl_ScanDataActions
print 'tbl_ScanDataActions count = ' +CAST(@count AS NVARCHAR)
select @count = count(*) from tbl_ServerInternalEvents
print 'tbl_ServerInternalEvents count = ' +CAST(@count AS NVARCHAR)
select @count = count(*) from tbl_SocketConnections
print 'tbl_SocketConnections count = ' +CAST(@count AS NVARCHAR)
select @count = count(*) from tbl_Transactions
print 'tbl_Transactions count = ' +CAST(@count AS NVARCHAR)
select @count = count(*) from tbl_WorkspaceActions
print 'tbl_WorkspaceActions count = ' +CAST(@count AS NVARCHAR)
select @count = count(*) from tbl_WorkspaceParticipants
print 'tbl_WorkspaceParticipants count = ' +CAST(@count AS NVARCHAR)

View File

@ -0,0 +1,75 @@
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_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_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
*/

View File

@ -0,0 +1,295 @@
-- repair_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;

View File

@ -0,0 +1,156 @@
-- For reports Activity-AS2 Transfers (Detailed) and Activity-AS2 Transfers (Summary)
IF EXISTS (SELECT * FROM sys.indexes WHERE name = 'IX_tbl_AS2Transactions_StartTime' AND object_id = OBJECT_ID('tbl_AS2Transactions'))
DROP INDEX IX_tbl_AS2Transactions_StartTime ON tbl_AS2Transactions
GO
CREATE INDEX IX_tbl_AS2Transactions_StartTime ON tbl_AS2Transactions (StartTime)
GO
UPDATE STATISTICS tbl_AS2Transactions;
GO
-- For reports Activity-by Permissions Group, Activity-by Users (Detailed),
-- Activity-by Users (Summary), Exec Summary, Traffic-Average Transfer Rates by User,
-- WebServiceInvokeEventRules-Activity(Detailed)
-- Remove IX_tbl_ProtocolCommands_Time_stamp since won't be necessary
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
IF EXISTS (SELECT * FROM sys.indexes WHERE name = 'IX_tbl_ProtocolCommands_Time_stamp_Command_FileName' AND object_id = OBJECT_ID('tbl_ProtocolCommands'))
DROP INDEX IX_tbl_ProtocolCommands_Time_stamp_Command_FileName ON tbl_ProtocolCommands
GO
CREATE INDEX IX_tbl_ProtocolCommands_Time_stamp_Command_FileName ON tbl_ProtocolCommands (Time_stamp, Command, FileName)
GO
UPDATE STATISTICS tbl_ProtocolCommands;
GO
-- For reports Traffic - Connections Summary, Traffic-Datewise-hourly Bytes Transferred,
-- Traffic-Datewise-IPwiseBytesTransferred, Traffic-Monthwise-IPWise Bytes Transferred,
-- Traffic-Protocolwise Connections
-- Remove IX_tbl_ProtocolCommands_Site_Name since won't be necessary
IF EXISTS (SELECT * FROM sys.indexes WHERE name = 'IX_tbl_ProtocolCommands_Site_Name' AND object_id = OBJECT_ID('tbl_ProtocolCommands'))
DROP INDEX IX_tbl_ProtocolCommands_Site_Name ON tbl_ProtocolCommands
GO
IF EXISTS (SELECT * FROM sys.indexes WHERE name = 'IX_tbl_ProtocolCommands_Site_Name_Time_stamp' AND object_id = OBJECT_ID('tbl_ProtocolCommands'))
DROP INDEX IX_tbl_ProtocolCommands_Site_Name_Time_stamp ON tbl_ProtocolCommands
GO
CREATE INDEX IX_tbl_ProtocolCommands_Site_Name_Time_stamp ON tbl_ProtocolCommands (SiteName, Time_stamp)
GO
UPDATE STATISTICS tbl_ProtocolCommands;
GO
-- For reports Traffic-Most Active IP Connections, Traffic-Most Active IP - Data Transferred
-- Remove IX_tbl_ProtocolCommands_TransactionID since won't be necessary
IF EXISTS (SELECT * FROM sys.indexes WHERE name = 'IX_tbl_ProtocolCommands_TransactionID' AND object_id = OBJECT_ID('tbl_ProtocolCommands'))
DROP INDEX IX_tbl_ProtocolCommands_TransactionID ON tbl_ProtocolCommands
GO
IF EXISTS (SELECT * FROM sys.indexes WHERE name = 'IX_tbl_ProtocolCommands_TransactionID_Time_Stamp_ResultID' AND object_id = OBJECT_ID('tbl_ProtocolCommands'))
DROP INDEX IX_tbl_ProtocolCommands_TransactionID_Time_Stamp_ResultID ON tbl_ProtocolCommands
GO
CREATE INDEX IX_tbl_ProtocolCommands_TransactionID_Time_Stamp_ResultID ON tbl_ProtocolCommands (TransactionID, Time_stamp, ResultID)
GO
UPDATE STATISTICS tbl_ProtocolCommands;
GO
-- For Admin-Audit Log
IF EXISTS (SELECT * FROM sys.indexes WHERE name = 'IX_tbl_AdminActions_Time_stamp' AND object_id = OBJECT_ID('tbl_AdminActions'))
DROP INDEX IX_tbl_AdminActions_Time_stamp ON tbl_AdminActions
GO
CREATE INDEX IX_tbl_AdminActions_Time_stamp ON tbl_AdminActions (Timestamp)
GO
UPDATE STATISTICS tbl_AdminActions;
GO
-- For Admin-Authentications
-- Remove IX_tbl_Authentications_Time_stamp since won't be necessary
IF EXISTS (SELECT * FROM sys.indexes WHERE name = 'IX_tbl_Authentications_Time_stamp' AND object_id = OBJECT_ID('tbl_Authentications'))
DROP INDEX IX_tbl_Authentications_Time_stamp ON tbl_Authentications
GO
IF EXISTS (SELECT * FROM sys.indexes WHERE name = 'IX_tbl_Authentications_Time_stamp_Protocol' AND object_id = OBJECT_ID('tbl_Authentications'))
DROP INDEX IX_tbl_Authentications_Time_stamp_Protocol ON tbl_Authentications
GO
CREATE INDEX IX_tbl_Authentications_Time_stamp_Protocol ON tbl_Authentications (Time_stamp, Protocol)
GO
UPDATE STATISTICS tbl_Authentications;
GO
-- For Troubleshooting-Failed Logins
-- Remove IX_tbl_Authentications_Time_stamp since won't be necessary
IF EXISTS (SELECT * FROM sys.indexes WHERE name = 'IX_tbl_Authentications_Time_stamp' AND object_id = OBJECT_ID('tbl_Authentications'))
DROP INDEX IX_tbl_Authentications_Time_stamp ON tbl_Authentications
GO
IF EXISTS (SELECT * FROM sys.indexes WHERE name = 'IX_tbl_Authentications_Time_stamp_SiteName_ResultID' AND object_id = OBJECT_ID('tbl_Authentications'))
DROP INDEX IX_tbl_Authentications_Time_stamp_SiteName_ResultID ON tbl_Authentications
GO
CREATE INDEX IX_tbl_Authentications_Time_stamp_SiteName_ResultID ON tbl_Authentications (Time_stamp, SiteName, ResultID)
GO
UPDATE STATISTICS tbl_Authentications;
GO
-- Content Integrity Control
-- [Nothing]
-- Reports: Event Rules (all), Troubleshooting-Event Rules Failuer
-- Remove IX_tbl_Actions_Time_stamp since won't be necessary
IF EXISTS (SELECT * FROM sys.indexes WHERE name = 'IX_tbl_Actions_Time_stamp' AND object_id = OBJECT_ID('tbl_Actions'))
DROP INDEX IX_tbl_Actions_Time_stamp ON tbl_Actions
GO
IF EXISTS (SELECT * FROM sys.indexes WHERE name = 'IX_tbl_Actions_Time_stamp_EventID_TransactionID' AND object_id = OBJECT_ID('tbl_Actions'))
DROP INDEX IX_tbl_Actions_Time_stamp_EventID_TransactionID ON tbl_Actions
GO
CREATE INDEX IX_tbl_Actions_Time_stamp_EventID_TransactionID ON tbl_Actions (Time_stamp, EventID, TransactionID)
GO
UPDATE STATISTICS tbl_Actions;
GO
-- Event Rules - Just Transfers
-- Remove IX_tbl_EventRules_Time_stamp since won't be necessary
IF EXISTS (SELECT * FROM sys.indexes WHERE name = 'IX_tbl_EventRules_Time_stamp' AND object_id = OBJECT_ID('tbl_EventRules'))
DROP INDEX IX_tbl_EventRules_Time_stamp ON tbl_EventRules
GO
IF EXISTS (SELECT * FROM sys.indexes WHERE name = 'IX_tbl_EventRules_Time_stamp_TransactionID' AND object_id = OBJECT_ID('tbl_EventRules'))
DROP INDEX IX_tbl_EventRules_Time_stamp_TransactionID ON tbl_EventRules
GO
CREATE INDEX IX_tbl_EventRules_Time_stamp_TransactionID ON tbl_EventRules (Time_stamp, TransactionID)
GO
UPDATE STATISTICS tbl_EventRules;
GO
-- For Troubleshooting-Socket Connection Errors
-- Remove IX_tbl_SocketConnections_Time_stamp since won't be necessary
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
IF EXISTS (SELECT * FROM sys.indexes WHERE name = 'IX_tbl_SocketConnections_Time_stamp_ResultID' AND object_id = OBJECT_ID('tbl_SocketConnections'))
DROP INDEX IX_tbl_SocketConnections_Time_stamp_ResultID ON tbl_SocketConnections
GO
CREATE INDEX IX_tbl_SocketConnections_Time_stamp_ResultID ON tbl_SocketConnections (Time_stamp, ResultID)
GO
UPDATE STATISTICS tbl_SocketConnections;
GO
-- For Workspaces-Files Picked Up
IF EXISTS (SELECT * FROM sys.indexes WHERE name = 'IX_tbl_OutlookReport_Type_TransactionDate' AND object_id = OBJECT_ID('tbl_OutlookReport'))
DROP INDEX IX_tbl_OutlookReport_Type_TransactionDate ON tbl_OutlookReport
GO
CREATE INDEX IX_tbl_OutlookReport_Type_TransactionDate ON tbl_OutlookReport (Type, TransactionDate)
GO
-- For Workspaces-Folders Shared, Unshared reports
IF EXISTS (SELECT * FROM sys.indexes WHERE name = 'IX_tbl_OutlookReport_WorkspaceID' AND object_id = OBJECT_ID('tbl_OutlookReport'))
DROP INDEX IX_tbl_OutlookReport_WorkspaceID ON tbl_OutlookReport
GO
CREATE INDEX IX_tbl_OutlookReport_WorkspaceID ON tbl_OutlookReport (WorkspaceID)
GO
UPDATE STATISTICS tbl_OutlookReport;
GO
-- For Workspaces-Folders Shared, Unshared reports
-- Remove IX_tbl_WorkspaceActions_Time_stamp since won't be necessary
IF EXISTS (SELECT * FROM sys.indexes WHERE name = 'IX_tbl_WorkspaceActions_Time_stamp' AND object_id = OBJECT_ID('tbl_WorkspaceActions'))
DROP INDEX IX_tbl_WorkspaceActions_Time_stamp ON tbl_WorkspaceActions
GO
IF EXISTS (SELECT * FROM sys.indexes WHERE name = 'IX_tbl_WorkspaceActions_Time_stamp_Action' AND object_id = OBJECT_ID('tbl_WorkspaceActions'))
DROP INDEX IX_tbl_WorkspaceActions_Time_stamp_Action ON tbl_WorkspaceActions
GO
CREATE INDEX IX_tbl_WorkspaceActions_Time_stamp_Action ON tbl_WorkspaceActions (Time_stamp, Action)
GO
UPDATE STATISTICS tbl_WorkspaceActions;
GO