feat(MED-97): create company benefits tables
This commit is contained in:
@@ -0,0 +1,239 @@
|
|||||||
|
-- Create account_balance_entries table to track individual account balances
|
||||||
|
create table "medreport"."account_balance_entries" (
|
||||||
|
"id" uuid not null default gen_random_uuid(),
|
||||||
|
"account_id" uuid not null,
|
||||||
|
"amount" numeric not null,
|
||||||
|
"entry_type" text not null, -- 'benefit', 'purchase', 'refund', etc.
|
||||||
|
"description" text,
|
||||||
|
"source_company_id" uuid, -- Company that provided the benefit
|
||||||
|
"reference_id" text, -- Reference to related record (e.g., analysis order ID)
|
||||||
|
"created_at" timestamp with time zone not null default now(),
|
||||||
|
"created_by" uuid,
|
||||||
|
"expires_at" timestamp with time zone, -- When the balance expires (for benefits)
|
||||||
|
"is_active" boolean not null default true
|
||||||
|
);
|
||||||
|
|
||||||
|
-- Add constraints
|
||||||
|
alter table "medreport"."account_balance_entries" add constraint "account_balance_entries_pkey" primary key (id);
|
||||||
|
alter table "medreport"."account_balance_entries" add constraint "account_balance_entries_account_id_fkey"
|
||||||
|
foreign key (account_id) references medreport.accounts(id) on delete cascade;
|
||||||
|
alter table "medreport"."account_balance_entries" add constraint "account_balance_entries_source_company_id_fkey"
|
||||||
|
foreign key (source_company_id) references medreport.accounts(id) on delete set null;
|
||||||
|
|
||||||
|
-- Add indexes for performance
|
||||||
|
create index "ix_account_balance_entries_account_id" on "medreport"."account_balance_entries" (account_id);
|
||||||
|
create index "ix_account_balance_entries_entry_type" on "medreport"."account_balance_entries" (entry_type);
|
||||||
|
create index "ix_account_balance_entries_created_at" on "medreport"."account_balance_entries" (created_at);
|
||||||
|
create index "ix_account_balance_entries_active" on "medreport"."account_balance_entries" (is_active) where is_active = true;
|
||||||
|
|
||||||
|
-- Enable RLS
|
||||||
|
alter table "medreport"."account_balance_entries" enable row level security;
|
||||||
|
|
||||||
|
-- Create RLS policies
|
||||||
|
create policy "Users can view their own balance entries"
|
||||||
|
on "medreport"."account_balance_entries"
|
||||||
|
for select
|
||||||
|
using (
|
||||||
|
account_id in (
|
||||||
|
select account_id
|
||||||
|
from medreport.accounts_memberships
|
||||||
|
where user_id = auth.uid()
|
||||||
|
)
|
||||||
|
);
|
||||||
|
|
||||||
|
create policy "Service role can manage all balance entries"
|
||||||
|
on "medreport"."account_balance_entries"
|
||||||
|
for all
|
||||||
|
to service_role
|
||||||
|
using (true)
|
||||||
|
with check (true);
|
||||||
|
|
||||||
|
-- Grant permissions
|
||||||
|
grant select, insert, update, delete on table "medreport"."account_balance_entries" to authenticated, service_role;
|
||||||
|
|
||||||
|
-- Create function to get account balance
|
||||||
|
create or replace function medreport.get_account_balance(p_account_id uuid)
|
||||||
|
returns numeric
|
||||||
|
language plpgsql
|
||||||
|
security definer
|
||||||
|
as $$
|
||||||
|
declare
|
||||||
|
total_balance numeric := 0;
|
||||||
|
begin
|
||||||
|
select coalesce(sum(amount), 0)
|
||||||
|
into total_balance
|
||||||
|
from medreport.account_balance_entries
|
||||||
|
where account_id = p_account_id
|
||||||
|
and is_active = true
|
||||||
|
and (expires_at is null or expires_at > now());
|
||||||
|
|
||||||
|
return total_balance;
|
||||||
|
end;
|
||||||
|
$$;
|
||||||
|
|
||||||
|
-- Grant execute permission
|
||||||
|
grant execute on function medreport.get_account_balance(uuid) to authenticated, service_role;
|
||||||
|
|
||||||
|
-- Create function to distribute health benefits to all company members
|
||||||
|
create or replace function medreport.distribute_health_benefits(
|
||||||
|
p_company_id uuid,
|
||||||
|
p_benefit_amount numeric,
|
||||||
|
p_benefit_occurrence text default 'yearly'
|
||||||
|
)
|
||||||
|
returns void
|
||||||
|
language plpgsql
|
||||||
|
security definer
|
||||||
|
as $$
|
||||||
|
declare
|
||||||
|
member_record record;
|
||||||
|
benefit_entry_id uuid;
|
||||||
|
expires_date timestamp with time zone;
|
||||||
|
begin
|
||||||
|
-- Calculate expiration date based on occurrence
|
||||||
|
case p_benefit_occurrence
|
||||||
|
when 'yearly' then
|
||||||
|
expires_date := now() + interval '1 year';
|
||||||
|
when 'monthly' then
|
||||||
|
expires_date := now() + interval '1 month';
|
||||||
|
when 'quarterly' then
|
||||||
|
expires_date := now() + interval '3 months';
|
||||||
|
else
|
||||||
|
expires_date := now() + interval '1 year'; -- default to yearly
|
||||||
|
end case;
|
||||||
|
|
||||||
|
-- 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 = p_company_id
|
||||||
|
and a.is_personal_account = true
|
||||||
|
loop
|
||||||
|
-- Insert balance entry for each personal account
|
||||||
|
insert into medreport.account_balance_entries (
|
||||||
|
account_id,
|
||||||
|
amount,
|
||||||
|
entry_type,
|
||||||
|
description,
|
||||||
|
source_company_id,
|
||||||
|
created_by,
|
||||||
|
expires_at
|
||||||
|
) values (
|
||||||
|
member_record.personal_account_id,
|
||||||
|
p_benefit_amount,
|
||||||
|
'benefit',
|
||||||
|
'Health benefit from company',
|
||||||
|
p_company_id,
|
||||||
|
auth.uid(),
|
||||||
|
expires_date
|
||||||
|
);
|
||||||
|
end loop;
|
||||||
|
end;
|
||||||
|
$$;
|
||||||
|
|
||||||
|
-- Grant execute permission
|
||||||
|
grant execute on function medreport.distribute_health_benefits(uuid, numeric, text) to authenticated, service_role;
|
||||||
|
|
||||||
|
-- Create trigger to automatically distribute benefits when company params are updated
|
||||||
|
create or replace function medreport.trigger_distribute_benefits()
|
||||||
|
returns trigger
|
||||||
|
language plpgsql
|
||||||
|
as $$
|
||||||
|
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
|
||||||
|
-- Distribute benefits to all company members
|
||||||
|
perform medreport.distribute_health_benefits(
|
||||||
|
new.account_id,
|
||||||
|
new.benefit_amount,
|
||||||
|
coalesce(new.benefit_occurance, 'yearly')
|
||||||
|
);
|
||||||
|
end if;
|
||||||
|
|
||||||
|
return new;
|
||||||
|
end;
|
||||||
|
$$;
|
||||||
|
|
||||||
|
-- Create the trigger
|
||||||
|
create trigger trigger_distribute_benefits_on_update
|
||||||
|
after update on medreport.company_params
|
||||||
|
for each row
|
||||||
|
when (old.benefit_amount is distinct from new.benefit_amount or old.benefit_occurance is distinct from new.benefit_occurance)
|
||||||
|
execute function medreport.trigger_distribute_benefits();
|
||||||
|
|
||||||
|
-- Create function to consume balance (for purchases)
|
||||||
|
create or replace function medreport.consume_account_balance(
|
||||||
|
p_account_id uuid,
|
||||||
|
p_amount numeric,
|
||||||
|
p_description text,
|
||||||
|
p_reference_id text default null
|
||||||
|
)
|
||||||
|
returns boolean
|
||||||
|
language plpgsql
|
||||||
|
security definer
|
||||||
|
as $$
|
||||||
|
declare
|
||||||
|
current_balance numeric;
|
||||||
|
remaining_amount numeric := p_amount;
|
||||||
|
entry_record record;
|
||||||
|
consumed_amount numeric;
|
||||||
|
begin
|
||||||
|
-- Get current balance
|
||||||
|
current_balance := medreport.get_account_balance(p_account_id);
|
||||||
|
|
||||||
|
-- Check if sufficient balance
|
||||||
|
if current_balance < p_amount then
|
||||||
|
return false;
|
||||||
|
end if;
|
||||||
|
|
||||||
|
-- Consume balance using FIFO (First In, First Out) with expiration priority
|
||||||
|
for entry_record in
|
||||||
|
select id, amount
|
||||||
|
from medreport.account_balance_entries
|
||||||
|
where account_id = p_account_id
|
||||||
|
and is_active = true
|
||||||
|
and (expires_at is null or expires_at > now())
|
||||||
|
order by
|
||||||
|
case when expires_at is not null then expires_at else '9999-12-31'::timestamp end,
|
||||||
|
created_at
|
||||||
|
loop
|
||||||
|
if remaining_amount <= 0 then
|
||||||
|
exit;
|
||||||
|
end if;
|
||||||
|
|
||||||
|
consumed_amount := least(entry_record.amount, remaining_amount);
|
||||||
|
|
||||||
|
-- Update the entry
|
||||||
|
update medreport.account_balance_entries
|
||||||
|
set amount = amount - consumed_amount,
|
||||||
|
is_active = case when amount - consumed_amount <= 0 then false else true end
|
||||||
|
where id = entry_record.id;
|
||||||
|
|
||||||
|
remaining_amount := remaining_amount - consumed_amount;
|
||||||
|
end loop;
|
||||||
|
|
||||||
|
-- Record the consumption
|
||||||
|
insert into medreport.account_balance_entries (
|
||||||
|
account_id,
|
||||||
|
amount,
|
||||||
|
entry_type,
|
||||||
|
description,
|
||||||
|
reference_id,
|
||||||
|
created_by
|
||||||
|
) values (
|
||||||
|
p_account_id,
|
||||||
|
-p_amount,
|
||||||
|
'purchase',
|
||||||
|
p_description,
|
||||||
|
p_reference_id,
|
||||||
|
auth.uid()
|
||||||
|
);
|
||||||
|
|
||||||
|
return true;
|
||||||
|
end;
|
||||||
|
$$;
|
||||||
|
|
||||||
|
-- Grant execute permission
|
||||||
|
grant execute on function medreport.consume_account_balance(uuid, numeric, text, text) to authenticated, service_role;
|
||||||
|
|
||||||
|
|
||||||
@@ -0,0 +1,303 @@
|
|||||||
|
-- Fix the trigger to actually call the distribution function
|
||||||
|
-- First, drop the existing trigger and function
|
||||||
|
drop trigger if exists trigger_distribute_benefits_on_update on medreport.company_params;
|
||||||
|
drop function if exists medreport.trigger_distribute_benefits();
|
||||||
|
|
||||||
|
-- Create a new trigger function that actually distributes benefits
|
||||||
|
create or replace function medreport.trigger_distribute_benefits()
|
||||||
|
returns trigger
|
||||||
|
language plpgsql
|
||||||
|
as $$
|
||||||
|
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
|
||||||
|
-- Distribute benefits to all company members
|
||||||
|
perform medreport.distribute_health_benefits(
|
||||||
|
new.account_id,
|
||||||
|
new.benefit_amount,
|
||||||
|
coalesce(new.benefit_occurance, 'yearly')
|
||||||
|
);
|
||||||
|
end if;
|
||||||
|
|
||||||
|
return new;
|
||||||
|
end;
|
||||||
|
$$;
|
||||||
|
|
||||||
|
-- Recreate the trigger
|
||||||
|
create trigger trigger_distribute_benefits_on_update
|
||||||
|
after update on medreport.company_params
|
||||||
|
for each row
|
||||||
|
when (old.benefit_amount is distinct from new.benefit_amount or old.benefit_occurance is distinct from new.benefit_occurance)
|
||||||
|
execute function medreport.trigger_distribute_benefits();
|
||||||
|
|
||||||
|
-- Create a table to track periodic benefit distributions
|
||||||
|
create table "medreport"."benefit_distribution_schedule" (
|
||||||
|
"id" uuid not null default gen_random_uuid(),
|
||||||
|
"company_id" uuid not null,
|
||||||
|
"benefit_amount" numeric not null,
|
||||||
|
"benefit_occurrence" text not null,
|
||||||
|
"last_distributed_at" timestamp with time zone,
|
||||||
|
"next_distribution_at" timestamp with time zone not null,
|
||||||
|
"is_active" boolean not null default true,
|
||||||
|
"created_at" timestamp with time zone not null default now(),
|
||||||
|
"updated_at" timestamp with time zone not null default now()
|
||||||
|
);
|
||||||
|
|
||||||
|
-- Add constraints
|
||||||
|
alter table "medreport"."benefit_distribution_schedule" add constraint "benefit_distribution_schedule_pkey" primary key (id);
|
||||||
|
alter table "medreport"."benefit_distribution_schedule" add constraint "benefit_distribution_schedule_company_id_fkey"
|
||||||
|
foreign key (company_id) references medreport.accounts(id) on delete cascade;
|
||||||
|
|
||||||
|
-- Add unique constraint on company_id for upsert functionality
|
||||||
|
create unique index "ix_benefit_distribution_schedule_company_id_unique"
|
||||||
|
on "medreport"."benefit_distribution_schedule" (company_id)
|
||||||
|
where is_active = true;
|
||||||
|
|
||||||
|
-- Add indexes
|
||||||
|
create index "ix_benefit_distribution_schedule_next_distribution" on "medreport"."benefit_distribution_schedule" (next_distribution_at) where is_active = true;
|
||||||
|
create index "ix_benefit_distribution_schedule_company_id" on "medreport"."benefit_distribution_schedule" (company_id);
|
||||||
|
|
||||||
|
-- Enable RLS
|
||||||
|
alter table "medreport"."benefit_distribution_schedule" enable row level security;
|
||||||
|
|
||||||
|
-- Create RLS policies
|
||||||
|
create policy "Service role can manage all distribution schedules"
|
||||||
|
on "medreport"."benefit_distribution_schedule"
|
||||||
|
for all
|
||||||
|
to service_role
|
||||||
|
using (true)
|
||||||
|
with check (true);
|
||||||
|
|
||||||
|
create policy "Users can view distribution schedules for their companies"
|
||||||
|
on "medreport"."benefit_distribution_schedule"
|
||||||
|
for select
|
||||||
|
to authenticated
|
||||||
|
using (
|
||||||
|
company_id in (
|
||||||
|
select account_id
|
||||||
|
from medreport.accounts_memberships
|
||||||
|
where user_id = auth.uid()
|
||||||
|
)
|
||||||
|
);
|
||||||
|
|
||||||
|
-- Grant permissions
|
||||||
|
grant select, insert, update, delete on table "medreport"."benefit_distribution_schedule" to service_role, authenticated;
|
||||||
|
|
||||||
|
-- Function to calculate next distribution date
|
||||||
|
create or replace function medreport.calculate_next_distribution_date(
|
||||||
|
p_occurrence text,
|
||||||
|
p_current_date timestamp with time zone default now()
|
||||||
|
)
|
||||||
|
returns timestamp with time zone
|
||||||
|
language plpgsql
|
||||||
|
as $$
|
||||||
|
declare
|
||||||
|
next_date timestamp with time zone;
|
||||||
|
current_year integer;
|
||||||
|
current_month integer;
|
||||||
|
current_quarter integer;
|
||||||
|
begin
|
||||||
|
case p_occurrence
|
||||||
|
when 'yearly' then
|
||||||
|
-- First day of next year
|
||||||
|
current_year := extract(year from p_current_date);
|
||||||
|
next_date := make_date(current_year + 1, 1, 1);
|
||||||
|
return next_date;
|
||||||
|
|
||||||
|
when 'monthly' then
|
||||||
|
-- First day of next month
|
||||||
|
current_year := extract(year from p_current_date);
|
||||||
|
current_month := extract(month from p_current_date);
|
||||||
|
if current_month = 12 then
|
||||||
|
next_date := make_date(current_year + 1, 1, 1);
|
||||||
|
else
|
||||||
|
next_date := make_date(current_year, current_month + 1, 1);
|
||||||
|
end if;
|
||||||
|
return next_date;
|
||||||
|
|
||||||
|
when 'quarterly' then
|
||||||
|
-- First day of next quarter
|
||||||
|
current_year := extract(year from p_current_date);
|
||||||
|
current_month := extract(month from p_current_date);
|
||||||
|
current_quarter := ((current_month - 1) / 3) + 1;
|
||||||
|
|
||||||
|
if current_quarter = 4 then
|
||||||
|
next_date := make_date(current_year + 1, 1, 1);
|
||||||
|
else
|
||||||
|
next_date := make_date(current_year, (current_quarter * 3) + 1, 1);
|
||||||
|
end if;
|
||||||
|
return next_date;
|
||||||
|
|
||||||
|
else
|
||||||
|
-- Default to yearly
|
||||||
|
current_year := extract(year from p_current_date);
|
||||||
|
next_date := make_date(current_year + 1, 1, 1);
|
||||||
|
return next_date;
|
||||||
|
end case;
|
||||||
|
end;
|
||||||
|
$$;
|
||||||
|
|
||||||
|
-- Grant execute permission
|
||||||
|
grant execute on function medreport.calculate_next_distribution_date(text, timestamp with time zone) to authenticated, service_role;
|
||||||
|
|
||||||
|
-- Function to process periodic benefit distributions
|
||||||
|
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.distribute_health_benefits(
|
||||||
|
schedule_record.company_id,
|
||||||
|
schedule_record.benefit_amount,
|
||||||
|
schedule_record.benefit_occurrence
|
||||||
|
);
|
||||||
|
|
||||||
|
-- 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;
|
||||||
|
$$;
|
||||||
|
|
||||||
|
-- Grant execute permission
|
||||||
|
grant execute on function medreport.process_periodic_benefit_distributions() to service_role;
|
||||||
|
|
||||||
|
-- Function to create or update a benefit distribution schedule
|
||||||
|
create or replace function medreport.upsert_benefit_distribution_schedule(
|
||||||
|
p_company_id uuid,
|
||||||
|
p_benefit_amount numeric,
|
||||||
|
p_benefit_occurrence text
|
||||||
|
)
|
||||||
|
returns void
|
||||||
|
language plpgsql
|
||||||
|
as $$
|
||||||
|
declare
|
||||||
|
next_distribution_date timestamp with time zone;
|
||||||
|
existing_record_id uuid;
|
||||||
|
begin
|
||||||
|
-- Calculate next distribution date
|
||||||
|
next_distribution_date := medreport.calculate_next_distribution_date(p_benefit_occurrence);
|
||||||
|
|
||||||
|
-- Check if there's an existing record for this company
|
||||||
|
select id into existing_record_id
|
||||||
|
from medreport.benefit_distribution_schedule
|
||||||
|
where company_id = p_company_id
|
||||||
|
limit 1;
|
||||||
|
|
||||||
|
if existing_record_id is not null then
|
||||||
|
-- Update existing record
|
||||||
|
update medreport.benefit_distribution_schedule
|
||||||
|
set
|
||||||
|
benefit_amount = p_benefit_amount,
|
||||||
|
benefit_occurrence = p_benefit_occurrence,
|
||||||
|
next_distribution_at = next_distribution_date,
|
||||||
|
is_active = true,
|
||||||
|
updated_at = now()
|
||||||
|
where id = existing_record_id;
|
||||||
|
else
|
||||||
|
-- Insert new record
|
||||||
|
insert into medreport.benefit_distribution_schedule (
|
||||||
|
company_id,
|
||||||
|
benefit_amount,
|
||||||
|
benefit_occurrence,
|
||||||
|
next_distribution_at
|
||||||
|
) values (
|
||||||
|
p_company_id,
|
||||||
|
p_benefit_amount,
|
||||||
|
p_benefit_occurrence,
|
||||||
|
next_distribution_date
|
||||||
|
);
|
||||||
|
end if;
|
||||||
|
end;
|
||||||
|
$$;
|
||||||
|
|
||||||
|
-- Grant execute permission
|
||||||
|
grant execute on function medreport.upsert_benefit_distribution_schedule(uuid, numeric, text) to service_role, authenticated;
|
||||||
|
grant execute on function medreport.distribute_health_benefits(uuid, numeric, text) to service_role, authenticated;
|
||||||
|
grant execute on function medreport.calculate_next_distribution_date(text, timestamp with time zone) to service_role, authenticated;
|
||||||
|
|
||||||
|
-- Also grant permissions to the original functions from the first migration
|
||||||
|
grant execute on function medreport.get_account_balance(uuid) to service_role, authenticated;
|
||||||
|
grant execute on function medreport.consume_account_balance(uuid, numeric, text, text) to service_role, authenticated;
|
||||||
|
|
||||||
|
-- Update the trigger to also create/update the distribution schedule
|
||||||
|
create or replace function medreport.trigger_distribute_benefits()
|
||||||
|
returns trigger
|
||||||
|
language plpgsql
|
||||||
|
security definer
|
||||||
|
as $$
|
||||||
|
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
|
||||||
|
-- Distribute benefits to all company members immediately
|
||||||
|
perform medreport.distribute_health_benefits(
|
||||||
|
new.account_id,
|
||||||
|
new.benefit_amount,
|
||||||
|
coalesce(new.benefit_occurance, 'yearly')
|
||||||
|
);
|
||||||
|
|
||||||
|
-- Create or update the distribution schedule for future distributions
|
||||||
|
perform medreport.upsert_benefit_distribution_schedule(
|
||||||
|
new.account_id,
|
||||||
|
new.benefit_amount,
|
||||||
|
coalesce(new.benefit_occurance, 'yearly')
|
||||||
|
);
|
||||||
|
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;
|
||||||
|
$$;
|
||||||
|
|
||||||
|
-- Create a function to manually trigger benefit distribution (for testing)
|
||||||
|
create or replace function medreport.trigger_benefit_distribution(p_company_id uuid)
|
||||||
|
returns void
|
||||||
|
language plpgsql
|
||||||
|
as $$
|
||||||
|
declare
|
||||||
|
company_params record;
|
||||||
|
begin
|
||||||
|
-- Get company params
|
||||||
|
select * into company_params
|
||||||
|
from medreport.company_params
|
||||||
|
where account_id = p_company_id;
|
||||||
|
|
||||||
|
if found and company_params.benefit_amount > 0 then
|
||||||
|
-- Distribute benefits
|
||||||
|
perform medreport.distribute_health_benefits(
|
||||||
|
p_company_id,
|
||||||
|
company_params.benefit_amount,
|
||||||
|
coalesce(company_params.benefit_occurance, 'yearly')
|
||||||
|
);
|
||||||
|
end if;
|
||||||
|
end;
|
||||||
|
$$;
|
||||||
|
|
||||||
|
-- Grant execute permission
|
||||||
|
grant execute on function medreport.trigger_benefit_distribution(uuid) to service_role, authenticated;
|
||||||
|
grant execute on function medreport.trigger_distribute_benefits() to service_role, authenticated;
|
||||||
48
supabase/migrations/20250101000002_fix_permissions.sql
Normal file
48
supabase/migrations/20250101000002_fix_permissions.sql
Normal file
@@ -0,0 +1,48 @@
|
|||||||
|
-- Quick fix for RLS permissions issue
|
||||||
|
-- Run this immediately to fix the permission denied error
|
||||||
|
|
||||||
|
-- Grant execute permissions to authenticated users for all benefit distribution functions
|
||||||
|
grant execute on function medreport.get_account_balance(uuid) to authenticated;
|
||||||
|
grant execute on function medreport.distribute_health_benefits(uuid, numeric, text) to authenticated;
|
||||||
|
grant execute on function medreport.consume_account_balance(uuid, numeric, text, text) to authenticated;
|
||||||
|
grant execute on function medreport.upsert_benefit_distribution_schedule(uuid, numeric, text) to authenticated;
|
||||||
|
grant execute on function medreport.calculate_next_distribution_date(text, timestamp with time zone) to authenticated;
|
||||||
|
grant execute on function medreport.trigger_benefit_distribution(uuid) to authenticated;
|
||||||
|
grant execute on function medreport.trigger_distribute_benefits() to authenticated;
|
||||||
|
grant execute on function medreport.process_periodic_benefit_distributions() to authenticated;
|
||||||
|
|
||||||
|
-- Also ensure the trigger function has security definer
|
||||||
|
create or replace function medreport.trigger_distribute_benefits()
|
||||||
|
returns trigger
|
||||||
|
language plpgsql
|
||||||
|
security definer
|
||||||
|
as $$
|
||||||
|
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
|
||||||
|
-- Distribute benefits to all company members immediately
|
||||||
|
perform medreport.distribute_health_benefits(
|
||||||
|
new.account_id,
|
||||||
|
new.benefit_amount,
|
||||||
|
coalesce(new.benefit_occurance, 'yearly')
|
||||||
|
);
|
||||||
|
|
||||||
|
-- Create or update the distribution schedule for future distributions
|
||||||
|
perform medreport.upsert_benefit_distribution_schedule(
|
||||||
|
new.account_id,
|
||||||
|
new.benefit_amount,
|
||||||
|
coalesce(new.benefit_occurance, 'yearly')
|
||||||
|
);
|
||||||
|
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;
|
||||||
|
$$;
|
||||||
|
|
||||||
|
-- Grant execute permission to the updated trigger function
|
||||||
|
grant execute on function medreport.trigger_distribute_benefits() to authenticated, service_role;
|
||||||
114
supabase/migrations/20250101000003_fix_upsert_and_rls.sql
Normal file
114
supabase/migrations/20250101000003_fix_upsert_and_rls.sql
Normal file
@@ -0,0 +1,114 @@
|
|||||||
|
-- Fix upsert function and RLS permissions
|
||||||
|
-- Run this to fix the ON CONFLICT error and 403 permission error
|
||||||
|
|
||||||
|
-- 1. Fix the upsert function to not use ON CONFLICT
|
||||||
|
create or replace function medreport.upsert_benefit_distribution_schedule(
|
||||||
|
p_company_id uuid,
|
||||||
|
p_benefit_amount numeric,
|
||||||
|
p_benefit_occurrence text
|
||||||
|
)
|
||||||
|
returns void
|
||||||
|
language plpgsql
|
||||||
|
as $$
|
||||||
|
declare
|
||||||
|
next_distribution_date timestamp with time zone;
|
||||||
|
existing_record_id uuid;
|
||||||
|
begin
|
||||||
|
-- Calculate next distribution date
|
||||||
|
next_distribution_date := medreport.calculate_next_distribution_date(p_benefit_occurrence);
|
||||||
|
|
||||||
|
-- Check if there's an existing record for this company
|
||||||
|
select id into existing_record_id
|
||||||
|
from medreport.benefit_distribution_schedule
|
||||||
|
where company_id = p_company_id
|
||||||
|
limit 1;
|
||||||
|
|
||||||
|
if existing_record_id is not null then
|
||||||
|
-- Update existing record
|
||||||
|
update medreport.benefit_distribution_schedule
|
||||||
|
set
|
||||||
|
benefit_amount = p_benefit_amount,
|
||||||
|
benefit_occurrence = p_benefit_occurrence,
|
||||||
|
next_distribution_at = next_distribution_date,
|
||||||
|
is_active = true,
|
||||||
|
updated_at = now()
|
||||||
|
where id = existing_record_id;
|
||||||
|
else
|
||||||
|
-- Insert new record
|
||||||
|
insert into medreport.benefit_distribution_schedule (
|
||||||
|
company_id,
|
||||||
|
benefit_amount,
|
||||||
|
benefit_occurrence,
|
||||||
|
next_distribution_at
|
||||||
|
) values (
|
||||||
|
p_company_id,
|
||||||
|
p_benefit_amount,
|
||||||
|
p_benefit_occurrence,
|
||||||
|
next_distribution_date
|
||||||
|
);
|
||||||
|
end if;
|
||||||
|
end;
|
||||||
|
$$;
|
||||||
|
|
||||||
|
-- 2. Add RLS policy for authenticated users to read distribution schedules
|
||||||
|
create policy "Users can view distribution schedules for their companies"
|
||||||
|
on "medreport"."benefit_distribution_schedule"
|
||||||
|
for select
|
||||||
|
to authenticated
|
||||||
|
using (
|
||||||
|
company_id in (
|
||||||
|
select account_id
|
||||||
|
from medreport.accounts_memberships
|
||||||
|
where user_id = auth.uid()
|
||||||
|
)
|
||||||
|
);
|
||||||
|
|
||||||
|
-- 3. Grant permissions to authenticated users
|
||||||
|
grant select, insert, update, delete on table "medreport"."benefit_distribution_schedule" to authenticated;
|
||||||
|
|
||||||
|
-- 4. Grant execute permissions to all functions
|
||||||
|
grant execute on function medreport.get_account_balance(uuid) to authenticated;
|
||||||
|
grant execute on function medreport.distribute_health_benefits(uuid, numeric, text) to authenticated;
|
||||||
|
grant execute on function medreport.consume_account_balance(uuid, numeric, text, text) to authenticated;
|
||||||
|
grant execute on function medreport.upsert_benefit_distribution_schedule(uuid, numeric, text) to authenticated;
|
||||||
|
grant execute on function medreport.calculate_next_distribution_date(text, timestamp with time zone) to authenticated;
|
||||||
|
grant execute on function medreport.trigger_benefit_distribution(uuid) to authenticated;
|
||||||
|
grant execute on function medreport.trigger_distribute_benefits() to authenticated;
|
||||||
|
grant execute on function medreport.process_periodic_benefit_distributions() to authenticated;
|
||||||
|
|
||||||
|
-- 5. Ensure trigger function has security definer
|
||||||
|
create or replace function medreport.trigger_distribute_benefits()
|
||||||
|
returns trigger
|
||||||
|
language plpgsql
|
||||||
|
security definer
|
||||||
|
as $$
|
||||||
|
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
|
||||||
|
-- Distribute benefits to all company members immediately
|
||||||
|
perform medreport.distribute_health_benefits(
|
||||||
|
new.account_id,
|
||||||
|
new.benefit_amount,
|
||||||
|
coalesce(new.benefit_occurance, 'yearly')
|
||||||
|
);
|
||||||
|
|
||||||
|
-- Create or update the distribution schedule for future distributions
|
||||||
|
perform medreport.upsert_benefit_distribution_schedule(
|
||||||
|
new.account_id,
|
||||||
|
new.benefit_amount,
|
||||||
|
coalesce(new.benefit_occurance, 'yearly')
|
||||||
|
);
|
||||||
|
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;
|
||||||
|
$$;
|
||||||
|
|
||||||
|
-- 6. Grant execute permission to the updated trigger function
|
||||||
|
grant execute on function medreport.trigger_distribute_benefits() to authenticated, service_role;
|
||||||
|
|
||||||
Reference in New Issue
Block a user