gooderp18绿色标准版
您最多选择25个主题 主题必须以字母或数字开头,可以包含连字符 (-),并且长度不得超过35个字符

516 行
29KB

  1. <?xml version="1.0" encoding="UTF-8" standalone="no"?>
  2. <!DOCTYPE html PUBLIC "-//W3C//DTD XHTML 1.0 Transitional//EN" "http://www.w3.org/TR/xhtml1/DTD/xhtml1-transitional.dtd"><html xmlns="http://www.w3.org/1999/xhtml"><head><meta http-equiv="Content-Type" content="text/html; charset=UTF-8" /><title>42.10. Trigger Functions</title><link rel="stylesheet" type="text/css" href="stylesheet.css" /><link rev="made" href="pgsql-docs@lists.postgresql.org" /><meta name="generator" content="DocBook XSL Stylesheets V1.79.1" /><link rel="prev" href="plpgsql-errors-and-messages.html" title="42.9. Errors and Messages" /><link rel="next" href="plpgsql-implementation.html" title="42.11. PL/pgSQL under the Hood" /></head><body><div xmlns="http://www.w3.org/TR/xhtml1/transitional" class="navheader"><table width="100%" summary="Navigation header"><tr><th colspan="5" align="center">42.10. Trigger Functions</th></tr><tr><td width="10%" align="left"><a accesskey="p" href="plpgsql-errors-and-messages.html" title="42.9. Errors and Messages">Prev</a> </td><td width="10%" align="left"><a accesskey="u" href="plpgsql.html" title="Chapter 42. PL/pgSQL - SQL Procedural Language">Up</a></td><th width="60%" align="center">Chapter 42. <span xmlns="http://www.w3.org/1999/xhtml" class="application">PL/pgSQL</span> - <acronym xmlns="http://www.w3.org/1999/xhtml" class="acronym">SQL</acronym> Procedural Language</th><td width="10%" align="right"><a accesskey="h" href="index.html" title="PostgreSQL 12.4 Documentation">Home</a></td><td width="10%" align="right"> <a accesskey="n" href="plpgsql-implementation.html" title="42.11. PL/pgSQL under the Hood">Next</a></td></tr></table><hr></hr></div><div class="sect1" id="PLPGSQL-TRIGGER"><div class="titlepage"><div><div><h2 class="title" style="clear: both">42.10. Trigger Functions</h2></div></div></div><div class="toc"><dl class="toc"><dt><span class="sect2"><a href="plpgsql-trigger.html#PLPGSQL-DML-TRIGGER">42.10.1. Triggers on Data Changes</a></span></dt><dt><span class="sect2"><a href="plpgsql-trigger.html#PLPGSQL-EVENT-TRIGGER">42.10.2. Triggers on Events</a></span></dt></dl></div><a id="id-1.8.8.12.2" class="indexterm"></a><p>
  3. <span class="application">PL/pgSQL</span> can be used to define trigger
  4. functions on data changes or database events.
  5. A trigger function is created with the <code class="command">CREATE FUNCTION</code>
  6. command, declaring it as a function with no arguments and a return type of
  7. <code class="type">trigger</code> (for data change triggers) or
  8. <code class="type">event_trigger</code> (for database event triggers).
  9. Special local variables named <code class="varname">TG_<em class="replaceable"><code>something</code></em></code> are
  10. automatically defined to describe the condition that triggered the call.
  11. </p><div class="sect2" id="PLPGSQL-DML-TRIGGER"><div class="titlepage"><div><div><h3 class="title">42.10.1. Triggers on Data Changes</h3></div></div></div><p>
  12. A <a class="link" href="triggers.html" title="Chapter 38. Triggers">data change trigger</a> is declared as a
  13. function with no arguments and a return type of <code class="type">trigger</code>.
  14. Note that the function must be declared with no arguments even if it
  15. expects to receive some arguments specified in <code class="command">CREATE TRIGGER</code>
  16. — such arguments are passed via <code class="varname">TG_ARGV</code>, as described
  17. below.
  18. </p><p>
  19. When a <span class="application">PL/pgSQL</span> function is called as a
  20. trigger, several special variables are created automatically in the
  21. top-level block. They are:
  22. </p><div class="variablelist"><dl class="variablelist"><dt><span class="term"><code class="varname">NEW</code></span></dt><dd><p>
  23. Data type <code class="type">RECORD</code>; variable holding the new
  24. database row for <code class="command">INSERT</code>/<code class="command">UPDATE</code> operations in row-level
  25. triggers. This variable is null in statement-level triggers
  26. and for <code class="command">DELETE</code> operations.
  27. </p></dd><dt><span class="term"><code class="varname">OLD</code></span></dt><dd><p>
  28. Data type <code class="type">RECORD</code>; variable holding the old
  29. database row for <code class="command">UPDATE</code>/<code class="command">DELETE</code> operations in row-level
  30. triggers. This variable is null in statement-level triggers
  31. and for <code class="command">INSERT</code> operations.
  32. </p></dd><dt><span class="term"><code class="varname">TG_NAME</code></span></dt><dd><p>
  33. Data type <code class="type">name</code>; variable that contains the name of the trigger actually
  34. fired.
  35. </p></dd><dt><span class="term"><code class="varname">TG_WHEN</code></span></dt><dd><p>
  36. Data type <code class="type">text</code>; a string of
  37. <code class="literal">BEFORE</code>, <code class="literal">AFTER</code>, or
  38. <code class="literal">INSTEAD OF</code>, depending on the trigger's definition.
  39. </p></dd><dt><span class="term"><code class="varname">TG_LEVEL</code></span></dt><dd><p>
  40. Data type <code class="type">text</code>; a string of either
  41. <code class="literal">ROW</code> or <code class="literal">STATEMENT</code>
  42. depending on the trigger's definition.
  43. </p></dd><dt><span class="term"><code class="varname">TG_OP</code></span></dt><dd><p>
  44. Data type <code class="type">text</code>; a string of
  45. <code class="literal">INSERT</code>, <code class="literal">UPDATE</code>,
  46. <code class="literal">DELETE</code>, or <code class="literal">TRUNCATE</code>
  47. telling for which operation the trigger was fired.
  48. </p></dd><dt><span class="term"><code class="varname">TG_RELID</code></span></dt><dd><p>
  49. Data type <code class="type">oid</code>; the object ID of the table that caused the
  50. trigger invocation.
  51. </p></dd><dt><span class="term"><code class="varname">TG_RELNAME</code></span></dt><dd><p>
  52. Data type <code class="type">name</code>; the name of the table that caused the trigger
  53. invocation. This is now deprecated, and could disappear in a future
  54. release. Use <code class="literal">TG_TABLE_NAME</code> instead.
  55. </p></dd><dt><span class="term"><code class="varname">TG_TABLE_NAME</code></span></dt><dd><p>
  56. Data type <code class="type">name</code>; the name of the table that
  57. caused the trigger invocation.
  58. </p></dd><dt><span class="term"><code class="varname">TG_TABLE_SCHEMA</code></span></dt><dd><p>
  59. Data type <code class="type">name</code>; the name of the schema of the
  60. table that caused the trigger invocation.
  61. </p></dd><dt><span class="term"><code class="varname">TG_NARGS</code></span></dt><dd><p>
  62. Data type <code class="type">integer</code>; the number of arguments given to the trigger
  63. function in the <code class="command">CREATE TRIGGER</code> statement.
  64. </p></dd><dt><span class="term"><code class="varname">TG_ARGV[]</code></span></dt><dd><p>
  65. Data type array of <code class="type">text</code>; the arguments from
  66. the <code class="command">CREATE TRIGGER</code> statement.
  67. The index counts from 0. Invalid
  68. indexes (less than 0 or greater than or equal to <code class="varname">tg_nargs</code>)
  69. result in a null value.
  70. </p></dd></dl></div><p>
  71. </p><p>
  72. A trigger function must return either <code class="symbol">NULL</code> or a
  73. record/row value having exactly the structure of the table the
  74. trigger was fired for.
  75. </p><p>
  76. Row-level triggers fired <code class="literal">BEFORE</code> can return null to signal the
  77. trigger manager to skip the rest of the operation for this row
  78. (i.e., subsequent triggers are not fired, and the
  79. <code class="command">INSERT</code>/<code class="command">UPDATE</code>/<code class="command">DELETE</code> does not occur
  80. for this row). If a nonnull
  81. value is returned then the operation proceeds with that row value.
  82. Returning a row value different from the original value
  83. of <code class="varname">NEW</code> alters the row that will be inserted or
  84. updated. Thus, if the trigger function wants the triggering
  85. action to succeed normally without altering the row
  86. value, <code class="varname">NEW</code> (or a value equal thereto) has to be
  87. returned. To alter the row to be stored, it is possible to
  88. replace single values directly in <code class="varname">NEW</code> and return the
  89. modified <code class="varname">NEW</code>, or to build a complete new record/row to
  90. return. In the case of a before-trigger
  91. on <code class="command">DELETE</code>, the returned value has no direct
  92. effect, but it has to be nonnull to allow the trigger action to
  93. proceed. Note that <code class="varname">NEW</code> is null
  94. in <code class="command">DELETE</code> triggers, so returning that is
  95. usually not sensible. The usual idiom in <code class="command">DELETE</code>
  96. triggers is to return <code class="varname">OLD</code>.
  97. </p><p>
  98. <code class="literal">INSTEAD OF</code> triggers (which are always row-level triggers,
  99. and may only be used on views) can return null to signal that they did
  100. not perform any updates, and that the rest of the operation for this
  101. row should be skipped (i.e., subsequent triggers are not fired, and the
  102. row is not counted in the rows-affected status for the surrounding
  103. <code class="command">INSERT</code>/<code class="command">UPDATE</code>/<code class="command">DELETE</code>).
  104. Otherwise a nonnull value should be returned, to signal
  105. that the trigger performed the requested operation. For
  106. <code class="command">INSERT</code> and <code class="command">UPDATE</code> operations, the return value
  107. should be <code class="varname">NEW</code>, which the trigger function may modify to
  108. support <code class="command">INSERT RETURNING</code> and <code class="command">UPDATE RETURNING</code>
  109. (this will also affect the row value passed to any subsequent triggers,
  110. or passed to a special <code class="varname">EXCLUDED</code> alias reference within
  111. an <code class="command">INSERT</code> statement with an <code class="literal">ON CONFLICT DO
  112. UPDATE</code> clause). For <code class="command">DELETE</code> operations, the return
  113. value should be <code class="varname">OLD</code>.
  114. </p><p>
  115. The return value of a row-level trigger
  116. fired <code class="literal">AFTER</code> or a statement-level trigger
  117. fired <code class="literal">BEFORE</code> or <code class="literal">AFTER</code> is
  118. always ignored; it might as well be null. However, any of these types of
  119. triggers might still abort the entire operation by raising an error.
  120. </p><p>
  121. <a class="xref" href="plpgsql-trigger.html#PLPGSQL-TRIGGER-EXAMPLE" title="Example 42.3. A PL/pgSQL Trigger Function">Example 42.3</a> shows an example of a
  122. trigger function in <span class="application">PL/pgSQL</span>.
  123. </p><div class="example" id="PLPGSQL-TRIGGER-EXAMPLE"><p class="title"><strong>Example 42.3. A <span class="application">PL/pgSQL</span> Trigger Function</strong></p><div class="example-contents"><p>
  124. This example trigger ensures that any time a row is inserted or updated
  125. in the table, the current user name and time are stamped into the
  126. row. And it checks that an employee's name is given and that the
  127. salary is a positive value.
  128. </p><pre class="programlisting">
  129. CREATE TABLE emp (
  130. empname text,
  131. salary integer,
  132. last_date timestamp,
  133. last_user text
  134. );
  135. CREATE FUNCTION emp_stamp() RETURNS trigger AS $emp_stamp$
  136. BEGIN
  137. -- Check that empname and salary are given
  138. IF NEW.empname IS NULL THEN
  139. RAISE EXCEPTION 'empname cannot be null';
  140. END IF;
  141. IF NEW.salary IS NULL THEN
  142. RAISE EXCEPTION '% cannot have null salary', NEW.empname;
  143. END IF;
  144. -- Who works for us when they must pay for it?
  145. IF NEW.salary &lt; 0 THEN
  146. RAISE EXCEPTION '% cannot have a negative salary', NEW.empname;
  147. END IF;
  148. -- Remember who changed the payroll when
  149. NEW.last_date := current_timestamp;
  150. NEW.last_user := current_user;
  151. RETURN NEW;
  152. END;
  153. $emp_stamp$ LANGUAGE plpgsql;
  154. CREATE TRIGGER emp_stamp BEFORE INSERT OR UPDATE ON emp
  155. FOR EACH ROW EXECUTE FUNCTION emp_stamp();
  156. </pre></div></div><br class="example-break" /><p>
  157. Another way to log changes to a table involves creating a new table that
  158. holds a row for each insert, update, or delete that occurs. This approach
  159. can be thought of as auditing changes to a table.
  160. <a class="xref" href="plpgsql-trigger.html#PLPGSQL-TRIGGER-AUDIT-EXAMPLE" title="Example 42.4. A PL/pgSQL Trigger Function for Auditing">Example 42.4</a> shows an example of an
  161. audit trigger function in <span class="application">PL/pgSQL</span>.
  162. </p><div class="example" id="PLPGSQL-TRIGGER-AUDIT-EXAMPLE"><p class="title"><strong>Example 42.4. A <span class="application">PL/pgSQL</span> Trigger Function for Auditing</strong></p><div class="example-contents"><p>
  163. This example trigger ensures that any insert, update or delete of a row
  164. in the <code class="literal">emp</code> table is recorded (i.e., audited) in the <code class="literal">emp_audit</code> table.
  165. The current time and user name are stamped into the row, together with
  166. the type of operation performed on it.
  167. </p><pre class="programlisting">
  168. CREATE TABLE emp (
  169. empname text NOT NULL,
  170. salary integer
  171. );
  172. CREATE TABLE emp_audit(
  173. operation char(1) NOT NULL,
  174. stamp timestamp NOT NULL,
  175. userid text NOT NULL,
  176. empname text NOT NULL,
  177. salary integer
  178. );
  179. CREATE OR REPLACE FUNCTION process_emp_audit() RETURNS TRIGGER AS $emp_audit$
  180. BEGIN
  181. --
  182. -- Create a row in emp_audit to reflect the operation performed on emp,
  183. -- making use of the special variable TG_OP to work out the operation.
  184. --
  185. IF (TG_OP = 'DELETE') THEN
  186. INSERT INTO emp_audit SELECT 'D', now(), user, OLD.*;
  187. ELSIF (TG_OP = 'UPDATE') THEN
  188. INSERT INTO emp_audit SELECT 'U', now(), user, NEW.*;
  189. ELSIF (TG_OP = 'INSERT') THEN
  190. INSERT INTO emp_audit SELECT 'I', now(), user, NEW.*;
  191. END IF;
  192. RETURN NULL; -- result is ignored since this is an AFTER trigger
  193. END;
  194. $emp_audit$ LANGUAGE plpgsql;
  195. CREATE TRIGGER emp_audit
  196. AFTER INSERT OR UPDATE OR DELETE ON emp
  197. FOR EACH ROW EXECUTE FUNCTION process_emp_audit();
  198. </pre></div></div><br class="example-break" /><p>
  199. A variation of the previous example uses a view joining the main table
  200. to the audit table, to show when each entry was last modified. This
  201. approach still records the full audit trail of changes to the table,
  202. but also presents a simplified view of the audit trail, showing just
  203. the last modified timestamp derived from the audit trail for each entry.
  204. <a class="xref" href="plpgsql-trigger.html#PLPGSQL-VIEW-TRIGGER-AUDIT-EXAMPLE" title="Example 42.5. A PL/pgSQL View Trigger Function for Auditing">Example 42.5</a> shows an example
  205. of an audit trigger on a view in <span class="application">PL/pgSQL</span>.
  206. </p><div class="example" id="PLPGSQL-VIEW-TRIGGER-AUDIT-EXAMPLE"><p class="title"><strong>Example 42.5. A <span class="application">PL/pgSQL</span> View Trigger Function for Auditing</strong></p><div class="example-contents"><p>
  207. This example uses a trigger on the view to make it updatable, and
  208. ensure that any insert, update or delete of a row in the view is
  209. recorded (i.e., audited) in the <code class="literal">emp_audit</code> table. The current time
  210. and user name are recorded, together with the type of operation
  211. performed, and the view displays the last modified time of each row.
  212. </p><pre class="programlisting">
  213. CREATE TABLE emp (
  214. empname text PRIMARY KEY,
  215. salary integer
  216. );
  217. CREATE TABLE emp_audit(
  218. operation char(1) NOT NULL,
  219. userid text NOT NULL,
  220. empname text NOT NULL,
  221. salary integer,
  222. stamp timestamp NOT NULL
  223. );
  224. CREATE VIEW emp_view AS
  225. SELECT e.empname,
  226. e.salary,
  227. max(ea.stamp) AS last_updated
  228. FROM emp e
  229. LEFT JOIN emp_audit ea ON ea.empname = e.empname
  230. GROUP BY 1, 2;
  231. CREATE OR REPLACE FUNCTION update_emp_view() RETURNS TRIGGER AS $$
  232. BEGIN
  233. --
  234. -- Perform the required operation on emp, and create a row in emp_audit
  235. -- to reflect the change made to emp.
  236. --
  237. IF (TG_OP = 'DELETE') THEN
  238. DELETE FROM emp WHERE empname = OLD.empname;
  239. IF NOT FOUND THEN RETURN NULL; END IF;
  240. OLD.last_updated = now();
  241. INSERT INTO emp_audit VALUES('D', user, OLD.*);
  242. RETURN OLD;
  243. ELSIF (TG_OP = 'UPDATE') THEN
  244. UPDATE emp SET salary = NEW.salary WHERE empname = OLD.empname;
  245. IF NOT FOUND THEN RETURN NULL; END IF;
  246. NEW.last_updated = now();
  247. INSERT INTO emp_audit VALUES('U', user, NEW.*);
  248. RETURN NEW;
  249. ELSIF (TG_OP = 'INSERT') THEN
  250. INSERT INTO emp VALUES(NEW.empname, NEW.salary);
  251. NEW.last_updated = now();
  252. INSERT INTO emp_audit VALUES('I', user, NEW.*);
  253. RETURN NEW;
  254. END IF;
  255. END;
  256. $$ LANGUAGE plpgsql;
  257. CREATE TRIGGER emp_audit
  258. INSTEAD OF INSERT OR UPDATE OR DELETE ON emp_view
  259. FOR EACH ROW EXECUTE FUNCTION update_emp_view();
  260. </pre></div></div><br class="example-break" /><p>
  261. One use of triggers is to maintain a summary table
  262. of another table. The resulting summary can be used in place of the
  263. original table for certain queries — often with vastly reduced run
  264. times.
  265. This technique is commonly used in Data Warehousing, where the tables
  266. of measured or observed data (called fact tables) might be extremely large.
  267. <a class="xref" href="plpgsql-trigger.html#PLPGSQL-TRIGGER-SUMMARY-EXAMPLE" title="Example 42.6. A PL/pgSQL Trigger Function for Maintaining a Summary Table">Example 42.6</a> shows an example of a
  268. trigger function in <span class="application">PL/pgSQL</span> that maintains
  269. a summary table for a fact table in a data warehouse.
  270. </p><div class="example" id="PLPGSQL-TRIGGER-SUMMARY-EXAMPLE"><p class="title"><strong>Example 42.6. A <span class="application">PL/pgSQL</span> Trigger Function for Maintaining a Summary Table</strong></p><div class="example-contents"><p>
  271. The schema detailed here is partly based on the <span class="emphasis"><em>Grocery Store
  272. </em></span> example from <span class="emphasis"><em>The Data Warehouse Toolkit</em></span>
  273. by Ralph Kimball.
  274. </p><pre class="programlisting">
  275. --
  276. -- Main tables - time dimension and sales fact.
  277. --
  278. CREATE TABLE time_dimension (
  279. time_key integer NOT NULL,
  280. day_of_week integer NOT NULL,
  281. day_of_month integer NOT NULL,
  282. month integer NOT NULL,
  283. quarter integer NOT NULL,
  284. year integer NOT NULL
  285. );
  286. CREATE UNIQUE INDEX time_dimension_key ON time_dimension(time_key);
  287. CREATE TABLE sales_fact (
  288. time_key integer NOT NULL,
  289. product_key integer NOT NULL,
  290. store_key integer NOT NULL,
  291. amount_sold numeric(12,2) NOT NULL,
  292. units_sold integer NOT NULL,
  293. amount_cost numeric(12,2) NOT NULL
  294. );
  295. CREATE INDEX sales_fact_time ON sales_fact(time_key);
  296. --
  297. -- Summary table - sales by time.
  298. --
  299. CREATE TABLE sales_summary_bytime (
  300. time_key integer NOT NULL,
  301. amount_sold numeric(15,2) NOT NULL,
  302. units_sold numeric(12) NOT NULL,
  303. amount_cost numeric(15,2) NOT NULL
  304. );
  305. CREATE UNIQUE INDEX sales_summary_bytime_key ON sales_summary_bytime(time_key);
  306. --
  307. -- Function and trigger to amend summarized column(s) on UPDATE, INSERT, DELETE.
  308. --
  309. CREATE OR REPLACE FUNCTION maint_sales_summary_bytime() RETURNS TRIGGER
  310. AS $maint_sales_summary_bytime$
  311. DECLARE
  312. delta_time_key integer;
  313. delta_amount_sold numeric(15,2);
  314. delta_units_sold numeric(12);
  315. delta_amount_cost numeric(15,2);
  316. BEGIN
  317. -- Work out the increment/decrement amount(s).
  318. IF (TG_OP = 'DELETE') THEN
  319. delta_time_key = OLD.time_key;
  320. delta_amount_sold = -1 * OLD.amount_sold;
  321. delta_units_sold = -1 * OLD.units_sold;
  322. delta_amount_cost = -1 * OLD.amount_cost;
  323. ELSIF (TG_OP = 'UPDATE') THEN
  324. -- forbid updates that change the time_key -
  325. -- (probably not too onerous, as DELETE + INSERT is how most
  326. -- changes will be made).
  327. IF ( OLD.time_key != NEW.time_key) THEN
  328. RAISE EXCEPTION 'Update of time_key : % -&gt; % not allowed',
  329. OLD.time_key, NEW.time_key;
  330. END IF;
  331. delta_time_key = OLD.time_key;
  332. delta_amount_sold = NEW.amount_sold - OLD.amount_sold;
  333. delta_units_sold = NEW.units_sold - OLD.units_sold;
  334. delta_amount_cost = NEW.amount_cost - OLD.amount_cost;
  335. ELSIF (TG_OP = 'INSERT') THEN
  336. delta_time_key = NEW.time_key;
  337. delta_amount_sold = NEW.amount_sold;
  338. delta_units_sold = NEW.units_sold;
  339. delta_amount_cost = NEW.amount_cost;
  340. END IF;
  341. -- Insert or update the summary row with the new values.
  342. &lt;&lt;insert_update&gt;&gt;
  343. LOOP
  344. UPDATE sales_summary_bytime
  345. SET amount_sold = amount_sold + delta_amount_sold,
  346. units_sold = units_sold + delta_units_sold,
  347. amount_cost = amount_cost + delta_amount_cost
  348. WHERE time_key = delta_time_key;
  349. EXIT insert_update WHEN found;
  350. BEGIN
  351. INSERT INTO sales_summary_bytime (
  352. time_key,
  353. amount_sold,
  354. units_sold,
  355. amount_cost)
  356. VALUES (
  357. delta_time_key,
  358. delta_amount_sold,
  359. delta_units_sold,
  360. delta_amount_cost
  361. );
  362. EXIT insert_update;
  363. EXCEPTION
  364. WHEN UNIQUE_VIOLATION THEN
  365. -- do nothing
  366. END;
  367. END LOOP insert_update;
  368. RETURN NULL;
  369. END;
  370. $maint_sales_summary_bytime$ LANGUAGE plpgsql;
  371. CREATE TRIGGER maint_sales_summary_bytime
  372. AFTER INSERT OR UPDATE OR DELETE ON sales_fact
  373. FOR EACH ROW EXECUTE FUNCTION maint_sales_summary_bytime();
  374. INSERT INTO sales_fact VALUES(1,1,1,10,3,15);
  375. INSERT INTO sales_fact VALUES(1,2,1,20,5,35);
  376. INSERT INTO sales_fact VALUES(2,2,1,40,15,135);
  377. INSERT INTO sales_fact VALUES(2,3,1,10,1,13);
  378. SELECT * FROM sales_summary_bytime;
  379. DELETE FROM sales_fact WHERE product_key = 1;
  380. SELECT * FROM sales_summary_bytime;
  381. UPDATE sales_fact SET units_sold = units_sold * 2;
  382. SELECT * FROM sales_summary_bytime;
  383. </pre></div></div><br class="example-break" /><p>
  384. <code class="literal">AFTER</code> triggers can also make use of <em class="firstterm">transition
  385. tables</em> to inspect the entire set of rows changed by the triggering
  386. statement. The <code class="command">CREATE TRIGGER</code> command assigns names to one
  387. or both transition tables, and then the function can refer to those names
  388. as though they were read-only temporary tables.
  389. <a class="xref" href="plpgsql-trigger.html#PLPGSQL-TRIGGER-AUDIT-TRANSITION-EXAMPLE" title="Example 42.7. Auditing with Transition Tables">Example 42.7</a> shows an example.
  390. </p><div class="example" id="PLPGSQL-TRIGGER-AUDIT-TRANSITION-EXAMPLE"><p class="title"><strong>Example 42.7. Auditing with Transition Tables</strong></p><div class="example-contents"><p>
  391. This example produces the same results as
  392. <a class="xref" href="plpgsql-trigger.html#PLPGSQL-TRIGGER-AUDIT-EXAMPLE" title="Example 42.4. A PL/pgSQL Trigger Function for Auditing">Example 42.4</a>, but instead of using a
  393. trigger that fires for every row, it uses a trigger that fires once
  394. per statement, after collecting the relevant information in a transition
  395. table. This can be significantly faster than the row-trigger approach
  396. when the invoking statement has modified many rows. Notice that we must
  397. make a separate trigger declaration for each kind of event, since the
  398. <code class="literal">REFERENCING</code> clauses must be different for each case. But
  399. this does not stop us from using a single trigger function if we choose.
  400. (In practice, it might be better to use three separate functions and
  401. avoid the run-time tests on <code class="varname">TG_OP</code>.)
  402. </p><pre class="programlisting">
  403. CREATE TABLE emp (
  404. empname text NOT NULL,
  405. salary integer
  406. );
  407. CREATE TABLE emp_audit(
  408. operation char(1) NOT NULL,
  409. stamp timestamp NOT NULL,
  410. userid text NOT NULL,
  411. empname text NOT NULL,
  412. salary integer
  413. );
  414. CREATE OR REPLACE FUNCTION process_emp_audit() RETURNS TRIGGER AS $emp_audit$
  415. BEGIN
  416. --
  417. -- Create rows in emp_audit to reflect the operations performed on emp,
  418. -- making use of the special variable TG_OP to work out the operation.
  419. --
  420. IF (TG_OP = 'DELETE') THEN
  421. INSERT INTO emp_audit
  422. SELECT 'D', now(), user, o.* FROM old_table o;
  423. ELSIF (TG_OP = 'UPDATE') THEN
  424. INSERT INTO emp_audit
  425. SELECT 'U', now(), user, n.* FROM new_table n;
  426. ELSIF (TG_OP = 'INSERT') THEN
  427. INSERT INTO emp_audit
  428. SELECT 'I', now(), user, n.* FROM new_table n;
  429. END IF;
  430. RETURN NULL; -- result is ignored since this is an AFTER trigger
  431. END;
  432. $emp_audit$ LANGUAGE plpgsql;
  433. CREATE TRIGGER emp_audit_ins
  434. AFTER INSERT ON emp
  435. REFERENCING NEW TABLE AS new_table
  436. FOR EACH STATEMENT EXECUTE FUNCTION process_emp_audit();
  437. CREATE TRIGGER emp_audit_upd
  438. AFTER UPDATE ON emp
  439. REFERENCING OLD TABLE AS old_table NEW TABLE AS new_table
  440. FOR EACH STATEMENT EXECUTE FUNCTION process_emp_audit();
  441. CREATE TRIGGER emp_audit_del
  442. AFTER DELETE ON emp
  443. REFERENCING OLD TABLE AS old_table
  444. FOR EACH STATEMENT EXECUTE FUNCTION process_emp_audit();
  445. </pre></div></div><br class="example-break" /></div><div class="sect2" id="PLPGSQL-EVENT-TRIGGER"><div class="titlepage"><div><div><h3 class="title">42.10.2. Triggers on Events</h3></div></div></div><p>
  446. <span class="application">PL/pgSQL</span> can be used to define
  447. <a class="link" href="event-triggers.html" title="Chapter 39. Event Triggers">event triggers</a>.
  448. <span class="productname">PostgreSQL</span> requires that a function that
  449. is to be called as an event trigger must be declared as a function with
  450. no arguments and a return type of <code class="literal">event_trigger</code>.
  451. </p><p>
  452. When a <span class="application">PL/pgSQL</span> function is called as an
  453. event trigger, several special variables are created automatically
  454. in the top-level block. They are:
  455. </p><div class="variablelist"><dl class="variablelist"><dt><span class="term"><code class="varname">TG_EVENT</code></span></dt><dd><p>
  456. Data type <code class="type">text</code>; a string representing the event the
  457. trigger is fired for.
  458. </p></dd><dt><span class="term"><code class="varname">TG_TAG</code></span></dt><dd><p>
  459. Data type <code class="type">text</code>; variable that contains the command tag
  460. for which the trigger is fired.
  461. </p></dd></dl></div><p>
  462. </p><p>
  463. <a class="xref" href="plpgsql-trigger.html#PLPGSQL-EVENT-TRIGGER-EXAMPLE" title="Example 42.8. A PL/pgSQL Event Trigger Function">Example 42.8</a> shows an example of an
  464. event trigger function in <span class="application">PL/pgSQL</span>.
  465. </p><div class="example" id="PLPGSQL-EVENT-TRIGGER-EXAMPLE"><p class="title"><strong>Example 42.8. A <span class="application">PL/pgSQL</span> Event Trigger Function</strong></p><div class="example-contents"><p>
  466. This example trigger simply raises a <code class="literal">NOTICE</code> message
  467. each time a supported command is executed.
  468. </p><pre class="programlisting">
  469. CREATE OR REPLACE FUNCTION snitch() RETURNS event_trigger AS $$
  470. BEGIN
  471. RAISE NOTICE 'snitch: % %', tg_event, tg_tag;
  472. END;
  473. $$ LANGUAGE plpgsql;
  474. CREATE EVENT TRIGGER snitch ON ddl_command_start EXECUTE FUNCTION snitch();
  475. </pre></div></div><br class="example-break" /></div></div><div class="navfooter"><hr /><table width="100%" summary="Navigation footer"><tr><td width="40%" align="left"><a accesskey="p" href="plpgsql-errors-and-messages.html">Prev</a> </td><td width="20%" align="center"><a accesskey="u" href="plpgsql.html">Up</a></td><td width="40%" align="right"> <a accesskey="n" href="plpgsql-implementation.html">Next</a></td></tr><tr><td width="40%" align="left" valign="top">42.9. Errors and Messages </td><td width="20%" align="center"><a accesskey="h" href="index.html">Home</a></td><td width="40%" align="right" valign="top"> 42.11. <span class="application">PL/pgSQL</span> under the Hood</td></tr></table></div></body></html>
上海开阖软件有限公司 沪ICP备12045867号-1