Skip to content

Commit

Permalink
new repo audit: added support for partition creation in the past
Browse files Browse the repository at this point in the history
  • Loading branch information
virgo47 committed Dec 6, 2021
1 parent 1cd12d0 commit 3a8baaf
Show file tree
Hide file tree
Showing 3 changed files with 87 additions and 4 deletions.
18 changes: 14 additions & 4 deletions config/sql/native-new/postgres-new-audit.sql
Expand Up @@ -249,6 +249,7 @@ DO $$ BEGIN
END; $$;

-- region partition creation procedures
-- Use negative futureCount for creating partitions for the past months if needed.
CREATE OR REPLACE PROCEDURE audit_create_monthly_partitions(futureCount int)
LANGUAGE plpgsql
AS $$
Expand All @@ -258,7 +259,7 @@ DECLARE
tableSuffix TEXT;
BEGIN
-- noinspection SqlUnused
FOR i IN 1..futureCount loop
FOR i IN 1..abs(futureCount) loop
dateTo := dateFrom + interval '1 month';
tableSuffix := to_char(dateFrom, 'YYYYMM');

Expand Down Expand Up @@ -294,21 +295,30 @@ BEGIN
'ma_audit_event_' || tableSuffix);
END;

dateFrom := dateTo;
IF futureCount < 0 THEN
-- going to the past
dateFrom := dateFrom - interval '1 month';
ELSE
dateFrom := dateTo;
END IF;

END loop;
END $$;
-- endregion

/*
IMPORTANT: Only default partitions are created in this script!
Use something like this, if you desire monthly partitioning:
call audit_create_monthly_partitions(12);
call audit_create_monthly_partitions(120);
This creates 12 monthly partitions into the future.
This creates 120 monthly partitions into the future (10 years).
It can be safely called multiple times, so you can run it again anytime in the future.
If you forget to run, audit events will go to default partition so no data is lost,
however it may be complicated to organize it into proper partitions after the fact.
Create past partitions if needed, e.g. for migration. E.g., for last 12 months (including current):
call audit_create_monthly_partitions(-12);
For Quartz tables see:
repo/task-quartz-impl/src/main/resources/com/evolveum/midpoint/task/quartzimpl/execution/tables_postgres.sql
Expand Down
66 changes: 66 additions & 0 deletions config/sql/native-new/postgres-new-upgrade-audit.sql
Expand Up @@ -10,5 +10,71 @@
-- If you use audit and main repository in a single database, this still must be run as well.
-- It is safe to run this script repeatedly, so if you're not sure you're up to date.

-- SCHEMA-COMMIT is a commit which should be used to initialize the DB for testing changes below it.
-- Check out that commit and initialize a fresh DB with postgres-new-audit.sql to test upgrades.

-- Initializing the last change number used in postgres-new-upgrade.sql.
call apply_audit_change(0, $$ SELECT 1 $$, true);

-- SCHEMA-COMMIT 4.0: commit 69e8c29b

-- changes for 4.4.1

-- support for partition generation in the past using negative argument
call apply_audit_change(1, $aac$
-- Use negative futureCount for creating partitions for the past months if needed.
CREATE OR REPLACE PROCEDURE audit_create_monthly_partitions(futureCount int)
LANGUAGE plpgsql
AS $$
DECLARE
dateFrom TIMESTAMPTZ = date_trunc('month', current_timestamp);
dateTo TIMESTAMPTZ;
tableSuffix TEXT;
BEGIN
-- noinspection SqlUnused
FOR i IN 1..abs(futureCount) loop
dateTo := dateFrom + interval '1 month';
tableSuffix := to_char(dateFrom, 'YYYYMM');

BEGIN
-- PERFORM = select without using the result
PERFORM ('ma_audit_event_' || tableSuffix)::regclass;
RAISE NOTICE 'Tables for partition % already exist, OK...', tableSuffix;
EXCEPTION WHEN OTHERS THEN
RAISE NOTICE 'Creating partitions for range: % - %', dateFrom, dateTo;

-- values FROM are inclusive (>=), TO are exclusive (<)
EXECUTE format(
'CREATE TABLE %I PARTITION OF ma_audit_event FOR VALUES FROM (%L) TO (%L);',
'ma_audit_event_' || tableSuffix, dateFrom, dateTo);
EXECUTE format(
'CREATE TABLE %I PARTITION OF ma_audit_delta FOR VALUES FROM (%L) TO (%L);',
'ma_audit_delta_' || tableSuffix, dateFrom, dateTo);
EXECUTE format(
'CREATE TABLE %I PARTITION OF ma_audit_ref FOR VALUES FROM (%L) TO (%L);',
'ma_audit_ref_' || tableSuffix, dateFrom, dateTo);

EXECUTE format(
'ALTER TABLE %I ADD CONSTRAINT %I FOREIGN KEY (recordId, timestamp)' ||
' REFERENCES %I (id, timestamp) ON DELETE CASCADE',
'ma_audit_delta_' || tableSuffix,
'ma_audit_delta_' || tableSuffix || '_fk',
'ma_audit_event_' || tableSuffix);
EXECUTE format(
'ALTER TABLE %I ADD CONSTRAINT %I FOREIGN KEY (recordId, timestamp)' ||
' REFERENCES %I (id, timestamp) ON DELETE CASCADE',
'ma_audit_ref_' || tableSuffix,
'ma_audit_ref_' || tableSuffix || '_fk',
'ma_audit_event_' || tableSuffix);
END;

IF futureCount < 0 THEN
-- going to the past
dateFrom := dateFrom - interval '1 month';
ELSE
dateFrom := dateTo;
END IF;

END loop;
END $$;
$aac$, false);
7 changes: 7 additions & 0 deletions config/sql/native-new/postgres-new-upgrade.sql
Expand Up @@ -9,5 +9,12 @@
-- This is the update script for the MAIN REPOSITORY, it will not work for a separate audit database.
-- It is safe to run this script repeatedly, so if you're not sure you're up to date.

-- SCHEMA-COMMIT is a commit which should be used to initialize the DB for testing changes below it.
-- Check out that commit and initialize a fresh DB with postgres-new-audit.sql to test upgrades.

-- Initializing the last change number used in postgres-new-upgrade.sql.
call apply_change(0, $$ SELECT 1 $$, true);

-- SCHEMA-COMMIT 4.0: commit 69e8c29b

-- changes for 4.4.1

0 comments on commit 3a8baaf

Please sign in to comment.