Files
medreport_mrb2b/supabase/migrations/20251002170200_upsert_account_balance.sql
Danel Kungla d8f314cb00 MED-186: added upsert to balance if increased
MED-185: add wallet balance. to new employee
2025-10-02 18:50:16 +03:00

173 lines
5.4 KiB
PL/PgSQL

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;
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
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
-- 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_benefit_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_benefit_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;
create or replace function medreport.process_periodic_benefit_distributions()
returns void
language plpgsql
as $$
declare
schedule_record record;
next_distribution_date timestamp with time zone;
begin
-- Get all active schedules that are due for distribution
for schedule_record in
select *
from medreport.benefit_distribution_schedule
where is_active = true
and next_distribution_at <= now()
loop
-- Distribute benefits
perform medreport.upsert_health_benefits(
schedule_record.id
);
-- Calculate next distribution date
next_distribution_date := medreport.calculate_next_distribution_date(
schedule_record.benefit_occurrence,
now()
);
-- Update the schedule
update medreport.benefit_distribution_schedule
set
last_distributed_at = now(),
next_distribution_at = next_distribution_date,
updated_at = now()
where id = schedule_record.id;
end loop;
end;
$$;
create or replace function medreport.trigger_distribute_benefits()
returns trigger
language plpgsql
security definer
as $$
declare
v_benefit_distribution_schedule_id uuid;
begin
-- Only distribute if benefit_amount is set and greater than 0
if new.benefit_amount is not null and new.benefit_amount > 0 then
-- Create or update the distribution schedule for future distributions
v_benefit_distribution_schedule_id := medreport.upsert_benefit_distribution_schedule(
new.account_id,
new.benefit_amount,
coalesce(new.benefit_occurance, 'yearly')
);
-- Distribute benefits to all company members immediately
if new.benefit_amount > old.benefit_amount then
perform medreport.upsert_health_benefits(
v_benefit_distribution_schedule_id
);
end if;
else
-- If benefit_amount is 0 or null, deactivate the schedule
update medreport.benefit_distribution_schedule
set is_active = false, updated_at = now()
where company_id = new.account_id;
end if;
return new;
end;
$$;
drop function if exists medreport.distribute_health_benefits(uuid);
create or replace function medreport.trigger_benefits_on_new_membership()
returns trigger
language plpgsql
security definer
as $$
declare
v_schedule_id uuid;
begin
select bds.id into v_schedule_id
from medreport.benefit_distribution_schedule bds
where bds.company_id = new.account_id
limit 1;
if v_schedule_id is not NULL then
PERFORM medreport.upsert_health_benefits(v_schedule_id);
end if;
return new;
end;
$$;
create trigger trigger_insert_benefits_on_accounts_membership
after insert on medreport.accounts_memberships
for EACH row
execute function medreport.trigger_benefits_on_new_membership();