CREATE OR REPLACE FUNCTION medreport.insert_company_params_on_new_company() RETURNS trigger LANGUAGE plpgsql AS $function$ BEGIN IF (TG_OP = 'INSERT' AND NEW.slug IS NOT NULL) THEN INSERT INTO medreport.company_params ( account_id, slug, benefit_occurance, benefit_amount ) VALUES ( NEW.id, NEW.slug, NULL, NULL ); END IF; RETURN NEW; END; $function$ ; grant execute on function medreport.insert_company_params_on_new_company() to authenticated, service_role; CREATE OR REPLACE FUNCTION log_company_params_changes() RETURNS trigger AS $$ BEGIN -- For INSERT operation IF (TG_OP = 'INSERT') THEN INSERT INTO audit.log_entries ( schema_name, table_name, record_key, operation, row_data, changed_data, changed_by, changed_by_role, changed_at ) VALUES ( 'medreport', -- Schema name 'company_params', -- Table name NEW.id, -- The ID of the inserted row 'INSERT', -- Operation type NULL, -- No old data for INSERT row_to_json(NEW), -- New data (after the INSERT) auth.uid(), -- The user performing the insert SESSION_USER, -- The role performing the insert CURRENT_TIMESTAMP -- Timestamp of the insert ); -- For UPDATE operation ELSIF (TG_OP = 'UPDATE') THEN INSERT INTO audit.log_entries ( schema_name, table_name, record_key, operation, row_data, changed_data, changed_by, changed_by_role, changed_at ) VALUES ( 'medreport', -- Schema name 'company_params', -- Table name OLD.id, -- The ID of the updated row 'UPDATE', -- Operation type row_to_json(OLD), -- Old data (before the update) row_to_json(NEW), -- New data (after the update) auth.uid(), -- The user performing the update SESSION_USER, -- The role performing the update CURRENT_TIMESTAMP -- Timestamp of the update ); -- For DELETE operation ELSIF (TG_OP = 'DELETE') THEN INSERT INTO audit.log_entries ( schema_name, table_name, record_key, operation, row_data, changed_data, changed_by, changed_by_role, changed_at ) VALUES ( 'medreport', -- Schema name 'company_params', -- Table name OLD.id, -- The ID of the deleted row 'DELETE', -- Operation type row_to_json(OLD), -- Old data (before the delete) NULL, -- No new data for DELETE auth.uid(), -- The user performing the delete SESSION_USER, -- The role performing the delete CURRENT_TIMESTAMP -- Timestamp of the delete ); END IF; RETURN NEW; END; $$ LANGUAGE plpgsql; CREATE TRIGGER company_params_audit_trigger AFTER INSERT OR UPDATE OR DELETE ON medreport.company_params FOR EACH ROW EXECUTE FUNCTION log_company_params_changes(); create or replace function medreport.create_team_account ( account_name text, new_personal_code text ) returns medreport.accounts security definer set search_path = '' as $$ declare existing_account medreport.accounts; current_user uuid := (select auth.uid())::uuid; new_account medreport.accounts; begin if not medreport.is_set('enable_team_accounts') then raise exception 'Team accounts are not enabled'; end if; -- Try to find existing account select * into existing_account from medreport.accounts where personal_code = new_personal_code limit 1; -- If not found, fail if not found then raise exception 'No account found with personal_code = %', new_personal_code; end if; insert into medreport.accounts( name, is_personal_account, primary_owner_user_id) values ( account_name, false, existing_account.id) returning * into new_account; -- Insert membership insert into medreport.accounts_memberships ( user_id, account_id, account_role, created_by, updated_by, created_at, updated_at, has_seen_confirmation ) values ( existing_account.id, new_account.id, 'owner', null, null, now(), now(), false ) on conflict do nothing; return new_account; end; $$ language plpgsql; grant execute on function medreport.create_team_account (text, text) to authenticated, service_role; ALTER TABLE "medreport"."accounts" DROP CONSTRAINT "accounts_primary_owner_user_id_fkey"; ALTER TABLE "medreport"."accounts" ADD CONSTRAINT "accounts_primary_owner_user_id_fkey" FOREIGN KEY (primary_owner_user_id) REFERENCES auth.users(id) ON DELETE CASCADE;