-- 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. Grant permissions to authenticated users grant select, insert, update, delete on table "medreport"."benefit_distribution_schedule" to authenticated; -- 3. 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; -- 4. 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; $$; -- 5. Grant execute permission to the updated trigger function grant execute on function medreport.trigger_distribute_benefits() to authenticated, service_role;