update tables if not eligible
This commit is contained in:
@@ -54,3 +54,97 @@ end;$function$
|
||||
grant
|
||||
execute on function medreport.get_account_members (text) to authenticated,
|
||||
service_role;
|
||||
|
||||
create policy "update_accounts_memberships"
|
||||
on "medreport"."accounts_memberships"
|
||||
as permissive
|
||||
for update
|
||||
to authenticated
|
||||
using (medreport.is_account_owner(account_id))
|
||||
with check (medreport.is_account_owner(account_id));
|
||||
|
||||
drop policy "restrict_mfa_accounts_memberships" on "medreport"."accounts_memberships";
|
||||
grant update on table "medreport"."accounts_memberships" to "authenticated";
|
||||
|
||||
drop TRIGGER if exists prevent_memberships_update_check on "medreport"."accounts_memberships";
|
||||
drop function if exists kit.prevent_memberships_update();
|
||||
|
||||
create or replace function medreport.upsert_health_benefits(
|
||||
p_benefit_distribution_schedule_id uuid
|
||||
)
|
||||
returns void
|
||||
language plpgsql
|
||||
security definer
|
||||
as $$
|
||||
declare
|
||||
member_record record;
|
||||
expires_date timestamp with time zone;
|
||||
v_company_id uuid;
|
||||
v_benefit_amount numeric;
|
||||
existing_entry_id uuid;
|
||||
v_target_amount numeric;
|
||||
begin
|
||||
-- Expires on first day of next year.
|
||||
expires_date := date_trunc('year', now() + interval '1 year');
|
||||
|
||||
-- Get company_id and benefit_amount from benefit_distribution_schedule
|
||||
select company_id, benefit_amount into v_company_id, v_benefit_amount
|
||||
from medreport.benefit_distribution_schedule
|
||||
where id = p_benefit_distribution_schedule_id;
|
||||
|
||||
-- Get all personal accounts that are members of this company
|
||||
for member_record in
|
||||
select distinct
|
||||
a.id as personal_account_id,
|
||||
coalesce(am.is_eligible_for_benefits) as is_eligible
|
||||
from medreport.accounts a
|
||||
join medreport.accounts_memberships am on a.id = am.user_id
|
||||
where am.account_id = v_company_id
|
||||
and a.is_personal_account = true
|
||||
loop
|
||||
v_target_amount := case when member_record.is_eligible
|
||||
then v_benefit_amount
|
||||
else 0 end;
|
||||
|
||||
-- Check if there is already a balance entry for this personal account from the same company in same month
|
||||
select id into existing_entry_id
|
||||
from medreport.account_balance_entries
|
||||
where entry_type = 'benefit'
|
||||
and account_id = member_record.personal_account_id
|
||||
and source_company_id = v_company_id
|
||||
and date_trunc('month', created_at) = date_trunc('month', now())
|
||||
LIMIT 1;
|
||||
|
||||
if existing_entry_id is not null then
|
||||
update medreport.account_balance_entries set
|
||||
amount = v_target_amount,
|
||||
expires_at = expires_date,
|
||||
benefit_distribution_schedule_id = p_benefit_distribution_schedule_id
|
||||
where id = existing_entry_id;
|
||||
else
|
||||
-- Insert new balance entry for personal account
|
||||
insert into medreport.account_balance_entries (
|
||||
account_id,
|
||||
amount,
|
||||
entry_type,
|
||||
description,
|
||||
source_company_id,
|
||||
created_by,
|
||||
expires_at,
|
||||
benefit_distribution_schedule_id
|
||||
) values (
|
||||
member_record.personal_account_id,
|
||||
v_target_amount,
|
||||
'benefit',
|
||||
'Health benefit from company',
|
||||
v_company_id,
|
||||
auth.uid(),
|
||||
expires_date,
|
||||
p_benefit_distribution_schedule_id
|
||||
);
|
||||
end if;
|
||||
end loop;
|
||||
end;
|
||||
$$;
|
||||
|
||||
grant execute on function medreport.upsert_health_benefits(uuid) to authenticated, service_role;
|
||||
Reference in New Issue
Block a user