-- Deploy numerus:ensure_role_exists to pg -- requires: schema_auth -- requires: user begin; set search_path to auth, public; create or replace function ensure_role_exists() returns trigger as $$ begin if not exists (select 1 from pg_roles where rolname = new.role) then raise foreign_key_violation using message = 'role not found: ' || new.role; end if; return new; end; $$ language plpgsql; comment on function ensure_role_exists() is 'Makes sure that a role given to a user is a valid, existing role in the cluster.'; revoke execute on function ensure_role_exists() from public; create trigger ensure_role_exists after insert or update on "user" for each row execute procedure ensure_role_exists(); commit;