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.

552 line
37KB

  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.5. Basic Statements</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-expressions.html" title="42.4. Expressions" /><link rel="next" href="plpgsql-control-structures.html" title="42.6. Control Structures" /></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.5. Basic Statements</th></tr><tr><td width="10%" align="left"><a accesskey="p" href="plpgsql-expressions.html" title="42.4. Expressions">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-control-structures.html" title="42.6. Control Structures">Next</a></td></tr></table><hr></hr></div><div class="sect1" id="PLPGSQL-STATEMENTS"><div class="titlepage"><div><div><h2 class="title" style="clear: both">42.5. Basic Statements</h2></div></div></div><div class="toc"><dl class="toc"><dt><span class="sect2"><a href="plpgsql-statements.html#PLPGSQL-STATEMENTS-ASSIGNMENT">42.5.1. Assignment</a></span></dt><dt><span class="sect2"><a href="plpgsql-statements.html#PLPGSQL-STATEMENTS-SQL-NORESULT">42.5.2. Executing a Command with No Result</a></span></dt><dt><span class="sect2"><a href="plpgsql-statements.html#PLPGSQL-STATEMENTS-SQL-ONEROW">42.5.3. Executing a Query with a Single-Row Result</a></span></dt><dt><span class="sect2"><a href="plpgsql-statements.html#PLPGSQL-STATEMENTS-EXECUTING-DYN">42.5.4. Executing Dynamic Commands</a></span></dt><dt><span class="sect2"><a href="plpgsql-statements.html#PLPGSQL-STATEMENTS-DIAGNOSTICS">42.5.5. Obtaining the Result Status</a></span></dt><dt><span class="sect2"><a href="plpgsql-statements.html#PLPGSQL-STATEMENTS-NULL">42.5.6. Doing Nothing At All</a></span></dt></dl></div><p>
  3. In this section and the following ones, we describe all the statement
  4. types that are explicitly understood by
  5. <span class="application">PL/pgSQL</span>.
  6. Anything not recognized as one of these statement types is presumed
  7. to be an SQL command and is sent to the main database engine to execute,
  8. as described in <a class="xref" href="plpgsql-statements.html#PLPGSQL-STATEMENTS-SQL-NORESULT" title="42.5.2. Executing a Command with No Result">Section 42.5.2</a>
  9. and <a class="xref" href="plpgsql-statements.html#PLPGSQL-STATEMENTS-SQL-ONEROW" title="42.5.3. Executing a Query with a Single-Row Result">Section 42.5.3</a>.
  10. </p><div class="sect2" id="PLPGSQL-STATEMENTS-ASSIGNMENT"><div class="titlepage"><div><div><h3 class="title">42.5.1. Assignment</h3></div></div></div><p>
  11. An assignment of a value to a <span class="application">PL/pgSQL</span>
  12. variable is written as:
  13. </p><pre class="synopsis">
  14. <em class="replaceable"><code>variable</code></em> { := | = } <em class="replaceable"><code>expression</code></em>;
  15. </pre><p>
  16. As explained previously, the expression in such a statement is evaluated
  17. by means of an SQL <code class="command">SELECT</code> command sent to the main
  18. database engine. The expression must yield a single value (possibly
  19. a row value, if the variable is a row or record variable). The target
  20. variable can be a simple variable (optionally qualified with a block
  21. name), a field of a row or record variable, or an element of an array
  22. that is a simple variable or field. Equal (<code class="literal">=</code>) can be
  23. used instead of PL/SQL-compliant <code class="literal">:=</code>.
  24. </p><p>
  25. If the expression's result data type doesn't match the variable's
  26. data type, the value will be coerced as though by an assignment cast
  27. (see <a class="xref" href="typeconv-query.html" title="10.4. Value Storage">Section 10.4</a>). If no assignment cast is known
  28. for the pair of data types involved, the <span class="application">PL/pgSQL</span>
  29. interpreter will attempt to convert the result value textually, that is
  30. by applying the result type's output function followed by the variable
  31. type's input function. Note that this could result in run-time errors
  32. generated by the input function, if the string form of the result value
  33. is not acceptable to the input function.
  34. </p><p>
  35. Examples:
  36. </p><pre class="programlisting">
  37. tax := subtotal * 0.06;
  38. my_record.user_id := 20;
  39. </pre><p>
  40. </p></div><div class="sect2" id="PLPGSQL-STATEMENTS-SQL-NORESULT"><div class="titlepage"><div><div><h3 class="title">42.5.2. Executing a Command with No Result</h3></div></div></div><p>
  41. For any SQL command that does not return rows, for example
  42. <code class="command">INSERT</code> without a <code class="literal">RETURNING</code> clause, you can
  43. execute the command within a <span class="application">PL/pgSQL</span> function
  44. just by writing the command.
  45. </p><p>
  46. Any <span class="application">PL/pgSQL</span> variable name appearing
  47. in the command text is treated as a parameter, and then the
  48. current value of the variable is provided as the parameter value
  49. at run time. This is exactly like the processing described earlier
  50. for expressions; for details see <a class="xref" href="plpgsql-implementation.html#PLPGSQL-VAR-SUBST" title="42.11.1. Variable Substitution">Section 42.11.1</a>.
  51. </p><p>
  52. When executing a SQL command in this way,
  53. <span class="application">PL/pgSQL</span> may cache and re-use the execution
  54. plan for the command, as discussed in
  55. <a class="xref" href="plpgsql-implementation.html#PLPGSQL-PLAN-CACHING" title="42.11.2. Plan Caching">Section 42.11.2</a>.
  56. </p><p>
  57. Sometimes it is useful to evaluate an expression or <code class="command">SELECT</code>
  58. query but discard the result, for example when calling a function
  59. that has side-effects but no useful result value. To do
  60. this in <span class="application">PL/pgSQL</span>, use the
  61. <code class="command">PERFORM</code> statement:
  62. </p><pre class="synopsis">
  63. PERFORM <em class="replaceable"><code>query</code></em>;
  64. </pre><p>
  65. This executes <em class="replaceable"><code>query</code></em> and discards the
  66. result. Write the <em class="replaceable"><code>query</code></em> the same
  67. way you would write an SQL <code class="command">SELECT</code> command, but replace the
  68. initial keyword <code class="command">SELECT</code> with <code class="command">PERFORM</code>.
  69. For <code class="command">WITH</code> queries, use <code class="command">PERFORM</code> and then
  70. place the query in parentheses. (In this case, the query can only
  71. return one row.)
  72. <span class="application">PL/pgSQL</span> variables will be
  73. substituted into the query just as for commands that return no result,
  74. and the plan is cached in the same way. Also, the special variable
  75. <code class="literal">FOUND</code> is set to true if the query produced at
  76. least one row, or false if it produced no rows (see
  77. <a class="xref" href="plpgsql-statements.html#PLPGSQL-STATEMENTS-DIAGNOSTICS" title="42.5.5. Obtaining the Result Status">Section 42.5.5</a>).
  78. </p><div class="note"><h3 class="title">Note</h3><p>
  79. One might expect that writing <code class="command">SELECT</code> directly
  80. would accomplish this result, but at
  81. present the only accepted way to do it is
  82. <code class="command">PERFORM</code>. A SQL command that can return rows,
  83. such as <code class="command">SELECT</code>, will be rejected as an error
  84. unless it has an <code class="literal">INTO</code> clause as discussed in the
  85. next section.
  86. </p></div><p>
  87. An example:
  88. </p><pre class="programlisting">
  89. PERFORM create_mv('cs_session_page_requests_mv', my_query);
  90. </pre><p>
  91. </p></div><div class="sect2" id="PLPGSQL-STATEMENTS-SQL-ONEROW"><div class="titlepage"><div><div><h3 class="title">42.5.3. Executing a Query with a Single-Row Result</h3></div></div></div><a id="id-1.8.8.7.5.2" class="indexterm"></a><a id="id-1.8.8.7.5.3" class="indexterm"></a><p>
  92. The result of a SQL command yielding a single row (possibly of multiple
  93. columns) can be assigned to a record variable, row-type variable, or list
  94. of scalar variables. This is done by writing the base SQL command and
  95. adding an <code class="literal">INTO</code> clause. For example,
  96. </p><pre class="synopsis">
  97. SELECT <em class="replaceable"><code>select_expressions</code></em> INTO [<span class="optional">STRICT</span>] <em class="replaceable"><code>target</code></em> FROM ...;
  98. INSERT ... RETURNING <em class="replaceable"><code>expressions</code></em> INTO [<span class="optional">STRICT</span>] <em class="replaceable"><code>target</code></em>;
  99. UPDATE ... RETURNING <em class="replaceable"><code>expressions</code></em> INTO [<span class="optional">STRICT</span>] <em class="replaceable"><code>target</code></em>;
  100. DELETE ... RETURNING <em class="replaceable"><code>expressions</code></em> INTO [<span class="optional">STRICT</span>] <em class="replaceable"><code>target</code></em>;
  101. </pre><p>
  102. where <em class="replaceable"><code>target</code></em> can be a record variable, a row
  103. variable, or a comma-separated list of simple variables and
  104. record/row fields.
  105. <span class="application">PL/pgSQL</span> variables will be
  106. substituted into the rest of the query, and the plan is cached,
  107. just as described above for commands that do not return rows.
  108. This works for <code class="command">SELECT</code>,
  109. <code class="command">INSERT</code>/<code class="command">UPDATE</code>/<code class="command">DELETE</code> with
  110. <code class="literal">RETURNING</code>, and utility commands that return row-set
  111. results (such as <code class="command">EXPLAIN</code>).
  112. Except for the <code class="literal">INTO</code> clause, the SQL command is the same
  113. as it would be written outside <span class="application">PL/pgSQL</span>.
  114. </p><div class="tip"><h3 class="title">Tip</h3><p>
  115. Note that this interpretation of <code class="command">SELECT</code> with <code class="literal">INTO</code>
  116. is quite different from <span class="productname">PostgreSQL</span>'s regular
  117. <code class="command">SELECT INTO</code> command, wherein the <code class="literal">INTO</code>
  118. target is a newly created table. If you want to create a table from a
  119. <code class="command">SELECT</code> result inside a
  120. <span class="application">PL/pgSQL</span> function, use the syntax
  121. <code class="command">CREATE TABLE ... AS SELECT</code>.
  122. </p></div><p>
  123. If a row or a variable list is used as target, the query's result columns
  124. must exactly match the structure of the target as to number and data
  125. types, or else a run-time error
  126. occurs. When a record variable is the target, it automatically
  127. configures itself to the row type of the query result columns.
  128. </p><p>
  129. The <code class="literal">INTO</code> clause can appear almost anywhere in the SQL
  130. command. Customarily it is written either just before or just after
  131. the list of <em class="replaceable"><code>select_expressions</code></em> in a
  132. <code class="command">SELECT</code> command, or at the end of the command for other
  133. command types. It is recommended that you follow this convention
  134. in case the <span class="application">PL/pgSQL</span> parser becomes
  135. stricter in future versions.
  136. </p><p>
  137. If <code class="literal">STRICT</code> is not specified in the <code class="literal">INTO</code>
  138. clause, then <em class="replaceable"><code>target</code></em> will be set to the first
  139. row returned by the query, or to nulls if the query returned no rows.
  140. (Note that <span class="quote">“<span class="quote">the first row</span>”</span> is not
  141. well-defined unless you've used <code class="literal">ORDER BY</code>.) Any result rows
  142. after the first row are discarded.
  143. You can check the special <code class="literal">FOUND</code> variable (see
  144. <a class="xref" href="plpgsql-statements.html#PLPGSQL-STATEMENTS-DIAGNOSTICS" title="42.5.5. Obtaining the Result Status">Section 42.5.5</a>) to
  145. determine whether a row was returned:
  146. </p><pre class="programlisting">
  147. SELECT * INTO myrec FROM emp WHERE empname = myname;
  148. IF NOT FOUND THEN
  149. RAISE EXCEPTION 'employee % not found', myname;
  150. END IF;
  151. </pre><p>
  152. If the <code class="literal">STRICT</code> option is specified, the query must
  153. return exactly one row or a run-time error will be reported, either
  154. <code class="literal">NO_DATA_FOUND</code> (no rows) or <code class="literal">TOO_MANY_ROWS</code>
  155. (more than one row). You can use an exception block if you wish
  156. to catch the error, for example:
  157. </p><pre class="programlisting">
  158. BEGIN
  159. SELECT * INTO STRICT myrec FROM emp WHERE empname = myname;
  160. EXCEPTION
  161. WHEN NO_DATA_FOUND THEN
  162. RAISE EXCEPTION 'employee % not found', myname;
  163. WHEN TOO_MANY_ROWS THEN
  164. RAISE EXCEPTION 'employee % not unique', myname;
  165. END;
  166. </pre><p>
  167. Successful execution of a command with <code class="literal">STRICT</code>
  168. always sets <code class="literal">FOUND</code> to true.
  169. </p><p>
  170. For <code class="command">INSERT</code>/<code class="command">UPDATE</code>/<code class="command">DELETE</code> with
  171. <code class="literal">RETURNING</code>, <span class="application">PL/pgSQL</span> reports
  172. an error for more than one returned row, even when
  173. <code class="literal">STRICT</code> is not specified. This is because there
  174. is no option such as <code class="literal">ORDER BY</code> with which to determine
  175. which affected row should be returned.
  176. </p><p>
  177. If <code class="literal">print_strict_params</code> is enabled for the function,
  178. then when an error is thrown because the requirements
  179. of <code class="literal">STRICT</code> are not met, the <code class="literal">DETAIL</code> part of
  180. the error message will include information about the parameters
  181. passed to the query.
  182. You can change the <code class="literal">print_strict_params</code>
  183. setting for all functions by setting
  184. <code class="varname">plpgsql.print_strict_params</code>, though only subsequent
  185. function compilations will be affected. You can also enable it
  186. on a per-function basis by using a compiler option, for example:
  187. </p><pre class="programlisting">
  188. CREATE FUNCTION get_userid(username text) RETURNS int
  189. AS $$
  190. #print_strict_params on
  191. DECLARE
  192. userid int;
  193. BEGIN
  194. SELECT users.userid INTO STRICT userid
  195. FROM users WHERE users.username = get_userid.username;
  196. RETURN userid;
  197. END
  198. $$ LANGUAGE plpgsql;
  199. </pre><p>
  200. On failure, this function might produce an error message such as
  201. </p><pre class="programlisting">
  202. ERROR: query returned no rows
  203. DETAIL: parameters: $1 = 'nosuchuser'
  204. CONTEXT: PL/pgSQL function get_userid(text) line 6 at SQL statement
  205. </pre><p>
  206. </p><div class="note"><h3 class="title">Note</h3><p>
  207. The <code class="literal">STRICT</code> option matches the behavior of
  208. Oracle PL/SQL's <code class="command">SELECT INTO</code> and related statements.
  209. </p></div><p>
  210. To handle cases where you need to process multiple result rows
  211. from a SQL query, see <a class="xref" href="plpgsql-control-structures.html#PLPGSQL-RECORDS-ITERATING" title="42.6.6. Looping through Query Results">Section 42.6.6</a>.
  212. </p></div><div class="sect2" id="PLPGSQL-STATEMENTS-EXECUTING-DYN"><div class="titlepage"><div><div><h3 class="title">42.5.4. Executing Dynamic Commands</h3></div></div></div><p>
  213. Oftentimes you will want to generate dynamic commands inside your
  214. <span class="application">PL/pgSQL</span> functions, that is, commands
  215. that will involve different tables or different data types each
  216. time they are executed. <span class="application">PL/pgSQL</span>'s
  217. normal attempts to cache plans for commands (as discussed in
  218. <a class="xref" href="plpgsql-implementation.html#PLPGSQL-PLAN-CACHING" title="42.11.2. Plan Caching">Section 42.11.2</a>) will not work in such
  219. scenarios. To handle this sort of problem, the
  220. <code class="command">EXECUTE</code> statement is provided:
  221. </p><pre class="synopsis">
  222. EXECUTE <em class="replaceable"><code>command-string</code></em> [<span class="optional"> INTO [<span class="optional">STRICT</span>] <em class="replaceable"><code>target</code></em> </span>] [<span class="optional"> USING <em class="replaceable"><code>expression</code></em> [<span class="optional">, ... </span>] </span>];
  223. </pre><p>
  224. where <em class="replaceable"><code>command-string</code></em> is an expression
  225. yielding a string (of type <code class="type">text</code>) containing the
  226. command to be executed. The optional <em class="replaceable"><code>target</code></em>
  227. is a record variable, a row variable, or a comma-separated list of
  228. simple variables and record/row fields, into which the results of
  229. the command will be stored. The optional <code class="literal">USING</code> expressions
  230. supply values to be inserted into the command.
  231. </p><p>
  232. No substitution of <span class="application">PL/pgSQL</span> variables is done on the
  233. computed command string. Any required variable values must be inserted
  234. in the command string as it is constructed; or you can use parameters
  235. as described below.
  236. </p><p>
  237. Also, there is no plan caching for commands executed via
  238. <code class="command">EXECUTE</code>. Instead, the command is always planned
  239. each time the statement is run. Thus the command
  240. string can be dynamically created within the function to perform
  241. actions on different tables and columns.
  242. </p><p>
  243. The <code class="literal">INTO</code> clause specifies where the results of
  244. a SQL command returning rows should be assigned. If a row
  245. or variable list is provided, it must exactly match the structure
  246. of the query's results (when a
  247. record variable is used, it will configure itself to match the
  248. result structure automatically). If multiple rows are returned,
  249. only the first will be assigned to the <code class="literal">INTO</code>
  250. variable. If no rows are returned, NULL is assigned to the
  251. <code class="literal">INTO</code> variable(s). If no <code class="literal">INTO</code>
  252. clause is specified, the query results are discarded.
  253. </p><p>
  254. If the <code class="literal">STRICT</code> option is given, an error is reported
  255. unless the query produces exactly one row.
  256. </p><p>
  257. The command string can use parameter values, which are referenced
  258. in the command as <code class="literal">$1</code>, <code class="literal">$2</code>, etc.
  259. These symbols refer to values supplied in the <code class="literal">USING</code>
  260. clause. This method is often preferable to inserting data values
  261. into the command string as text: it avoids run-time overhead of
  262. converting the values to text and back, and it is much less prone
  263. to SQL-injection attacks since there is no need for quoting or escaping.
  264. An example is:
  265. </p><pre class="programlisting">
  266. EXECUTE 'SELECT count(*) FROM mytable WHERE inserted_by = $1 AND inserted &lt;= $2'
  267. INTO c
  268. USING checked_user, checked_date;
  269. </pre><p>
  270. </p><p>
  271. Note that parameter symbols can only be used for data values
  272. — if you want to use dynamically determined table or column
  273. names, you must insert them into the command string textually.
  274. For example, if the preceding query needed to be done against a
  275. dynamically selected table, you could do this:
  276. </p><pre class="programlisting">
  277. EXECUTE 'SELECT count(*) FROM '
  278. || quote_ident(tabname)
  279. || ' WHERE inserted_by = $1 AND inserted &lt;= $2'
  280. INTO c
  281. USING checked_user, checked_date;
  282. </pre><p>
  283. A cleaner approach is to use <code class="function">format()</code>'s <code class="literal">%I</code>
  284. specification for table or column names (strings separated by a
  285. newline are concatenated):
  286. </p><pre class="programlisting">
  287. EXECUTE format('SELECT count(*) FROM %I '
  288. 'WHERE inserted_by = $1 AND inserted &lt;= $2', tabname)
  289. INTO c
  290. USING checked_user, checked_date;
  291. </pre><p>
  292. Another restriction on parameter symbols is that they only work in
  293. <code class="command">SELECT</code>, <code class="command">INSERT</code>, <code class="command">UPDATE</code>, and
  294. <code class="command">DELETE</code> commands. In other statement
  295. types (generically called utility statements), you must insert
  296. values textually even if they are just data values.
  297. </p><p>
  298. An <code class="command">EXECUTE</code> with a simple constant command string and some
  299. <code class="literal">USING</code> parameters, as in the first example above, is
  300. functionally equivalent to just writing the command directly in
  301. <span class="application">PL/pgSQL</span> and allowing replacement of
  302. <span class="application">PL/pgSQL</span> variables to happen automatically.
  303. The important difference is that <code class="command">EXECUTE</code> will re-plan
  304. the command on each execution, generating a plan that is specific
  305. to the current parameter values; whereas
  306. <span class="application">PL/pgSQL</span> may otherwise create a generic plan
  307. and cache it for re-use. In situations where the best plan depends
  308. strongly on the parameter values, it can be helpful to use
  309. <code class="command">EXECUTE</code> to positively ensure that a generic plan is not
  310. selected.
  311. </p><p>
  312. <code class="command">SELECT INTO</code> is not currently supported within
  313. <code class="command">EXECUTE</code>; instead, execute a plain <code class="command">SELECT</code>
  314. command and specify <code class="literal">INTO</code> as part of the <code class="command">EXECUTE</code>
  315. itself.
  316. </p><div class="note"><h3 class="title">Note</h3><p>
  317. The <span class="application">PL/pgSQL</span>
  318. <code class="command">EXECUTE</code> statement is not related to the
  319. <a class="xref" href="sql-execute.html" title="EXECUTE"><span class="refentrytitle">EXECUTE</span></a> SQL
  320. statement supported by the
  321. <span class="productname">PostgreSQL</span> server. The server's
  322. <code class="command">EXECUTE</code> statement cannot be used directly within
  323. <span class="application">PL/pgSQL</span> functions (and is not needed).
  324. </p></div><div class="example" id="PLPGSQL-QUOTE-LITERAL-EXAMPLE"><p class="title"><strong>Example 42.1. Quoting Values in Dynamic Queries</strong></p><div class="example-contents"><a id="id-1.8.8.7.6.12.2" class="indexterm"></a><a id="id-1.8.8.7.6.12.3" class="indexterm"></a><a id="id-1.8.8.7.6.12.4" class="indexterm"></a><a id="id-1.8.8.7.6.12.5" class="indexterm"></a><p>
  325. When working with dynamic commands you will often have to handle escaping
  326. of single quotes. The recommended method for quoting fixed text in your
  327. function body is dollar quoting. (If you have legacy code that does
  328. not use dollar quoting, please refer to the
  329. overview in <a class="xref" href="plpgsql-development-tips.html#PLPGSQL-QUOTE-TIPS" title="42.12.1. Handling of Quotation Marks">Section 42.12.1</a>, which can save you
  330. some effort when translating said code to a more reasonable scheme.)
  331. </p><p>
  332. Dynamic values require careful handling since they might contain
  333. quote characters.
  334. An example using <code class="function">format()</code> (this assumes that you are
  335. dollar quoting the function body so quote marks need not be doubled):
  336. </p><pre class="programlisting">
  337. EXECUTE format('UPDATE tbl SET %I = $1 '
  338. 'WHERE key = $2', colname) USING newvalue, keyvalue;
  339. </pre><p>
  340. It is also possible to call the quoting functions directly:
  341. </p><pre class="programlisting">
  342. EXECUTE 'UPDATE tbl SET '
  343. || quote_ident(colname)
  344. || ' = '
  345. || quote_literal(newvalue)
  346. || ' WHERE key = '
  347. || quote_literal(keyvalue);
  348. </pre><p>
  349. </p><p>
  350. This example demonstrates the use of the
  351. <code class="function">quote_ident</code> and
  352. <code class="function">quote_literal</code> functions (see <a class="xref" href="functions-string.html" title="9.4. String Functions and Operators">Section 9.4</a>). For safety, expressions containing column
  353. or table identifiers should be passed through
  354. <code class="function">quote_ident</code> before insertion in a dynamic query.
  355. Expressions containing values that should be literal strings in the
  356. constructed command should be passed through <code class="function">quote_literal</code>.
  357. These functions take the appropriate steps to return the input text
  358. enclosed in double or single quotes respectively, with any embedded
  359. special characters properly escaped.
  360. </p><p>
  361. Because <code class="function">quote_literal</code> is labeled
  362. <code class="literal">STRICT</code>, it will always return null when called with a
  363. null argument. In the above example, if <code class="literal">newvalue</code> or
  364. <code class="literal">keyvalue</code> were null, the entire dynamic query string would
  365. become null, leading to an error from <code class="command">EXECUTE</code>.
  366. You can avoid this problem by using the <code class="function">quote_nullable</code>
  367. function, which works the same as <code class="function">quote_literal</code> except that
  368. when called with a null argument it returns the string <code class="literal">NULL</code>.
  369. For example,
  370. </p><pre class="programlisting">
  371. EXECUTE 'UPDATE tbl SET '
  372. || quote_ident(colname)
  373. || ' = '
  374. || quote_nullable(newvalue)
  375. || ' WHERE key = '
  376. || quote_nullable(keyvalue);
  377. </pre><p>
  378. If you are dealing with values that might be null, you should usually
  379. use <code class="function">quote_nullable</code> in place of <code class="function">quote_literal</code>.
  380. </p><p>
  381. As always, care must be taken to ensure that null values in a query do
  382. not deliver unintended results. For example the <code class="literal">WHERE</code> clause
  383. </p><pre class="programlisting">
  384. 'WHERE key = ' || quote_nullable(keyvalue)
  385. </pre><p>
  386. will never succeed if <code class="literal">keyvalue</code> is null, because the
  387. result of using the equality operator <code class="literal">=</code> with a null operand
  388. is always null. If you wish null to work like an ordinary key value,
  389. you would need to rewrite the above as
  390. </p><pre class="programlisting">
  391. 'WHERE key IS NOT DISTINCT FROM ' || quote_nullable(keyvalue)
  392. </pre><p>
  393. (At present, <code class="literal">IS NOT DISTINCT FROM</code> is handled much less
  394. efficiently than <code class="literal">=</code>, so don't do this unless you must.
  395. See <a class="xref" href="functions-comparison.html" title="9.2. Comparison Functions and Operators">Section 9.2</a> for
  396. more information on nulls and <code class="literal">IS DISTINCT</code>.)
  397. </p><p>
  398. Note that dollar quoting is only useful for quoting fixed text.
  399. It would be a very bad idea to try to write this example as:
  400. </p><pre class="programlisting">
  401. EXECUTE 'UPDATE tbl SET '
  402. || quote_ident(colname)
  403. || ' = $$'
  404. || newvalue
  405. || '$$ WHERE key = '
  406. || quote_literal(keyvalue);
  407. </pre><p>
  408. because it would break if the contents of <code class="literal">newvalue</code>
  409. happened to contain <code class="literal">$$</code>. The same objection would
  410. apply to any other dollar-quoting delimiter you might pick.
  411. So, to safely quote text that is not known in advance, you
  412. <span class="emphasis"><em>must</em></span> use <code class="function">quote_literal</code>,
  413. <code class="function">quote_nullable</code>, or <code class="function">quote_ident</code>, as appropriate.
  414. </p><p>
  415. Dynamic SQL statements can also be safely constructed using the
  416. <code class="function">format</code> function (see <a class="xref" href="functions-string.html#FUNCTIONS-STRING-FORMAT" title="9.4.1. format">Section 9.4.1</a>). For example:
  417. </p><pre class="programlisting">
  418. EXECUTE format('UPDATE tbl SET %I = %L '
  419. 'WHERE key = %L', colname, newvalue, keyvalue);
  420. </pre><p>
  421. <code class="literal">%I</code> is equivalent to <code class="function">quote_ident</code>, and
  422. <code class="literal">%L</code> is equivalent to <code class="function">quote_nullable</code>.
  423. The <code class="function">format</code> function can be used in conjunction with
  424. the <code class="literal">USING</code> clause:
  425. </p><pre class="programlisting">
  426. EXECUTE format('UPDATE tbl SET %I = $1 WHERE key = $2', colname)
  427. USING newvalue, keyvalue;
  428. </pre><p>
  429. This form is better because the variables are handled in their native
  430. data type format, rather than unconditionally converting them to
  431. text and quoting them via <code class="literal">%L</code>. It is also more efficient.
  432. </p></div></div><br class="example-break" /><p>
  433. A much larger example of a dynamic command and
  434. <code class="command">EXECUTE</code> can be seen in <a class="xref" href="plpgsql-porting.html#PLPGSQL-PORTING-EX2" title="Example 42.10. Porting a Function that Creates Another Function from PL/SQL to PL/pgSQL">Example 42.10</a>, which builds and executes a
  435. <code class="command">CREATE FUNCTION</code> command to define a new function.
  436. </p></div><div class="sect2" id="PLPGSQL-STATEMENTS-DIAGNOSTICS"><div class="titlepage"><div><div><h3 class="title">42.5.5. Obtaining the Result Status</h3></div></div></div><p>
  437. There are several ways to determine the effect of a command. The
  438. first method is to use the <code class="command">GET DIAGNOSTICS</code>
  439. command, which has the form:
  440. </p><pre class="synopsis">
  441. GET [<span class="optional"> CURRENT </span>] DIAGNOSTICS <em class="replaceable"><code>variable</code></em> { = | := } <em class="replaceable"><code>item</code></em> [<span class="optional"> , ... </span>];
  442. </pre><p>
  443. This command allows retrieval of system status indicators.
  444. <code class="literal">CURRENT</code> is a noise word (but see also <code class="command">GET STACKED
  445. DIAGNOSTICS</code> in <a class="xref" href="plpgsql-control-structures.html#PLPGSQL-EXCEPTION-DIAGNOSTICS" title="42.6.8.1. Obtaining Information about an Error">Section 42.6.8.1</a>).
  446. Each <em class="replaceable"><code>item</code></em> is a key word identifying a status
  447. value to be assigned to the specified <em class="replaceable"><code>variable</code></em>
  448. (which should be of the right data type to receive it). The currently
  449. available status items are shown
  450. in <a class="xref" href="plpgsql-statements.html#PLPGSQL-CURRENT-DIAGNOSTICS-VALUES" title="Table 42.1. Available Diagnostics Items">Table 42.1</a>. Colon-equal
  451. (<code class="literal">:=</code>) can be used instead of the SQL-standard <code class="literal">=</code>
  452. token. An example:
  453. </p><pre class="programlisting">
  454. GET DIAGNOSTICS integer_var = ROW_COUNT;
  455. </pre><p>
  456. </p><div class="table" id="PLPGSQL-CURRENT-DIAGNOSTICS-VALUES"><p class="title"><strong>Table 42.1. Available Diagnostics Items</strong></p><div class="table-contents"><table class="table" summary="Available 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="varname">ROW_COUNT</code></td><td><code class="type">bigint</code></td><td>the number of rows processed by the most
  457. recent <acronym class="acronym">SQL</acronym> command</td></tr><tr><td><code class="literal">PG_CONTEXT</code></td><td><code class="type">text</code></td><td>line(s) of text describing the current call stack
  458. (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>
  459. The second method to determine the effects of a command is to check the
  460. special variable named <code class="literal">FOUND</code>, which is of
  461. type <code class="type">boolean</code>. <code class="literal">FOUND</code> starts out
  462. false within each <span class="application">PL/pgSQL</span> function call.
  463. It is set by each of the following types of statements:
  464. </p><div class="itemizedlist"><ul class="itemizedlist" style="list-style-type: disc; "><li class="listitem"><p>
  465. A <code class="command">SELECT INTO</code> statement sets
  466. <code class="literal">FOUND</code> true if a row is assigned, false if no
  467. row is returned.
  468. </p></li><li class="listitem"><p>
  469. A <code class="command">PERFORM</code> statement sets <code class="literal">FOUND</code>
  470. true if it produces (and discards) one or more rows, false if
  471. no row is produced.
  472. </p></li><li class="listitem"><p>
  473. <code class="command">UPDATE</code>, <code class="command">INSERT</code>, and <code class="command">DELETE</code>
  474. statements set <code class="literal">FOUND</code> true if at least one
  475. row is affected, false if no row is affected.
  476. </p></li><li class="listitem"><p>
  477. A <code class="command">FETCH</code> statement sets <code class="literal">FOUND</code>
  478. true if it returns a row, false if no row is returned.
  479. </p></li><li class="listitem"><p>
  480. A <code class="command">MOVE</code> statement sets <code class="literal">FOUND</code>
  481. true if it successfully repositions the cursor, false otherwise.
  482. </p></li><li class="listitem"><p>
  483. A <code class="command">FOR</code> or <code class="command">FOREACH</code> statement sets
  484. <code class="literal">FOUND</code> true
  485. if it iterates one or more times, else false.
  486. <code class="literal">FOUND</code> is set this way when the
  487. loop exits; inside the execution of the loop,
  488. <code class="literal">FOUND</code> is not modified by the
  489. loop statement, although it might be changed by the
  490. execution of other statements within the loop body.
  491. </p></li><li class="listitem"><p>
  492. <code class="command">RETURN QUERY</code> and <code class="command">RETURN QUERY
  493. EXECUTE</code> statements set <code class="literal">FOUND</code>
  494. true if the query returns at least one row, false if no row
  495. is returned.
  496. </p></li></ul></div><p>
  497. Other <span class="application">PL/pgSQL</span> statements do not change
  498. the state of <code class="literal">FOUND</code>.
  499. Note in particular that <code class="command">EXECUTE</code>
  500. changes the output of <code class="command">GET DIAGNOSTICS</code>, but
  501. does not change <code class="literal">FOUND</code>.
  502. </p><p>
  503. <code class="literal">FOUND</code> is a local variable within each
  504. <span class="application">PL/pgSQL</span> function; any changes to it
  505. affect only the current function.
  506. </p></div><div class="sect2" id="PLPGSQL-STATEMENTS-NULL"><div class="titlepage"><div><div><h3 class="title">42.5.6. Doing Nothing At All</h3></div></div></div><p>
  507. Sometimes a placeholder statement that does nothing is useful.
  508. For example, it can indicate that one arm of an if/then/else
  509. chain is deliberately empty. For this purpose, use the
  510. <code class="command">NULL</code> statement:
  511. </p><pre class="synopsis">
  512. NULL;
  513. </pre><p>
  514. </p><p>
  515. For example, the following two fragments of code are equivalent:
  516. </p><pre class="programlisting">
  517. BEGIN
  518. y := x / 0;
  519. EXCEPTION
  520. WHEN division_by_zero THEN
  521. NULL; -- ignore the error
  522. END;
  523. </pre><p>
  524. </p><pre class="programlisting">
  525. BEGIN
  526. y := x / 0;
  527. EXCEPTION
  528. WHEN division_by_zero THEN -- ignore the error
  529. END;
  530. </pre><p>
  531. Which is preferable is a matter of taste.
  532. </p><div class="note"><h3 class="title">Note</h3><p>
  533. In Oracle's PL/SQL, empty statement lists are not allowed, and so
  534. <code class="command">NULL</code> statements are <span class="emphasis"><em>required</em></span> for situations
  535. such as this. <span class="application">PL/pgSQL</span> allows you to
  536. just write nothing, instead.
  537. </p></div></div></div><div class="navfooter"><hr /><table width="100%" summary="Navigation footer"><tr><td width="40%" align="left"><a accesskey="p" href="plpgsql-expressions.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-control-structures.html">Next</a></td></tr><tr><td width="40%" align="left" valign="top">42.4. Expressions </td><td width="20%" align="center"><a accesskey="h" href="index.html">Home</a></td><td width="40%" align="right" valign="top"> 42.6. Control Structures</td></tr></table></div></body></html>
上海开阖软件有限公司 沪ICP备12045867号-1