gooderp18绿色标准版
You can not select more than 25 topics Topics must start with a letter or number, can include dashes ('-') and can be up to 35 characters long.

426 lines
24KB

  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>7.8. WITH Queries (Common Table Expressions)</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="queries-values.html" title="7.7. VALUES Lists" /><link rel="next" href="datatype.html" title="Chapter 8. Data Types" /></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">7.8. <code xmlns="http://www.w3.org/1999/xhtml" class="literal">WITH</code> Queries (Common Table Expressions)</th></tr><tr><td width="10%" align="left"><a accesskey="p" href="queries-values.html" title="7.7. VALUES Lists">Prev</a> </td><td width="10%" align="left"><a accesskey="u" href="queries.html" title="Chapter 7. Queries">Up</a></td><th width="60%" align="center">Chapter 7. Queries</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="datatype.html" title="Chapter 8. Data Types">Next</a></td></tr></table><hr></hr></div><div class="sect1" id="QUERIES-WITH"><div class="titlepage"><div><div><h2 class="title" style="clear: both">7.8. <code class="literal">WITH</code> Queries (Common Table Expressions)</h2></div></div></div><div class="toc"><dl class="toc"><dt><span class="sect2"><a href="queries-with.html#QUERIES-WITH-SELECT">7.8.1. <code class="command">SELECT</code> in <code class="literal">WITH</code></a></span></dt><dt><span class="sect2"><a href="queries-with.html#QUERIES-WITH-MODIFYING">7.8.2. Data-Modifying Statements in <code class="literal">WITH</code></a></span></dt></dl></div><a id="id-1.5.6.12.2" class="indexterm"></a><a id="id-1.5.6.12.3" class="indexterm"></a><p>
  3. <code class="literal">WITH</code> provides a way to write auxiliary statements for use in a
  4. larger query. These statements, which are often referred to as Common
  5. Table Expressions or <acronym class="acronym">CTE</acronym>s, can be thought of as defining
  6. temporary tables that exist just for one query. Each auxiliary statement
  7. in a <code class="literal">WITH</code> clause can be a <code class="command">SELECT</code>,
  8. <code class="command">INSERT</code>, <code class="command">UPDATE</code>, or <code class="command">DELETE</code>; and the
  9. <code class="literal">WITH</code> clause itself is attached to a primary statement that can
  10. also be a <code class="command">SELECT</code>, <code class="command">INSERT</code>, <code class="command">UPDATE</code>, or
  11. <code class="command">DELETE</code>.
  12. </p><div class="sect2" id="QUERIES-WITH-SELECT"><div class="titlepage"><div><div><h3 class="title">7.8.1. <code class="command">SELECT</code> in <code class="literal">WITH</code></h3></div></div></div><p>
  13. The basic value of <code class="command">SELECT</code> in <code class="literal">WITH</code> is to
  14. break down complicated queries into simpler parts. An example is:
  15. </p><pre class="programlisting">
  16. WITH regional_sales AS (
  17. SELECT region, SUM(amount) AS total_sales
  18. FROM orders
  19. GROUP BY region
  20. ), top_regions AS (
  21. SELECT region
  22. FROM regional_sales
  23. WHERE total_sales &gt; (SELECT SUM(total_sales)/10 FROM regional_sales)
  24. )
  25. SELECT region,
  26. product,
  27. SUM(quantity) AS product_units,
  28. SUM(amount) AS product_sales
  29. FROM orders
  30. WHERE region IN (SELECT region FROM top_regions)
  31. GROUP BY region, product;
  32. </pre><p>
  33. which displays per-product sales totals in only the top sales regions.
  34. The <code class="literal">WITH</code> clause defines two auxiliary statements named
  35. <code class="structname">regional_sales</code> and <code class="structname">top_regions</code>,
  36. where the output of <code class="structname">regional_sales</code> is used in
  37. <code class="structname">top_regions</code> and the output of <code class="structname">top_regions</code>
  38. is used in the primary <code class="command">SELECT</code> query.
  39. This example could have been written without <code class="literal">WITH</code>,
  40. but we'd have needed two levels of nested sub-<code class="command">SELECT</code>s. It's a bit
  41. easier to follow this way.
  42. </p><p>
  43. <a id="id-1.5.6.12.5.3.1" class="indexterm"></a>
  44. The optional <code class="literal">RECURSIVE</code> modifier changes <code class="literal">WITH</code>
  45. from a mere syntactic convenience into a feature that accomplishes
  46. things not otherwise possible in standard SQL. Using
  47. <code class="literal">RECURSIVE</code>, a <code class="literal">WITH</code> query can refer to its own
  48. output. A very simple example is this query to sum the integers from 1
  49. through 100:
  50. </p><pre class="programlisting">
  51. WITH RECURSIVE t(n) AS (
  52. VALUES (1)
  53. UNION ALL
  54. SELECT n+1 FROM t WHERE n &lt; 100
  55. )
  56. SELECT sum(n) FROM t;
  57. </pre><p>
  58. The general form of a recursive <code class="literal">WITH</code> query is always a
  59. <em class="firstterm">non-recursive term</em>, then <code class="literal">UNION</code> (or
  60. <code class="literal">UNION ALL</code>), then a
  61. <em class="firstterm">recursive term</em>, where only the recursive term can contain
  62. a reference to the query's own output. Such a query is executed as
  63. follows:
  64. </p><div class="procedure" id="id-1.5.6.12.5.4"><p class="title"><strong>Recursive Query Evaluation</strong></p><ol class="procedure" type="1"><li class="step"><p>
  65. Evaluate the non-recursive term. For <code class="literal">UNION</code> (but not
  66. <code class="literal">UNION ALL</code>), discard duplicate rows. Include all remaining
  67. rows in the result of the recursive query, and also place them in a
  68. temporary <em class="firstterm">working table</em>.
  69. </p></li><li class="step"><p>
  70. So long as the working table is not empty, repeat these steps:
  71. </p><ol type="a" class="substeps"><li class="step"><p>
  72. Evaluate the recursive term, substituting the current contents of
  73. the working table for the recursive self-reference.
  74. For <code class="literal">UNION</code> (but not <code class="literal">UNION ALL</code>), discard
  75. duplicate rows and rows that duplicate any previous result row.
  76. Include all remaining rows in the result of the recursive query, and
  77. also place them in a temporary <em class="firstterm">intermediate table</em>.
  78. </p></li><li class="step"><p>
  79. Replace the contents of the working table with the contents of the
  80. intermediate table, then empty the intermediate table.
  81. </p></li></ol></li></ol></div><div class="note"><h3 class="title">Note</h3><p>
  82. Strictly speaking, this process is iteration not recursion, but
  83. <code class="literal">RECURSIVE</code> is the terminology chosen by the SQL standards
  84. committee.
  85. </p></div><p>
  86. In the example above, the working table has just a single row in each step,
  87. and it takes on the values from 1 through 100 in successive steps. In
  88. the 100th step, there is no output because of the <code class="literal">WHERE</code>
  89. clause, and so the query terminates.
  90. </p><p>
  91. Recursive queries are typically used to deal with hierarchical or
  92. tree-structured data. A useful example is this query to find all the
  93. direct and indirect sub-parts of a product, given only a table that
  94. shows immediate inclusions:
  95. </p><pre class="programlisting">
  96. WITH RECURSIVE included_parts(sub_part, part, quantity) AS (
  97. SELECT sub_part, part, quantity FROM parts WHERE part = 'our_product'
  98. UNION ALL
  99. SELECT p.sub_part, p.part, p.quantity
  100. FROM included_parts pr, parts p
  101. WHERE p.part = pr.sub_part
  102. )
  103. SELECT sub_part, SUM(quantity) as total_quantity
  104. FROM included_parts
  105. GROUP BY sub_part
  106. </pre><p>
  107. </p><p>
  108. When working with recursive queries it is important to be sure that
  109. the recursive part of the query will eventually return no tuples,
  110. or else the query will loop indefinitely. Sometimes, using
  111. <code class="literal">UNION</code> instead of <code class="literal">UNION ALL</code> can accomplish this
  112. by discarding rows that duplicate previous output rows. However, often a
  113. cycle does not involve output rows that are completely duplicate: it may be
  114. necessary to check just one or a few fields to see if the same point has
  115. been reached before. The standard method for handling such situations is
  116. to compute an array of the already-visited values. For example, consider
  117. the following query that searches a table <code class="structname">graph</code> using a
  118. <code class="structfield">link</code> field:
  119. </p><pre class="programlisting">
  120. WITH RECURSIVE search_graph(id, link, data, depth) AS (
  121. SELECT g.id, g.link, g.data, 1
  122. FROM graph g
  123. UNION ALL
  124. SELECT g.id, g.link, g.data, sg.depth + 1
  125. FROM graph g, search_graph sg
  126. WHERE g.id = sg.link
  127. )
  128. SELECT * FROM search_graph;
  129. </pre><p>
  130. This query will loop if the <code class="structfield">link</code> relationships contain
  131. cycles. Because we require a <span class="quote">“<span class="quote">depth</span>”</span> output, just changing
  132. <code class="literal">UNION ALL</code> to <code class="literal">UNION</code> would not eliminate the looping.
  133. Instead we need to recognize whether we have reached the same row again
  134. while following a particular path of links. We add two columns
  135. <code class="structfield">path</code> and <code class="structfield">cycle</code> to the loop-prone query:
  136. </p><pre class="programlisting">
  137. WITH RECURSIVE search_graph(id, link, data, depth, path, cycle) AS (
  138. SELECT g.id, g.link, g.data, 1,
  139. ARRAY[g.id],
  140. false
  141. FROM graph g
  142. UNION ALL
  143. SELECT g.id, g.link, g.data, sg.depth + 1,
  144. path || g.id,
  145. g.id = ANY(path)
  146. FROM graph g, search_graph sg
  147. WHERE g.id = sg.link AND NOT cycle
  148. )
  149. SELECT * FROM search_graph;
  150. </pre><p>
  151. Aside from preventing cycles, the array value is often useful in its own
  152. right as representing the <span class="quote">“<span class="quote">path</span>”</span> taken to reach any particular row.
  153. </p><p>
  154. In the general case where more than one field needs to be checked to
  155. recognize a cycle, use an array of rows. For example, if we needed to
  156. compare fields <code class="structfield">f1</code> and <code class="structfield">f2</code>:
  157. </p><pre class="programlisting">
  158. WITH RECURSIVE search_graph(id, link, data, depth, path, cycle) AS (
  159. SELECT g.id, g.link, g.data, 1,
  160. ARRAY[ROW(g.f1, g.f2)],
  161. false
  162. FROM graph g
  163. UNION ALL
  164. SELECT g.id, g.link, g.data, sg.depth + 1,
  165. path || ROW(g.f1, g.f2),
  166. ROW(g.f1, g.f2) = ANY(path)
  167. FROM graph g, search_graph sg
  168. WHERE g.id = sg.link AND NOT cycle
  169. )
  170. SELECT * FROM search_graph;
  171. </pre><p>
  172. </p><div class="tip"><h3 class="title">Tip</h3><p>
  173. Omit the <code class="literal">ROW()</code> syntax in the common case where only one field
  174. needs to be checked to recognize a cycle. This allows a simple array
  175. rather than a composite-type array to be used, gaining efficiency.
  176. </p></div><div class="tip"><h3 class="title">Tip</h3><p>
  177. The recursive query evaluation algorithm produces its output in
  178. breadth-first search order. You can display the results in depth-first
  179. search order by making the outer query <code class="literal">ORDER BY</code> a
  180. <span class="quote">“<span class="quote">path</span>”</span> column constructed in this way.
  181. </p></div><p>
  182. A helpful trick for testing queries
  183. when you are not certain if they might loop is to place a <code class="literal">LIMIT</code>
  184. in the parent query. For example, this query would loop forever without
  185. the <code class="literal">LIMIT</code>:
  186. </p><pre class="programlisting">
  187. WITH RECURSIVE t(n) AS (
  188. SELECT 1
  189. UNION ALL
  190. SELECT n+1 FROM t
  191. )
  192. SELECT n FROM t LIMIT 100;
  193. </pre><p>
  194. This works because <span class="productname">PostgreSQL</span>'s implementation
  195. evaluates only as many rows of a <code class="literal">WITH</code> query as are actually
  196. fetched by the parent query. Using this trick in production is not
  197. recommended, because other systems might work differently. Also, it
  198. usually won't work if you make the outer query sort the recursive query's
  199. results or join them to some other table, because in such cases the
  200. outer query will usually try to fetch all of the <code class="literal">WITH</code> query's
  201. output anyway.
  202. </p><p>
  203. A useful property of <code class="literal">WITH</code> queries is that they are
  204. normally evaluated only once per execution of the parent query, even if
  205. they are referred to more than once by the parent query or
  206. sibling <code class="literal">WITH</code> queries.
  207. Thus, expensive calculations that are needed in multiple places can be
  208. placed within a <code class="literal">WITH</code> query to avoid redundant work. Another
  209. possible application is to prevent unwanted multiple evaluations of
  210. functions with side-effects.
  211. However, the other side of this coin is that the optimizer is not able to
  212. push restrictions from the parent query down into a multiply-referenced
  213. <code class="literal">WITH</code> query, since that might affect all uses of the
  214. <code class="literal">WITH</code> query's output when it should affect only one.
  215. The multiply-referenced <code class="literal">WITH</code> query will be
  216. evaluated as written, without suppression of rows that the parent query
  217. might discard afterwards. (But, as mentioned above, evaluation might stop
  218. early if the reference(s) to the query demand only a limited number of
  219. rows.)
  220. </p><p>
  221. However, if a <code class="literal">WITH</code> query is non-recursive and
  222. side-effect-free (that is, it is a <code class="literal">SELECT</code> containing
  223. no volatile functions) then it can be folded into the parent query,
  224. allowing joint optimization of the two query levels. By default, this
  225. happens if the parent query references the <code class="literal">WITH</code> query
  226. just once, but not if it references the <code class="literal">WITH</code> query
  227. more than once. You can override that decision by
  228. specifying <code class="literal">MATERIALIZED</code> to force separate calculation
  229. of the <code class="literal">WITH</code> query, or by specifying <code class="literal">NOT
  230. MATERIALIZED</code> to force it to be merged into the parent query.
  231. The latter choice risks duplicate computation of
  232. the <code class="literal">WITH</code> query, but it can still give a net savings if
  233. each usage of the <code class="literal">WITH</code> query needs only a small part
  234. of the <code class="literal">WITH</code> query's full output.
  235. </p><p>
  236. A simple example of these rules is
  237. </p><pre class="programlisting">
  238. WITH w AS (
  239. SELECT * FROM big_table
  240. )
  241. SELECT * FROM w WHERE key = 123;
  242. </pre><p>
  243. This <code class="literal">WITH</code> query will be folded, producing the same
  244. execution plan as
  245. </p><pre class="programlisting">
  246. SELECT * FROM big_table WHERE key = 123;
  247. </pre><p>
  248. In particular, if there's an index on <code class="structfield">key</code>,
  249. it will probably be used to fetch just the rows having <code class="literal">key =
  250. 123</code>. On the other hand, in
  251. </p><pre class="programlisting">
  252. WITH w AS (
  253. SELECT * FROM big_table
  254. )
  255. SELECT * FROM w AS w1 JOIN w AS w2 ON w1.key = w2.ref
  256. WHERE w2.key = 123;
  257. </pre><p>
  258. the <code class="literal">WITH</code> query will be materialized, producing a
  259. temporary copy of <code class="structname">big_table</code> that is then
  260. joined with itself — without benefit of any index. This query
  261. will be executed much more efficiently if written as
  262. </p><pre class="programlisting">
  263. WITH w AS NOT MATERIALIZED (
  264. SELECT * FROM big_table
  265. )
  266. SELECT * FROM w AS w1 JOIN w AS w2 ON w1.key = w2.ref
  267. WHERE w2.key = 123;
  268. </pre><p>
  269. so that the parent query's restrictions can be applied directly
  270. to scans of <code class="structname">big_table</code>.
  271. </p><p>
  272. An example where <code class="literal">NOT MATERIALIZED</code> could be
  273. undesirable is
  274. </p><pre class="programlisting">
  275. WITH w AS (
  276. SELECT key, very_expensive_function(val) as f FROM some_table
  277. )
  278. SELECT * FROM w AS w1 JOIN w AS w2 ON w1.f = w2.f;
  279. </pre><p>
  280. Here, materialization of the <code class="literal">WITH</code> query ensures
  281. that <code class="function">very_expensive_function</code> is evaluated only
  282. once per table row, not twice.
  283. </p><p>
  284. The examples above only show <code class="literal">WITH</code> being used with
  285. <code class="command">SELECT</code>, but it can be attached in the same way to
  286. <code class="command">INSERT</code>, <code class="command">UPDATE</code>, or <code class="command">DELETE</code>.
  287. In each case it effectively provides temporary table(s) that can
  288. be referred to in the main command.
  289. </p></div><div class="sect2" id="QUERIES-WITH-MODIFYING"><div class="titlepage"><div><div><h3 class="title">7.8.2. Data-Modifying Statements in <code class="literal">WITH</code></h3></div></div></div><p>
  290. You can use data-modifying statements (<code class="command">INSERT</code>,
  291. <code class="command">UPDATE</code>, or <code class="command">DELETE</code>) in <code class="literal">WITH</code>. This
  292. allows you to perform several different operations in the same query.
  293. An example is:
  294. </p><pre class="programlisting">
  295. WITH moved_rows AS (
  296. DELETE FROM products
  297. WHERE
  298. "date" &gt;= '2010-10-01' AND
  299. "date" &lt; '2010-11-01'
  300. RETURNING *
  301. )
  302. INSERT INTO products_log
  303. SELECT * FROM moved_rows;
  304. </pre><p>
  305. This query effectively moves rows from <code class="structname">products</code> to
  306. <code class="structname">products_log</code>. The <code class="command">DELETE</code> in <code class="literal">WITH</code>
  307. deletes the specified rows from <code class="structname">products</code>, returning their
  308. contents by means of its <code class="literal">RETURNING</code> clause; and then the
  309. primary query reads that output and inserts it into
  310. <code class="structname">products_log</code>.
  311. </p><p>
  312. A fine point of the above example is that the <code class="literal">WITH</code> clause is
  313. attached to the <code class="command">INSERT</code>, not the sub-<code class="command">SELECT</code> within
  314. the <code class="command">INSERT</code>. This is necessary because data-modifying
  315. statements are only allowed in <code class="literal">WITH</code> clauses that are attached
  316. to the top-level statement. However, normal <code class="literal">WITH</code> visibility
  317. rules apply, so it is possible to refer to the <code class="literal">WITH</code>
  318. statement's output from the sub-<code class="command">SELECT</code>.
  319. </p><p>
  320. Data-modifying statements in <code class="literal">WITH</code> usually have
  321. <code class="literal">RETURNING</code> clauses (see <a class="xref" href="dml-returning.html" title="6.4. Returning Data From Modified Rows">Section 6.4</a>),
  322. as shown in the example above.
  323. It is the output of the <code class="literal">RETURNING</code> clause, <span class="emphasis"><em>not</em></span> the
  324. target table of the data-modifying statement, that forms the temporary
  325. table that can be referred to by the rest of the query. If a
  326. data-modifying statement in <code class="literal">WITH</code> lacks a <code class="literal">RETURNING</code>
  327. clause, then it forms no temporary table and cannot be referred to in
  328. the rest of the query. Such a statement will be executed nonetheless.
  329. A not-particularly-useful example is:
  330. </p><pre class="programlisting">
  331. WITH t AS (
  332. DELETE FROM foo
  333. )
  334. DELETE FROM bar;
  335. </pre><p>
  336. This example would remove all rows from tables <code class="structname">foo</code> and
  337. <code class="structname">bar</code>. The number of affected rows reported to the client
  338. would only include rows removed from <code class="structname">bar</code>.
  339. </p><p>
  340. Recursive self-references in data-modifying statements are not
  341. allowed. In some cases it is possible to work around this limitation by
  342. referring to the output of a recursive <code class="literal">WITH</code>, for example:
  343. </p><pre class="programlisting">
  344. WITH RECURSIVE included_parts(sub_part, part) AS (
  345. SELECT sub_part, part FROM parts WHERE part = 'our_product'
  346. UNION ALL
  347. SELECT p.sub_part, p.part
  348. FROM included_parts pr, parts p
  349. WHERE p.part = pr.sub_part
  350. )
  351. DELETE FROM parts
  352. WHERE part IN (SELECT part FROM included_parts);
  353. </pre><p>
  354. This query would remove all direct and indirect subparts of a product.
  355. </p><p>
  356. Data-modifying statements in <code class="literal">WITH</code> are executed exactly once,
  357. and always to completion, independently of whether the primary query
  358. reads all (or indeed any) of their output. Notice that this is different
  359. from the rule for <code class="command">SELECT</code> in <code class="literal">WITH</code>: as stated in the
  360. previous section, execution of a <code class="command">SELECT</code> is carried only as far
  361. as the primary query demands its output.
  362. </p><p>
  363. The sub-statements in <code class="literal">WITH</code> are executed concurrently with
  364. each other and with the main query. Therefore, when using data-modifying
  365. statements in <code class="literal">WITH</code>, the order in which the specified updates
  366. actually happen is unpredictable. All the statements are executed with
  367. the same <em class="firstterm">snapshot</em> (see <a class="xref" href="mvcc.html" title="Chapter 13. Concurrency Control">Chapter 13</a>), so they
  368. cannot <span class="quote">“<span class="quote">see</span>”</span> one another's effects on the target tables. This
  369. alleviates the effects of the unpredictability of the actual order of row
  370. updates, and means that <code class="literal">RETURNING</code> data is the only way to
  371. communicate changes between different <code class="literal">WITH</code> sub-statements and
  372. the main query. An example of this is that in
  373. </p><pre class="programlisting">
  374. WITH t AS (
  375. UPDATE products SET price = price * 1.05
  376. RETURNING *
  377. )
  378. SELECT * FROM products;
  379. </pre><p>
  380. the outer <code class="command">SELECT</code> would return the original prices before the
  381. action of the <code class="command">UPDATE</code>, while in
  382. </p><pre class="programlisting">
  383. WITH t AS (
  384. UPDATE products SET price = price * 1.05
  385. RETURNING *
  386. )
  387. SELECT * FROM t;
  388. </pre><p>
  389. the outer <code class="command">SELECT</code> would return the updated data.
  390. </p><p>
  391. Trying to update the same row twice in a single statement is not
  392. supported. Only one of the modifications takes place, but it is not easy
  393. (and sometimes not possible) to reliably predict which one. This also
  394. applies to deleting a row that was already updated in the same statement:
  395. only the update is performed. Therefore you should generally avoid trying
  396. to modify a single row twice in a single statement. In particular avoid
  397. writing <code class="literal">WITH</code> sub-statements that could affect the same rows
  398. changed by the main statement or a sibling sub-statement. The effects
  399. of such a statement will not be predictable.
  400. </p><p>
  401. At present, any table used as the target of a data-modifying statement in
  402. <code class="literal">WITH</code> must not have a conditional rule, nor an <code class="literal">ALSO</code>
  403. rule, nor an <code class="literal">INSTEAD</code> rule that expands to multiple statements.
  404. </p></div></div><div class="navfooter"><hr /><table width="100%" summary="Navigation footer"><tr><td width="40%" align="left"><a accesskey="p" href="queries-values.html">Prev</a> </td><td width="20%" align="center"><a accesskey="u" href="queries.html">Up</a></td><td width="40%" align="right"> <a accesskey="n" href="datatype.html">Next</a></td></tr><tr><td width="40%" align="left" valign="top">7.7. <code class="literal">VALUES</code> Lists </td><td width="20%" align="center"><a accesskey="h" href="index.html">Home</a></td><td width="40%" align="right" valign="top"> Chapter 8. Data Types</td></tr></table></div></body></html>
上海开阖软件有限公司 沪ICP备12045867号-1