gooderp18绿色标准版
Nelze vybrat více než 25 témat Téma musí začínat písmenem nebo číslem, může obsahovat pomlčky („-“) a může být dlouhé až 35 znaků.

750 lines
34KB

  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>40.4. Rules on INSERT, UPDATE, and DELETE</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="rules-materializedviews.html" title="40.3. Materialized Views" /><link rel="next" href="rules-privileges.html" title="40.5. Rules and Privileges" /></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">40.4. Rules on <code xmlns="http://www.w3.org/1999/xhtml" class="command">INSERT</code>, <code xmlns="http://www.w3.org/1999/xhtml" class="command">UPDATE</code>, and <code xmlns="http://www.w3.org/1999/xhtml" class="command">DELETE</code></th></tr><tr><td width="10%" align="left"><a accesskey="p" href="rules-materializedviews.html" title="40.3. Materialized Views">Prev</a> </td><td width="10%" align="left"><a accesskey="u" href="rules.html" title="Chapter 40. The Rule System">Up</a></td><th width="60%" align="center">Chapter 40. The Rule System</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="rules-privileges.html" title="40.5. Rules and Privileges">Next</a></td></tr></table><hr></hr></div><div class="sect1" id="RULES-UPDATE"><div class="titlepage"><div><div><h2 class="title" style="clear: both">40.4. Rules on <code class="command">INSERT</code>, <code class="command">UPDATE</code>, and <code class="command">DELETE</code></h2></div></div></div><div class="toc"><dl class="toc"><dt><span class="sect2"><a href="rules-update.html#id-1.8.6.9.7">40.4.1. How Update Rules Work</a></span></dt><dt><span class="sect2"><a href="rules-update.html#RULES-UPDATE-VIEWS">40.4.2. Cooperation with Views</a></span></dt></dl></div><a id="id-1.8.6.9.2" class="indexterm"></a><a id="id-1.8.6.9.3" class="indexterm"></a><a id="id-1.8.6.9.4" class="indexterm"></a><p>
  3. Rules that are defined on <code class="command">INSERT</code>, <code class="command">UPDATE</code>,
  4. and <code class="command">DELETE</code> are significantly different from the view rules
  5. described in the previous section. First, their <code class="command">CREATE
  6. RULE</code> command allows more:
  7. </p><div class="itemizedlist"><ul class="itemizedlist" style="list-style-type: disc; "><li class="listitem"><p>
  8. They are allowed to have no action.
  9. </p></li><li class="listitem"><p>
  10. They can have multiple actions.
  11. </p></li><li class="listitem"><p>
  12. They can be <code class="literal">INSTEAD</code> or <code class="literal">ALSO</code> (the default).
  13. </p></li><li class="listitem"><p>
  14. The pseudorelations <code class="literal">NEW</code> and <code class="literal">OLD</code> become useful.
  15. </p></li><li class="listitem"><p>
  16. They can have rule qualifications.
  17. </p></li></ul></div><p>
  18. Second, they don't modify the query tree in place. Instead they
  19. create zero or more new query trees and can throw away the
  20. original one.
  21. </p><div class="caution"><h3 class="title">Caution</h3><p>
  22. In many cases, tasks that could be performed by rules
  23. on <code class="command">INSERT</code>/<code class="command">UPDATE</code>/<code class="command">DELETE</code> are better done
  24. with triggers. Triggers are notationally a bit more complicated, but their
  25. semantics are much simpler to understand. Rules tend to have surprising
  26. results when the original query contains volatile functions: volatile
  27. functions may get executed more times than expected in the process of
  28. carrying out the rules.
  29. </p><p>
  30. Also, there are some cases that are not supported by these types of rules at
  31. all, notably including <code class="literal">WITH</code> clauses in the original query and
  32. multiple-assignment sub-<code class="literal">SELECT</code>s in the <code class="literal">SET</code> list
  33. of <code class="command">UPDATE</code> queries. This is because copying these constructs
  34. into a rule query would result in multiple evaluations of the sub-query,
  35. contrary to the express intent of the query's author.
  36. </p></div><div class="sect2" id="id-1.8.6.9.7"><div class="titlepage"><div><div><h3 class="title">40.4.1. How Update Rules Work</h3></div></div></div><p>
  37. Keep the syntax:
  38. </p><pre class="programlisting">
  39. CREATE [ OR REPLACE ] RULE <em class="replaceable"><code>name</code></em> AS ON <em class="replaceable"><code>event</code></em>
  40. TO <em class="replaceable"><code>table</code></em> [ WHERE <em class="replaceable"><code>condition</code></em> ]
  41. DO [ ALSO | INSTEAD ] { NOTHING | <em class="replaceable"><code>command</code></em> | ( <em class="replaceable"><code>command</code></em> ; <em class="replaceable"><code>command</code></em> ... ) }
  42. </pre><p>
  43. in mind.
  44. In the following, <em class="firstterm">update rules</em> means rules that are defined
  45. on <code class="command">INSERT</code>, <code class="command">UPDATE</code>, or <code class="command">DELETE</code>.
  46. </p><p>
  47. Update rules get applied by the rule system when the result
  48. relation and the command type of a query tree are equal to the
  49. object and event given in the <code class="command">CREATE RULE</code> command.
  50. For update rules, the rule system creates a list of query trees.
  51. Initially the query-tree list is empty.
  52. There can be zero (<code class="literal">NOTHING</code> key word), one, or multiple actions.
  53. To simplify, we will look at a rule with one action. This rule
  54. can have a qualification or not and it can be <code class="literal">INSTEAD</code> or
  55. <code class="literal">ALSO</code> (the default).
  56. </p><p>
  57. What is a rule qualification? It is a restriction that tells
  58. when the actions of the rule should be done and when not. This
  59. qualification can only reference the pseudorelations <code class="literal">NEW</code> and/or <code class="literal">OLD</code>,
  60. which basically represent the relation that was given as object (but with a
  61. special meaning).
  62. </p><p>
  63. So we have three cases that produce the following query trees for
  64. a one-action rule.
  65. </p><div class="variablelist"><dl class="variablelist"><dt><span class="term">No qualification, with either <code class="literal">ALSO</code> or
  66. <code class="literal">INSTEAD</code></span></dt><dd><p>
  67. the query tree from the rule action with the original query
  68. tree's qualification added
  69. </p></dd><dt><span class="term">Qualification given and <code class="literal">ALSO</code></span></dt><dd><p>
  70. the query tree from the rule action with the rule
  71. qualification and the original query tree's qualification
  72. added
  73. </p></dd><dt><span class="term">Qualification given and <code class="literal">INSTEAD</code></span></dt><dd><p>
  74. the query tree from the rule action with the rule
  75. qualification and the original query tree's qualification; and
  76. the original query tree with the negated rule qualification
  77. added
  78. </p></dd></dl></div><p>
  79. Finally, if the rule is <code class="literal">ALSO</code>, the unchanged original query tree is
  80. added to the list. Since only qualified <code class="literal">INSTEAD</code> rules already add the
  81. original query tree, we end up with either one or two output query trees
  82. for a rule with one action.
  83. </p><p>
  84. For <code class="literal">ON INSERT</code> rules, the original query (if not suppressed by <code class="literal">INSTEAD</code>)
  85. is done before any actions added by rules. This allows the actions to
  86. see the inserted row(s). But for <code class="literal">ON UPDATE</code> and <code class="literal">ON
  87. DELETE</code> rules, the original query is done after the actions added by rules.
  88. This ensures that the actions can see the to-be-updated or to-be-deleted
  89. rows; otherwise, the actions might do nothing because they find no rows
  90. matching their qualifications.
  91. </p><p>
  92. The query trees generated from rule actions are thrown into the
  93. rewrite system again, and maybe more rules get applied resulting
  94. in more or less query trees.
  95. So a rule's actions must have either a different
  96. command type or a different result relation than the rule itself is
  97. on, otherwise this recursive process will end up in an infinite loop.
  98. (Recursive expansion of a rule will be detected and reported as an
  99. error.)
  100. </p><p>
  101. The query trees found in the actions of the
  102. <code class="structname">pg_rewrite</code> system catalog are only
  103. templates. Since they can reference the range-table entries for
  104. <code class="literal">NEW</code> and <code class="literal">OLD</code>, some substitutions have to be made before they can be
  105. used. For any reference to <code class="literal">NEW</code>, the target list of the original
  106. query is searched for a corresponding entry. If found, that
  107. entry's expression replaces the reference. Otherwise, <code class="literal">NEW</code> means the
  108. same as <code class="literal">OLD</code> (for an <code class="command">UPDATE</code>) or is replaced by
  109. a null value (for an <code class="command">INSERT</code>). Any reference to <code class="literal">OLD</code> is
  110. replaced by a reference to the range-table entry that is the
  111. result relation.
  112. </p><p>
  113. After the system is done applying update rules, it applies view rules to the
  114. produced query tree(s). Views cannot insert new update actions so
  115. there is no need to apply update rules to the output of view rewriting.
  116. </p><div class="sect3" id="id-1.8.6.9.7.10"><div class="titlepage"><div><div><h4 class="title">40.4.1.1. A First Rule Step by Step</h4></div></div></div><p>
  117. Say we want to trace changes to the <code class="literal">sl_avail</code> column in the
  118. <code class="literal">shoelace_data</code> relation. So we set up a log table
  119. and a rule that conditionally writes a log entry when an
  120. <code class="command">UPDATE</code> is performed on
  121. <code class="literal">shoelace_data</code>.
  122. </p><pre class="programlisting">
  123. CREATE TABLE shoelace_log (
  124. sl_name text, -- shoelace changed
  125. sl_avail integer, -- new available value
  126. log_who text, -- who did it
  127. log_when timestamp -- when
  128. );
  129. CREATE RULE log_shoelace AS ON UPDATE TO shoelace_data
  130. WHERE NEW.sl_avail &lt;&gt; OLD.sl_avail
  131. DO INSERT INTO shoelace_log VALUES (
  132. NEW.sl_name,
  133. NEW.sl_avail,
  134. current_user,
  135. current_timestamp
  136. );
  137. </pre><p>
  138. </p><p>
  139. Now someone does:
  140. </p><pre class="programlisting">
  141. UPDATE shoelace_data SET sl_avail = 6 WHERE sl_name = 'sl7';
  142. </pre><p>
  143. and we look at the log table:
  144. </p><pre class="programlisting">
  145. SELECT * FROM shoelace_log;
  146. sl_name | sl_avail | log_who | log_when
  147. ---------+----------+---------+----------------------------------
  148. sl7 | 6 | Al | Tue Oct 20 16:14:45 1998 MET DST
  149. (1 row)
  150. </pre><p>
  151. </p><p>
  152. That's what we expected. What happened in the background is the following.
  153. The parser created the query tree:
  154. </p><pre class="programlisting">
  155. UPDATE shoelace_data SET sl_avail = 6
  156. FROM shoelace_data shoelace_data
  157. WHERE shoelace_data.sl_name = 'sl7';
  158. </pre><p>
  159. There is a rule <code class="literal">log_shoelace</code> that is <code class="literal">ON UPDATE</code> with the rule
  160. qualification expression:
  161. </p><pre class="programlisting">
  162. NEW.sl_avail &lt;&gt; OLD.sl_avail
  163. </pre><p>
  164. and the action:
  165. </p><pre class="programlisting">
  166. INSERT INTO shoelace_log VALUES (
  167. new.sl_name, new.sl_avail,
  168. current_user, current_timestamp )
  169. FROM shoelace_data new, shoelace_data old;
  170. </pre><p>
  171. (This looks a little strange since you cannot normally write
  172. <code class="literal">INSERT ... VALUES ... FROM</code>. The <code class="literal">FROM</code>
  173. clause here is just to indicate that there are range-table entries
  174. in the query tree for <code class="literal">new</code> and <code class="literal">old</code>.
  175. These are needed so that they can be referenced by variables in
  176. the <code class="command">INSERT</code> command's query tree.)
  177. </p><p>
  178. The rule is a qualified <code class="literal">ALSO</code> rule, so the rule system
  179. has to return two query trees: the modified rule action and the original
  180. query tree. In step 1, the range table of the original query is
  181. incorporated into the rule's action query tree. This results in:
  182. </p><pre class="programlisting">
  183. INSERT INTO shoelace_log VALUES (
  184. new.sl_name, new.sl_avail,
  185. current_user, current_timestamp )
  186. FROM shoelace_data new, shoelace_data old,
  187. <span class="emphasis"><strong>shoelace_data shoelace_data</strong></span>;
  188. </pre><p>
  189. In step 2, the rule qualification is added to it, so the result set
  190. is restricted to rows where <code class="literal">sl_avail</code> changes:
  191. </p><pre class="programlisting">
  192. INSERT INTO shoelace_log VALUES (
  193. new.sl_name, new.sl_avail,
  194. current_user, current_timestamp )
  195. FROM shoelace_data new, shoelace_data old,
  196. shoelace_data shoelace_data
  197. <span class="emphasis"><strong>WHERE new.sl_avail &lt;&gt; old.sl_avail</strong></span>;
  198. </pre><p>
  199. (This looks even stranger, since <code class="literal">INSERT ... VALUES</code> doesn't have
  200. a <code class="literal">WHERE</code> clause either, but the planner and executor will have no
  201. difficulty with it. They need to support this same functionality
  202. anyway for <code class="literal">INSERT ... SELECT</code>.)
  203. </p><p>
  204. In step 3, the original query tree's qualification is added,
  205. restricting the result set further to only the rows that would have been touched
  206. by the original query:
  207. </p><pre class="programlisting">
  208. INSERT INTO shoelace_log VALUES (
  209. new.sl_name, new.sl_avail,
  210. current_user, current_timestamp )
  211. FROM shoelace_data new, shoelace_data old,
  212. shoelace_data shoelace_data
  213. WHERE new.sl_avail &lt;&gt; old.sl_avail
  214. <span class="emphasis"><strong>AND shoelace_data.sl_name = 'sl7'</strong></span>;
  215. </pre><p>
  216. </p><p>
  217. Step 4 replaces references to <code class="literal">NEW</code> by the target list entries from the
  218. original query tree or by the matching variable references
  219. from the result relation:
  220. </p><pre class="programlisting">
  221. INSERT INTO shoelace_log VALUES (
  222. <span class="emphasis"><strong>shoelace_data.sl_name</strong></span>, <span class="emphasis"><strong>6</strong></span>,
  223. current_user, current_timestamp )
  224. FROM shoelace_data new, shoelace_data old,
  225. shoelace_data shoelace_data
  226. WHERE <span class="emphasis"><strong>6</strong></span> &lt;&gt; old.sl_avail
  227. AND shoelace_data.sl_name = 'sl7';
  228. </pre><p>
  229. </p><p>
  230. Step 5 changes <code class="literal">OLD</code> references into result relation references:
  231. </p><pre class="programlisting">
  232. INSERT INTO shoelace_log VALUES (
  233. shoelace_data.sl_name, 6,
  234. current_user, current_timestamp )
  235. FROM shoelace_data new, shoelace_data old,
  236. shoelace_data shoelace_data
  237. WHERE 6 &lt;&gt; <span class="emphasis"><strong>shoelace_data.sl_avail</strong></span>
  238. AND shoelace_data.sl_name = 'sl7';
  239. </pre><p>
  240. </p><p>
  241. That's it. Since the rule is <code class="literal">ALSO</code>, we also output the
  242. original query tree. In short, the output from the rule system
  243. is a list of two query trees that correspond to these statements:
  244. </p><pre class="programlisting">
  245. INSERT INTO shoelace_log VALUES (
  246. shoelace_data.sl_name, 6,
  247. current_user, current_timestamp )
  248. FROM shoelace_data
  249. WHERE 6 &lt;&gt; shoelace_data.sl_avail
  250. AND shoelace_data.sl_name = 'sl7';
  251. UPDATE shoelace_data SET sl_avail = 6
  252. WHERE sl_name = 'sl7';
  253. </pre><p>
  254. These are executed in this order, and that is exactly what
  255. the rule was meant to do.
  256. </p><p>
  257. The substitutions and the added qualifications
  258. ensure that, if the original query would be, say:
  259. </p><pre class="programlisting">
  260. UPDATE shoelace_data SET sl_color = 'green'
  261. WHERE sl_name = 'sl7';
  262. </pre><p>
  263. no log entry would get written. In that case, the original query
  264. tree does not contain a target list entry for
  265. <code class="literal">sl_avail</code>, so <code class="literal">NEW.sl_avail</code> will get
  266. replaced by <code class="literal">shoelace_data.sl_avail</code>. Thus, the extra
  267. command generated by the rule is:
  268. </p><pre class="programlisting">
  269. INSERT INTO shoelace_log VALUES (
  270. shoelace_data.sl_name, <span class="emphasis"><strong>shoelace_data.sl_avail</strong></span>,
  271. current_user, current_timestamp )
  272. FROM shoelace_data
  273. WHERE <span class="emphasis"><strong>shoelace_data.sl_avail</strong></span> &lt;&gt; shoelace_data.sl_avail
  274. AND shoelace_data.sl_name = 'sl7';
  275. </pre><p>
  276. and that qualification will never be true.
  277. </p><p>
  278. It will also work if the original query modifies multiple rows. So
  279. if someone issued the command:
  280. </p><pre class="programlisting">
  281. UPDATE shoelace_data SET sl_avail = 0
  282. WHERE sl_color = 'black';
  283. </pre><p>
  284. four rows in fact get updated (<code class="literal">sl1</code>, <code class="literal">sl2</code>, <code class="literal">sl3</code>, and <code class="literal">sl4</code>).
  285. But <code class="literal">sl3</code> already has <code class="literal">sl_avail = 0</code>. In this case, the original
  286. query trees qualification is different and that results
  287. in the extra query tree:
  288. </p><pre class="programlisting">
  289. INSERT INTO shoelace_log
  290. SELECT shoelace_data.sl_name, 0,
  291. current_user, current_timestamp
  292. FROM shoelace_data
  293. WHERE 0 &lt;&gt; shoelace_data.sl_avail
  294. AND <span class="emphasis"><strong>shoelace_data.sl_color = 'black'</strong></span>;
  295. </pre><p>
  296. being generated by the rule. This query tree will surely insert
  297. three new log entries. And that's absolutely correct.
  298. </p><p>
  299. Here we can see why it is important that the original query tree
  300. is executed last. If the <code class="command">UPDATE</code> had been
  301. executed first, all the rows would have already been set to zero, so the
  302. logging <code class="command">INSERT</code> would not find any row where
  303. <code class="literal">0 &lt;&gt; shoelace_data.sl_avail</code>.
  304. </p></div></div><div class="sect2" id="RULES-UPDATE-VIEWS"><div class="titlepage"><div><div><h3 class="title">40.4.2. Cooperation with Views</h3></div></div></div><a id="id-1.8.6.9.8.2" class="indexterm"></a><p>
  305. A simple way to protect view relations from the mentioned
  306. possibility that someone can try to run <code class="command">INSERT</code>,
  307. <code class="command">UPDATE</code>, or <code class="command">DELETE</code> on them is
  308. to let those query trees get thrown away. So we could create the rules:
  309. </p><pre class="programlisting">
  310. CREATE RULE shoe_ins_protect AS ON INSERT TO shoe
  311. DO INSTEAD NOTHING;
  312. CREATE RULE shoe_upd_protect AS ON UPDATE TO shoe
  313. DO INSTEAD NOTHING;
  314. CREATE RULE shoe_del_protect AS ON DELETE TO shoe
  315. DO INSTEAD NOTHING;
  316. </pre><p>
  317. If someone now tries to do any of these operations on the view
  318. relation <code class="literal">shoe</code>, the rule system will
  319. apply these rules. Since the rules have
  320. no actions and are <code class="literal">INSTEAD</code>, the resulting list of
  321. query trees will be empty and the whole query will become
  322. nothing because there is nothing left to be optimized or
  323. executed after the rule system is done with it.
  324. </p><p>
  325. A more sophisticated way to use the rule system is to
  326. create rules that rewrite the query tree into one that
  327. does the right operation on the real tables. To do that
  328. on the <code class="literal">shoelace</code> view, we create
  329. the following rules:
  330. </p><pre class="programlisting">
  331. CREATE RULE shoelace_ins AS ON INSERT TO shoelace
  332. DO INSTEAD
  333. INSERT INTO shoelace_data VALUES (
  334. NEW.sl_name,
  335. NEW.sl_avail,
  336. NEW.sl_color,
  337. NEW.sl_len,
  338. NEW.sl_unit
  339. );
  340. CREATE RULE shoelace_upd AS ON UPDATE TO shoelace
  341. DO INSTEAD
  342. UPDATE shoelace_data
  343. SET sl_name = NEW.sl_name,
  344. sl_avail = NEW.sl_avail,
  345. sl_color = NEW.sl_color,
  346. sl_len = NEW.sl_len,
  347. sl_unit = NEW.sl_unit
  348. WHERE sl_name = OLD.sl_name;
  349. CREATE RULE shoelace_del AS ON DELETE TO shoelace
  350. DO INSTEAD
  351. DELETE FROM shoelace_data
  352. WHERE sl_name = OLD.sl_name;
  353. </pre><p>
  354. </p><p>
  355. If you want to support <code class="literal">RETURNING</code> queries on the view,
  356. you need to make the rules include <code class="literal">RETURNING</code> clauses that
  357. compute the view rows. This is usually pretty trivial for views on a
  358. single table, but it's a bit tedious for join views such as
  359. <code class="literal">shoelace</code>. An example for the insert case is:
  360. </p><pre class="programlisting">
  361. CREATE RULE shoelace_ins AS ON INSERT TO shoelace
  362. DO INSTEAD
  363. INSERT INTO shoelace_data VALUES (
  364. NEW.sl_name,
  365. NEW.sl_avail,
  366. NEW.sl_color,
  367. NEW.sl_len,
  368. NEW.sl_unit
  369. )
  370. RETURNING
  371. shoelace_data.*,
  372. (SELECT shoelace_data.sl_len * u.un_fact
  373. FROM unit u WHERE shoelace_data.sl_unit = u.un_name);
  374. </pre><p>
  375. Note that this one rule supports both <code class="command">INSERT</code> and
  376. <code class="command">INSERT RETURNING</code> queries on the view — the
  377. <code class="literal">RETURNING</code> clause is simply ignored for <code class="command">INSERT</code>.
  378. </p><p>
  379. Now assume that once in a while, a pack of shoelaces arrives at
  380. the shop and a big parts list along with it. But you don't want
  381. to manually update the <code class="literal">shoelace</code> view every
  382. time. Instead we set up two little tables: one where you can
  383. insert the items from the part list, and one with a special
  384. trick. The creation commands for these are:
  385. </p><pre class="programlisting">
  386. CREATE TABLE shoelace_arrive (
  387. arr_name text,
  388. arr_quant integer
  389. );
  390. CREATE TABLE shoelace_ok (
  391. ok_name text,
  392. ok_quant integer
  393. );
  394. CREATE RULE shoelace_ok_ins AS ON INSERT TO shoelace_ok
  395. DO INSTEAD
  396. UPDATE shoelace
  397. SET sl_avail = sl_avail + NEW.ok_quant
  398. WHERE sl_name = NEW.ok_name;
  399. </pre><p>
  400. Now you can fill the table <code class="literal">shoelace_arrive</code> with
  401. the data from the parts list:
  402. </p><pre class="programlisting">
  403. SELECT * FROM shoelace_arrive;
  404. arr_name | arr_quant
  405. ----------+-----------
  406. sl3 | 10
  407. sl6 | 20
  408. sl8 | 20
  409. (3 rows)
  410. </pre><p>
  411. Take a quick look at the current data:
  412. </p><pre class="programlisting">
  413. SELECT * FROM shoelace;
  414. sl_name | sl_avail | sl_color | sl_len | sl_unit | sl_len_cm
  415. ----------+----------+----------+--------+---------+-----------
  416. sl1 | 5 | black | 80 | cm | 80
  417. sl2 | 6 | black | 100 | cm | 100
  418. sl7 | 6 | brown | 60 | cm | 60
  419. sl3 | 0 | black | 35 | inch | 88.9
  420. sl4 | 8 | black | 40 | inch | 101.6
  421. sl8 | 1 | brown | 40 | inch | 101.6
  422. sl5 | 4 | brown | 1 | m | 100
  423. sl6 | 0 | brown | 0.9 | m | 90
  424. (8 rows)
  425. </pre><p>
  426. Now move the arrived shoelaces in:
  427. </p><pre class="programlisting">
  428. INSERT INTO shoelace_ok SELECT * FROM shoelace_arrive;
  429. </pre><p>
  430. and check the results:
  431. </p><pre class="programlisting">
  432. SELECT * FROM shoelace ORDER BY sl_name;
  433. sl_name | sl_avail | sl_color | sl_len | sl_unit | sl_len_cm
  434. ----------+----------+----------+--------+---------+-----------
  435. sl1 | 5 | black | 80 | cm | 80
  436. sl2 | 6 | black | 100 | cm | 100
  437. sl7 | 6 | brown | 60 | cm | 60
  438. sl4 | 8 | black | 40 | inch | 101.6
  439. sl3 | 10 | black | 35 | inch | 88.9
  440. sl8 | 21 | brown | 40 | inch | 101.6
  441. sl5 | 4 | brown | 1 | m | 100
  442. sl6 | 20 | brown | 0.9 | m | 90
  443. (8 rows)
  444. SELECT * FROM shoelace_log;
  445. sl_name | sl_avail | log_who| log_when
  446. ---------+----------+--------+----------------------------------
  447. sl7 | 6 | Al | Tue Oct 20 19:14:45 1998 MET DST
  448. sl3 | 10 | Al | Tue Oct 20 19:25:16 1998 MET DST
  449. sl6 | 20 | Al | Tue Oct 20 19:25:16 1998 MET DST
  450. sl8 | 21 | Al | Tue Oct 20 19:25:16 1998 MET DST
  451. (4 rows)
  452. </pre><p>
  453. </p><p>
  454. It's a long way from the one <code class="literal">INSERT ... SELECT</code>
  455. to these results. And the description of the query-tree
  456. transformation will be the last in this chapter. First, there is
  457. the parser's output:
  458. </p><pre class="programlisting">
  459. INSERT INTO shoelace_ok
  460. SELECT shoelace_arrive.arr_name, shoelace_arrive.arr_quant
  461. FROM shoelace_arrive shoelace_arrive, shoelace_ok shoelace_ok;
  462. </pre><p>
  463. Now the first rule <code class="literal">shoelace_ok_ins</code> is applied and turns this
  464. into:
  465. </p><pre class="programlisting">
  466. UPDATE shoelace
  467. SET sl_avail = shoelace.sl_avail + shoelace_arrive.arr_quant
  468. FROM shoelace_arrive shoelace_arrive, shoelace_ok shoelace_ok,
  469. shoelace_ok old, shoelace_ok new,
  470. shoelace shoelace
  471. WHERE shoelace.sl_name = shoelace_arrive.arr_name;
  472. </pre><p>
  473. and throws away the original <code class="command">INSERT</code> on
  474. <code class="literal">shoelace_ok</code>. This rewritten query is passed to
  475. the rule system again, and the second applied rule
  476. <code class="literal">shoelace_upd</code> produces:
  477. </p><pre class="programlisting">
  478. UPDATE shoelace_data
  479. SET sl_name = shoelace.sl_name,
  480. sl_avail = shoelace.sl_avail + shoelace_arrive.arr_quant,
  481. sl_color = shoelace.sl_color,
  482. sl_len = shoelace.sl_len,
  483. sl_unit = shoelace.sl_unit
  484. FROM shoelace_arrive shoelace_arrive, shoelace_ok shoelace_ok,
  485. shoelace_ok old, shoelace_ok new,
  486. shoelace shoelace, shoelace old,
  487. shoelace new, shoelace_data shoelace_data
  488. WHERE shoelace.sl_name = shoelace_arrive.arr_name
  489. AND shoelace_data.sl_name = shoelace.sl_name;
  490. </pre><p>
  491. Again it's an <code class="literal">INSTEAD</code> rule and the previous query tree is trashed.
  492. Note that this query still uses the view <code class="literal">shoelace</code>.
  493. But the rule system isn't finished with this step, so it continues
  494. and applies the <code class="literal">_RETURN</code> rule on it, and we get:
  495. </p><pre class="programlisting">
  496. UPDATE shoelace_data
  497. SET sl_name = s.sl_name,
  498. sl_avail = s.sl_avail + shoelace_arrive.arr_quant,
  499. sl_color = s.sl_color,
  500. sl_len = s.sl_len,
  501. sl_unit = s.sl_unit
  502. FROM shoelace_arrive shoelace_arrive, shoelace_ok shoelace_ok,
  503. shoelace_ok old, shoelace_ok new,
  504. shoelace shoelace, shoelace old,
  505. shoelace new, shoelace_data shoelace_data,
  506. shoelace old, shoelace new,
  507. shoelace_data s, unit u
  508. WHERE s.sl_name = shoelace_arrive.arr_name
  509. AND shoelace_data.sl_name = s.sl_name;
  510. </pre><p>
  511. Finally, the rule <code class="literal">log_shoelace</code> gets applied,
  512. producing the extra query tree:
  513. </p><pre class="programlisting">
  514. INSERT INTO shoelace_log
  515. SELECT s.sl_name,
  516. s.sl_avail + shoelace_arrive.arr_quant,
  517. current_user,
  518. current_timestamp
  519. FROM shoelace_arrive shoelace_arrive, shoelace_ok shoelace_ok,
  520. shoelace_ok old, shoelace_ok new,
  521. shoelace shoelace, shoelace old,
  522. shoelace new, shoelace_data shoelace_data,
  523. shoelace old, shoelace new,
  524. shoelace_data s, unit u,
  525. shoelace_data old, shoelace_data new
  526. shoelace_log shoelace_log
  527. WHERE s.sl_name = shoelace_arrive.arr_name
  528. AND shoelace_data.sl_name = s.sl_name
  529. AND (s.sl_avail + shoelace_arrive.arr_quant) &lt;&gt; s.sl_avail;
  530. </pre><p>
  531. After that the rule system runs out of rules and returns the
  532. generated query trees.
  533. </p><p>
  534. So we end up with two final query trees that are equivalent to the
  535. <acronym class="acronym">SQL</acronym> statements:
  536. </p><pre class="programlisting">
  537. INSERT INTO shoelace_log
  538. SELECT s.sl_name,
  539. s.sl_avail + shoelace_arrive.arr_quant,
  540. current_user,
  541. current_timestamp
  542. FROM shoelace_arrive shoelace_arrive, shoelace_data shoelace_data,
  543. shoelace_data s
  544. WHERE s.sl_name = shoelace_arrive.arr_name
  545. AND shoelace_data.sl_name = s.sl_name
  546. AND s.sl_avail + shoelace_arrive.arr_quant &lt;&gt; s.sl_avail;
  547. UPDATE shoelace_data
  548. SET sl_avail = shoelace_data.sl_avail + shoelace_arrive.arr_quant
  549. FROM shoelace_arrive shoelace_arrive,
  550. shoelace_data shoelace_data,
  551. shoelace_data s
  552. WHERE s.sl_name = shoelace_arrive.sl_name
  553. AND shoelace_data.sl_name = s.sl_name;
  554. </pre><p>
  555. The result is that data coming from one relation inserted into another,
  556. changed into updates on a third, changed into updating
  557. a fourth plus logging that final update in a fifth
  558. gets reduced into two queries.
  559. </p><p>
  560. There is a little detail that's a bit ugly. Looking at the two
  561. queries, it turns out that the <code class="literal">shoelace_data</code>
  562. relation appears twice in the range table where it could
  563. definitely be reduced to one. The planner does not handle it and
  564. so the execution plan for the rule systems output of the
  565. <code class="command">INSERT</code> will be
  566. </p><pre class="literallayout">
  567. Nested Loop
  568. -&gt; Merge Join
  569. -&gt; Seq Scan
  570. -&gt; Sort
  571. -&gt; Seq Scan on s
  572. -&gt; Seq Scan
  573. -&gt; Sort
  574. -&gt; Seq Scan on shoelace_arrive
  575. -&gt; Seq Scan on shoelace_data
  576. </pre><p>
  577. while omitting the extra range table entry would result in a
  578. </p><pre class="literallayout">
  579. Merge Join
  580. -&gt; Seq Scan
  581. -&gt; Sort
  582. -&gt; Seq Scan on s
  583. -&gt; Seq Scan
  584. -&gt; Sort
  585. -&gt; Seq Scan on shoelace_arrive
  586. </pre><p>
  587. which produces exactly the same entries in the log table. Thus,
  588. the rule system caused one extra scan on the table
  589. <code class="literal">shoelace_data</code> that is absolutely not
  590. necessary. And the same redundant scan is done once more in the
  591. <code class="command">UPDATE</code>. But it was a really hard job to make
  592. that all possible at all.
  593. </p><p>
  594. Now we make a final demonstration of the
  595. <span class="productname">PostgreSQL</span> rule system and its power.
  596. Say you add some shoelaces with extraordinary colors to your
  597. database:
  598. </p><pre class="programlisting">
  599. INSERT INTO shoelace VALUES ('sl9', 0, 'pink', 35.0, 'inch', 0.0);
  600. INSERT INTO shoelace VALUES ('sl10', 1000, 'magenta', 40.0, 'inch', 0.0);
  601. </pre><p>
  602. We would like to make a view to check which
  603. <code class="literal">shoelace</code> entries do not fit any shoe in color.
  604. The view for this is:
  605. </p><pre class="programlisting">
  606. CREATE VIEW shoelace_mismatch AS
  607. SELECT * FROM shoelace WHERE NOT EXISTS
  608. (SELECT shoename FROM shoe WHERE slcolor = sl_color);
  609. </pre><p>
  610. Its output is:
  611. </p><pre class="programlisting">
  612. SELECT * FROM shoelace_mismatch;
  613. sl_name | sl_avail | sl_color | sl_len | sl_unit | sl_len_cm
  614. ---------+----------+----------+--------+---------+-----------
  615. sl9 | 0 | pink | 35 | inch | 88.9
  616. sl10 | 1000 | magenta | 40 | inch | 101.6
  617. </pre><p>
  618. </p><p>
  619. Now we want to set it up so that mismatching shoelaces that are
  620. not in stock are deleted from the database.
  621. To make it a little harder for <span class="productname">PostgreSQL</span>,
  622. we don't delete it directly. Instead we create one more view:
  623. </p><pre class="programlisting">
  624. CREATE VIEW shoelace_can_delete AS
  625. SELECT * FROM shoelace_mismatch WHERE sl_avail = 0;
  626. </pre><p>
  627. and do it this way:
  628. </p><pre class="programlisting">
  629. DELETE FROM shoelace WHERE EXISTS
  630. (SELECT * FROM shoelace_can_delete
  631. WHERE sl_name = shoelace.sl_name);
  632. </pre><p>
  633. <span class="foreignphrase"><em class="foreignphrase">Voilà</em></span>:
  634. </p><pre class="programlisting">
  635. SELECT * FROM shoelace;
  636. sl_name | sl_avail | sl_color | sl_len | sl_unit | sl_len_cm
  637. ---------+----------+----------+--------+---------+-----------
  638. sl1 | 5 | black | 80 | cm | 80
  639. sl2 | 6 | black | 100 | cm | 100
  640. sl7 | 6 | brown | 60 | cm | 60
  641. sl4 | 8 | black | 40 | inch | 101.6
  642. sl3 | 10 | black | 35 | inch | 88.9
  643. sl8 | 21 | brown | 40 | inch | 101.6
  644. sl10 | 1000 | magenta | 40 | inch | 101.6
  645. sl5 | 4 | brown | 1 | m | 100
  646. sl6 | 20 | brown | 0.9 | m | 90
  647. (9 rows)
  648. </pre><p>
  649. </p><p>
  650. A <code class="command">DELETE</code> on a view, with a subquery qualification that
  651. in total uses 4 nesting/joined views, where one of them
  652. itself has a subquery qualification containing a view
  653. and where calculated view columns are used,
  654. gets rewritten into
  655. one single query tree that deletes the requested data
  656. from a real table.
  657. </p><p>
  658. There are probably only a few situations out in the real world
  659. where such a construct is necessary. But it makes you feel
  660. comfortable that it works.
  661. </p></div></div><div class="navfooter"><hr /><table width="100%" summary="Navigation footer"><tr><td width="40%" align="left"><a accesskey="p" href="rules-materializedviews.html">Prev</a> </td><td width="20%" align="center"><a accesskey="u" href="rules.html">Up</a></td><td width="40%" align="right"> <a accesskey="n" href="rules-privileges.html">Next</a></td></tr><tr><td width="40%" align="left" valign="top">40.3. Materialized Views </td><td width="20%" align="center"><a accesskey="h" href="index.html">Home</a></td><td width="40%" align="right" valign="top"> 40.5. Rules and Privileges</td></tr></table></div></body></html>
上海开阖软件有限公司 沪ICP备12045867号-1