69 lines
2.4 KiB
PL/PgSQL
69 lines
2.4 KiB
PL/PgSQL
ALTER TABLE medreport.ai_responses ENABLE ROW LEVEL SECURITY;
|
|
|
|
create policy "ai_responses_select"
|
|
on medreport.ai_responses
|
|
for select
|
|
to authenticated
|
|
using (account_id = auth.uid());
|
|
|
|
create policy "ai_responses_insert"
|
|
on medreport.ai_responses
|
|
for insert
|
|
to authenticated
|
|
with check (account_id = auth.uid());
|
|
|
|
|
|
grant select, insert, update, delete on table medreport.ai_responses to authenticated;
|
|
|
|
ALTER TABLE medreport.ai_responses
|
|
ALTER COLUMN prompt_id TYPE text
|
|
USING prompt_name::text;
|
|
|
|
ALTER TABLE medreport.ai_responses
|
|
ALTER COLUMN prompt_name TYPE text
|
|
USING prompt_name::text;
|
|
|
|
ALTER TABLE medreport.ai_responses
|
|
ADD CONSTRAINT ai_responses_id_pkey PRIMARY KEY (id);
|
|
|
|
create or replace function medreport.get_latest_analysis_response_elements_for_current_user(p_user_id uuid)
|
|
returns table (
|
|
analysis_name medreport.analysis_response_elements.analysis_name%type,
|
|
response_time medreport.analysis_response_elements.response_time%type,
|
|
norm_upper medreport.analysis_response_elements.norm_upper%type,
|
|
norm_lower medreport.analysis_response_elements.norm_lower%type,
|
|
norm_status medreport.analysis_response_elements.norm_status%type,
|
|
response_value medreport.analysis_response_elements.response_value%type,
|
|
analysis_name_lab medreport.analysis_elements.analysis_name_lab%type
|
|
)
|
|
language sql
|
|
as $$
|
|
WITH ranked AS (
|
|
SELECT
|
|
are.analysis_name,
|
|
are.response_time,
|
|
are.norm_upper,
|
|
are.norm_lower,
|
|
are.norm_status,
|
|
are.response_value,
|
|
ae.analysis_name_lab,
|
|
ROW_NUMBER() OVER (
|
|
PARTITION BY are.analysis_name
|
|
ORDER BY are.response_time DESC, are.id DESC
|
|
) AS rn
|
|
FROM medreport.analysis_responses ar
|
|
JOIN medreport.analysis_response_elements are
|
|
ON are.analysis_response_id = ar.id
|
|
JOIN medreport.analysis_elements ae
|
|
ON are.analysis_element_original_id = ae.analysis_id_original
|
|
WHERE ar.user_id = '9ec20b5a-a939-4e5d-9148-6733e36047f3' -- 👈 your user id
|
|
AND ar.order_status = 'COMPLETED'
|
|
)
|
|
SELECT analysis_name, response_time, norm_upper, norm_lower, norm_status, response_value, analysis_name_lab
|
|
FROM ranked
|
|
WHERE rn = 1
|
|
ORDER BY analysis_name;
|
|
$$;
|
|
|
|
grant execute on function medreport.get_latest_analysis_response_elements_for_current_user(uuid) to authenticated, service_role;
|