At update of non-LP_NORMAL TID, fail instead of corrupting page header.
[pgsql.git] / doc / src / sgml / event-trigger.sgml
blob1bd9abb667650f47a07e99b14a549640e2727498
1 <!-- doc/src/sgml/event-trigger.sgml -->
3 <chapter id="event-triggers">
4 <title>Event Triggers</title>
6 <indexterm zone="event-triggers">
7 <primary>event trigger</primary>
8 </indexterm>
10 <para>
11 To supplement the trigger mechanism discussed in <xref linkend="triggers"/>,
12 <productname>PostgreSQL</productname> also provides event triggers. Unlike regular
13 triggers, which are attached to a single table and capture only DML events,
14 event triggers are global to a particular database and are capable of
15 capturing DDL events.
16 </para>
18 <para>
19 Like regular triggers, event triggers can be written in any procedural
20 language that includes event trigger support, or in C, but not in plain
21 SQL.
22 </para>
24 <sect1 id="event-trigger-definition">
25 <title>Overview of Event Trigger Behavior</title>
27 <para>
28 An event trigger fires whenever the event with which it is associated
29 occurs in the database in which it is defined. Currently, the
30 supported events are
31 <literal>login</literal>,
32 <literal>ddl_command_start</literal>,
33 <literal>ddl_command_end</literal>,
34 <literal>table_rewrite</literal>
35 and <literal>sql_drop</literal>.
36 Support for additional events may be added in future releases.
37 </para>
39 <sect2 id="event-trigger-login">
40 <title>login</title>
42 <para>
43 The <literal>login</literal> event occurs when an authenticated user logs
44 into the system. Any bug in a trigger procedure for this event may
45 prevent successful login to the system. Such bugs may be worked around by
46 setting <xref linkend="guc-event-triggers"/> to <literal>false</literal>
47 either in a connection string or configuration file. Alternatively, you can
48 restart the system in single-user mode (as event triggers are
49 disabled in this mode). See the <xref linkend="app-postgres"/> reference
50 page for details about using single-user mode.
51 The <literal>login</literal> event will also fire on standby servers.
52 To prevent servers from becoming inaccessible, such triggers must avoid
53 writing anything to the database when running on a standby.
54 Also, it's recommended to avoid long-running queries in
55 <literal>login</literal> event triggers. Note that, for instance,
56 canceling a connection in <application>psql</application> will not cancel
57 the in-progress <literal>login</literal> trigger.
58 </para>
60 <para>
61 For an example on how to use the <literal>login</literal> event trigger,
62 see <xref linkend="event-trigger-database-login-example"/>.
63 </para>
64 </sect2>
66 <sect2 id="event-trigger-ddl_command_start">
67 <title>ddl_command_start</title>
69 <para>
70 The <literal>ddl_command_start</literal> event occurs just before the
71 execution of a DDL command. DDL commands in this context are:
72 <itemizedlist>
73 <listitem><para><literal>CREATE</literal></para></listitem>
74 <listitem><para><literal>ALTER</literal></para></listitem>
75 <listitem><para><literal>DROP</literal></para></listitem>
76 <listitem><para><literal>COMMENT</literal></para></listitem>
77 <listitem><para><literal>GRANT</literal></para></listitem>
78 <listitem><para><literal>IMPORT FOREIGN SCHEMA</literal></para></listitem>
79 <listitem><para><literal>REINDEX</literal></para></listitem>
80 <listitem><para><literal>REFRESH MATERIALIZED VIEW</literal></para></listitem>
81 <listitem><para><literal>REVOKE</literal></para></listitem>
82 <listitem><para><literal>SECURITY LABEL</literal></para></listitem>
83 </itemizedlist>
84 <literal>ddl_command_start</literal> also occurs just before the
85 execution of a <literal>SELECT INTO</literal> command, since this is
86 equivalent to <literal>CREATE TABLE AS</literal>.
87 </para>
89 <para>
90 As an exception, this event does not occur for DDL commands targeting
91 shared objects:
92 <itemizedlist>
93 <listitem><para>databases</para></listitem>
94 <listitem><para>roles (role definitions and role memberships)</para></listitem>
95 <listitem><para>tablespaces</para></listitem>
96 <listitem><para>parameter privileges</para></listitem>
97 <listitem><para><command>ALTER SYSTEM</command></para></listitem>
98 </itemizedlist>
99 This event also does not occur for commands targeting event triggers
100 themselves.
101 </para>
103 <para>
104 No check whether the affected object exists or doesn't exist is performed
105 before the event trigger fires.
106 </para>
107 </sect2>
109 <sect2 id="event-trigger-ddl_command_end">
110 <title>ddl_command_end</title>
112 <para>
113 The <literal>ddl_command_end</literal> event occurs just after the execution of
114 the same set of commands as <literal>ddl_command_start</literal>. To
115 obtain more details on the <acronym>DDL</acronym>
116 operations that took place, use the set-returning function
117 <literal>pg_event_trigger_ddl_commands()</literal> from the
118 <literal>ddl_command_end</literal> event trigger code (see
119 <xref linkend="functions-event-triggers"/>). Note that the trigger fires
120 after the actions have taken place (but before the transaction commits),
121 and thus the system catalogs can be read as already changed.
122 </para>
123 </sect2>
125 <sect2 id="event-trigger-sql_drop">
126 <title>sql_drop</title>
128 <para>
129 The <literal>sql_drop</literal> event occurs just before the
130 <literal>ddl_command_end</literal> event trigger for any operation that drops
131 database objects. Note that besides the obvious <literal>DROP</literal>
132 commands, some <literal>ALTER</literal> commands can also trigger an
133 <literal>sql_drop</literal> event.
134 </para>
136 <para>
137 To list the objects that have been dropped, use the
138 set-returning function <literal>pg_event_trigger_dropped_objects()</literal> from the
139 <literal>sql_drop</literal> event trigger code (see
140 <xref linkend="functions-event-triggers"/>). Note that
141 the trigger is executed after the objects have been deleted from the
142 system catalogs, so it's not possible to look them up anymore.
143 </para>
144 </sect2>
146 <sect2 id="event-trigger-table_rewrite">
147 <title>table_rewrite</title>
149 <para>
150 The <literal>table_rewrite</literal> event occurs just before a table is
151 rewritten by some actions of the commands <literal>ALTER TABLE</literal> and
152 <literal>ALTER TYPE</literal>. While other
153 control statements are available to rewrite a table,
154 like <literal>CLUSTER</literal> and <literal>VACUUM</literal>,
155 the <literal>table_rewrite</literal> event is not triggered by them.
156 To find the OID of the table that was rewritten, use the function
157 <literal>pg_event_trigger_table_rewrite_oid()</literal>, to discover the
158 reason(s) for the rewrite, use the function
159 <literal>pg_event_trigger_table_rewrite_reason()</literal> (see <xref
160 linkend="functions-event-triggers"/>).
161 </para>
162 </sect2>
164 <sect2 id="event-trigger-aborted-transactions">
165 <title>Event Triggers in Aborted Transactions</title>
167 <para>
168 Event triggers (like other functions) cannot be executed in an aborted
169 transaction. Thus, if a DDL command fails with an error, any associated
170 <literal>ddl_command_end</literal> triggers will not be executed. Conversely,
171 if a <literal>ddl_command_start</literal> trigger fails with an error, no
172 further event triggers will fire, and no attempt will be made to execute
173 the command itself. Similarly, if a <literal>ddl_command_end</literal> trigger
174 fails with an error, the effects of the DDL statement will be rolled
175 back, just as they would be in any other case where the containing
176 transaction aborts.
177 </para>
178 </sect2>
180 <sect2 id="event-trigger-creating">
181 <title>Creating Event Triggers</title>
183 <para>
184 Event triggers are created using the command <xref linkend="sql-createeventtrigger"/>.
185 In order to create an event trigger, you must first create a function with
186 the special return type <literal>event_trigger</literal>. This function
187 need not (and may not) return a value; the return type serves merely as
188 a signal that the function is to be invoked as an event trigger.
189 </para>
191 <para>
192 If more than one event trigger is defined for a particular event, they will
193 fire in alphabetical order by trigger name.
194 </para>
196 <para>
197 A trigger definition can also specify a <literal>WHEN</literal>
198 condition so that, for example, a <literal>ddl_command_start</literal>
199 trigger can be fired only for particular commands which the user wishes
200 to intercept. A common use of such triggers is to restrict the range of
201 DDL operations which users may perform.
202 </para>
203 </sect2>
204 </sect1>
206 <sect1 id="event-trigger-interface">
207 <title>Writing Event Trigger Functions in C</title>
209 <indexterm zone="event-trigger-interface">
210 <primary>event trigger</primary>
211 <secondary>in C</secondary>
212 </indexterm>
214 <para>
215 This section describes the low-level details of the interface to an
216 event trigger function. This information is only needed when writing
217 event trigger functions in C. If you are using a higher-level language
218 then these details are handled for you. In most cases you should
219 consider using a procedural language before writing your event triggers
220 in C. The documentation of each procedural language explains how to
221 write an event trigger in that language.
222 </para>
224 <para>
225 Event trigger functions must use the <quote>version 1</quote> function
226 manager interface.
227 </para>
229 <para>
230 When a function is called by the event trigger manager, it is not passed
231 any normal arguments, but it is passed a <quote>context</quote> pointer
232 pointing to a <structname>EventTriggerData</structname> structure. C functions can
233 check whether they were called from the event trigger manager or not by
234 executing the macro:
235 <programlisting>
236 CALLED_AS_EVENT_TRIGGER(fcinfo)
237 </programlisting>
238 which expands to:
239 <programlisting>
240 ((fcinfo)-&gt;context != NULL &amp;&amp; IsA((fcinfo)-&gt;context, EventTriggerData))
241 </programlisting>
242 If this returns true, then it is safe to cast
243 <literal>fcinfo-&gt;context</literal> to type <literal>EventTriggerData
244 *</literal> and make use of the pointed-to
245 <structname>EventTriggerData</structname> structure. The function must
246 <emphasis>not</emphasis> alter the <structname>EventTriggerData</structname>
247 structure or any of the data it points to.
248 </para>
250 <para>
251 <structname>struct EventTriggerData</structname> is defined in
252 <filename>commands/event_trigger.h</filename>:
254 <programlisting>
255 typedef struct EventTriggerData
257 NodeTag type;
258 const char *event; /* event name */
259 Node *parsetree; /* parse tree */
260 CommandTag tag; /* command tag */
261 } EventTriggerData;
262 </programlisting>
264 where the members are defined as follows:
266 <variablelist>
267 <varlistentry>
268 <term><structfield>type</structfield></term>
269 <listitem>
270 <para>
271 Always <literal>T_EventTriggerData</literal>.
272 </para>
273 </listitem>
274 </varlistentry>
276 <varlistentry>
277 <term><structfield>event</structfield></term>
278 <listitem>
279 <para>
280 Describes the event for which the function is called, one of
281 <literal>"login"</literal>, <literal>"ddl_command_start"</literal>,
282 <literal>"ddl_command_end"</literal>, <literal>"sql_drop"</literal>,
283 <literal>"table_rewrite"</literal>.
284 See <xref linkend="event-trigger-definition"/> for the meaning of these
285 events.
286 </para>
287 </listitem>
288 </varlistentry>
290 <varlistentry>
291 <term><structfield>parsetree</structfield></term>
292 <listitem>
293 <para>
294 A pointer to the parse tree of the command. Check the PostgreSQL
295 source code for details. The parse tree structure is subject to change
296 without notice.
297 </para>
298 </listitem>
299 </varlistentry>
301 <varlistentry>
302 <term><structfield>tag</structfield></term>
303 <listitem>
304 <para>
305 The command tag associated with the event for which the event trigger
306 is run, for example <literal>"CREATE FUNCTION"</literal>.
307 </para>
308 </listitem>
309 </varlistentry>
310 </variablelist>
311 </para>
313 <para>
314 An event trigger function must return a <symbol>NULL</symbol> pointer
315 (<emphasis>not</emphasis> an SQL null value, that is, do not
316 set <parameter>isNull</parameter> true).
317 </para>
318 </sect1>
320 <sect1 id="event-trigger-example">
321 <title>A Complete Event Trigger Example</title>
323 <para>
324 Here is a very simple example of an event trigger function written in C.
325 (Examples of triggers written in procedural languages can be found in
326 the documentation of the procedural languages.)
327 </para>
329 <para>
330 The function <function>noddl</function> raises an exception each time it is called.
331 The event trigger definition associated the function with
332 the <literal>ddl_command_start</literal> event. The effect is that all DDL
333 commands (with the exceptions mentioned
334 in <xref linkend="event-trigger-definition"/>) are prevented from running.
335 </para>
337 <para>
338 This is the source code of the trigger function:
339 <programlisting><![CDATA[
340 #include "postgres.h"
342 #include "commands/event_trigger.h"
343 #include "fmgr.h"
345 PG_MODULE_MAGIC;
347 PG_FUNCTION_INFO_V1(noddl);
349 Datum
350 noddl(PG_FUNCTION_ARGS)
352 EventTriggerData *trigdata;
354 if (!CALLED_AS_EVENT_TRIGGER(fcinfo)) /* internal error */
355 elog(ERROR, "not fired by event trigger manager");
357 trigdata = (EventTriggerData *) fcinfo->context;
359 ereport(ERROR,
360 (errcode(ERRCODE_INSUFFICIENT_PRIVILEGE),
361 errmsg("command \"%s\" denied",
362 GetCommandTagName(trigdata->tag))));
364 PG_RETURN_NULL();
366 ]]></programlisting>
367 </para>
369 <para>
370 After you have compiled the source code (see <xref linkend="dfunc"/>),
371 declare the function and the triggers:
372 <programlisting>
373 CREATE FUNCTION noddl() RETURNS event_trigger
374 AS 'noddl' LANGUAGE C;
376 CREATE EVENT TRIGGER noddl ON ddl_command_start
377 EXECUTE FUNCTION noddl();
378 </programlisting>
379 </para>
381 <para>
382 Now you can test the operation of the trigger:
383 <screen>
384 =# \dy
385 List of event triggers
386 Name | Event | Owner | Enabled | Function | Tags
387 -------+-------------------+-------+---------+----------+------
388 noddl | ddl_command_start | dim | enabled | noddl |
389 (1 row)
391 =# CREATE TABLE foo(id serial);
392 ERROR: command "CREATE TABLE" denied
393 </screen>
394 </para>
396 <para>
397 In this situation, in order to be able to run some DDL commands when you
398 need to do so, you have to either drop the event trigger or disable it. It
399 can be convenient to disable the trigger for only the duration of a
400 transaction:
401 <programlisting>
402 BEGIN;
403 ALTER EVENT TRIGGER noddl DISABLE;
404 CREATE TABLE foo (id serial);
405 ALTER EVENT TRIGGER noddl ENABLE;
406 COMMIT;
407 </programlisting>
408 (Recall that DDL commands on event triggers themselves are not affected by
409 event triggers.)
410 </para>
411 </sect1>
413 <sect1 id="event-trigger-table-rewrite-example">
414 <title>A Table Rewrite Event Trigger Example</title>
416 <para>
417 Thanks to the <literal>table_rewrite</literal> event, it is possible to implement
418 a table rewriting policy only allowing the rewrite in maintenance windows.
419 </para>
421 <para>
422 Here's an example implementing such a policy.
423 <programlisting>
424 CREATE OR REPLACE FUNCTION no_rewrite()
425 RETURNS event_trigger
426 LANGUAGE plpgsql AS
429 --- Implement local Table Rewriting policy:
430 --- public.foo is not allowed rewriting, ever
431 --- other tables are only allowed rewriting between 1am and 6am
432 --- unless they have more than 100 blocks
434 DECLARE
435 table_oid oid := pg_event_trigger_table_rewrite_oid();
436 current_hour integer := extract('hour' from current_time);
437 pages integer;
438 max_pages integer := 100;
439 BEGIN
440 IF pg_event_trigger_table_rewrite_oid() = 'public.foo'::regclass
441 THEN
442 RAISE EXCEPTION 'you''re not allowed to rewrite the table %',
443 table_oid::regclass;
444 END IF;
446 SELECT INTO pages relpages FROM pg_class WHERE oid = table_oid;
447 IF pages > max_pages
448 THEN
449 RAISE EXCEPTION 'rewrites only allowed for table with less than % pages',
450 max_pages;
451 END IF;
453 IF current_hour NOT BETWEEN 1 AND 6
454 THEN
455 RAISE EXCEPTION 'rewrites only allowed between 1am and 6am';
456 END IF;
457 END;
460 CREATE EVENT TRIGGER no_rewrite_allowed
461 ON table_rewrite
462 EXECUTE FUNCTION no_rewrite();
463 </programlisting>
464 </para>
465 </sect1>
467 <sect1 id="event-trigger-database-login-example">
468 <title>A Database Login Event Trigger Example</title>
470 <para>
471 The event trigger on the <literal>login</literal> event can be
472 useful for logging user logins, for verifying the connection and
473 assigning roles according to current circumstances, or for session
474 data initialization. It is very important that any event trigger using
475 the <literal>login</literal> event checks whether or not the database is
476 in recovery before performing any writes. Writing to a standby server
477 will make it inaccessible.
478 </para>
480 <para>
481 The following example demonstrates these options.
482 <programlisting>
483 -- create test tables and roles
484 CREATE TABLE user_login_log (
485 "user" text,
486 "session_start" timestamp with time zone
488 CREATE ROLE day_worker;
489 CREATE ROLE night_worker;
491 -- the example trigger function
492 CREATE OR REPLACE FUNCTION init_session()
493 RETURNS event_trigger SECURITY DEFINER
494 LANGUAGE plpgsql AS
496 DECLARE
497 hour integer = EXTRACT('hour' FROM current_time at time zone 'utc');
498 rec boolean;
499 BEGIN
500 -- 1. Forbid logging in between 2AM and 4AM.
501 IF hour BETWEEN 2 AND 4 THEN
502 RAISE EXCEPTION 'Login forbidden';
503 END IF;
505 -- The checks below cannot be performed on standby servers so
506 -- ensure the database is not in recovery before we perform any
507 -- operations.
508 SELECT pg_is_in_recovery() INTO rec;
509 IF rec THEN
510 RETURN;
511 END IF;
513 -- 2. Assign some roles. At daytime, grant the day_worker role, else the
514 -- night_worker role.
515 IF hour BETWEEN 8 AND 20 THEN
516 EXECUTE 'REVOKE night_worker FROM ' || quote_ident(session_user);
517 EXECUTE 'GRANT day_worker TO ' || quote_ident(session_user);
518 ELSE
519 EXECUTE 'REVOKE day_worker FROM ' || quote_ident(session_user);
520 EXECUTE 'GRANT night_worker TO ' || quote_ident(session_user);
521 END IF;
523 -- 3. Initialize user session data
524 CREATE TEMP TABLE session_storage (x float, y integer);
525 ALTER TABLE session_storage OWNER TO session_user;
527 -- 4. Log the connection time
528 INSERT INTO public.user_login_log VALUES (session_user, current_timestamp);
530 END;
533 -- trigger definition
534 CREATE EVENT TRIGGER init_session
535 ON login
536 EXECUTE FUNCTION init_session();
537 ALTER EVENT TRIGGER init_session ENABLE ALWAYS;
538 </programlisting>
539 </para>
540 </sect1>
541 </chapter>