-- 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;