--- /dev/null
+-- 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,
+ RANK() OVER (
+ PARTITION BY id
+ ORDER BY audit_time 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,
+ RANK() OVER (
+ PARTITION BY id
+ ORDER BY audit_time 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;
+