52 lines
2.3 KiB
MySQL
52 lines
2.3 KiB
MySQL
|
-- CASCADE HANDLERS TABLE
|
||
|
ALTER TABLE Account.reportHandlers DROP FOREIGN KEY reportHandlers_reports_id_fk;
|
||
|
ALTER TABLE Account.reportHandlers
|
||
|
ADD CONSTRAINT reportHandlers_reports_id_fk
|
||
|
FOREIGN KEY (reportId) REFERENCES reports (id) ON DELETE CASCADE;
|
||
|
|
||
|
-- CASCADE REASONS/REPORTERS TABLE
|
||
|
ALTER TABLE Account.reportReasons DROP FOREIGN KEY reportReasons_reports_id_fk;
|
||
|
ALTER TABLE Account.reportReasons
|
||
|
ADD CONSTRAINT reportReasons_reports_id_fk
|
||
|
FOREIGN KEY (reportId) REFERENCES reports (id) ON DELETE CASCADE;
|
||
|
|
||
|
-- CASCADE RESULTS TABLE
|
||
|
ALTER TABLE Account.reportResults DROP FOREIGN KEY reportResults_reports_id_fk;
|
||
|
ALTER TABLE Account.reportResults
|
||
|
ADD CONSTRAINT reportResults_reports_id_fk
|
||
|
FOREIGN KEY (reportId) REFERENCES reports (id) ON DELETE CASCADE;
|
||
|
|
||
|
-- CASCADE SNAPSHOT MESSAGE MAP
|
||
|
ALTER TABLE Account.snapshotMessageMap DROP FOREIGN KEY snapshotMessageMap_snapshots_id_fk;
|
||
|
ALTER TABLE Account.snapshotMessageMap
|
||
|
ADD CONSTRAINT snapshotMessageMap_snapshots_id_fk
|
||
|
FOREIGN KEY (snapshotId) REFERENCES snapshots (id) ON DELETE CASCADE;
|
||
|
ALTER TABLE Account.snapshotMessageMap DROP FOREIGN KEY snapshotMessageMap_snapshotMessages_id_fk;
|
||
|
ALTER TABLE Account.snapshotMessageMap
|
||
|
ADD CONSTRAINT snapshotMessageMap_snapshotMessages_id_fk
|
||
|
FOREIGN KEY (messageId) REFERENCES snapshotMessages (id) ON DELETE CASCADE;
|
||
|
|
||
|
-- CASCADE SNAPSHOT RECIPIENTS TABLE
|
||
|
ALTER TABLE Account.snapshotRecipients DROP FOREIGN KEY snapshotRecipients_snapshotMessages_id_fk;
|
||
|
ALTER TABLE Account.snapshotRecipients
|
||
|
ADD CONSTRAINT snapshotRecipients_snapshotMessages_id_fk
|
||
|
FOREIGN KEY (messageId) REFERENCES snapshotMessages (id) ON DELETE CASCADE;
|
||
|
|
||
|
-- CREATE CLEANUP TASK
|
||
|
DELIMITER //
|
||
|
|
||
|
CREATE EVENT `report_cleanup`
|
||
|
ON SCHEDULE EVERY 1 MONTH
|
||
|
ON COMPLETION PRESERVE
|
||
|
DO BEGIN
|
||
|
-- DELETE REPORTS (AND ASSOCIATED SNAPSHOT IF ANY) CLOSED > 30 DAYS AGO
|
||
|
DELETE reports, snapshots FROM reports, snapshots
|
||
|
LEFT JOIN reportResults ON reports.id = reportResults.reportId
|
||
|
LEFT JOIN snapshots ON reports.snapshotId = snapshots.id
|
||
|
WHERE reportResults.closedTime NOT BETWEEN NOW() - INTERVAL 30 DAY AND NOW();
|
||
|
|
||
|
-- DELETE ORPHANED SNAPSHOT MESSAGES
|
||
|
DELETE snapshotMessages FROM snapshotMessages
|
||
|
LEFT JOIN snapshotMessageMap ON snapshotMessages.id = snapshotMessageMap.messageId
|
||
|
WHERE snapshotMessageMap.snapshotId IS NULL;
|
||
|
END//
|