ty tom, works now
kvpg2=# cREATE or replace FUNCTION trigger_after_drop_schema() RETURNS event_trigger
LANGUAGE plpgsql AS $$
DECLARE
r RECORD;
BEGIN
FOR r IN SELECT * FROM pg_event_trigger_dropped_objects()
LOOP
IF r.object_type = 'schema' THEN
execute format ('drop role IF EXISTS r_%I', r.object_name);
end if;
END LOOP;
END;
$$;
CREATE FUNCTION
kvpg2=# drop schema test;
DROP SCHEMA
kvpg2=# \du r_test
List of roles
Role name | Attributes
-----------+------------
br
Kaido
kvpg2=# cREATE or replace FUNCTION trigger_after_drop_schema() RETURNS event_trigger
LANGUAGE plpgsql AS $$
DECLARE
r RECORD;
BEGIN
FOR r IN SELECT * FROM pg_event_trigger_dropped_objects()
LOOP
IF r.object_type = 'schema' THEN
execute format ('drop role IF EXISTS r_%I', r.object_name);
end if;
END LOOP;
END;
$$;
CREATE FUNCTION
kvpg2=# drop schema test;
DROP SCHEMA
kvpg2=# \du r_test
List of roles
Role name | Attributes
-----------+------------
br
Kaido
On Fri, 26 Jul 2024 at 20:44, Tom Lane <tgl@xxxxxxxxxxxxx> wrote:
kaido vaikla <kaido.vaikla@xxxxxxxxx> writes:
> FOR r IN SELECT * FROM pg_event_trigger_dropped_objects()
> LOOP
> execute format ('drop role IF EXISTS r_%I', r.object_name);
> END LOOP;
> kvpg2=# drop schema test;
> ERROR: null values cannot be formatted as an SQL identifier
> CONTEXT: PL/pgSQL function trigger_after_drop_schema() line 7 at EXECUTE
> Question, what i do wrong?
Assume that every dropped object has a name, looks like.
You would probably do well to check object_type before
trying to drop the role.
regards, tom lane