JBAS-1501 Copy audit table maintenance scripts
authorBill Erickson <berickxx@gmail.com>
Thu, 21 Jul 2016 21:07:34 +0000 (17:07 -0400)
committerBill Erickson <berickxx@gmail.com>
Thu, 21 Mar 2019 19:46:23 +0000 (15:46 -0400)
New DB function for deleting rows from auditor.asset_copy_history plus a
script we can run from CRON for nightly batches.

Signed-off-by: Bill Erickson <berickxx@gmail.com>
KCLS/sql/schema/deploy/audit-table-maint.sql [new file with mode: 0644]
KCLS/sql/schema/revert/audit-table-maint.sql [new file with mode: 0644]
KCLS/sql/schema/sqitch.plan
KCLS/sql/schema/verify/audit-table-maint.sql [new file with mode: 0644]
KCLS/utility-scripts/purge_auditor/purge-auditor.sh [new file with mode: 0755]
KCLS/utility-scripts/purge_auditor/purge-auditor.sql [new file with mode: 0644]

diff --git a/KCLS/sql/schema/deploy/audit-table-maint.sql b/KCLS/sql/schema/deploy/audit-table-maint.sql
new file mode 100644 (file)
index 0000000..38f482d
--- /dev/null
@@ -0,0 +1,99 @@
+-- Deploy kcls-evergreen:audit-table-maint to pg
+-- requires: payflow-hosted-org-settings
+
+BEGIN;
+
+CREATE OR REPLACE FUNCTION auditor.purge_audit_data (
+    keep_cur_entries INTEGER, -- num entries to keep for current interval
+    keep_old_entries INTEGER, -- num entries to keep for previous interval
+    pivot_age INTERVAL,       -- what defines current vs previous interval (e.g. 1 year)
+    drop_age INTERVAL,        -- delete all entries older than this. (e.g. 3 years)
+    run_duration INTERVAL     -- exit the function once it's run this long. (e.g. 2 hours)
+) RETURNS VOID AS $FUNC$
+DECLARE
+    aid BIGINT;
+    del_counter BIGINT DEFAULT 0;
+    start_time TIMESTAMPTZ;
+BEGIN
+
+    start_time := CLOCK_TIMESTAMP();
+
+    DELETE FROM auditor.asset_copy_history 
+        WHERE audit_time < (NOW() - drop_age);
+
+    IF CLOCK_TIMESTAMP() - start_time > run_duration THEN
+        RAISE NOTICE 
+            'Exiting auditor.purge_audit_data() on max duration %', 
+            run_duration;
+        RETURN;
+    END IF;
+
+    RAISE NOTICE 'Done with old entry deletes.  Starting current deletes.';
+
+    -- loop over auditor rows that constitute the 16th or older
+    -- row per copy and delete each.
+    FOR aid IN 
+        WITH ranked_entries_per_copy AS (
+            SELECT audit_id,
+                ROW_NUMBER() OVER (
+                    PARTITION BY id
+                    ORDER BY audit_time DESC, audit_id DESC
+                ) AS position
+            FROM auditor.asset_copy_history
+        ) SELECT ranked.audit_id
+            FROM ranked_entries_per_copy ranked 
+            WHERE ranked.position > keep_cur_entries
+    LOOP
+        
+        DELETE FROM auditor.asset_copy_history WHERE audit_id = aid;
+        del_counter := del_counter + 1;
+
+        IF (del_counter % 10000) = 0 THEN
+            RAISE NOTICE 'Deleted % auditor rows', del_counter;
+        END IF;
+
+        IF CLOCK_TIMESTAMP() - start_time > run_duration THEN
+            RAISE NOTICE 
+                'Exiting auditor.purge_audit_data() on max duration %', 
+                run_duration;
+            RETURN;
+        END IF;
+    END LOOP;
+
+    RAISE NOTICE 'Done with current entry maintenence; cleaning older entries';
+
+    -- loop over auditor rows older than pivot_age that constitute 
+    -- the 4th or older row per copy and delete them.
+    FOR aid IN 
+        WITH ranked_entries_per_copy AS (
+            SELECT audit_id,
+                ROW_NUMBER() OVER (
+                    PARTITION BY id
+                    ORDER BY audit_time DESC, audit_id DESC
+                ) AS position
+            FROM auditor.asset_copy_history
+            WHERE audit_time < (NOW() - pivot_age)
+        ) SELECT ranked.audit_id
+            FROM ranked_entries_per_copy ranked 
+            WHERE ranked.position > keep_old_entries
+    LOOP
+        
+        DELETE FROM auditor.asset_copy_history WHERE audit_id = aid;
+        del_counter := del_counter + 1;
+
+        IF (del_counter % 10000) = 0 THEN
+            RAISE NOTICE 'Deleted % auditor rows', del_counter;
+        END IF;
+
+        IF CLOCK_TIMESTAMP() - start_time > run_duration THEN
+            RAISE NOTICE 
+                'Exiting auditor.purge_audit_data() on max duration %', 
+                run_duration;
+            RETURN;
+        END IF;
+    END LOOP;
+END;
+$FUNC$ LANGUAGE PLPGSQL;
+
+COMMIT;
+
diff --git a/KCLS/sql/schema/revert/audit-table-maint.sql b/KCLS/sql/schema/revert/audit-table-maint.sql
new file mode 100644 (file)
index 0000000..acf6d09
--- /dev/null
@@ -0,0 +1,8 @@
+-- Revert kcls-evergreen:audit-table-maint from pg
+
+BEGIN;
+
+DROP FUNCTION auditor.purge_audit_data(
+    INTEGER, INTEGER, INTERVAL, INTERVAL, INTERVAL);
+
+COMMIT;
index cb65197..d6b36b0 100644 (file)
@@ -29,3 +29,4 @@ purge-user-activity [sip-activity-types] 2016-04-29T17:07:46Z Bill Erickson <ber
 vand-auth-edit-date [purge-user-activity] 2016-06-01T18:24:54Z Bill Erickson <berickxx@gmail.com> # Vandelay authority import sets edit[or|_date]
 payflow-hosted-org-settings [vand-auth-edit-date] 2016-07-06T18:39:40Z Bill Erickson <berickxx@gmail.com> # PayflowPro Hosted Pages org unit settings
 sip-act-type-freegalsip [payflow-hosted-org-settings] 2016-08-19T20:24:01Z Bill Erickson <berickxx@gmail.com> # User activity type for freegalsip login
