Files
medreport_mrb2b/supabase/migrations/20250604115051_add_audit_schema.sql
Helena f5079e4e97 B2B-84: add public message sync function and audit schema (#5)
* B2B-84: add public message sync function and audit schema

* clean up unnecessary comment

* clean up unnecessary seed file

* address comments

---------

Co-authored-by: Helena <helena@Helenas-MacBook-Pro.local>
2025-06-06 13:34:25 +03:00

88 lines
2.1 KiB
PL/PgSQL

create schema if not exists audit;
create table if not exists audit.log_entries (
"id" bigint generated by default as identity not null,
"schema_name" text not null,
"table_name" text not null,
"record_key" bigint,
"operation" text not null,
"row_data" jsonb,
"changed_data" jsonb,
"changed_by" uuid,
"changed_by_role" text,
"changed_at" timestamptz not null default now()
);
alter table "audit"."log_entries" enable row level security;
create policy "service_role_all"
on "audit"."log_entries"
as permissive
for all
to service_role
using (true);
create or replace function audit.log_audit_changes()
returns trigger
language plpgsql
as $$
declare
current_user_id uuid;
current_user_role text;
begin
begin
current_user_id := auth.uid();
current_user_role := auth.jwt() ->> 'role';
end;
insert into audit.log_entries (
schema_name,
table_name,
record_key,
operation,
row_data,
changed_data,
changed_by,
changed_by_role
)
values (
tg_table_schema,
tg_table_name,
case when tg_op in ('DELETE', 'UPDATE') then old.id else null end,
tg_op,
case when tg_op in ('DELETE', 'UPDATE') then to_jsonb(old) else null end,
case when tg_op in ('INSERT', 'UPDATE') then to_jsonb(new) else null end,
current_user_id,
current_user_role
);
return null;
end;
$$;
create table "audit"."sync_entries" (
"id" bigint generated by default as identity not null,
"status" text not null,
"operation" text not null,
"comment" text,
"created_at" timestamp with time zone not null default now(),
"changed_by_role" text not null
);
create type "audit"."sync_status" as enum ('SUCCESS', 'FAIL');
alter table "audit"."sync_entries" enable row level security;
CREATE UNIQUE INDEX sync_entries_pkey ON audit.sync_entries USING btree (id);
alter table "audit"."sync_entries" add constraint "sync_entries_pkey" PRIMARY KEY using index "sync_entries_pkey";
create policy "service_role_all"
on "audit"."sync_entries"
as permissive
for all
to public
using (true);
GRANT USAGE ON SCHEMA audit TO service_role;
GRANT ALL ON ALL TABLES IN SCHEMA audit TO service_role;