A/T event truncation example collab/berick/truncate-event-tables
authorBill Erickson <berickxx@gmail.com>
Tue, 29 Aug 2017 14:56:53 +0000 (10:56 -0400)
committerBill Erickson <berickxx@gmail.com>
Tue, 29 Aug 2017 14:56:53 +0000 (10:56 -0400)
Signed-off-by: Bill Erickson <berickxx@gmail.com>
truncate-at-events.sql [new file with mode: 0644]

diff --git a/truncate-at-events.sql b/truncate-at-events.sql
new file mode 100644 (file)
index 0000000..7209071
--- /dev/null
@@ -0,0 +1,110 @@
+
+BEGIN;
+
+SET STATEMENT_TIMEOUT = 0;
+
+SELECT CLOCK_TIMESTAMP(), 'getting started';
+
+-- XXX this line for testing purposes only.  It will be in the main upgrade.
+ALTER TABLE action_trigger.event_definition ADD COLUMN retention_interval INTERVAL;
+
+-- Apply some max_delay values where needed.
+-- These defs are unused, but best to apply a max_delay now so we can
+-- apply a retention_interval that won't be forgotten later.
+UPDATE action_trigger.event_definition SET max_delay = '10 days' 
+    WHERE id IN (2, 9, 24, 36, 49) AND max_delay IS NULL;
+
+-- most events are purged after a short period
+UPDATE action_trigger.event_definition SET retention_interval = '1 day';
+
+-- keep these events forever
+UPDATE action_trigger.event_definition 
+    SET retention_interval = NULL
+    WHERE hook IN (
+        -- keep these event types forever
+        'acqpo.activated',
+        'format.acqcle.html',
+        'format.acqinv.html',
+        'format.po.html'
+    );
+
+-- keep these events for 1 year
+UPDATE action_trigger.event_definition 
+    SET retention_interval = '1 year'
+    WHERE hook IN (
+        'checkout.due',                                                
+        'hold.available',                                              
+        'hold_request.cancel.expire_holds_shelf',                      
+        'hold_request.cancel.expire_no_target',                        
+        'hold_request.cancel.staff',                                   
+        'hold_request.long_wait',
+        'hold_request.shelf_expires_soon',
+        'penalty.PATRON_EXCEEDS_COLLECTIONS_WARNING',                  
+        'password.reset_request',
+        'money.format.payment_receipt.email',
+        'money.format.payment_receipt.print',
+        'lost.auto',
+        'longoverdue.auto',
+        'circ.staff_age_to_lost',
+        'circ.format.missing_pieces.slip.print',
+        'circ.format.missing_pieces.letter.print'
+    );
+
+CREATE TEMPORARY TABLE tmp_at_event ON COMMIT DROP AS 
+    SELECT evt.* FROM action_trigger.event evt
+    JOIN action_trigger.event_definition def ON (def.id = evt.event_def)
+    WHERE 
+        evt.state = 'pending'
+        OR def.retention_interval IS NULL -- these never expire
+        OR evt.update_time > (NOW() - def.retention_interval)    
+;
+
+SELECT CLOCK_TIMESTAMP(), 'tmp_at_event created',
+    (SELECT COUNT(*) FROM tmp_at_event);
+
+--SELECT COUNT(*), DATE_TRUNC('year', update_time), state 
+--    FROM tmp_at_event GROUP BY 2, 3 ORDER BY 2, 3;
+
+-- keep only template outputs that are linked from saved events
+CREATE TEMPORARY TABLE tmp_at_event_output ON COMMIT DROP AS 
+    WITH linked_outputs AS (
+        SELECT templates.id AS id FROM (
+            SELECT template_output AS id
+                FROM tmp_at_event WHERE template_output IS NOT NULL
+            UNION
+            SELECT error_output AS id
+                FROM tmp_at_event WHERE error_output IS NOT NULL
+            UNION
+            SELECT async_output AS id
+                FROM tmp_at_event WHERE async_output IS NOT NULL
+        ) templates
+    )
+    SELECT * FROM action_trigger.event_output
+    WHERE id IN (SELECT id FROM linked_outputs);
+
+SELECT CLOCK_TIMESTAMP(), 'tmp_at_event_output created',
+    (SELECT COUNT(*) FROM tmp_at_event_output);
+
+-- TRUNCATE AND REBUILD TABLES FROM TMP DATA
+TRUNCATE action_trigger.event, action_trigger.event_output;
+
+-- rebuild event_output first since event depends on it.
+
+INSERT INTO action_trigger.event_output SELECT * FROM tmp_at_event_output;
+SELECT CLOCK_TIMESTAMP(), 'action_trigger.event_output rebuilt',
+    (SELECT COUNT(*) FROM action_trigger.event_output);
+
+INSERT INTO action_trigger.event SELECT * FROM tmp_at_event;
+SELECT CLOCK_TIMESTAMP(), 'action_trigger.event rebuilt',
+    (SELECT COUNT(*) FROM action_trigger.event);
+
+ROLLBACK;
+
+/*
+COMMIT;
+
+ANALYZE action_trigger.event;
+ANALYZE action_trigger.event_output;
+*/
+
+