drop function if exists medreport.get_latest_analysis_response_elements_for_current_user(uuid); 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 = auth.uid() AND ar.order_status IN ('COMPLETED', 'ON_HOLD') ) 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;