-
Notifications
You must be signed in to change notification settings - Fork 9
Commit
This commit does not belong to any branch on this repository, and may belong to a fork outside of the repository.
fix: audit events table to dedicated schema
- Loading branch information
1 parent
08db852
commit 1ca95fe
Showing
1 changed file
with
60 additions
and
0 deletions.
There are no files selected for viewing
60 changes: 60 additions & 0 deletions
60
repositories/migrations/20240403105200_audit_table_schema_change.sql
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
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 |