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

939 行
55KB

  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.6. Control Structures</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-statements.html" title="42.5. Basic Statements" /><link rel="next" href="plpgsql-cursors.html" title="42.7. Cursors" /></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.6. Control Structures</th></tr><tr><td width="10%" align="left"><a accesskey="p" href="plpgsql-statements.html" title="42.5. Basic Statements">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-cursors.html" title="42.7. Cursors">Next</a></td></tr></table><hr></hr></div><div class="sect1" id="PLPGSQL-CONTROL-STRUCTURES"><div class="titlepage"><div><div><h2 class="title" style="clear: both">42.6. Control Structures</h2></div></div></div><div class="toc"><dl class="toc"><dt><span class="sect2"><a href="plpgsql-control-structures.html#PLPGSQL-STATEMENTS-RETURNING">42.6.1. Returning From a Function</a></span></dt><dt><span class="sect2"><a href="plpgsql-control-structures.html#PLPGSQL-STATEMENTS-RETURNING-PROCEDURE">42.6.2. Returning from a Procedure</a></span></dt><dt><span class="sect2"><a href="plpgsql-control-structures.html#PLPGSQL-STATEMENTS-CALLING-PROCEDURE">42.6.3. Calling a Procedure</a></span></dt><dt><span class="sect2"><a href="plpgsql-control-structures.html#PLPGSQL-CONDITIONALS">42.6.4. Conditionals</a></span></dt><dt><span class="sect2"><a href="plpgsql-control-structures.html#PLPGSQL-CONTROL-STRUCTURES-LOOPS">42.6.5. Simple Loops</a></span></dt><dt><span class="sect2"><a href="plpgsql-control-structures.html#PLPGSQL-RECORDS-ITERATING">42.6.6. Looping through Query Results</a></span></dt><dt><span class="sect2"><a href="plpgsql-control-structures.html#PLPGSQL-FOREACH-ARRAY">42.6.7. Looping through Arrays</a></span></dt><dt><span class="sect2"><a href="plpgsql-control-structures.html#PLPGSQL-ERROR-TRAPPING">42.6.8. Trapping Errors</a></span></dt><dt><span class="sect2"><a href="plpgsql-control-structures.html#PLPGSQL-CALL-STACK">42.6.9. Obtaining Execution Location Information</a></span></dt></dl></div><p>
  3. Control structures are probably the most useful (and
  4. important) part of <span class="application">PL/pgSQL</span>. With
  5. <span class="application">PL/pgSQL</span>'s control structures,
  6. you can manipulate <span class="productname">PostgreSQL</span> data in a very
  7. flexible and powerful way.
  8. </p><div class="sect2" id="PLPGSQL-STATEMENTS-RETURNING"><div class="titlepage"><div><div><h3 class="title">42.6.1. Returning From a Function</h3></div></div></div><p>
  9. There are two commands available that allow you to return data
  10. from a function: <code class="command">RETURN</code> and <code class="command">RETURN
  11. NEXT</code>.
  12. </p><div class="sect3" id="id-1.8.8.8.3.3"><div class="titlepage"><div><div><h4 class="title">42.6.1.1. <code class="command">RETURN</code></h4></div></div></div><pre class="synopsis">
  13. RETURN <em class="replaceable"><code>expression</code></em>;
  14. </pre><p>
  15. <code class="command">RETURN</code> with an expression terminates the
  16. function and returns the value of
  17. <em class="replaceable"><code>expression</code></em> to the caller. This form
  18. is used for <span class="application">PL/pgSQL</span> functions that do
  19. not return a set.
  20. </p><p>
  21. In a function that returns a scalar type, the expression's result will
  22. automatically be cast into the function's return type as described for
  23. assignments. But to return a composite (row) value, you must write an
  24. expression delivering exactly the requested column set. This may
  25. require use of explicit casting.
  26. </p><p>
  27. If you declared the function with output parameters, write just
  28. <code class="command">RETURN</code> with no expression. The current values
  29. of the output parameter variables will be returned.
  30. </p><p>
  31. If you declared the function to return <code class="type">void</code>, a
  32. <code class="command">RETURN</code> statement can be used to exit the function
  33. early; but do not write an expression following
  34. <code class="command">RETURN</code>.
  35. </p><p>
  36. The return value of a function cannot be left undefined. If
  37. control reaches the end of the top-level block of the function
  38. without hitting a <code class="command">RETURN</code> statement, a run-time
  39. error will occur. This restriction does not apply to functions
  40. with output parameters and functions returning <code class="type">void</code>,
  41. however. In those cases a <code class="command">RETURN</code> statement is
  42. automatically executed if the top-level block finishes.
  43. </p><p>
  44. Some examples:
  45. </p><pre class="programlisting">
  46. -- functions returning a scalar type
  47. RETURN 1 + 2;
  48. RETURN scalar_var;
  49. -- functions returning a composite type
  50. RETURN composite_type_var;
  51. RETURN (1, 2, 'three'::text); -- must cast columns to correct types
  52. </pre><p>
  53. </p></div><div class="sect3" id="id-1.8.8.8.3.4"><div class="titlepage"><div><div><h4 class="title">42.6.1.2. <code class="command">RETURN NEXT</code> and <code class="command">RETURN QUERY</code></h4></div></div></div><a id="id-1.8.8.8.3.4.2" class="indexterm"></a><a id="id-1.8.8.8.3.4.3" class="indexterm"></a><pre class="synopsis">
  54. RETURN NEXT <em class="replaceable"><code>expression</code></em>;
  55. RETURN QUERY <em class="replaceable"><code>query</code></em>;
  56. RETURN QUERY EXECUTE <em class="replaceable"><code>command-string</code></em> [<span class="optional"> USING <em class="replaceable"><code>expression</code></em> [<span class="optional">, ... </span>] </span>];
  57. </pre><p>
  58. When a <span class="application">PL/pgSQL</span> function is declared to return
  59. <code class="literal">SETOF <em class="replaceable"><code>sometype</code></em></code>, the procedure
  60. to follow is slightly different. In that case, the individual
  61. items to return are specified by a sequence of <code class="command">RETURN
  62. NEXT</code> or <code class="command">RETURN QUERY</code> commands, and
  63. then a final <code class="command">RETURN</code> command with no argument
  64. is used to indicate that the function has finished executing.
  65. <code class="command">RETURN NEXT</code> can be used with both scalar and
  66. composite data types; with a composite result type, an entire
  67. <span class="quote">“<span class="quote">table</span>”</span> of results will be returned.
  68. <code class="command">RETURN QUERY</code> appends the results of executing
  69. a query to the function's result set. <code class="command">RETURN
  70. NEXT</code> and <code class="command">RETURN QUERY</code> can be freely
  71. intermixed in a single set-returning function, in which case
  72. their results will be concatenated.
  73. </p><p>
  74. <code class="command">RETURN NEXT</code> and <code class="command">RETURN
  75. QUERY</code> do not actually return from the function —
  76. they simply append zero or more rows to the function's result
  77. set. Execution then continues with the next statement in the
  78. <span class="application">PL/pgSQL</span> function. As successive
  79. <code class="command">RETURN NEXT</code> or <code class="command">RETURN
  80. QUERY</code> commands are executed, the result set is built
  81. up. A final <code class="command">RETURN</code>, which should have no
  82. argument, causes control to exit the function (or you can just
  83. let control reach the end of the function).
  84. </p><p>
  85. <code class="command">RETURN QUERY</code> has a variant
  86. <code class="command">RETURN QUERY EXECUTE</code>, which specifies the
  87. query to be executed dynamically. Parameter expressions can
  88. be inserted into the computed query string via <code class="literal">USING</code>,
  89. in just the same way as in the <code class="command">EXECUTE</code> command.
  90. </p><p>
  91. If you declared the function with output parameters, write just
  92. <code class="command">RETURN NEXT</code> with no expression. On each
  93. execution, the current values of the output parameter
  94. variable(s) will be saved for eventual return as a row of the
  95. result. Note that you must declare the function as returning
  96. <code class="literal">SETOF record</code> when there are multiple output
  97. parameters, or <code class="literal">SETOF <em class="replaceable"><code>sometype</code></em></code>
  98. when there is just one output parameter of type
  99. <em class="replaceable"><code>sometype</code></em>, in order to create a set-returning
  100. function with output parameters.
  101. </p><p>
  102. Here is an example of a function using <code class="command">RETURN
  103. NEXT</code>:
  104. </p><pre class="programlisting">
  105. CREATE TABLE foo (fooid INT, foosubid INT, fooname TEXT);
  106. INSERT INTO foo VALUES (1, 2, 'three');
  107. INSERT INTO foo VALUES (4, 5, 'six');
  108. CREATE OR REPLACE FUNCTION get_all_foo() RETURNS SETOF foo AS
  109. $BODY$
  110. DECLARE
  111. r foo%rowtype;
  112. BEGIN
  113. FOR r IN
  114. SELECT * FROM foo WHERE fooid &gt; 0
  115. LOOP
  116. -- can do some processing here
  117. RETURN NEXT r; -- return current row of SELECT
  118. END LOOP;
  119. RETURN;
  120. END
  121. $BODY$
  122. LANGUAGE plpgsql;
  123. SELECT * FROM get_all_foo();
  124. </pre><p>
  125. </p><p>
  126. Here is an example of a function using <code class="command">RETURN
  127. QUERY</code>:
  128. </p><pre class="programlisting">
  129. CREATE FUNCTION get_available_flightid(date) RETURNS SETOF integer AS
  130. $BODY$
  131. BEGIN
  132. RETURN QUERY SELECT flightid
  133. FROM flight
  134. WHERE flightdate &gt;= $1
  135. AND flightdate &lt; ($1 + 1);
  136. -- Since execution is not finished, we can check whether rows were returned
  137. -- and raise exception if not.
  138. IF NOT FOUND THEN
  139. RAISE EXCEPTION 'No flight at %.', $1;
  140. END IF;
  141. RETURN;
  142. END
  143. $BODY$
  144. LANGUAGE plpgsql;
  145. -- Returns available flights or raises exception if there are no
  146. -- available flights.
  147. SELECT * FROM get_available_flightid(CURRENT_DATE);
  148. </pre><p>
  149. </p><div class="note"><h3 class="title">Note</h3><p>
  150. The current implementation of <code class="command">RETURN NEXT</code>
  151. and <code class="command">RETURN QUERY</code> stores the entire result set
  152. before returning from the function, as discussed above. That
  153. means that if a <span class="application">PL/pgSQL</span> function produces a
  154. very large result set, performance might be poor: data will be
  155. written to disk to avoid memory exhaustion, but the function
  156. itself will not return until the entire result set has been
  157. generated. A future version of <span class="application">PL/pgSQL</span> might
  158. allow users to define set-returning functions
  159. that do not have this limitation. Currently, the point at
  160. which data begins being written to disk is controlled by the
  161. <a class="xref" href="runtime-config-resource.html#GUC-WORK-MEM">work_mem</a>
  162. configuration variable. Administrators who have sufficient
  163. memory to store larger result sets in memory should consider
  164. increasing this parameter.
  165. </p></div></div></div><div class="sect2" id="PLPGSQL-STATEMENTS-RETURNING-PROCEDURE"><div class="titlepage"><div><div><h3 class="title">42.6.2. Returning from a Procedure</h3></div></div></div><p>
  166. A procedure does not have a return value. A procedure can therefore end
  167. without a <code class="command">RETURN</code> statement. If you wish to use
  168. a <code class="command">RETURN</code> statement to exit the code early, write
  169. just <code class="command">RETURN</code> with no expression.
  170. </p><p>
  171. If the procedure has output parameters, the final values of the output
  172. parameter variables will be returned to the caller.
  173. </p></div><div class="sect2" id="PLPGSQL-STATEMENTS-CALLING-PROCEDURE"><div class="titlepage"><div><div><h3 class="title">42.6.3. Calling a Procedure</h3></div></div></div><p>
  174. A <span class="application">PL/pgSQL</span> function, procedure,
  175. or <code class="command">DO</code> block can call a procedure
  176. using <code class="command">CALL</code>. Output parameters are handled
  177. differently from the way that <code class="command">CALL</code> works in plain
  178. SQL. Each <code class="literal">INOUT</code> parameter of the procedure must
  179. correspond to a variable in the <code class="command">CALL</code> statement, and
  180. whatever the procedure returns is assigned back to that variable after
  181. it returns. For example:
  182. </p><pre class="programlisting">
  183. CREATE PROCEDURE triple(INOUT x int)
  184. LANGUAGE plpgsql
  185. AS $$
  186. BEGIN
  187. x := x * 3;
  188. END;
  189. $$;
  190. DO $$
  191. DECLARE myvar int := 5;
  192. BEGIN
  193. CALL triple(myvar);
  194. RAISE NOTICE 'myvar = %', myvar; -- prints 15
  195. END
  196. $$;
  197. </pre><p>
  198. </p></div><div class="sect2" id="PLPGSQL-CONDITIONALS"><div class="titlepage"><div><div><h3 class="title">42.6.4. Conditionals</h3></div></div></div><p>
  199. <code class="command">IF</code> and <code class="command">CASE</code> statements let you execute
  200. alternative commands based on certain conditions.
  201. <span class="application">PL/pgSQL</span> has three forms of <code class="command">IF</code>:
  202. </p><div class="itemizedlist"><ul class="itemizedlist" style="list-style-type: disc; "><li class="listitem"><p><code class="literal">IF ... THEN ... END IF</code></p></li><li class="listitem"><p><code class="literal">IF ... THEN ... ELSE ... END IF</code></p></li><li class="listitem"><p><code class="literal">IF ... THEN ... ELSIF ... THEN ... ELSE ... END IF</code></p></li></ul></div><p>
  203. and two forms of <code class="command">CASE</code>:
  204. </p><div class="itemizedlist"><ul class="itemizedlist" style="list-style-type: disc; "><li class="listitem"><p><code class="literal">CASE ... WHEN ... THEN ... ELSE ... END CASE</code></p></li><li class="listitem"><p><code class="literal">CASE WHEN ... THEN ... ELSE ... END CASE</code></p></li></ul></div><p>
  205. </p><div class="sect3" id="id-1.8.8.8.6.3"><div class="titlepage"><div><div><h4 class="title">42.6.4.1. <code class="literal">IF-THEN</code></h4></div></div></div><pre class="synopsis">
  206. IF <em class="replaceable"><code>boolean-expression</code></em> THEN
  207. <em class="replaceable"><code>statements</code></em>
  208. END IF;
  209. </pre><p>
  210. <code class="literal">IF-THEN</code> statements are the simplest form of
  211. <code class="literal">IF</code>. The statements between
  212. <code class="literal">THEN</code> and <code class="literal">END IF</code> will be
  213. executed if the condition is true. Otherwise, they are
  214. skipped.
  215. </p><p>
  216. Example:
  217. </p><pre class="programlisting">
  218. IF v_user_id &lt;&gt; 0 THEN
  219. UPDATE users SET email = v_email WHERE user_id = v_user_id;
  220. END IF;
  221. </pre><p>
  222. </p></div><div class="sect3" id="id-1.8.8.8.6.4"><div class="titlepage"><div><div><h4 class="title">42.6.4.2. <code class="literal">IF-THEN-ELSE</code></h4></div></div></div><pre class="synopsis">
  223. IF <em class="replaceable"><code>boolean-expression</code></em> THEN
  224. <em class="replaceable"><code>statements</code></em>
  225. ELSE
  226. <em class="replaceable"><code>statements</code></em>
  227. END IF;
  228. </pre><p>
  229. <code class="literal">IF-THEN-ELSE</code> statements add to
  230. <code class="literal">IF-THEN</code> by letting you specify an
  231. alternative set of statements that should be executed if the
  232. condition is not true. (Note this includes the case where the
  233. condition evaluates to NULL.)
  234. </p><p>
  235. Examples:
  236. </p><pre class="programlisting">
  237. IF parentid IS NULL OR parentid = ''
  238. THEN
  239. RETURN fullname;
  240. ELSE
  241. RETURN hp_true_filename(parentid) || '/' || fullname;
  242. END IF;
  243. </pre><p>
  244. </p><pre class="programlisting">
  245. IF v_count &gt; 0 THEN
  246. INSERT INTO users_count (count) VALUES (v_count);
  247. RETURN 't';
  248. ELSE
  249. RETURN 'f';
  250. END IF;
  251. </pre><p>
  252. </p></div><div class="sect3" id="id-1.8.8.8.6.5"><div class="titlepage"><div><div><h4 class="title">42.6.4.3. <code class="literal">IF-THEN-ELSIF</code></h4></div></div></div><pre class="synopsis">
  253. IF <em class="replaceable"><code>boolean-expression</code></em> THEN
  254. <em class="replaceable"><code>statements</code></em>
  255. [<span class="optional"> ELSIF <em class="replaceable"><code>boolean-expression</code></em> THEN
  256. <em class="replaceable"><code>statements</code></em>
  257. [<span class="optional"> ELSIF <em class="replaceable"><code>boolean-expression</code></em> THEN
  258. <em class="replaceable"><code>statements</code></em>
  259. ...
  260. </span>]
  261. </span>]
  262. [<span class="optional"> ELSE
  263. <em class="replaceable"><code>statements</code></em> </span>]
  264. END IF;
  265. </pre><p>
  266. Sometimes there are more than just two alternatives.
  267. <code class="literal">IF-THEN-ELSIF</code> provides a convenient
  268. method of checking several alternatives in turn.
  269. The <code class="literal">IF</code> conditions are tested successively
  270. until the first one that is true is found. Then the
  271. associated statement(s) are executed, after which control
  272. passes to the next statement after <code class="literal">END IF</code>.
  273. (Any subsequent <code class="literal">IF</code> conditions are <span class="emphasis"><em>not</em></span>
  274. tested.) If none of the <code class="literal">IF</code> conditions is true,
  275. then the <code class="literal">ELSE</code> block (if any) is executed.
  276. </p><p>
  277. Here is an example:
  278. </p><pre class="programlisting">
  279. IF number = 0 THEN
  280. result := 'zero';
  281. ELSIF number &gt; 0 THEN
  282. result := 'positive';
  283. ELSIF number &lt; 0 THEN
  284. result := 'negative';
  285. ELSE
  286. -- hmm, the only other possibility is that number is null
  287. result := 'NULL';
  288. END IF;
  289. </pre><p>
  290. </p><p>
  291. The key word <code class="literal">ELSIF</code> can also be spelled
  292. <code class="literal">ELSEIF</code>.
  293. </p><p>
  294. An alternative way of accomplishing the same task is to nest
  295. <code class="literal">IF-THEN-ELSE</code> statements, as in the
  296. following example:
  297. </p><pre class="programlisting">
  298. IF demo_row.sex = 'm' THEN
  299. pretty_sex := 'man';
  300. ELSE
  301. IF demo_row.sex = 'f' THEN
  302. pretty_sex := 'woman';
  303. END IF;
  304. END IF;
  305. </pre><p>
  306. </p><p>
  307. However, this method requires writing a matching <code class="literal">END IF</code>
  308. for each <code class="literal">IF</code>, so it is much more cumbersome than
  309. using <code class="literal">ELSIF</code> when there are many alternatives.
  310. </p></div><div class="sect3" id="id-1.8.8.8.6.6"><div class="titlepage"><div><div><h4 class="title">42.6.4.4. Simple <code class="literal">CASE</code></h4></div></div></div><pre class="synopsis">
  311. CASE <em class="replaceable"><code>search-expression</code></em>
  312. WHEN <em class="replaceable"><code>expression</code></em> [<span class="optional">, <em class="replaceable"><code>expression</code></em> [<span class="optional"> ... </span>]</span>] THEN
  313. <em class="replaceable"><code>statements</code></em>
  314. [<span class="optional"> WHEN <em class="replaceable"><code>expression</code></em> [<span class="optional">, <em class="replaceable"><code>expression</code></em> [<span class="optional"> ... </span>]</span>] THEN
  315. <em class="replaceable"><code>statements</code></em>
  316. ... </span>]
  317. [<span class="optional"> ELSE
  318. <em class="replaceable"><code>statements</code></em> </span>]
  319. END CASE;
  320. </pre><p>
  321. The simple form of <code class="command">CASE</code> provides conditional execution
  322. based on equality of operands. The <em class="replaceable"><code>search-expression</code></em>
  323. is evaluated (once) and successively compared to each
  324. <em class="replaceable"><code>expression</code></em> in the <code class="literal">WHEN</code> clauses.
  325. If a match is found, then the corresponding
  326. <em class="replaceable"><code>statements</code></em> are executed, and then control
  327. passes to the next statement after <code class="literal">END CASE</code>. (Subsequent
  328. <code class="literal">WHEN</code> expressions are not evaluated.) If no match is
  329. found, the <code class="literal">ELSE</code> <em class="replaceable"><code>statements</code></em> are
  330. executed; but if <code class="literal">ELSE</code> is not present, then a
  331. <code class="literal">CASE_NOT_FOUND</code> exception is raised.
  332. </p><p>
  333. Here is a simple example:
  334. </p><pre class="programlisting">
  335. CASE x
  336. WHEN 1, 2 THEN
  337. msg := 'one or two';
  338. ELSE
  339. msg := 'other value than one or two';
  340. END CASE;
  341. </pre><p>
  342. </p></div><div class="sect3" id="id-1.8.8.8.6.7"><div class="titlepage"><div><div><h4 class="title">42.6.4.5. Searched <code class="literal">CASE</code></h4></div></div></div><pre class="synopsis">
  343. CASE
  344. WHEN <em class="replaceable"><code>boolean-expression</code></em> THEN
  345. <em class="replaceable"><code>statements</code></em>
  346. [<span class="optional"> WHEN <em class="replaceable"><code>boolean-expression</code></em> THEN
  347. <em class="replaceable"><code>statements</code></em>
  348. ... </span>]
  349. [<span class="optional"> ELSE
  350. <em class="replaceable"><code>statements</code></em> </span>]
  351. END CASE;
  352. </pre><p>
  353. The searched form of <code class="command">CASE</code> provides conditional execution
  354. based on truth of Boolean expressions. Each <code class="literal">WHEN</code> clause's
  355. <em class="replaceable"><code>boolean-expression</code></em> is evaluated in turn,
  356. until one is found that yields <code class="literal">true</code>. Then the
  357. corresponding <em class="replaceable"><code>statements</code></em> are executed, and
  358. then control passes to the next statement after <code class="literal">END CASE</code>.
  359. (Subsequent <code class="literal">WHEN</code> expressions are not evaluated.)
  360. If no true result is found, the <code class="literal">ELSE</code>
  361. <em class="replaceable"><code>statements</code></em> are executed;
  362. but if <code class="literal">ELSE</code> is not present, then a
  363. <code class="literal">CASE_NOT_FOUND</code> exception is raised.
  364. </p><p>
  365. Here is an example:
  366. </p><pre class="programlisting">
  367. CASE
  368. WHEN x BETWEEN 0 AND 10 THEN
  369. msg := 'value is between zero and ten';
  370. WHEN x BETWEEN 11 AND 20 THEN
  371. msg := 'value is between eleven and twenty';
  372. END CASE;
  373. </pre><p>
  374. </p><p>
  375. This form of <code class="command">CASE</code> is entirely equivalent to
  376. <code class="literal">IF-THEN-ELSIF</code>, except for the rule that reaching
  377. an omitted <code class="literal">ELSE</code> clause results in an error rather
  378. than doing nothing.
  379. </p></div></div><div class="sect2" id="PLPGSQL-CONTROL-STRUCTURES-LOOPS"><div class="titlepage"><div><div><h3 class="title">42.6.5. Simple Loops</h3></div></div></div><a id="id-1.8.8.8.7.2" class="indexterm"></a><p>
  380. With the <code class="literal">LOOP</code>, <code class="literal">EXIT</code>,
  381. <code class="literal">CONTINUE</code>, <code class="literal">WHILE</code>, <code class="literal">FOR</code>,
  382. and <code class="literal">FOREACH</code> statements, you can arrange for your
  383. <span class="application">PL/pgSQL</span> function to repeat a series of commands.
  384. </p><div class="sect3" id="id-1.8.8.8.7.4"><div class="titlepage"><div><div><h4 class="title">42.6.5.1. <code class="literal">LOOP</code></h4></div></div></div><pre class="synopsis">
  385. [<span class="optional"> &lt;&lt;<em class="replaceable"><code>label</code></em>&gt;&gt; </span>]
  386. LOOP
  387. <em class="replaceable"><code>statements</code></em>
  388. END LOOP [<span class="optional"> <em class="replaceable"><code>label</code></em> </span>];
  389. </pre><p>
  390. <code class="literal">LOOP</code> defines an unconditional loop that is repeated
  391. indefinitely until terminated by an <code class="literal">EXIT</code> or
  392. <code class="command">RETURN</code> statement. The optional
  393. <em class="replaceable"><code>label</code></em> can be used by <code class="literal">EXIT</code>
  394. and <code class="literal">CONTINUE</code> statements within nested loops to
  395. specify which loop those statements refer to.
  396. </p></div><div class="sect3" id="id-1.8.8.8.7.5"><div class="titlepage"><div><div><h4 class="title">42.6.5.2. <code class="literal">EXIT</code></h4></div></div></div><a id="id-1.8.8.8.7.5.2" class="indexterm"></a><pre class="synopsis">
  397. EXIT [<span class="optional"> <em class="replaceable"><code>label</code></em> </span>] [<span class="optional"> WHEN <em class="replaceable"><code>boolean-expression</code></em> </span>];
  398. </pre><p>
  399. If no <em class="replaceable"><code>label</code></em> is given, the innermost
  400. loop is terminated and the statement following <code class="literal">END
  401. LOOP</code> is executed next. If <em class="replaceable"><code>label</code></em>
  402. is given, it must be the label of the current or some outer
  403. level of nested loop or block. Then the named loop or block is
  404. terminated and control continues with the statement after the
  405. loop's/block's corresponding <code class="literal">END</code>.
  406. </p><p>
  407. If <code class="literal">WHEN</code> is specified, the loop exit occurs only if
  408. <em class="replaceable"><code>boolean-expression</code></em> is true. Otherwise, control passes
  409. to the statement after <code class="literal">EXIT</code>.
  410. </p><p>
  411. <code class="literal">EXIT</code> can be used with all types of loops; it is
  412. not limited to use with unconditional loops.
  413. </p><p>
  414. When used with a
  415. <code class="literal">BEGIN</code> block, <code class="literal">EXIT</code> passes
  416. control to the next statement after the end of the block.
  417. Note that a label must be used for this purpose; an unlabeled
  418. <code class="literal">EXIT</code> is never considered to match a
  419. <code class="literal">BEGIN</code> block. (This is a change from
  420. pre-8.4 releases of <span class="productname">PostgreSQL</span>, which
  421. would allow an unlabeled <code class="literal">EXIT</code> to match
  422. a <code class="literal">BEGIN</code> block.)
  423. </p><p>
  424. Examples:
  425. </p><pre class="programlisting">
  426. LOOP
  427. -- some computations
  428. IF count &gt; 0 THEN
  429. EXIT; -- exit loop
  430. END IF;
  431. END LOOP;
  432. LOOP
  433. -- some computations
  434. EXIT WHEN count &gt; 0; -- same result as previous example
  435. END LOOP;
  436. &lt;&lt;ablock&gt;&gt;
  437. BEGIN
  438. -- some computations
  439. IF stocks &gt; 100000 THEN
  440. EXIT ablock; -- causes exit from the BEGIN block
  441. END IF;
  442. -- computations here will be skipped when stocks &gt; 100000
  443. END;
  444. </pre><p>
  445. </p></div><div class="sect3" id="id-1.8.8.8.7.6"><div class="titlepage"><div><div><h4 class="title">42.6.5.3. <code class="literal">CONTINUE</code></h4></div></div></div><a id="id-1.8.8.8.7.6.2" class="indexterm"></a><pre class="synopsis">
  446. CONTINUE [<span class="optional"> <em class="replaceable"><code>label</code></em> </span>] [<span class="optional"> WHEN <em class="replaceable"><code>boolean-expression</code></em> </span>];
  447. </pre><p>
  448. If no <em class="replaceable"><code>label</code></em> is given, the next iteration of
  449. the innermost loop is begun. That is, all statements remaining
  450. in the loop body are skipped, and control returns
  451. to the loop control expression (if any) to determine whether
  452. another loop iteration is needed.
  453. If <em class="replaceable"><code>label</code></em> is present, it
  454. specifies the label of the loop whose execution will be
  455. continued.
  456. </p><p>
  457. If <code class="literal">WHEN</code> is specified, the next iteration of the
  458. loop is begun only if <em class="replaceable"><code>boolean-expression</code></em> is
  459. true. Otherwise, control passes to the statement after
  460. <code class="literal">CONTINUE</code>.
  461. </p><p>
  462. <code class="literal">CONTINUE</code> can be used with all types of loops; it
  463. is not limited to use with unconditional loops.
  464. </p><p>
  465. Examples:
  466. </p><pre class="programlisting">
  467. LOOP
  468. -- some computations
  469. EXIT WHEN count &gt; 100;
  470. CONTINUE WHEN count &lt; 50;
  471. -- some computations for count IN [50 .. 100]
  472. END LOOP;
  473. </pre><p>
  474. </p></div><div class="sect3" id="id-1.8.8.8.7.7"><div class="titlepage"><div><div><h4 class="title">42.6.5.4. <code class="literal">WHILE</code></h4></div></div></div><a id="id-1.8.8.8.7.7.2" class="indexterm"></a><pre class="synopsis">
  475. [<span class="optional"> &lt;&lt;<em class="replaceable"><code>label</code></em>&gt;&gt; </span>]
  476. WHILE <em class="replaceable"><code>boolean-expression</code></em> LOOP
  477. <em class="replaceable"><code>statements</code></em>
  478. END LOOP [<span class="optional"> <em class="replaceable"><code>label</code></em> </span>];
  479. </pre><p>
  480. The <code class="literal">WHILE</code> statement repeats a
  481. sequence of statements so long as the
  482. <em class="replaceable"><code>boolean-expression</code></em>
  483. evaluates to true. The expression is checked just before
  484. each entry to the loop body.
  485. </p><p>
  486. For example:
  487. </p><pre class="programlisting">
  488. WHILE amount_owed &gt; 0 AND gift_certificate_balance &gt; 0 LOOP
  489. -- some computations here
  490. END LOOP;
  491. WHILE NOT done LOOP
  492. -- some computations here
  493. END LOOP;
  494. </pre><p>
  495. </p></div><div class="sect3" id="PLPGSQL-INTEGER-FOR"><div class="titlepage"><div><div><h4 class="title">42.6.5.5. <code class="literal">FOR</code> (Integer Variant)</h4></div></div></div><pre class="synopsis">
  496. [<span class="optional"> &lt;&lt;<em class="replaceable"><code>label</code></em>&gt;&gt; </span>]
  497. FOR <em class="replaceable"><code>name</code></em> IN [<span class="optional"> REVERSE </span>] <em class="replaceable"><code>expression</code></em> .. <em class="replaceable"><code>expression</code></em> [<span class="optional"> BY <em class="replaceable"><code>expression</code></em> </span>] LOOP
  498. <em class="replaceable"><code>statements</code></em>
  499. END LOOP [<span class="optional"> <em class="replaceable"><code>label</code></em> </span>];
  500. </pre><p>
  501. This form of <code class="literal">FOR</code> creates a loop that iterates over a range
  502. of integer values. The variable
  503. <em class="replaceable"><code>name</code></em> is automatically defined as type
  504. <code class="type">integer</code> and exists only inside the loop (any existing
  505. definition of the variable name is ignored within the loop).
  506. The two expressions giving
  507. the lower and upper bound of the range are evaluated once when entering
  508. the loop. If the <code class="literal">BY</code> clause isn't specified the iteration
  509. step is 1, otherwise it's the value specified in the <code class="literal">BY</code>
  510. clause, which again is evaluated once on loop entry.
  511. If <code class="literal">REVERSE</code> is specified then the step value is
  512. subtracted, rather than added, after each iteration.
  513. </p><p>
  514. Some examples of integer <code class="literal">FOR</code> loops:
  515. </p><pre class="programlisting">
  516. FOR i IN 1..10 LOOP
  517. -- i will take on the values 1,2,3,4,5,6,7,8,9,10 within the loop
  518. END LOOP;
  519. FOR i IN REVERSE 10..1 LOOP
  520. -- i will take on the values 10,9,8,7,6,5,4,3,2,1 within the loop
  521. END LOOP;
  522. FOR i IN REVERSE 10..1 BY 2 LOOP
  523. -- i will take on the values 10,8,6,4,2 within the loop
  524. END LOOP;
  525. </pre><p>
  526. </p><p>
  527. If the lower bound is greater than the upper bound (or less than,
  528. in the <code class="literal">REVERSE</code> case), the loop body is not
  529. executed at all. No error is raised.
  530. </p><p>
  531. If a <em class="replaceable"><code>label</code></em> is attached to the
  532. <code class="literal">FOR</code> loop then the integer loop variable can be
  533. referenced with a qualified name, using that
  534. <em class="replaceable"><code>label</code></em>.
  535. </p></div></div><div class="sect2" id="PLPGSQL-RECORDS-ITERATING"><div class="titlepage"><div><div><h3 class="title">42.6.6. Looping through Query Results</h3></div></div></div><p>
  536. Using a different type of <code class="literal">FOR</code> loop, you can iterate through
  537. the results of a query and manipulate that data
  538. accordingly. The syntax is:
  539. </p><pre class="synopsis">
  540. [<span class="optional"> &lt;&lt;<em class="replaceable"><code>label</code></em>&gt;&gt; </span>]
  541. FOR <em class="replaceable"><code>target</code></em> IN <em class="replaceable"><code>query</code></em> LOOP
  542. <em class="replaceable"><code>statements</code></em>
  543. END LOOP [<span class="optional"> <em class="replaceable"><code>label</code></em> </span>];
  544. </pre><p>
  545. The <em class="replaceable"><code>target</code></em> is a record variable, row variable,
  546. or comma-separated list of scalar variables.
  547. The <em class="replaceable"><code>target</code></em> is successively assigned each row
  548. resulting from the <em class="replaceable"><code>query</code></em> and the loop body is
  549. executed for each row. Here is an example:
  550. </p><pre class="programlisting">
  551. CREATE FUNCTION refresh_mviews() RETURNS integer AS $$
  552. DECLARE
  553. mviews RECORD;
  554. BEGIN
  555. RAISE NOTICE 'Refreshing all materialized views...';
  556. FOR mviews IN
  557. SELECT n.nspname AS mv_schema,
  558. c.relname AS mv_name,
  559. pg_catalog.pg_get_userbyid(c.relowner) AS owner
  560. FROM pg_catalog.pg_class c
  561. LEFT JOIN pg_catalog.pg_namespace n ON (n.oid = c.relnamespace)
  562. WHERE c.relkind = 'm'
  563. ORDER BY 1
  564. LOOP
  565. -- Now "mviews" has one record with information about the materialized view
  566. RAISE NOTICE 'Refreshing materialized view %.% (owner: %)...',
  567. quote_ident(mviews.mv_schema),
  568. quote_ident(mviews.mv_name),
  569. quote_ident(mviews.owner);
  570. EXECUTE format('REFRESH MATERIALIZED VIEW %I.%I', mviews.mv_schema, mviews.mv_name);
  571. END LOOP;
  572. RAISE NOTICE 'Done refreshing materialized views.';
  573. RETURN 1;
  574. END;
  575. $$ LANGUAGE plpgsql;
  576. </pre><p>
  577. If the loop is terminated by an <code class="literal">EXIT</code> statement, the last
  578. assigned row value is still accessible after the loop.
  579. </p><p>
  580. The <em class="replaceable"><code>query</code></em> used in this type of <code class="literal">FOR</code>
  581. statement can be any SQL command that returns rows to the caller:
  582. <code class="command">SELECT</code> is the most common case,
  583. but you can also use <code class="command">INSERT</code>, <code class="command">UPDATE</code>, or
  584. <code class="command">DELETE</code> with a <code class="literal">RETURNING</code> clause. Some utility
  585. commands such as <code class="command">EXPLAIN</code> will work too.
  586. </p><p>
  587. <span class="application">PL/pgSQL</span> variables are substituted into the query text,
  588. and the query plan is cached for possible re-use, as discussed in
  589. detail in <a class="xref" href="plpgsql-implementation.html#PLPGSQL-VAR-SUBST" title="42.11.1. Variable Substitution">Section 42.11.1</a> and
  590. <a class="xref" href="plpgsql-implementation.html#PLPGSQL-PLAN-CACHING" title="42.11.2. Plan Caching">Section 42.11.2</a>.
  591. </p><p>
  592. The <code class="literal">FOR-IN-EXECUTE</code> statement is another way to iterate over
  593. rows:
  594. </p><pre class="synopsis">
  595. [<span class="optional"> &lt;&lt;<em class="replaceable"><code>label</code></em>&gt;&gt; </span>]
  596. FOR <em class="replaceable"><code>target</code></em> IN EXECUTE <em class="replaceable"><code>text_expression</code></em> [<span class="optional"> USING <em class="replaceable"><code>expression</code></em> [<span class="optional">, ... </span>] </span>] LOOP
  597. <em class="replaceable"><code>statements</code></em>
  598. END LOOP [<span class="optional"> <em class="replaceable"><code>label</code></em> </span>];
  599. </pre><p>
  600. This is like the previous form, except that the source query
  601. is specified as a string expression, which is evaluated and replanned
  602. on each entry to the <code class="literal">FOR</code> loop. This allows the programmer to
  603. choose the speed of a preplanned query or the flexibility of a dynamic
  604. query, just as with a plain <code class="command">EXECUTE</code> statement.
  605. As with <code class="command">EXECUTE</code>, parameter values can be inserted
  606. into the dynamic command via <code class="literal">USING</code>.
  607. </p><p>
  608. Another way to specify the query whose results should be iterated
  609. through is to declare it as a cursor. This is described in
  610. <a class="xref" href="plpgsql-cursors.html#PLPGSQL-CURSOR-FOR-LOOP" title="42.7.4. Looping through a Cursor's Result">Section 42.7.4</a>.
  611. </p></div><div class="sect2" id="PLPGSQL-FOREACH-ARRAY"><div class="titlepage"><div><div><h3 class="title">42.6.7. Looping through Arrays</h3></div></div></div><p>
  612. The <code class="literal">FOREACH</code> loop is much like a <code class="literal">FOR</code> loop,
  613. but instead of iterating through the rows returned by a SQL query,
  614. it iterates through the elements of an array value.
  615. (In general, <code class="literal">FOREACH</code> is meant for looping through
  616. components of a composite-valued expression; variants for looping
  617. through composites besides arrays may be added in future.)
  618. The <code class="literal">FOREACH</code> statement to loop over an array is:
  619. </p><pre class="synopsis">
  620. [<span class="optional"> &lt;&lt;<em class="replaceable"><code>label</code></em>&gt;&gt; </span>]
  621. FOREACH <em class="replaceable"><code>target</code></em> [<span class="optional"> SLICE <em class="replaceable"><code>number</code></em> </span>] IN ARRAY <em class="replaceable"><code>expression</code></em> LOOP
  622. <em class="replaceable"><code>statements</code></em>
  623. END LOOP [<span class="optional"> <em class="replaceable"><code>label</code></em> </span>];
  624. </pre><p>
  625. </p><p>
  626. Without <code class="literal">SLICE</code>, or if <code class="literal">SLICE 0</code> is specified,
  627. the loop iterates through individual elements of the array produced
  628. by evaluating the <em class="replaceable"><code>expression</code></em>.
  629. The <em class="replaceable"><code>target</code></em> variable is assigned each
  630. element value in sequence, and the loop body is executed for each element.
  631. Here is an example of looping through the elements of an integer
  632. array:
  633. </p><pre class="programlisting">
  634. CREATE FUNCTION sum(int[]) RETURNS int8 AS $$
  635. DECLARE
  636. s int8 := 0;
  637. x int;
  638. BEGIN
  639. FOREACH x IN ARRAY $1
  640. LOOP
  641. s := s + x;
  642. END LOOP;
  643. RETURN s;
  644. END;
  645. $$ LANGUAGE plpgsql;
  646. </pre><p>
  647. The elements are visited in storage order, regardless of the number of
  648. array dimensions. Although the <em class="replaceable"><code>target</code></em> is
  649. usually just a single variable, it can be a list of variables when
  650. looping through an array of composite values (records). In that case,
  651. for each array element, the variables are assigned from successive
  652. columns of the composite value.
  653. </p><p>
  654. With a positive <code class="literal">SLICE</code> value, <code class="literal">FOREACH</code>
  655. iterates through slices of the array rather than single elements.
  656. The <code class="literal">SLICE</code> value must be an integer constant not larger
  657. than the number of dimensions of the array. The
  658. <em class="replaceable"><code>target</code></em> variable must be an array,
  659. and it receives successive slices of the array value, where each slice
  660. is of the number of dimensions specified by <code class="literal">SLICE</code>.
  661. Here is an example of iterating through one-dimensional slices:
  662. </p><pre class="programlisting">
  663. CREATE FUNCTION scan_rows(int[]) RETURNS void AS $$
  664. DECLARE
  665. x int[];
  666. BEGIN
  667. FOREACH x SLICE 1 IN ARRAY $1
  668. LOOP
  669. RAISE NOTICE 'row = %', x;
  670. END LOOP;
  671. END;
  672. $$ LANGUAGE plpgsql;
  673. SELECT scan_rows(ARRAY[[1,2,3],[4,5,6],[7,8,9],[10,11,12]]);
  674. NOTICE: row = {1,2,3}
  675. NOTICE: row = {4,5,6}
  676. NOTICE: row = {7,8,9}
  677. NOTICE: row = {10,11,12}
  678. </pre><p>
  679. </p></div><div class="sect2" id="PLPGSQL-ERROR-TRAPPING"><div class="titlepage"><div><div><h3 class="title">42.6.8. Trapping Errors</h3></div></div></div><a id="id-1.8.8.8.10.2" class="indexterm"></a><p>
  680. By default, any error occurring in a <span class="application">PL/pgSQL</span>
  681. function aborts execution of the function, and indeed of the
  682. surrounding transaction as well. You can trap errors and recover
  683. from them by using a <code class="command">BEGIN</code> block with an
  684. <code class="literal">EXCEPTION</code> clause. The syntax is an extension of the
  685. normal syntax for a <code class="command">BEGIN</code> block:
  686. </p><pre class="synopsis">
  687. [<span class="optional"> &lt;&lt;<em class="replaceable"><code>label</code></em>&gt;&gt; </span>]
  688. [<span class="optional"> DECLARE
  689. <em class="replaceable"><code>declarations</code></em> </span>]
  690. BEGIN
  691. <em class="replaceable"><code>statements</code></em>
  692. EXCEPTION
  693. WHEN <em class="replaceable"><code>condition</code></em> [<span class="optional"> OR <em class="replaceable"><code>condition</code></em> ... </span>] THEN
  694. <em class="replaceable"><code>handler_statements</code></em>
  695. [<span class="optional"> WHEN <em class="replaceable"><code>condition</code></em> [<span class="optional"> OR <em class="replaceable"><code>condition</code></em> ... </span>] THEN
  696. <em class="replaceable"><code>handler_statements</code></em>
  697. ... </span>]
  698. END;
  699. </pre><p>
  700. </p><p>
  701. If no error occurs, this form of block simply executes all the
  702. <em class="replaceable"><code>statements</code></em>, and then control passes
  703. to the next statement after <code class="literal">END</code>. But if an error
  704. occurs within the <em class="replaceable"><code>statements</code></em>, further
  705. processing of the <em class="replaceable"><code>statements</code></em> is
  706. abandoned, and control passes to the <code class="literal">EXCEPTION</code> list.
  707. The list is searched for the first <em class="replaceable"><code>condition</code></em>
  708. matching the error that occurred. If a match is found, the
  709. corresponding <em class="replaceable"><code>handler_statements</code></em> are
  710. executed, and then control passes to the next statement after
  711. <code class="literal">END</code>. If no match is found, the error propagates out
  712. as though the <code class="literal">EXCEPTION</code> clause were not there at all:
  713. the error can be caught by an enclosing block with
  714. <code class="literal">EXCEPTION</code>, or if there is none it aborts processing
  715. of the function.
  716. </p><p>
  717. The <em class="replaceable"><code>condition</code></em> names can be any of
  718. those shown in <a class="xref" href="errcodes-appendix.html" title="Appendix A. PostgreSQL Error Codes">Appendix A</a>. A category
  719. name matches any error within its category. The special
  720. condition name <code class="literal">OTHERS</code> matches every error type except
  721. <code class="literal">QUERY_CANCELED</code> and <code class="literal">ASSERT_FAILURE</code>.
  722. (It is possible, but often unwise, to trap those two error types
  723. by name.) Condition names are
  724. not case-sensitive. Also, an error condition can be specified
  725. by <code class="literal">SQLSTATE</code> code; for example these are equivalent:
  726. </p><pre class="programlisting">
  727. WHEN division_by_zero THEN ...
  728. WHEN SQLSTATE '22012' THEN ...
  729. </pre><p>
  730. </p><p>
  731. If a new error occurs within the selected
  732. <em class="replaceable"><code>handler_statements</code></em>, it cannot be caught
  733. by this <code class="literal">EXCEPTION</code> clause, but is propagated out.
  734. A surrounding <code class="literal">EXCEPTION</code> clause could catch it.
  735. </p><p>
  736. When an error is caught by an <code class="literal">EXCEPTION</code> clause,
  737. the local variables of the <span class="application">PL/pgSQL</span> function
  738. remain as they were when the error occurred, but all changes
  739. to persistent database state within the block are rolled back.
  740. As an example, consider this fragment:
  741. </p><pre class="programlisting">
  742. INSERT INTO mytab(firstname, lastname) VALUES('Tom', 'Jones');
  743. BEGIN
  744. UPDATE mytab SET firstname = 'Joe' WHERE lastname = 'Jones';
  745. x := x + 1;
  746. y := x / 0;
  747. EXCEPTION
  748. WHEN division_by_zero THEN
  749. RAISE NOTICE 'caught division_by_zero';
  750. RETURN x;
  751. END;
  752. </pre><p>
  753. When control reaches the assignment to <code class="literal">y</code>, it will
  754. fail with a <code class="literal">division_by_zero</code> error. This will be caught by
  755. the <code class="literal">EXCEPTION</code> clause. The value returned in the
  756. <code class="command">RETURN</code> statement will be the incremented value of
  757. <code class="literal">x</code>, but the effects of the <code class="command">UPDATE</code> command will
  758. have been rolled back. The <code class="command">INSERT</code> command preceding the
  759. block is not rolled back, however, so the end result is that the database
  760. contains <code class="literal">Tom Jones</code> not <code class="literal">Joe Jones</code>.
  761. </p><div class="tip"><h3 class="title">Tip</h3><p>
  762. A block containing an <code class="literal">EXCEPTION</code> clause is significantly
  763. more expensive to enter and exit than a block without one. Therefore,
  764. don't use <code class="literal">EXCEPTION</code> without need.
  765. </p></div><div class="example" id="PLPGSQL-UPSERT-EXAMPLE"><p class="title"><strong>Example 42.2. Exceptions with <code class="command">UPDATE</code>/<code class="command">INSERT</code></strong></p><div class="example-contents"><p>
  766. This example uses exception handling to perform either
  767. <code class="command">UPDATE</code> or <code class="command">INSERT</code>, as appropriate. It is
  768. recommended that applications use <code class="command">INSERT</code> with
  769. <code class="literal">ON CONFLICT DO UPDATE</code> rather than actually using
  770. this pattern. This example serves primarily to illustrate use of
  771. <span class="application">PL/pgSQL</span> control flow structures:
  772. </p><pre class="programlisting">
  773. CREATE TABLE db (a INT PRIMARY KEY, b TEXT);
  774. CREATE FUNCTION merge_db(key INT, data TEXT) RETURNS VOID AS
  775. $$
  776. BEGIN
  777. LOOP
  778. -- first try to update the key
  779. UPDATE db SET b = data WHERE a = key;
  780. IF found THEN
  781. RETURN;
  782. END IF;
  783. -- not there, so try to insert the key
  784. -- if someone else inserts the same key concurrently,
  785. -- we could get a unique-key failure
  786. BEGIN
  787. INSERT INTO db(a,b) VALUES (key, data);
  788. RETURN;
  789. EXCEPTION WHEN unique_violation THEN
  790. -- Do nothing, and loop to try the UPDATE again.
  791. END;
  792. END LOOP;
  793. END;
  794. $$
  795. LANGUAGE plpgsql;
  796. SELECT merge_db(1, 'david');
  797. SELECT merge_db(1, 'dennis');
  798. </pre><p>
  799. This coding assumes the <code class="literal">unique_violation</code> error is caused by
  800. the <code class="command">INSERT</code>, and not by, say, an <code class="command">INSERT</code> in a
  801. trigger function on the table. It might also misbehave if there is
  802. more than one unique index on the table, since it will retry the
  803. operation regardless of which index caused the error.
  804. More safety could be had by using the
  805. features discussed next to check that the trapped error was the one
  806. expected.
  807. </p></div></div><br class="example-break" /><div class="sect3" id="PLPGSQL-EXCEPTION-DIAGNOSTICS"><div class="titlepage"><div><div><h4 class="title">42.6.8.1. Obtaining Information about an Error</h4></div></div></div><p>
  808. Exception handlers frequently need to identify the specific error that
  809. occurred. There are two ways to get information about the current
  810. exception in <span class="application">PL/pgSQL</span>: special variables and the
  811. <code class="command">GET STACKED DIAGNOSTICS</code> command.
  812. </p><p>
  813. Within an exception handler, the special variable
  814. <code class="varname">SQLSTATE</code> contains the error code that corresponds to
  815. the exception that was raised (refer to <a class="xref" href="errcodes-appendix.html#ERRCODES-TABLE" title="Table A.1. PostgreSQL Error Codes">Table A.1</a>
  816. for a list of possible error codes). The special variable
  817. <code class="varname">SQLERRM</code> contains the error message associated with the
  818. exception. These variables are undefined outside exception handlers.
  819. </p><p>
  820. Within an exception handler, one may also retrieve
  821. information about the current exception by using the
  822. <code class="command">GET STACKED DIAGNOSTICS</code> command, which has the form:
  823. </p><pre class="synopsis">
  824. GET STACKED DIAGNOSTICS <em class="replaceable"><code>variable</code></em> { = | := } <em class="replaceable"><code>item</code></em> [<span class="optional"> , ... </span>];
  825. </pre><p>
  826. Each <em class="replaceable"><code>item</code></em> is a key word identifying a status
  827. value to be assigned to the specified <em class="replaceable"><code>variable</code></em>
  828. (which should be of the right data type to receive it). The currently
  829. available status items are shown
  830. in <a class="xref" href="plpgsql-control-structures.html#PLPGSQL-EXCEPTION-DIAGNOSTICS-VALUES" title="Table 42.2. Error Diagnostics Items">Table 42.2</a>.
  831. </p><div class="table" id="PLPGSQL-EXCEPTION-DIAGNOSTICS-VALUES"><p class="title"><strong>Table 42.2. Error Diagnostics Items</strong></p><div class="table-contents"><table class="table" summary="Error Diagnostics Items" border="1"><colgroup><col /><col /><col /></colgroup><thead><tr><th>Name</th><th>Type</th><th>Description</th></tr></thead><tbody><tr><td><code class="literal">RETURNED_SQLSTATE</code></td><td><code class="type">text</code></td><td>the SQLSTATE error code of the exception</td></tr><tr><td><code class="literal">COLUMN_NAME</code></td><td><code class="type">text</code></td><td>the name of the column related to exception</td></tr><tr><td><code class="literal">CONSTRAINT_NAME</code></td><td><code class="type">text</code></td><td>the name of the constraint related to exception</td></tr><tr><td><code class="literal">PG_DATATYPE_NAME</code></td><td><code class="type">text</code></td><td>the name of the data type related to exception</td></tr><tr><td><code class="literal">MESSAGE_TEXT</code></td><td><code class="type">text</code></td><td>the text of the exception's primary message</td></tr><tr><td><code class="literal">TABLE_NAME</code></td><td><code class="type">text</code></td><td>the name of the table related to exception</td></tr><tr><td><code class="literal">SCHEMA_NAME</code></td><td><code class="type">text</code></td><td>the name of the schema related to exception</td></tr><tr><td><code class="literal">PG_EXCEPTION_DETAIL</code></td><td><code class="type">text</code></td><td>the text of the exception's detail message, if any</td></tr><tr><td><code class="literal">PG_EXCEPTION_HINT</code></td><td><code class="type">text</code></td><td>the text of the exception's hint message, if any</td></tr><tr><td><code class="literal">PG_EXCEPTION_CONTEXT</code></td><td><code class="type">text</code></td><td>line(s) of text describing the call stack at the time of the
  832. exception (see <a class="xref" href="plpgsql-control-structures.html#PLPGSQL-CALL-STACK" title="42.6.9. Obtaining Execution Location Information">Section 42.6.9</a>)</td></tr></tbody></table></div></div><br class="table-break" /><p>
  833. If the exception did not set a value for an item, an empty string
  834. will be returned.
  835. </p><p>
  836. Here is an example:
  837. </p><pre class="programlisting">
  838. DECLARE
  839. text_var1 text;
  840. text_var2 text;
  841. text_var3 text;
  842. BEGIN
  843. -- some processing which might cause an exception
  844. ...
  845. EXCEPTION WHEN OTHERS THEN
  846. GET STACKED DIAGNOSTICS text_var1 = MESSAGE_TEXT,
  847. text_var2 = PG_EXCEPTION_DETAIL,
  848. text_var3 = PG_EXCEPTION_HINT;
  849. END;
  850. </pre><p>
  851. </p></div></div><div class="sect2" id="PLPGSQL-CALL-STACK"><div class="titlepage"><div><div><h3 class="title">42.6.9. Obtaining Execution Location Information</h3></div></div></div><p>
  852. The <code class="command">GET DIAGNOSTICS</code> command, previously described
  853. in <a class="xref" href="plpgsql-statements.html#PLPGSQL-STATEMENTS-DIAGNOSTICS" title="42.5.5. Obtaining the Result Status">Section 42.5.5</a>, retrieves information
  854. about current execution state (whereas the <code class="command">GET STACKED
  855. DIAGNOSTICS</code> command discussed above reports information about
  856. the execution state as of a previous error). Its <code class="literal">PG_CONTEXT</code>
  857. status item is useful for identifying the current execution
  858. location. <code class="literal">PG_CONTEXT</code> returns a text string with line(s)
  859. of text describing the call stack. The first line refers to the current
  860. function and currently executing <code class="command">GET DIAGNOSTICS</code>
  861. command. The second and any subsequent lines refer to calling functions
  862. further up the call stack. For example:
  863. </p><pre class="programlisting">
  864. CREATE OR REPLACE FUNCTION outer_func() RETURNS integer AS $$
  865. BEGIN
  866. RETURN inner_func();
  867. END;
  868. $$ LANGUAGE plpgsql;
  869. CREATE OR REPLACE FUNCTION inner_func() RETURNS integer AS $$
  870. DECLARE
  871. stack text;
  872. BEGIN
  873. GET DIAGNOSTICS stack = PG_CONTEXT;
  874. RAISE NOTICE E'--- Call Stack ---\n%', stack;
  875. RETURN 1;
  876. END;
  877. $$ LANGUAGE plpgsql;
  878. SELECT outer_func();
  879. NOTICE: --- Call Stack ---
  880. PL/pgSQL function inner_func() line 5 at GET DIAGNOSTICS
  881. PL/pgSQL function outer_func() line 3 at RETURN
  882. CONTEXT: PL/pgSQL function outer_func() line 3 at RETURN
  883. outer_func
  884. ------------
  885. 1
  886. (1 row)
  887. </pre><p>
  888. </p><p>
  889. <code class="literal">GET STACKED DIAGNOSTICS ... PG_EXCEPTION_CONTEXT</code>
  890. returns the same sort of stack trace, but describing the location
  891. at which an error was detected, rather than the current location.
  892. </p></div></div><div class="navfooter"><hr /><table width="100%" summary="Navigation footer"><tr><td width="40%" align="left"><a accesskey="p" href="plpgsql-statements.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-cursors.html">Next</a></td></tr><tr><td width="40%" align="left" valign="top">42.5. Basic Statements </td><td width="20%" align="center"><a accesskey="h" href="index.html">Home</a></td><td width="40%" align="right" valign="top"> 42.7. Cursors</td></tr></table></div></body></html>
上海开阖软件有限公司 沪ICP备12045867号-1