Merge branch 'main' into MED-85
This commit is contained in:
@@ -0,0 +1,2 @@
|
||||
ALTER TABLE medreport.analysis_response_elements
|
||||
ADD comment text;
|
||||
@@ -0,0 +1,48 @@
|
||||
DROP FUNCTION IF EXISTS medreport.get_account_members(text);
|
||||
|
||||
CREATE OR REPLACE FUNCTION medreport.get_account_members(account_slug text)
|
||||
RETURNS TABLE(
|
||||
id uuid,
|
||||
user_id uuid,
|
||||
account_id uuid,
|
||||
role character varying,
|
||||
role_hierarchy_level integer,
|
||||
primary_owner_user_id uuid,
|
||||
name character varying,
|
||||
email character varying,
|
||||
personal_code text,
|
||||
picture_url character varying,
|
||||
created_at timestamp with time zone,
|
||||
updated_at timestamp with time zone
|
||||
)
|
||||
LANGUAGE plpgsql
|
||||
SET search_path TO ''
|
||||
AS $function$begin
|
||||
return QUERY
|
||||
select
|
||||
acc.id,
|
||||
am.user_id,
|
||||
am.account_id,
|
||||
am.account_role,
|
||||
r.hierarchy_level,
|
||||
a.primary_owner_user_id,
|
||||
acc.name,
|
||||
acc.email,
|
||||
acc.personal_code,
|
||||
acc.picture_url,
|
||||
am.created_at,
|
||||
am.updated_at
|
||||
from
|
||||
medreport.accounts_memberships am
|
||||
join medreport.accounts a on a.id = am.account_id
|
||||
join medreport.accounts acc on acc.id = am.user_id
|
||||
join medreport.roles r on r.name = am.account_role
|
||||
where
|
||||
a.slug = account_slug;
|
||||
|
||||
end;$function$
|
||||
;
|
||||
|
||||
grant
|
||||
execute on function medreport.get_account_members (text) to authenticated,
|
||||
service_role;
|
||||
@@ -0,0 +1,85 @@
|
||||
|
||||
create type audit.doctor_page_view_action as ENUM('VIEW_ANALYSIS_RESULTS','VIEW_DASHBOARD','VIEW_OPEN_JOBS','VIEW_OWN_JOBS','VIEW_DONE_JOBS');
|
||||
|
||||
create table audit.doctor_page_views (
|
||||
"id" bigint generated by default as identity not null,
|
||||
"viewer_user_id" uuid references auth.users (id) not null,
|
||||
"data_owner_user_id" uuid references auth.users (id),
|
||||
"viewed_record_key" text,
|
||||
"action" audit.doctor_page_view_action not null,
|
||||
"created_at" timestamp with time zone not null default now()
|
||||
);
|
||||
|
||||
grant usage on schema audit to authenticated;
|
||||
grant select, insert, update, delete on table audit.doctor_page_views to authenticated;
|
||||
|
||||
alter table "audit"."page_views" enable row level security;
|
||||
|
||||
create policy "insert_own"
|
||||
on audit.doctor_page_views
|
||||
as permissive
|
||||
for insert
|
||||
to authenticated
|
||||
with check (auth.uid() = viewer_user_id);
|
||||
|
||||
CREATE OR REPLACE FUNCTION medreport.log_doctor_analysis_feedback_changes()
|
||||
RETURNS TRIGGER AS $$
|
||||
DECLARE
|
||||
current_user_id uuid;
|
||||
current_user_role text;
|
||||
operation_type text;
|
||||
BEGIN
|
||||
begin
|
||||
current_user_id := auth.uid();
|
||||
current_user_role := auth.jwt() ->> 'role';
|
||||
end;
|
||||
IF (OLD.doctor_user_id IS DISTINCT FROM NEW.doctor_user_id) THEN
|
||||
operation_type := CASE
|
||||
WHEN NEW.doctor_user_id IS NULL THEN 'UNSELECT_JOB'
|
||||
ELSE 'SELECT_JOB'
|
||||
END;
|
||||
ELSIF (NEW.status = 'DRAFT' OR (OLD.status IS DISTINCT FROM NEW.status AND NEW.status = 'COMPLETED')) THEN
|
||||
operation_type := CASE
|
||||
WHEN NEW.status = 'DRAFT' THEN 'UPDATED_DRAFT'
|
||||
WHEN NEW.status = 'COMPLETED' THEN 'PUBLISHED_SUMMARY'
|
||||
ELSE NULL
|
||||
END;
|
||||
ELSE
|
||||
operation_type := NULL;
|
||||
END IF;
|
||||
|
||||
IF operation_type IS NOT NULL THEN
|
||||
INSERT INTO audit.log_entries (
|
||||
schema_name,
|
||||
table_name,
|
||||
record_key,
|
||||
operation,
|
||||
changed_by,
|
||||
changed_by_role,
|
||||
changed_at
|
||||
)
|
||||
VALUES (
|
||||
'medreport',
|
||||
'doctor_analysis_feedback',
|
||||
NEW.id::text,
|
||||
operation_type,
|
||||
current_user_id,
|
||||
current_user_role,
|
||||
NOW()
|
||||
);
|
||||
END IF;
|
||||
|
||||
RETURN NEW;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
DROP TRIGGER IF EXISTS doctor_analysis_feedback_audit_trigger ON medreport.doctor_analysis_feedback;
|
||||
|
||||
CREATE TRIGGER doctor_analysis_feedback_audit_trigger
|
||||
AFTER UPDATE ON medreport.doctor_analysis_feedback
|
||||
FOR EACH ROW
|
||||
EXECUTE FUNCTION medreport.log_doctor_analysis_feedback_changes();
|
||||
|
||||
GRANT EXECUTE ON FUNCTION medreport.log_doctor_analysis_feedback_changes() TO authenticated;
|
||||
|
||||
alter table audit.doctor_page_views enable row level security;
|
||||
42
supabase/migrations/20250826160800_improve_logging.sql
Normal file
42
supabase/migrations/20250826160800_improve_logging.sql
Normal file
@@ -0,0 +1,42 @@
|
||||
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
|
||||
COALESCE( to_jsonb(OLD)->>'id',
|
||||
to_jsonb(OLD)->>'user_id',
|
||||
to_jsonb(OLD)->>'account_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;
|
||||
$$;
|
||||
|
||||
Reference in New Issue
Block a user