+audit-table-maint [payflow-hosted-org-settings] 2016-07-22T14:49:08Z Bill Erickson <berickxx@gmail.com> # Audit table cleanup functions
diff --git a/KCLS/sql/schema/verify/audit-table-maint.sql b/KCLS/sql/schema/verify/audit-table-maint.sql
new file mode 100644 (file)
index 0000000..8556645
--- /dev/null
@@ -0,0 +1,7 @@
+-- Verify kcls-evergreen:audit-table-maint on pg
+
+BEGIN;
+
+-- XXX Add verifications here.
+
+ROLLBACK;
diff --git a/KCLS/utility-scripts/purge_auditor/purge-auditor.sh b/KCLS/utility-scripts/purge_auditor/purge-auditor.sh
new file mode 100755 (executable)
index 0000000..30e36d8
--- /dev/null
@@ -0,0 +1,17 @@
+#!/bin/bash
+
+RUN_DURATION="1 hour"
+KEEP_CUR_ENTRIES="15"
+KEEP_OLD_ENTRIES="3"
+PIVOT_AGE="1 year"
+DROP_AGE="3 years"
+
+psql -U evergreen \
+    --set keep_cur_entries="'$KEEP_CUR_ENTRIES'" \
+    --set keep_old_entries="'$KEEP_OLD_ENTRIES'" \
+    --set pivot_age="'$PIVOT_AGE'" \
+    --set drop_age="'$DROP_AGE'" \
+    --set run_duration="'$RUN_DURATION'" \
+    -f purge-auditor.sql
+
+
diff --git a/KCLS/utility-scripts/purge_auditor/purge-auditor.sql b/KCLS/utility-scripts/purge_auditor/purge-auditor.sql
new file mode 100644 (file)
index 0000000..d23469c
--- /dev/null
@@ -0,0 +1,16 @@
+-- TODO: Transaction wrapper is for testing only.  Remove it for production.
+
+--BEGIN;
+
+SET STATEMENT_TIMEOUT = 0;
+
+SELECT auditor.purge_audit_data(
+    :keep_cur_entries::INTEGER, 
+    :keep_old_entries::INTEGER, 
+    :pivot_age::INTERVAL,
+    :drop_age::INTERVAL,
+    :run_duration::INTERVAL
+);
+
+--ROLLBACK;
+--COMMIT;