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.

1052 lines
50KB

  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>37.5. Query Language (SQL) Functions</title><link rel="stylesheet" type="text/css" href="stylesheet.css" /><link rev="made" href="pgsql-docs@lists.postgresql.org" /><meta name="generator" content="DocBook XSL Stylesheets V1.79.1" /><link rel="prev" href="xproc.html" title="37.4. User-Defined Procedures" /><link rel="next" href="xfunc-overload.html" title="37.6. Function Overloading" /></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">37.5. Query Language (<acronym xmlns="http://www.w3.org/1999/xhtml" class="acronym">SQL</acronym>) Functions</th></tr><tr><td width="10%" align="left"><a accesskey="p" href="xproc.html" title="37.4. User-Defined Procedures">Prev</a> </td><td width="10%" align="left"><a accesskey="u" href="extend.html" title="Chapter 37. Extending SQL">Up</a></td><th width="60%" align="center">Chapter 37. Extending <acronym xmlns="http://www.w3.org/1999/xhtml" class="acronym">SQL</acronym></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="xfunc-overload.html" title="37.6. Function Overloading">Next</a></td></tr></table><hr></hr></div><div class="sect1" id="XFUNC-SQL"><div class="titlepage"><div><div><h2 class="title" style="clear: both">37.5. Query Language (<acronym class="acronym">SQL</acronym>) Functions</h2></div></div></div><div class="toc"><dl class="toc"><dt><span class="sect2"><a href="xfunc-sql.html#XFUNC-SQL-FUNCTION-ARGUMENTS">37.5.1. Arguments for <acronym class="acronym">SQL</acronym> Functions</a></span></dt><dt><span class="sect2"><a href="xfunc-sql.html#XFUNC-SQL-BASE-FUNCTIONS">37.5.2. <acronym class="acronym">SQL</acronym> Functions on Base Types</a></span></dt><dt><span class="sect2"><a href="xfunc-sql.html#XFUNC-SQL-COMPOSITE-FUNCTIONS">37.5.3. <acronym class="acronym">SQL</acronym> Functions on Composite Types</a></span></dt><dt><span class="sect2"><a href="xfunc-sql.html#XFUNC-OUTPUT-PARAMETERS">37.5.4. <acronym class="acronym">SQL</acronym> Functions with Output Parameters</a></span></dt><dt><span class="sect2"><a href="xfunc-sql.html#XFUNC-SQL-VARIADIC-FUNCTIONS">37.5.5. <acronym class="acronym">SQL</acronym> Functions with Variable Numbers of Arguments</a></span></dt><dt><span class="sect2"><a href="xfunc-sql.html#XFUNC-SQL-PARAMETER-DEFAULTS">37.5.6. <acronym class="acronym">SQL</acronym> Functions with Default Values for Arguments</a></span></dt><dt><span class="sect2"><a href="xfunc-sql.html#XFUNC-SQL-TABLE-FUNCTIONS">37.5.7. <acronym class="acronym">SQL</acronym> Functions as Table Sources</a></span></dt><dt><span class="sect2"><a href="xfunc-sql.html#XFUNC-SQL-FUNCTIONS-RETURNING-SET">37.5.8. <acronym class="acronym">SQL</acronym> Functions Returning Sets</a></span></dt><dt><span class="sect2"><a href="xfunc-sql.html#XFUNC-SQL-FUNCTIONS-RETURNING-TABLE">37.5.9. <acronym class="acronym">SQL</acronym> Functions Returning <code class="literal">TABLE</code></a></span></dt><dt><span class="sect2"><a href="xfunc-sql.html#id-1.8.3.8.18">37.5.10. Polymorphic <acronym class="acronym">SQL</acronym> Functions</a></span></dt><dt><span class="sect2"><a href="xfunc-sql.html#id-1.8.3.8.19">37.5.11. <acronym class="acronym">SQL</acronym> Functions with Collations</a></span></dt></dl></div><a id="id-1.8.3.8.2" class="indexterm"></a><p>
  3. SQL functions execute an arbitrary list of SQL statements, returning
  4. the result of the last query in the list.
  5. In the simple (non-set)
  6. case, the first row of the last query's result will be returned.
  7. (Bear in mind that <span class="quote">“<span class="quote">the first row</span>”</span> of a multirow
  8. result is not well-defined unless you use <code class="literal">ORDER BY</code>.)
  9. If the last query happens
  10. to return no rows at all, the null value will be returned.
  11. </p><p>
  12. Alternatively, an SQL function can be declared to return a set (that is,
  13. multiple rows) by specifying the function's return type as <code class="literal">SETOF
  14. <em class="replaceable"><code>sometype</code></em></code>, or equivalently by declaring it as
  15. <code class="literal">RETURNS TABLE(<em class="replaceable"><code>columns</code></em>)</code>. In this case
  16. all rows of the last query's result are returned. Further details appear
  17. below.
  18. </p><p>
  19. The body of an SQL function must be a list of SQL
  20. statements separated by semicolons. A semicolon after the last
  21. statement is optional. Unless the function is declared to return
  22. <code class="type">void</code>, the last statement must be a <code class="command">SELECT</code>,
  23. or an <code class="command">INSERT</code>, <code class="command">UPDATE</code>, or <code class="command">DELETE</code>
  24. that has a <code class="literal">RETURNING</code> clause.
  25. </p><p>
  26. Any collection of commands in the <acronym class="acronym">SQL</acronym>
  27. language can be packaged together and defined as a function.
  28. Besides <code class="command">SELECT</code> queries, the commands can include data
  29. modification queries (<code class="command">INSERT</code>,
  30. <code class="command">UPDATE</code>, and <code class="command">DELETE</code>), as well as
  31. other SQL commands. (You cannot use transaction control commands, e.g.
  32. <code class="command">COMMIT</code>, <code class="command">SAVEPOINT</code>, and some utility
  33. commands, e.g. <code class="literal">VACUUM</code>, in <acronym class="acronym">SQL</acronym> functions.)
  34. However, the final command
  35. must be a <code class="command">SELECT</code> or have a <code class="literal">RETURNING</code>
  36. clause that returns whatever is
  37. specified as the function's return type. Alternatively, if you
  38. want to define a SQL function that performs actions but has no
  39. useful value to return, you can define it as returning <code class="type">void</code>.
  40. For example, this function removes rows with negative salaries from
  41. the <code class="literal">emp</code> table:
  42. </p><pre class="screen">
  43. CREATE FUNCTION clean_emp() RETURNS void AS '
  44. DELETE FROM emp
  45. WHERE salary &lt; 0;
  46. ' LANGUAGE SQL;
  47. SELECT clean_emp();
  48. clean_emp
  49. -----------
  50. (1 row)
  51. </pre><p>
  52. </p><div class="note"><h3 class="title">Note</h3><p>
  53. The entire body of a SQL function is parsed before any of it is
  54. executed. While a SQL function can contain commands that alter
  55. the system catalogs (e.g., <code class="command">CREATE TABLE</code>), the effects
  56. of such commands will not be visible during parse analysis of
  57. later commands in the function. Thus, for example,
  58. <code class="literal">CREATE TABLE foo (...); INSERT INTO foo VALUES(...);</code>
  59. will not work as desired if packaged up into a single SQL function,
  60. since <code class="structname">foo</code> won't exist yet when the <code class="command">INSERT</code>
  61. command is parsed. It's recommended to use <span class="application">PL/pgSQL</span>
  62. instead of a SQL function in this type of situation.
  63. </p></div><p>
  64. The syntax of the <code class="command">CREATE FUNCTION</code> command requires
  65. the function body to be written as a string constant. It is usually
  66. most convenient to use dollar quoting (see <a class="xref" href="sql-syntax-lexical.html#SQL-SYNTAX-DOLLAR-QUOTING" title="4.1.2.4. Dollar-Quoted String Constants">Section 4.1.2.4</a>) for the string constant.
  67. If you choose to use regular single-quoted string constant syntax,
  68. you must double single quote marks (<code class="literal">'</code>) and backslashes
  69. (<code class="literal">\</code>) (assuming escape string syntax) in the body of
  70. the function (see <a class="xref" href="sql-syntax-lexical.html#SQL-SYNTAX-STRINGS" title="4.1.2.1. String Constants">Section 4.1.2.1</a>).
  71. </p><div class="sect2" id="XFUNC-SQL-FUNCTION-ARGUMENTS"><div class="titlepage"><div><div><h3 class="title">37.5.1. Arguments for <acronym class="acronym">SQL</acronym> Functions</h3></div></div></div><a id="id-1.8.3.8.9.2" class="indexterm"></a><p>
  72. Arguments of a SQL function can be referenced in the function
  73. body using either names or numbers. Examples of both methods appear
  74. below.
  75. </p><p>
  76. To use a name, declare the function argument as having a name, and
  77. then just write that name in the function body. If the argument name
  78. is the same as any column name in the current SQL command within the
  79. function, the column name will take precedence. To override this,
  80. qualify the argument name with the name of the function itself, that is
  81. <code class="literal"><em class="replaceable"><code>function_name</code></em>.<em class="replaceable"><code>argument_name</code></em></code>.
  82. (If this would conflict with a qualified column name, again the column
  83. name wins. You can avoid the ambiguity by choosing a different alias for
  84. the table within the SQL command.)
  85. </p><p>
  86. In the older numeric approach, arguments are referenced using the syntax
  87. <code class="literal">$<em class="replaceable"><code>n</code></em></code>: <code class="literal">$1</code> refers to the first input
  88. argument, <code class="literal">$2</code> to the second, and so on. This will work
  89. whether or not the particular argument was declared with a name.
  90. </p><p>
  91. If an argument is of a composite type, then the dot notation,
  92. e.g., <code class="literal"><em class="replaceable"><code>argname</code></em>.<em class="replaceable"><code>fieldname</code></em></code> or
  93. <code class="literal">$1.<em class="replaceable"><code>fieldname</code></em></code>, can be used to access attributes of the
  94. argument. Again, you might need to qualify the argument's name with the
  95. function name to make the form with an argument name unambiguous.
  96. </p><p>
  97. SQL function arguments can only be used as data values,
  98. not as identifiers. Thus for example this is reasonable:
  99. </p><pre class="programlisting">
  100. INSERT INTO mytable VALUES ($1);
  101. </pre><p>
  102. but this will not work:
  103. </p><pre class="programlisting">
  104. INSERT INTO $1 VALUES (42);
  105. </pre><p>
  106. </p><div class="note"><h3 class="title">Note</h3><p>
  107. The ability to use names to reference SQL function arguments was added
  108. in <span class="productname">PostgreSQL</span> 9.2. Functions to be used in
  109. older servers must use the <code class="literal">$<em class="replaceable"><code>n</code></em></code> notation.
  110. </p></div></div><div class="sect2" id="XFUNC-SQL-BASE-FUNCTIONS"><div class="titlepage"><div><div><h3 class="title">37.5.2. <acronym class="acronym">SQL</acronym> Functions on Base Types</h3></div></div></div><p>
  111. The simplest possible <acronym class="acronym">SQL</acronym> function has no arguments and
  112. simply returns a base type, such as <code class="type">integer</code>:
  113. </p><pre class="screen">
  114. CREATE FUNCTION one() RETURNS integer AS $$
  115. SELECT 1 AS result;
  116. $$ LANGUAGE SQL;
  117. -- Alternative syntax for string literal:
  118. CREATE FUNCTION one() RETURNS integer AS '
  119. SELECT 1 AS result;
  120. ' LANGUAGE SQL;
  121. SELECT one();
  122. one
  123. -----
  124. 1
  125. </pre><p>
  126. </p><p>
  127. Notice that we defined a column alias within the function body for the result of the function
  128. (with the name <code class="literal">result</code>), but this column alias is not visible
  129. outside the function. Hence, the result is labeled <code class="literal">one</code>
  130. instead of <code class="literal">result</code>.
  131. </p><p>
  132. It is almost as easy to define <acronym class="acronym">SQL</acronym> functions
  133. that take base types as arguments:
  134. </p><pre class="screen">
  135. CREATE FUNCTION add_em(x integer, y integer) RETURNS integer AS $$
  136. SELECT x + y;
  137. $$ LANGUAGE SQL;
  138. SELECT add_em(1, 2) AS answer;
  139. answer
  140. --------
  141. 3
  142. </pre><p>
  143. </p><p>
  144. Alternatively, we could dispense with names for the arguments and
  145. use numbers:
  146. </p><pre class="screen">
  147. CREATE FUNCTION add_em(integer, integer) RETURNS integer AS $$
  148. SELECT $1 + $2;
  149. $$ LANGUAGE SQL;
  150. SELECT add_em(1, 2) AS answer;
  151. answer
  152. --------
  153. 3
  154. </pre><p>
  155. </p><p>
  156. Here is a more useful function, which might be used to debit a
  157. bank account:
  158. </p><pre class="programlisting">
  159. CREATE FUNCTION tf1 (accountno integer, debit numeric) RETURNS numeric AS $$
  160. UPDATE bank
  161. SET balance = balance - debit
  162. WHERE accountno = tf1.accountno;
  163. SELECT 1;
  164. $$ LANGUAGE SQL;
  165. </pre><p>
  166. A user could execute this function to debit account 17 by $100.00 as
  167. follows:
  168. </p><pre class="programlisting">
  169. SELECT tf1(17, 100.0);
  170. </pre><p>
  171. </p><p>
  172. In this example, we chose the name <code class="literal">accountno</code> for the first
  173. argument, but this is the same as the name of a column in the
  174. <code class="literal">bank</code> table. Within the <code class="command">UPDATE</code> command,
  175. <code class="literal">accountno</code> refers to the column <code class="literal">bank.accountno</code>,
  176. so <code class="literal">tf1.accountno</code> must be used to refer to the argument.
  177. We could of course avoid this by using a different name for the argument.
  178. </p><p>
  179. In practice one would probably like a more useful result from the
  180. function than a constant 1, so a more likely definition
  181. is:
  182. </p><pre class="programlisting">
  183. CREATE FUNCTION tf1 (accountno integer, debit numeric) RETURNS numeric AS $$
  184. UPDATE bank
  185. SET balance = balance - debit
  186. WHERE accountno = tf1.accountno;
  187. SELECT balance FROM bank WHERE accountno = tf1.accountno;
  188. $$ LANGUAGE SQL;
  189. </pre><p>
  190. which adjusts the balance and returns the new balance.
  191. The same thing could be done in one command using <code class="literal">RETURNING</code>:
  192. </p><pre class="programlisting">
  193. CREATE FUNCTION tf1 (accountno integer, debit numeric) RETURNS numeric AS $$
  194. UPDATE bank
  195. SET balance = balance - debit
  196. WHERE accountno = tf1.accountno
  197. RETURNING balance;
  198. $$ LANGUAGE SQL;
  199. </pre><p>
  200. </p><p>
  201. A <acronym class="acronym">SQL</acronym> function must return exactly its declared
  202. result type. This may require inserting an explicit cast.
  203. For example, suppose we wanted the
  204. previous <code class="function">add_em</code> function to return
  205. type <code class="type">float8</code> instead. This won't work:
  206. </p><pre class="programlisting">
  207. CREATE FUNCTION add_em(integer, integer) RETURNS float8 AS $$
  208. SELECT $1 + $2;
  209. $$ LANGUAGE SQL;
  210. </pre><p>
  211. even though in other contexts <span class="productname">PostgreSQL</span>
  212. would be willing to insert an implicit cast to
  213. convert <code class="type">integer</code> to <code class="type">float8</code>.
  214. We need to write it as
  215. </p><pre class="programlisting">
  216. CREATE FUNCTION add_em(integer, integer) RETURNS float8 AS $$
  217. SELECT ($1 + $2)::float8;
  218. $$ LANGUAGE SQL;
  219. </pre><p>
  220. </p></div><div class="sect2" id="XFUNC-SQL-COMPOSITE-FUNCTIONS"><div class="titlepage"><div><div><h3 class="title">37.5.3. <acronym class="acronym">SQL</acronym> Functions on Composite Types</h3></div></div></div><p>
  221. When writing functions with arguments of composite types, we must not
  222. only specify which argument we want but also the desired attribute
  223. (field) of that argument. For example, suppose that
  224. <code class="type">emp</code> is a table containing employee data, and therefore
  225. also the name of the composite type of each row of the table. Here
  226. is a function <code class="function">double_salary</code> that computes what someone's
  227. salary would be if it were doubled:
  228. </p><pre class="screen">
  229. CREATE TABLE emp (
  230. name text,
  231. salary numeric,
  232. age integer,
  233. cubicle point
  234. );
  235. INSERT INTO emp VALUES ('Bill', 4200, 45, '(2,1)');
  236. CREATE FUNCTION double_salary(emp) RETURNS numeric AS $$
  237. SELECT $1.salary * 2 AS salary;
  238. $$ LANGUAGE SQL;
  239. SELECT name, double_salary(emp.*) AS dream
  240. FROM emp
  241. WHERE emp.cubicle ~= point '(2,1)';
  242. name | dream
  243. ------+-------
  244. Bill | 8400
  245. </pre><p>
  246. </p><p>
  247. Notice the use of the syntax <code class="literal">$1.salary</code>
  248. to select one field of the argument row value. Also notice
  249. how the calling <code class="command">SELECT</code> command
  250. uses <em class="replaceable"><code>table_name</code></em><code class="literal">.*</code> to select
  251. the entire current row of a table as a composite value. The table
  252. row can alternatively be referenced using just the table name,
  253. like this:
  254. </p><pre class="screen">
  255. SELECT name, double_salary(emp) AS dream
  256. FROM emp
  257. WHERE emp.cubicle ~= point '(2,1)';
  258. </pre><p>
  259. but this usage is deprecated since it's easy to get confused.
  260. (See <a class="xref" href="rowtypes.html#ROWTYPES-USAGE" title="8.16.5. Using Composite Types in Queries">Section 8.16.5</a> for details about these
  261. two notations for the composite value of a table row.)
  262. </p><p>
  263. Sometimes it is handy to construct a composite argument value
  264. on-the-fly. This can be done with the <code class="literal">ROW</code> construct.
  265. For example, we could adjust the data being passed to the function:
  266. </p><pre class="screen">
  267. SELECT name, double_salary(ROW(name, salary*1.1, age, cubicle)) AS dream
  268. FROM emp;
  269. </pre><p>
  270. </p><p>
  271. It is also possible to build a function that returns a composite type.
  272. This is an example of a function
  273. that returns a single <code class="type">emp</code> row:
  274. </p><pre class="programlisting">
  275. CREATE FUNCTION new_emp() RETURNS emp AS $$
  276. SELECT text 'None' AS name,
  277. 1000.0 AS salary,
  278. 25 AS age,
  279. point '(2,2)' AS cubicle;
  280. $$ LANGUAGE SQL;
  281. </pre><p>
  282. In this example we have specified each of the attributes
  283. with a constant value, but any computation
  284. could have been substituted for these constants.
  285. </p><p>
  286. Note two important things about defining the function:
  287. </p><div class="itemizedlist"><ul class="itemizedlist" style="list-style-type: disc; "><li class="listitem"><p>
  288. The select list order in the query must be exactly the same as
  289. that in which the columns appear in the table associated
  290. with the composite type. (Naming the columns, as we did above,
  291. is irrelevant to the system.)
  292. </p></li><li class="listitem"><p>
  293. We must ensure each expression's type matches the corresponding
  294. column of the composite type, inserting a cast if necessary.
  295. Otherwise we'll get errors like this:
  296. </p><pre class="screen">
  297. <code class="computeroutput">
  298. ERROR: function declared to return emp returns varchar instead of text at column 1
  299. </code>
  300. </pre><p>
  301. As with the base-type case, the function will not insert any casts
  302. automatically.
  303. </p></li></ul></div><p>
  304. </p><p>
  305. A different way to define the same function is:
  306. </p><pre class="programlisting">
  307. CREATE FUNCTION new_emp() RETURNS emp AS $$
  308. SELECT ROW('None', 1000.0, 25, '(2,2)')::emp;
  309. $$ LANGUAGE SQL;
  310. </pre><p>
  311. Here we wrote a <code class="command">SELECT</code> that returns just a single
  312. column of the correct composite type. This isn't really better
  313. in this situation, but it is a handy alternative in some cases
  314. — for example, if we need to compute the result by calling
  315. another function that returns the desired composite value.
  316. Another example is that if we are trying to write a function that
  317. returns a domain over composite, rather than a plain composite type,
  318. it is always necessary to write it as returning a single column,
  319. since there is no other way to produce a value that is exactly of
  320. the domain type.
  321. </p><p>
  322. We could call this function directly either by using it in
  323. a value expression:
  324. </p><pre class="screen">
  325. SELECT new_emp();
  326. new_emp
  327. --------------------------
  328. (None,1000.0,25,"(2,2)")
  329. </pre><p>
  330. or by calling it as a table function:
  331. </p><pre class="screen">
  332. SELECT * FROM new_emp();
  333. name | salary | age | cubicle
  334. ------+--------+-----+---------
  335. None | 1000.0 | 25 | (2,2)
  336. </pre><p>
  337. The second way is described more fully in <a class="xref" href="xfunc-sql.html#XFUNC-SQL-TABLE-FUNCTIONS" title="37.5.7. SQL Functions as Table Sources">Section 37.5.7</a>.
  338. </p><p>
  339. When you use a function that returns a composite type,
  340. you might want only one field (attribute) from its result.
  341. You can do that with syntax like this:
  342. </p><pre class="screen">
  343. SELECT (new_emp()).name;
  344. name
  345. ------
  346. None
  347. </pre><p>
  348. The extra parentheses are needed to keep the parser from getting
  349. confused. If you try to do it without them, you get something like this:
  350. </p><pre class="screen">
  351. SELECT new_emp().name;
  352. ERROR: syntax error at or near "."
  353. LINE 1: SELECT new_emp().name;
  354. ^
  355. </pre><p>
  356. </p><p>
  357. Another option is to use functional notation for extracting an attribute:
  358. </p><pre class="screen">
  359. SELECT name(new_emp());
  360. name
  361. ------
  362. None
  363. </pre><p>
  364. As explained in <a class="xref" href="rowtypes.html#ROWTYPES-USAGE" title="8.16.5. Using Composite Types in Queries">Section 8.16.5</a>, the field notation and
  365. functional notation are equivalent.
  366. </p><p>
  367. Another way to use a function returning a composite type is to pass the
  368. result to another function that accepts the correct row type as input:
  369. </p><pre class="screen">
  370. CREATE FUNCTION getname(emp) RETURNS text AS $$
  371. SELECT $1.name;
  372. $$ LANGUAGE SQL;
  373. SELECT getname(new_emp());
  374. getname
  375. ---------
  376. None
  377. (1 row)
  378. </pre><p>
  379. </p></div><div class="sect2" id="XFUNC-OUTPUT-PARAMETERS"><div class="titlepage"><div><div><h3 class="title">37.5.4. <acronym class="acronym">SQL</acronym> Functions with Output Parameters</h3></div></div></div><a id="id-1.8.3.8.12.2" class="indexterm"></a><p>
  380. An alternative way of describing a function's results is to define it
  381. with <em class="firstterm">output parameters</em>, as in this example:
  382. </p><pre class="screen">
  383. CREATE FUNCTION add_em (IN x int, IN y int, OUT sum int)
  384. AS 'SELECT x + y'
  385. LANGUAGE SQL;
  386. SELECT add_em(3,7);
  387. add_em
  388. --------
  389. 10
  390. (1 row)
  391. </pre><p>
  392. This is not essentially different from the version of <code class="literal">add_em</code>
  393. shown in <a class="xref" href="xfunc-sql.html#XFUNC-SQL-BASE-FUNCTIONS" title="37.5.2. SQL Functions on Base Types">Section 37.5.2</a>. The real value of
  394. output parameters is that they provide a convenient way of defining
  395. functions that return several columns. For example,
  396. </p><pre class="screen">
  397. CREATE FUNCTION sum_n_product (x int, y int, OUT sum int, OUT product int)
  398. AS 'SELECT x + y, x * y'
  399. LANGUAGE SQL;
  400. SELECT * FROM sum_n_product(11,42);
  401. sum | product
  402. -----+---------
  403. 53 | 462
  404. (1 row)
  405. </pre><p>
  406. What has essentially happened here is that we have created an anonymous
  407. composite type for the result of the function. The above example has
  408. the same end result as
  409. </p><pre class="screen">
  410. CREATE TYPE sum_prod AS (sum int, product int);
  411. CREATE FUNCTION sum_n_product (int, int) RETURNS sum_prod
  412. AS 'SELECT $1 + $2, $1 * $2'
  413. LANGUAGE SQL;
  414. </pre><p>
  415. but not having to bother with the separate composite type definition
  416. is often handy. Notice that the names attached to the output parameters
  417. are not just decoration, but determine the column names of the anonymous
  418. composite type. (If you omit a name for an output parameter, the
  419. system will choose a name on its own.)
  420. </p><p>
  421. Notice that output parameters are not included in the calling argument
  422. list when invoking such a function from SQL. This is because
  423. <span class="productname">PostgreSQL</span> considers only the input
  424. parameters to define the function's calling signature. That means
  425. also that only the input parameters matter when referencing the function
  426. for purposes such as dropping it. We could drop the above function
  427. with either of
  428. </p><pre class="screen">
  429. DROP FUNCTION sum_n_product (x int, y int, OUT sum int, OUT product int);
  430. DROP FUNCTION sum_n_product (int, int);
  431. </pre><p>
  432. </p><p>
  433. Parameters can be marked as <code class="literal">IN</code> (the default),
  434. <code class="literal">OUT</code>, <code class="literal">INOUT</code>, or <code class="literal">VARIADIC</code>.
  435. An <code class="literal">INOUT</code>
  436. parameter serves as both an input parameter (part of the calling
  437. argument list) and an output parameter (part of the result record type).
  438. <code class="literal">VARIADIC</code> parameters are input parameters, but are treated
  439. specially as described next.
  440. </p></div><div class="sect2" id="XFUNC-SQL-VARIADIC-FUNCTIONS"><div class="titlepage"><div><div><h3 class="title">37.5.5. <acronym class="acronym">SQL</acronym> Functions with Variable Numbers of Arguments</h3></div></div></div><a id="id-1.8.3.8.13.2" class="indexterm"></a><a id="id-1.8.3.8.13.3" class="indexterm"></a><p>
  441. <acronym class="acronym">SQL</acronym> functions can be declared to accept
  442. variable numbers of arguments, so long as all the <span class="quote">“<span class="quote">optional</span>”</span>
  443. arguments are of the same data type. The optional arguments will be
  444. passed to the function as an array. The function is declared by
  445. marking the last parameter as <code class="literal">VARIADIC</code>; this parameter
  446. must be declared as being of an array type. For example:
  447. </p><pre class="screen">
  448. CREATE FUNCTION mleast(VARIADIC arr numeric[]) RETURNS numeric AS $$
  449. SELECT min($1[i]) FROM generate_subscripts($1, 1) g(i);
  450. $$ LANGUAGE SQL;
  451. SELECT mleast(10, -1, 5, 4.4);
  452. mleast
  453. --------
  454. -1
  455. (1 row)
  456. </pre><p>
  457. Effectively, all the actual arguments at or beyond the
  458. <code class="literal">VARIADIC</code> position are gathered up into a one-dimensional
  459. array, as if you had written
  460. </p><pre class="screen">
  461. SELECT mleast(ARRAY[10, -1, 5, 4.4]); -- doesn't work
  462. </pre><p>
  463. You can't actually write that, though — or at least, it will
  464. not match this function definition. A parameter marked
  465. <code class="literal">VARIADIC</code> matches one or more occurrences of its element
  466. type, not of its own type.
  467. </p><p>
  468. Sometimes it is useful to be able to pass an already-constructed array
  469. to a variadic function; this is particularly handy when one variadic
  470. function wants to pass on its array parameter to another one. Also,
  471. this is the only secure way to call a variadic function found in a schema
  472. that permits untrusted users to create objects; see
  473. <a class="xref" href="typeconv-func.html" title="10.3. Functions">Section 10.3</a>. You can do this by
  474. specifying <code class="literal">VARIADIC</code> in the call:
  475. </p><pre class="screen">
  476. SELECT mleast(VARIADIC ARRAY[10, -1, 5, 4.4]);
  477. </pre><p>
  478. This prevents expansion of the function's variadic parameter into its
  479. element type, thereby allowing the array argument value to match
  480. normally. <code class="literal">VARIADIC</code> can only be attached to the last
  481. actual argument of a function call.
  482. </p><p>
  483. Specifying <code class="literal">VARIADIC</code> in the call is also the only way to
  484. pass an empty array to a variadic function, for example:
  485. </p><pre class="screen">
  486. SELECT mleast(VARIADIC ARRAY[]::numeric[]);
  487. </pre><p>
  488. Simply writing <code class="literal">SELECT mleast()</code> does not work because a
  489. variadic parameter must match at least one actual argument.
  490. (You could define a second function also named <code class="literal">mleast</code>,
  491. with no parameters, if you wanted to allow such calls.)
  492. </p><p>
  493. The array element parameters generated from a variadic parameter are
  494. treated as not having any names of their own. This means it is not
  495. possible to call a variadic function using named arguments (<a class="xref" href="sql-syntax-calling-funcs.html" title="4.3. Calling Functions">Section 4.3</a>), except when you specify
  496. <code class="literal">VARIADIC</code>. For example, this will work:
  497. </p><pre class="screen">
  498. SELECT mleast(VARIADIC arr =&gt; ARRAY[10, -1, 5, 4.4]);
  499. </pre><p>
  500. but not these:
  501. </p><pre class="screen">
  502. SELECT mleast(arr =&gt; 10);
  503. SELECT mleast(arr =&gt; ARRAY[10, -1, 5, 4.4]);
  504. </pre><p>
  505. </p></div><div class="sect2" id="XFUNC-SQL-PARAMETER-DEFAULTS"><div class="titlepage"><div><div><h3 class="title">37.5.6. <acronym class="acronym">SQL</acronym> Functions with Default Values for Arguments</h3></div></div></div><a id="id-1.8.3.8.14.2" class="indexterm"></a><p>
  506. Functions can be declared with default values for some or all input
  507. arguments. The default values are inserted whenever the function is
  508. called with insufficiently many actual arguments. Since arguments
  509. can only be omitted from the end of the actual argument list, all
  510. parameters after a parameter with a default value have to have
  511. default values as well. (Although the use of named argument notation
  512. could allow this restriction to be relaxed, it's still enforced so that
  513. positional argument notation works sensibly.) Whether or not you use it,
  514. this capability creates a need for precautions when calling functions in
  515. databases where some users mistrust other users; see
  516. <a class="xref" href="typeconv-func.html" title="10.3. Functions">Section 10.3</a>.
  517. </p><p>
  518. For example:
  519. </p><pre class="screen">
  520. CREATE FUNCTION foo(a int, b int DEFAULT 2, c int DEFAULT 3)
  521. RETURNS int
  522. LANGUAGE SQL
  523. AS $$
  524. SELECT $1 + $2 + $3;
  525. $$;
  526. SELECT foo(10, 20, 30);
  527. foo
  528. -----
  529. 60
  530. (1 row)
  531. SELECT foo(10, 20);
  532. foo
  533. -----
  534. 33
  535. (1 row)
  536. SELECT foo(10);
  537. foo
  538. -----
  539. 15
  540. (1 row)
  541. SELECT foo(); -- fails since there is no default for the first argument
  542. ERROR: function foo() does not exist
  543. </pre><p>
  544. The <code class="literal">=</code> sign can also be used in place of the
  545. key word <code class="literal">DEFAULT</code>.
  546. </p></div><div class="sect2" id="XFUNC-SQL-TABLE-FUNCTIONS"><div class="titlepage"><div><div><h3 class="title">37.5.7. <acronym class="acronym">SQL</acronym> Functions as Table Sources</h3></div></div></div><p>
  547. All SQL functions can be used in the <code class="literal">FROM</code> clause of a query,
  548. but it is particularly useful for functions returning composite types.
  549. If the function is defined to return a base type, the table function
  550. produces a one-column table. If the function is defined to return
  551. a composite type, the table function produces a column for each attribute
  552. of the composite type.
  553. </p><p>
  554. Here is an example:
  555. </p><pre class="screen">
  556. CREATE TABLE foo (fooid int, foosubid int, fooname text);
  557. INSERT INTO foo VALUES (1, 1, 'Joe');
  558. INSERT INTO foo VALUES (1, 2, 'Ed');
  559. INSERT INTO foo VALUES (2, 1, 'Mary');
  560. CREATE FUNCTION getfoo(int) RETURNS foo AS $$
  561. SELECT * FROM foo WHERE fooid = $1;
  562. $$ LANGUAGE SQL;
  563. SELECT *, upper(fooname) FROM getfoo(1) AS t1;
  564. fooid | foosubid | fooname | upper
  565. -------+----------+---------+-------
  566. 1 | 1 | Joe | JOE
  567. (1 row)
  568. </pre><p>
  569. As the example shows, we can work with the columns of the function's
  570. result just the same as if they were columns of a regular table.
  571. </p><p>
  572. Note that we only got one row out of the function. This is because
  573. we did not use <code class="literal">SETOF</code>. That is described in the next section.
  574. </p></div><div class="sect2" id="XFUNC-SQL-FUNCTIONS-RETURNING-SET"><div class="titlepage"><div><div><h3 class="title">37.5.8. <acronym class="acronym">SQL</acronym> Functions Returning Sets</h3></div></div></div><a id="id-1.8.3.8.16.2" class="indexterm"></a><p>
  575. When an SQL function is declared as returning <code class="literal">SETOF
  576. <em class="replaceable"><code>sometype</code></em></code>, the function's final
  577. query is executed to completion, and each row it
  578. outputs is returned as an element of the result set.
  579. </p><p>
  580. This feature is normally used when calling the function in the <code class="literal">FROM</code>
  581. clause. In this case each row returned by the function becomes
  582. a row of the table seen by the query. For example, assume that
  583. table <code class="literal">foo</code> has the same contents as above, and we say:
  584. </p><pre class="programlisting">
  585. CREATE FUNCTION getfoo(int) RETURNS SETOF foo AS $$
  586. SELECT * FROM foo WHERE fooid = $1;
  587. $$ LANGUAGE SQL;
  588. SELECT * FROM getfoo(1) AS t1;
  589. </pre><p>
  590. Then we would get:
  591. </p><pre class="screen">
  592. fooid | foosubid | fooname
  593. -------+----------+---------
  594. 1 | 1 | Joe
  595. 1 | 2 | Ed
  596. (2 rows)
  597. </pre><p>
  598. </p><p>
  599. It is also possible to return multiple rows with the columns defined by
  600. output parameters, like this:
  601. </p><pre class="programlisting">
  602. CREATE TABLE tab (y int, z int);
  603. INSERT INTO tab VALUES (1, 2), (3, 4), (5, 6), (7, 8);
  604. CREATE FUNCTION sum_n_product_with_tab (x int, OUT sum int, OUT product int)
  605. RETURNS SETOF record
  606. AS $$
  607. SELECT $1 + tab.y, $1 * tab.y FROM tab;
  608. $$ LANGUAGE SQL;
  609. SELECT * FROM sum_n_product_with_tab(10);
  610. sum | product
  611. -----+---------
  612. 11 | 10
  613. 13 | 30
  614. 15 | 50
  615. 17 | 70
  616. (4 rows)
  617. </pre><p>
  618. The key point here is that you must write <code class="literal">RETURNS SETOF record</code>
  619. to indicate that the function returns multiple rows instead of just one.
  620. If there is only one output parameter, write that parameter's type
  621. instead of <code class="type">record</code>.
  622. </p><p>
  623. It is frequently useful to construct a query's result by invoking a
  624. set-returning function multiple times, with the parameters for each
  625. invocation coming from successive rows of a table or subquery. The
  626. preferred way to do this is to use the <code class="literal">LATERAL</code> key word,
  627. which is described in <a class="xref" href="queries-table-expressions.html#QUERIES-LATERAL" title="7.2.1.5. LATERAL Subqueries">Section 7.2.1.5</a>.
  628. Here is an example using a set-returning function to enumerate
  629. elements of a tree structure:
  630. </p><pre class="screen">
  631. SELECT * FROM nodes;
  632. name | parent
  633. -----------+--------
  634. Top |
  635. Child1 | Top
  636. Child2 | Top
  637. Child3 | Top
  638. SubChild1 | Child1
  639. SubChild2 | Child1
  640. (6 rows)
  641. CREATE FUNCTION listchildren(text) RETURNS SETOF text AS $$
  642. SELECT name FROM nodes WHERE parent = $1
  643. $$ LANGUAGE SQL STABLE;
  644. SELECT * FROM listchildren('Top');
  645. listchildren
  646. --------------
  647. Child1
  648. Child2
  649. Child3
  650. (3 rows)
  651. SELECT name, child FROM nodes, LATERAL listchildren(name) AS child;
  652. name | child
  653. --------+-----------
  654. Top | Child1
  655. Top | Child2
  656. Top | Child3
  657. Child1 | SubChild1
  658. Child1 | SubChild2
  659. (5 rows)
  660. </pre><p>
  661. This example does not do anything that we couldn't have done with a
  662. simple join, but in more complex calculations the option to put
  663. some of the work into a function can be quite convenient.
  664. </p><p>
  665. Functions returning sets can also be called in the select list
  666. of a query. For each row that the query
  667. generates by itself, the set-returning function is invoked, and an output
  668. row is generated for each element of the function's result set.
  669. The previous example could also be done with queries like
  670. these:
  671. </p><pre class="screen">
  672. SELECT listchildren('Top');
  673. listchildren
  674. --------------
  675. Child1
  676. Child2
  677. Child3
  678. (3 rows)
  679. SELECT name, listchildren(name) FROM nodes;
  680. name | listchildren
  681. --------+--------------
  682. Top | Child1
  683. Top | Child2
  684. Top | Child3
  685. Child1 | SubChild1
  686. Child1 | SubChild2
  687. (5 rows)
  688. </pre><p>
  689. In the last <code class="command">SELECT</code>,
  690. notice that no output row appears for <code class="literal">Child2</code>, <code class="literal">Child3</code>, etc.
  691. This happens because <code class="function">listchildren</code> returns an empty set
  692. for those arguments, so no result rows are generated. This is the same
  693. behavior as we got from an inner join to the function result when using
  694. the <code class="literal">LATERAL</code> syntax.
  695. </p><p>
  696. <span class="productname">PostgreSQL</span>'s behavior for a set-returning function in a
  697. query's select list is almost exactly the same as if the set-returning
  698. function had been written in a <code class="literal">LATERAL FROM</code>-clause item
  699. instead. For example,
  700. </p><pre class="programlisting">
  701. SELECT x, generate_series(1,5) AS g FROM tab;
  702. </pre><p>
  703. is almost equivalent to
  704. </p><pre class="programlisting">
  705. SELECT x, g FROM tab, LATERAL generate_series(1,5) AS g;
  706. </pre><p>
  707. It would be exactly the same, except that in this specific example,
  708. the planner could choose to put <code class="structname">g</code> on the outside of the
  709. nested-loop join, since <code class="structname">g</code> has no actual lateral dependency
  710. on <code class="structname">tab</code>. That would result in a different output row
  711. order. Set-returning functions in the select list are always evaluated
  712. as though they are on the inside of a nested-loop join with the rest of
  713. the <code class="literal">FROM</code> clause, so that the function(s) are run to
  714. completion before the next row from the <code class="literal">FROM</code> clause is
  715. considered.
  716. </p><p>
  717. If there is more than one set-returning function in the query's select
  718. list, the behavior is similar to what you get from putting the functions
  719. into a single <code class="literal">LATERAL ROWS FROM( ... )</code> <code class="literal">FROM</code>-clause
  720. item. For each row from the underlying query, there is an output row
  721. using the first result from each function, then an output row using the
  722. second result, and so on. If some of the set-returning functions
  723. produce fewer outputs than others, null values are substituted for the
  724. missing data, so that the total number of rows emitted for one
  725. underlying row is the same as for the set-returning function that
  726. produced the most outputs. Thus the set-returning functions
  727. run <span class="quote">“<span class="quote">in lockstep</span>”</span> until they are all exhausted, and then
  728. execution continues with the next underlying row.
  729. </p><p>
  730. Set-returning functions can be nested in a select list, although that is
  731. not allowed in <code class="literal">FROM</code>-clause items. In such cases, each level
  732. of nesting is treated separately, as though it were
  733. a separate <code class="literal">LATERAL ROWS FROM( ... )</code> item. For example, in
  734. </p><pre class="programlisting">
  735. SELECT srf1(srf2(x), srf3(y)), srf4(srf5(z)) FROM tab;
  736. </pre><p>
  737. the set-returning functions <code class="function">srf2</code>, <code class="function">srf3</code>,
  738. and <code class="function">srf5</code> would be run in lockstep for each row
  739. of <code class="structname">tab</code>, and then <code class="function">srf1</code> and <code class="function">srf4</code>
  740. would be applied in lockstep to each row produced by the lower
  741. functions.
  742. </p><p>
  743. Set-returning functions cannot be used within conditional-evaluation
  744. constructs, such as <code class="literal">CASE</code> or <code class="literal">COALESCE</code>. For
  745. example, consider
  746. </p><pre class="programlisting">
  747. SELECT x, CASE WHEN x &gt; 0 THEN generate_series(1, 5) ELSE 0 END FROM tab;
  748. </pre><p>
  749. It might seem that this should produce five repetitions of input rows
  750. that have <code class="literal">x &gt; 0</code>, and a single repetition of those that do
  751. not; but actually, because <code class="function">generate_series(1, 5)</code> would be
  752. run in an implicit <code class="literal">LATERAL FROM</code> item before
  753. the <code class="literal">CASE</code> expression is ever evaluated, it would produce five
  754. repetitions of every input row. To reduce confusion, such cases produce
  755. a parse-time error instead.
  756. </p><div class="note"><h3 class="title">Note</h3><p>
  757. If a function's last command is <code class="command">INSERT</code>, <code class="command">UPDATE</code>,
  758. or <code class="command">DELETE</code> with <code class="literal">RETURNING</code>, that command will
  759. always be executed to completion, even if the function is not declared
  760. with <code class="literal">SETOF</code> or the calling query does not fetch all the
  761. result rows. Any extra rows produced by the <code class="literal">RETURNING</code>
  762. clause are silently dropped, but the commanded table modifications
  763. still happen (and are all completed before returning from the function).
  764. </p></div><div class="note"><h3 class="title">Note</h3><p>
  765. Before <span class="productname">PostgreSQL</span> 10, putting more than one
  766. set-returning function in the same select list did not behave very
  767. sensibly unless they always produced equal numbers of rows. Otherwise,
  768. what you got was a number of output rows equal to the least common
  769. multiple of the numbers of rows produced by the set-returning
  770. functions. Also, nested set-returning functions did not work as
  771. described above; instead, a set-returning function could have at most
  772. one set-returning argument, and each nest of set-returning functions
  773. was run independently. Also, conditional execution (set-returning
  774. functions inside <code class="literal">CASE</code> etc) was previously allowed,
  775. complicating things even more.
  776. Use of the <code class="literal">LATERAL</code> syntax is recommended when writing
  777. queries that need to work in older <span class="productname">PostgreSQL</span> versions,
  778. because that will give consistent results across different versions.
  779. If you have a query that is relying on conditional execution of a
  780. set-returning function, you may be able to fix it by moving the
  781. conditional test into a custom set-returning function. For example,
  782. </p><pre class="programlisting">
  783. SELECT x, CASE WHEN y &gt; 0 THEN generate_series(1, z) ELSE 5 END FROM tab;
  784. </pre><p>
  785. could become
  786. </p><pre class="programlisting">
  787. CREATE FUNCTION case_generate_series(cond bool, start int, fin int, els int)
  788. RETURNS SETOF int AS $$
  789. BEGIN
  790. IF cond THEN
  791. RETURN QUERY SELECT generate_series(start, fin);
  792. ELSE
  793. RETURN QUERY SELECT els;
  794. END IF;
  795. END$$ LANGUAGE plpgsql;
  796. SELECT x, case_generate_series(y &gt; 0, 1, z, 5) FROM tab;
  797. </pre><p>
  798. This formulation will work the same in all versions
  799. of <span class="productname">PostgreSQL</span>.
  800. </p></div></div><div class="sect2" id="XFUNC-SQL-FUNCTIONS-RETURNING-TABLE"><div class="titlepage"><div><div><h3 class="title">37.5.9. <acronym class="acronym">SQL</acronym> Functions Returning <code class="literal">TABLE</code></h3></div></div></div><a id="id-1.8.3.8.17.2" class="indexterm"></a><p>
  801. There is another way to declare a function as returning a set,
  802. which is to use the syntax
  803. <code class="literal">RETURNS TABLE(<em class="replaceable"><code>columns</code></em>)</code>.
  804. This is equivalent to using one or more <code class="literal">OUT</code> parameters plus
  805. marking the function as returning <code class="literal">SETOF record</code> (or
  806. <code class="literal">SETOF</code> a single output parameter's type, as appropriate).
  807. This notation is specified in recent versions of the SQL standard, and
  808. thus may be more portable than using <code class="literal">SETOF</code>.
  809. </p><p>
  810. For example, the preceding sum-and-product example could also be
  811. done this way:
  812. </p><pre class="programlisting">
  813. CREATE FUNCTION sum_n_product_with_tab (x int)
  814. RETURNS TABLE(sum int, product int) AS $$
  815. SELECT $1 + tab.y, $1 * tab.y FROM tab;
  816. $$ LANGUAGE SQL;
  817. </pre><p>
  818. It is not allowed to use explicit <code class="literal">OUT</code> or <code class="literal">INOUT</code>
  819. parameters with the <code class="literal">RETURNS TABLE</code> notation — you must
  820. put all the output columns in the <code class="literal">TABLE</code> list.
  821. </p></div><div class="sect2" id="id-1.8.3.8.18"><div class="titlepage"><div><div><h3 class="title">37.5.10. Polymorphic <acronym class="acronym">SQL</acronym> Functions</h3></div></div></div><p>
  822. <acronym class="acronym">SQL</acronym> functions can be declared to accept and
  823. return the polymorphic types <code class="type">anyelement</code>,
  824. <code class="type">anyarray</code>, <code class="type">anynonarray</code>,
  825. <code class="type">anyenum</code>, and <code class="type">anyrange</code>. See <a class="xref" href="extend-type-system.html#EXTEND-TYPES-POLYMORPHIC" title="37.2.5. Polymorphic Types">Section 37.2.5</a> for a more detailed
  826. explanation of polymorphic functions. Here is a polymorphic
  827. function <code class="function">make_array</code> that builds up an array
  828. from two arbitrary data type elements:
  829. </p><pre class="screen">
  830. CREATE FUNCTION make_array(anyelement, anyelement) RETURNS anyarray AS $$
  831. SELECT ARRAY[$1, $2];
  832. $$ LANGUAGE SQL;
  833. SELECT make_array(1, 2) AS intarray, make_array('a'::text, 'b') AS textarray;
  834. intarray | textarray
  835. ----------+-----------
  836. {1,2} | {a,b}
  837. (1 row)
  838. </pre><p>
  839. </p><p>
  840. Notice the use of the typecast <code class="literal">'a'::text</code>
  841. to specify that the argument is of type <code class="type">text</code>. This is
  842. required if the argument is just a string literal, since otherwise
  843. it would be treated as type
  844. <code class="type">unknown</code>, and array of <code class="type">unknown</code> is not a valid
  845. type.
  846. Without the typecast, you will get errors like this:
  847. </p><pre class="screen">
  848. <code class="computeroutput">
  849. ERROR: could not determine polymorphic type because input has type "unknown"
  850. </code>
  851. </pre><p>
  852. </p><p>
  853. It is permitted to have polymorphic arguments with a fixed
  854. return type, but the converse is not. For example:
  855. </p><pre class="screen">
  856. CREATE FUNCTION is_greater(anyelement, anyelement) RETURNS boolean AS $$
  857. SELECT $1 &gt; $2;
  858. $$ LANGUAGE SQL;
  859. SELECT is_greater(1, 2);
  860. is_greater
  861. ------------
  862. f
  863. (1 row)
  864. CREATE FUNCTION invalid_func() RETURNS anyelement AS $$
  865. SELECT 1;
  866. $$ LANGUAGE SQL;
  867. ERROR: cannot determine result data type
  868. DETAIL: A function returning a polymorphic type must have at least one polymorphic argument.
  869. </pre><p>
  870. </p><p>
  871. Polymorphism can be used with functions that have output arguments.
  872. For example:
  873. </p><pre class="screen">
  874. CREATE FUNCTION dup (f1 anyelement, OUT f2 anyelement, OUT f3 anyarray)
  875. AS 'select $1, array[$1,$1]' LANGUAGE SQL;
  876. SELECT * FROM dup(22);
  877. f2 | f3
  878. ----+---------
  879. 22 | {22,22}
  880. (1 row)
  881. </pre><p>
  882. </p><p>
  883. Polymorphism can also be used with variadic functions.
  884. For example:
  885. </p><pre class="screen">
  886. CREATE FUNCTION anyleast (VARIADIC anyarray) RETURNS anyelement AS $$
  887. SELECT min($1[i]) FROM generate_subscripts($1, 1) g(i);
  888. $$ LANGUAGE SQL;
  889. SELECT anyleast(10, -1, 5, 4);
  890. anyleast
  891. ----------
  892. -1
  893. (1 row)
  894. SELECT anyleast('abc'::text, 'def');
  895. anyleast
  896. ----------
  897. abc
  898. (1 row)
  899. CREATE FUNCTION concat_values(text, VARIADIC anyarray) RETURNS text AS $$
  900. SELECT array_to_string($2, $1);
  901. $$ LANGUAGE SQL;
  902. SELECT concat_values('|', 1, 4, 2);
  903. concat_values
  904. ---------------
  905. 1|4|2
  906. (1 row)
  907. </pre><p>
  908. </p></div><div class="sect2" id="id-1.8.3.8.19"><div class="titlepage"><div><div><h3 class="title">37.5.11. <acronym class="acronym">SQL</acronym> Functions with Collations</h3></div></div></div><a id="id-1.8.3.8.19.2" class="indexterm"></a><p>
  909. When a SQL function has one or more parameters of collatable data types,
  910. a collation is identified for each function call depending on the
  911. collations assigned to the actual arguments, as described in <a class="xref" href="collation.html" title="23.2. Collation Support">Section 23.2</a>. If a collation is successfully identified
  912. (i.e., there are no conflicts of implicit collations among the arguments)
  913. then all the collatable parameters are treated as having that collation
  914. implicitly. This will affect the behavior of collation-sensitive
  915. operations within the function. For example, using the
  916. <code class="function">anyleast</code> function described above, the result of
  917. </p><pre class="programlisting">
  918. SELECT anyleast('abc'::text, 'ABC');
  919. </pre><p>
  920. will depend on the database's default collation. In <code class="literal">C</code> locale
  921. the result will be <code class="literal">ABC</code>, but in many other locales it will
  922. be <code class="literal">abc</code>. The collation to use can be forced by adding
  923. a <code class="literal">COLLATE</code> clause to any of the arguments, for example
  924. </p><pre class="programlisting">
  925. SELECT anyleast('abc'::text, 'ABC' COLLATE "C");
  926. </pre><p>
  927. Alternatively, if you wish a function to operate with a particular
  928. collation regardless of what it is called with, insert
  929. <code class="literal">COLLATE</code> clauses as needed in the function definition.
  930. This version of <code class="function">anyleast</code> would always use <code class="literal">en_US</code>
  931. locale to compare strings:
  932. </p><pre class="programlisting">
  933. CREATE FUNCTION anyleast (VARIADIC anyarray) RETURNS anyelement AS $$
  934. SELECT min($1[i] COLLATE "en_US") FROM generate_subscripts($1, 1) g(i);
  935. $$ LANGUAGE SQL;
  936. </pre><p>
  937. But note that this will throw an error if applied to a non-collatable
  938. data type.
  939. </p><p>
  940. If no common collation can be identified among the actual arguments,
  941. then a SQL function treats its parameters as having their data types'
  942. default collation (which is usually the database's default collation,
  943. but could be different for parameters of domain types).
  944. </p><p>
  945. The behavior of collatable parameters can be thought of as a limited
  946. form of polymorphism, applicable only to textual data types.
  947. </p></div></div><div class="navfooter"><hr /><table width="100%" summary="Navigation footer"><tr><td width="40%" align="left"><a accesskey="p" href="xproc.html">Prev</a> </td><td width="20%" align="center"><a accesskey="u" href="extend.html">Up</a></td><td width="40%" align="right"> <a accesskey="n" href="xfunc-overload.html">Next</a></td></tr><tr><td width="40%" align="left" valign="top">37.4. User-Defined Procedures </td><td width="20%" align="center"><a accesskey="h" href="index.html">Home</a></td><td width="40%" align="right" valign="top"> 37.6. Function Overloading</td></tr></table></div></body></html>
上海开阖软件有限公司 沪ICP备12045867号-1