2016-10-29 15:27:19 +02:00
|
|
|
-- RENAME COLUMN `creator` to `creatorId`
|
|
|
|
ALTER TABLE Account.snapshots CHANGE creator creatorId INT(11);
|
|
|
|
|
2016-10-29 15:26:16 +02:00
|
|
|
-- STORE DATETIME SNAPSHOT CREATED (CLEANUP PURPOSES)
|
|
|
|
ALTER TABLE Account.snapshots ADD created DATETIME DEFAULT NOW() NOT NULL;
|
|
|
|
ALTER TABLE Account.snapshots
|
2016-10-29 15:27:19 +02:00
|
|
|
MODIFY COLUMN creatorId INT(11) AFTER created;
|
2016-10-29 15:26:16 +02:00
|
|
|
|
2016-10-28 00:40:09 +02:00
|
|
|
-- 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 //
|
|
|
|
|
2016-10-28 19:13:20 +02:00
|
|
|
-- CREATE EVENT TO RUN EVERY DAY AT 00:00
|
2016-10-28 00:40:09 +02:00
|
|
|
CREATE EVENT `report_cleanup`
|
2016-10-28 19:13:20 +02:00
|
|
|
ON SCHEDULE
|
|
|
|
EVERY 1 DAY
|
|
|
|
-- FORCE TASK TO RUN AT 00:00 DAILY
|
|
|
|
STARTS (TIMESTAMP(CURRENT_DATE) + INTERVAL 1 DAY)
|
2016-10-28 00:40:09 +02:00
|
|
|
ON COMPLETION PRESERVE
|
2016-10-28 19:13:20 +02:00
|
|
|
COMMENT 'Cleans up old report and snapshot data.'
|
2016-10-28 00:40:09 +02:00
|
|
|
DO BEGIN
|
|
|
|
-- DELETE REPORTS (AND ASSOCIATED SNAPSHOT IF ANY) CLOSED > 30 DAYS AGO
|
2016-10-28 19:13:20 +02:00
|
|
|
DELETE reports, snapshots FROM reports
|
2016-10-28 00:40:09 +02:00
|
|
|
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();
|
|
|
|
|
2016-10-29 15:38:16 +02:00
|
|
|
-- DELETE SNAPSHOTS NOT LINKED TO REPORT AND OLDER THAN 30 DAYS
|
|
|
|
DELETE snapshots FROM snapshots
|
|
|
|
LEFT JOIN reports ON snapshots.id = reports.snapshotId
|
|
|
|
WHERE reports.id IS NULL
|
|
|
|
AND snapshots.created NOT BETWEEN NOW() - INTERVAL 30 DAY AND NOW();
|
|
|
|
|
2016-10-28 00:40:09 +02:00
|
|
|
-- DELETE ORPHANED SNAPSHOT MESSAGES
|
|
|
|
DELETE snapshotMessages FROM snapshotMessages
|
|
|
|
LEFT JOIN snapshotMessageMap ON snapshotMessages.id = snapshotMessageMap.messageId
|
|
|
|
WHERE snapshotMessageMap.snapshotId IS NULL;
|
|
|
|
END//
|