1-- should fail, return type mismatch
2create event trigger regress_event_trigger
3   on ddl_command_start
4   execute procedure pg_backend_pid();
5
6-- OK
7create function test_event_trigger() returns event_trigger as $$
8BEGIN
9    RAISE NOTICE 'test_event_trigger: % %', tg_event, tg_tag;
10END
11$$ language plpgsql;
12
13-- should fail, can't call it as a plain function
14SELECT test_event_trigger();
15
16-- should fail, event triggers cannot have declared arguments
17create function test_event_trigger_arg(name text)
18returns event_trigger as $$ BEGIN RETURN 1; END $$ language plpgsql;
19
20-- should fail, SQL functions cannot be event triggers
21create function test_event_trigger_sql() returns event_trigger as $$
22SELECT 1 $$ language sql;
23
24-- should fail, no elephant_bootstrap entry point
25create event trigger regress_event_trigger on elephant_bootstrap
26   execute procedure test_event_trigger();
27
28-- OK
29create event trigger regress_event_trigger on ddl_command_start
30   execute procedure test_event_trigger();
31
32-- OK
33create event trigger regress_event_trigger_end on ddl_command_end
34   execute function test_event_trigger();
35
36-- should fail, food is not a valid filter variable
37create event trigger regress_event_trigger2 on ddl_command_start
38   when food in ('sandwich')
39   execute procedure test_event_trigger();
40
41-- should fail, sandwich is not a valid command tag
42create event trigger regress_event_trigger2 on ddl_command_start
43   when tag in ('sandwich')
44   execute procedure test_event_trigger();
45
46-- should fail, create skunkcabbage is not a valid command tag
47create event trigger regress_event_trigger2 on ddl_command_start
48   when tag in ('create table', 'create skunkcabbage')
49   execute procedure test_event_trigger();
50
51-- should fail, can't have event triggers on event triggers
52create event trigger regress_event_trigger2 on ddl_command_start
53   when tag in ('DROP EVENT TRIGGER')
54   execute procedure test_event_trigger();
55
56-- should fail, can't have event triggers on global objects
57create event trigger regress_event_trigger2 on ddl_command_start
58   when tag in ('CREATE ROLE')
59   execute procedure test_event_trigger();
60
61-- should fail, can't have event triggers on global objects
62create event trigger regress_event_trigger2 on ddl_command_start
63   when tag in ('CREATE DATABASE')
64   execute procedure test_event_trigger();
65
66-- should fail, can't have event triggers on global objects
67create event trigger regress_event_trigger2 on ddl_command_start
68   when tag in ('CREATE TABLESPACE')
69   execute procedure test_event_trigger();
70
71-- should fail, can't have same filter variable twice
72create event trigger regress_event_trigger2 on ddl_command_start
73   when tag in ('create table') and tag in ('CREATE FUNCTION')
74   execute procedure test_event_trigger();
75
76-- should fail, can't have arguments
77create event trigger regress_event_trigger2 on ddl_command_start
78   execute procedure test_event_trigger('argument not allowed');
79
80-- OK
81create event trigger regress_event_trigger2 on ddl_command_start
82   when tag in ('create table', 'CREATE FUNCTION')
83   execute procedure test_event_trigger();
84
85-- OK
86comment on event trigger regress_event_trigger is 'test comment';
87
88-- drop as non-superuser should fail
89create role regress_evt_user;
90set role regress_evt_user;
91create event trigger regress_event_trigger_noperms on ddl_command_start
92   execute procedure test_event_trigger();
93reset role;
94
95-- test enabling and disabling
96alter event trigger regress_event_trigger disable;
97-- fires _trigger2 and _trigger_end should fire, but not _trigger
98create table event_trigger_fire1 (a int);
99alter event trigger regress_event_trigger enable;
100set session_replication_role = replica;
101-- fires nothing
102create table event_trigger_fire2 (a int);
103alter event trigger regress_event_trigger enable replica;
104-- fires only _trigger
105create table event_trigger_fire3 (a int);
106alter event trigger regress_event_trigger enable always;
107-- fires only _trigger
108create table event_trigger_fire4 (a int);
109reset session_replication_role;
110-- fires all three
111create table event_trigger_fire5 (a int);
112-- clean up
113alter event trigger regress_event_trigger disable;
114drop table event_trigger_fire2, event_trigger_fire3, event_trigger_fire4, event_trigger_fire5;
115
116-- regress_event_trigger_end should fire on these commands
117grant all on table event_trigger_fire1 to public;
118comment on table event_trigger_fire1 is 'here is a comment';
119revoke all on table event_trigger_fire1 from public;
120drop table event_trigger_fire1;
121create foreign data wrapper useless;
122create server useless_server foreign data wrapper useless;
123create user mapping for regress_evt_user server useless_server;
124alter default privileges for role regress_evt_user
125 revoke delete on tables from regress_evt_user;
126
127-- alter owner to non-superuser should fail
128alter event trigger regress_event_trigger owner to regress_evt_user;
129
130-- alter owner to superuser should work
131alter role regress_evt_user superuser;
132alter event trigger regress_event_trigger owner to regress_evt_user;
133
134-- should fail, name collision
135alter event trigger regress_event_trigger rename to regress_event_trigger2;
136
137-- OK
138alter event trigger regress_event_trigger rename to regress_event_trigger3;
139
140-- should fail, doesn't exist any more
141drop event trigger regress_event_trigger;
142
143-- should fail, regress_evt_user owns some objects
144drop role regress_evt_user;
145
146-- cleanup before next test
147-- these are all OK; the second one should emit a NOTICE
148drop event trigger if exists regress_event_trigger2;
149drop event trigger if exists regress_event_trigger2;
150drop event trigger regress_event_trigger3;
151drop event trigger regress_event_trigger_end;
152
153-- test support for dropped objects
154CREATE SCHEMA schema_one authorization regress_evt_user;
155CREATE SCHEMA schema_two authorization regress_evt_user;
156CREATE SCHEMA audit_tbls authorization regress_evt_user;
157CREATE TEMP TABLE a_temp_tbl ();
158SET SESSION AUTHORIZATION regress_evt_user;
159
160CREATE TABLE schema_one.table_one(a int);
161CREATE TABLE schema_one."table two"(a int);
162CREATE TABLE schema_one.table_three(a int);
163CREATE TABLE audit_tbls.schema_one_table_two(the_value text);
164
165CREATE TABLE schema_two.table_two(a int);
166CREATE TABLE schema_two.table_three(a int, b text);
167CREATE TABLE audit_tbls.schema_two_table_three(the_value text);
168
169CREATE OR REPLACE FUNCTION schema_two.add(int, int) RETURNS int LANGUAGE plpgsql
170  CALLED ON NULL INPUT
171  AS $$ BEGIN RETURN coalesce($1,0) + coalesce($2,0); END; $$;
172CREATE AGGREGATE schema_two.newton
173  (BASETYPE = int, SFUNC = schema_two.add, STYPE = int);
174
175RESET SESSION AUTHORIZATION;
176
177CREATE TABLE undroppable_objs (
178	object_type text,
179	object_identity text
180);
181INSERT INTO undroppable_objs VALUES
182('table', 'schema_one.table_three'),
183('table', 'audit_tbls.schema_two_table_three');
184
185CREATE TABLE dropped_objects (
186	type text,
187	schema text,
188	object text
189);
190
191-- This tests errors raised within event triggers; the one in audit_tbls
192-- uses 2nd-level recursive invocation via test_evtrig_dropped_objects().
193CREATE OR REPLACE FUNCTION undroppable() RETURNS event_trigger
194LANGUAGE plpgsql AS $$
195DECLARE
196	obj record;
197BEGIN
198	PERFORM 1 FROM pg_tables WHERE tablename = 'undroppable_objs';
199	IF NOT FOUND THEN
200		RAISE NOTICE 'table undroppable_objs not found, skipping';
201		RETURN;
202	END IF;
203	FOR obj IN
204		SELECT * FROM pg_event_trigger_dropped_objects() JOIN
205			undroppable_objs USING (object_type, object_identity)
206	LOOP
207		RAISE EXCEPTION 'object % of type % cannot be dropped',
208			obj.object_identity, obj.object_type;
209	END LOOP;
210END;
211$$;
212
213CREATE EVENT TRIGGER undroppable ON sql_drop
214	EXECUTE PROCEDURE undroppable();
215
216CREATE OR REPLACE FUNCTION test_evtrig_dropped_objects() RETURNS event_trigger
217LANGUAGE plpgsql AS $$
218DECLARE
219    obj record;
220BEGIN
221    FOR obj IN SELECT * FROM pg_event_trigger_dropped_objects()
222    LOOP
223        IF obj.object_type = 'table' THEN
224                EXECUTE format('DROP TABLE IF EXISTS audit_tbls.%I',
225					format('%s_%s', obj.schema_name, obj.object_name));
226        END IF;
227
228	INSERT INTO dropped_objects
229		(type, schema, object) VALUES
230		(obj.object_type, obj.schema_name, obj.object_identity);
231    END LOOP;
232END
233$$;
234
235CREATE EVENT TRIGGER regress_event_trigger_drop_objects ON sql_drop
236	WHEN TAG IN ('drop table', 'drop function', 'drop view',
237		'drop owned', 'drop schema', 'alter table')
238	EXECUTE PROCEDURE test_evtrig_dropped_objects();
239
240ALTER TABLE schema_one.table_one DROP COLUMN a;
241DROP SCHEMA schema_one, schema_two CASCADE;
242DELETE FROM undroppable_objs WHERE object_identity = 'audit_tbls.schema_two_table_three';
243DROP SCHEMA schema_one, schema_two CASCADE;
244DELETE FROM undroppable_objs WHERE object_identity = 'schema_one.table_three';
245DROP SCHEMA schema_one, schema_two CASCADE;
246
247SELECT * FROM dropped_objects WHERE schema IS NULL OR schema <> 'pg_toast';
248
249DROP OWNED BY regress_evt_user;
250SELECT * FROM dropped_objects WHERE type = 'schema';
251
252DROP ROLE regress_evt_user;
253
254DROP EVENT TRIGGER regress_event_trigger_drop_objects;
255DROP EVENT TRIGGER undroppable;
256
257CREATE OR REPLACE FUNCTION event_trigger_report_dropped()
258 RETURNS event_trigger
259 LANGUAGE plpgsql
260AS $$
261DECLARE r record;
262BEGIN
263    FOR r IN SELECT * from pg_event_trigger_dropped_objects()
264    LOOP
265    IF NOT r.normal AND NOT r.original THEN
266        CONTINUE;
267    END IF;
268    RAISE NOTICE 'NORMAL: orig=% normal=% istemp=% type=% identity=% name=% args=%',
269        r.original, r.normal, r.is_temporary, r.object_type,
270        r.object_identity, r.address_names, r.address_args;
271    END LOOP;
272END; $$;
273CREATE EVENT TRIGGER regress_event_trigger_report_dropped ON sql_drop
274    EXECUTE PROCEDURE event_trigger_report_dropped();
275CREATE SCHEMA evttrig
276	CREATE TABLE one (col_a SERIAL PRIMARY KEY, col_b text DEFAULT 'forty two')
277	CREATE INDEX one_idx ON one (col_b)
278	CREATE TABLE two (col_c INTEGER CHECK (col_c > 0) REFERENCES one DEFAULT 42);
279
280-- Partitioned tables with a partitioned index
281CREATE TABLE evttrig.parted (
282    id int PRIMARY KEY)
283    PARTITION BY RANGE (id);
284CREATE TABLE evttrig.part_1_10 PARTITION OF evttrig.parted (id)
285  FOR VALUES FROM (1) TO (10);
286CREATE TABLE evttrig.part_10_20 PARTITION OF evttrig.parted (id)
287  FOR VALUES FROM (10) TO (20) PARTITION BY RANGE (id);
288CREATE TABLE evttrig.part_10_15 PARTITION OF evttrig.part_10_20 (id)
289  FOR VALUES FROM (10) TO (15);
290CREATE TABLE evttrig.part_15_20 PARTITION OF evttrig.part_10_20 (id)
291  FOR VALUES FROM (15) TO (20);
292
293ALTER TABLE evttrig.two DROP COLUMN col_c;
294ALTER TABLE evttrig.one ALTER COLUMN col_b DROP DEFAULT;
295ALTER TABLE evttrig.one DROP CONSTRAINT one_pkey;
296DROP INDEX evttrig.one_idx;
297DROP SCHEMA evttrig CASCADE;
298DROP TABLE a_temp_tbl;
299
300DROP EVENT TRIGGER regress_event_trigger_report_dropped;
301
302-- only allowed from within an event trigger function, should fail
303select pg_event_trigger_table_rewrite_oid();
304
305-- test Table Rewrite Event Trigger
306CREATE OR REPLACE FUNCTION test_evtrig_no_rewrite() RETURNS event_trigger
307LANGUAGE plpgsql AS $$
308BEGIN
309  RAISE EXCEPTION 'rewrites not allowed';
310END;
311$$;
312
313create event trigger no_rewrite_allowed on table_rewrite
314  execute procedure test_evtrig_no_rewrite();
315
316create table rewriteme (id serial primary key, foo float);
317insert into rewriteme
318     select x * 1.001 from generate_series(1, 500) as t(x);
319alter table rewriteme alter column foo type numeric;
320alter table rewriteme add column baz int default 0;
321
322-- test with more than one reason to rewrite a single table
323CREATE OR REPLACE FUNCTION test_evtrig_no_rewrite() RETURNS event_trigger
324LANGUAGE plpgsql AS $$
325BEGIN
326  RAISE NOTICE 'Table ''%'' is being rewritten (reason = %)',
327               pg_event_trigger_table_rewrite_oid()::regclass,
328               pg_event_trigger_table_rewrite_reason();
329END;
330$$;
331
332alter table rewriteme
333 add column onemore int default 0,
334 add column another int default -1,
335 alter column foo type numeric(10,4);
336
337-- shouldn't trigger a table_rewrite event
338alter table rewriteme alter column foo type numeric(12,4);
339
340-- typed tables are rewritten when their type changes.  Don't emit table
341-- name, because firing order is not stable.
342CREATE OR REPLACE FUNCTION test_evtrig_no_rewrite() RETURNS event_trigger
343LANGUAGE plpgsql AS $$
344BEGIN
345  RAISE NOTICE 'Table is being rewritten (reason = %)',
346               pg_event_trigger_table_rewrite_reason();
347END;
348$$;
349
350create type rewritetype as (a int);
351create table rewritemetoo1 of rewritetype;
352create table rewritemetoo2 of rewritetype;
353alter type rewritetype alter attribute a type text cascade;
354
355-- but this doesn't work
356create table rewritemetoo3 (a rewritetype);
357alter type rewritetype alter attribute a type varchar cascade;
358
359drop table rewriteme;
360drop event trigger no_rewrite_allowed;
361drop function test_evtrig_no_rewrite();
362
363-- test Row Security Event Trigger
364RESET SESSION AUTHORIZATION;
365CREATE TABLE event_trigger_test (a integer, b text);
366
367CREATE OR REPLACE FUNCTION start_command()
368RETURNS event_trigger AS $$
369BEGIN
370RAISE NOTICE '% - ddl_command_start', tg_tag;
371END;
372$$ LANGUAGE plpgsql;
373
374CREATE OR REPLACE FUNCTION end_command()
375RETURNS event_trigger AS $$
376BEGIN
377RAISE NOTICE '% - ddl_command_end', tg_tag;
378END;
379$$ LANGUAGE plpgsql;
380
381CREATE OR REPLACE FUNCTION drop_sql_command()
382RETURNS event_trigger AS $$
383BEGIN
384RAISE NOTICE '% - sql_drop', tg_tag;
385END;
386$$ LANGUAGE plpgsql;
387
388CREATE EVENT TRIGGER start_rls_command ON ddl_command_start
389    WHEN TAG IN ('CREATE POLICY', 'ALTER POLICY', 'DROP POLICY') EXECUTE PROCEDURE start_command();
390
391CREATE EVENT TRIGGER end_rls_command ON ddl_command_end
392    WHEN TAG IN ('CREATE POLICY', 'ALTER POLICY', 'DROP POLICY') EXECUTE PROCEDURE end_command();
393
394CREATE EVENT TRIGGER sql_drop_command ON sql_drop
395    WHEN TAG IN ('DROP POLICY') EXECUTE PROCEDURE drop_sql_command();
396
397CREATE POLICY p1 ON event_trigger_test USING (FALSE);
398ALTER POLICY p1 ON event_trigger_test USING (TRUE);
399ALTER POLICY p1 ON event_trigger_test RENAME TO p2;
400DROP POLICY p2 ON event_trigger_test;
401
402-- Check the object addresses of all the event triggers.
403SELECT
404    e.evtname,
405    pg_describe_object('pg_event_trigger'::regclass, e.oid, 0) as descr,
406    b.type, b.object_names, b.object_args,
407    pg_identify_object(a.classid, a.objid, a.objsubid) as ident
408  FROM pg_event_trigger as e,
409    LATERAL pg_identify_object_as_address('pg_event_trigger'::regclass, e.oid, 0) as b,
410    LATERAL pg_get_object_address(b.type, b.object_names, b.object_args) as a
411  ORDER BY e.evtname;
412
413DROP EVENT TRIGGER start_rls_command;
414DROP EVENT TRIGGER end_rls_command;
415DROP EVENT TRIGGER sql_drop_command;
416