Skip to content

Commit

Permalink
fix: audit events table to dedicated schema
Browse files Browse the repository at this point in the history
  • Loading branch information
Pascal-Delange committed Apr 3, 2024
1 parent 08db852 commit 1ca95fe
Showing 1 changed file with 60 additions and 0 deletions.
Original file line number Diff line number Diff line change
@@ -0,0 +1,60 @@
-- +goose Up
-- +goose StatementBegin
CREATE SCHEMA IF NOT EXISTS audit;

ALTER TABLE audit
SET SCHEMA audit;

ALTER TABLE audit.audit
RENAME TO audit_events;

CREATE
OR REPLACE FUNCTION global_audit () RETURNS TRIGGER AS $$
BEGIN
IF (TG_OP = 'DELETE') THEN
INSERT INTO audit.audit_events ("operation", "user_id", "table", "entity_id", "data", "created_at")
VALUES ('DELETE', current_setting('custom.current_user_id', TRUE), TG_TABLE_NAME, OLD.id, to_jsonb(OLD), now());

ELSIF (TG_OP = 'UPDATE') THEN
INSERT INTO audit.audit_events ("operation", "user_id", "table", "entity_id", "data", "created_at")
VALUES ('UPDATE', current_setting('custom.current_user_id', TRUE), TG_TABLE_NAME, NEW.id, to_jsonb(NEW), now());

ELSIF (TG_OP = 'INSERT') THEN
INSERT INTO audit.audit_events ("operation", "user_id", "table", "entity_id", "data", "created_at")
VALUES ('INSERT', current_setting('custom.current_user_id', TRUE), TG_TABLE_NAME, NEW.id, to_jsonb(NEW), now());
END IF;
RETURN NULL;
END;
$$ LANGUAGE plpgsql;

-- +goose StatementEnd
-- +goose Down
-- +goose StatementBegin
CREATE
OR REPLACE FUNCTION global_audit () RETURNS TRIGGER AS $$
BEGIN
IF (TG_OP = 'DELETE') THEN
INSERT INTO audit.audit_events ("operation", "user_id", "table", "entity_id", "data", "created_at")
VALUES ('DELETE', current_setting('custom.current_user_id', TRUE), TG_TABLE_NAME, OLD.id, to_jsonb(OLD), now());

ELSIF (TG_OP = 'UPDATE') THEN
INSERT INTO audit.audit_events ("operation", "user_id", "table", "entity_id", "data", "created_at")
VALUES ('UPDATE', current_setting('custom.current_user_id', TRUE), TG_TABLE_NAME, NEW.id, to_jsonb(NEW), now());

ELSIF (TG_OP = 'INSERT') THEN
INSERT INTO audit.audit_events ("operation", "user_id", "table", "entity_id", "data", "created_at")
VALUES ('INSERT', current_setting('custom.current_user_id', TRUE), TG_TABLE_NAME, NEW.id, to_jsonb(NEW), now());
END IF;
RETURN NULL;
END;
$$ LANGUAGE plpgsql;

ALTER TABLE audit.audit_events
RENAME TO audit;

ALTER TABLE audit.audit
SET SCHEMA marble;

DROP SCHEMA audit CASCADE;

-- +goose StatementEnd

0 comments on commit 1ca95fe

Please sign in to comment.