2 36.5. Query Language (SQL) Functions #
4 36.5.1. Arguments for SQL Functions
5 36.5.2. SQL Functions on Base Types
6 36.5.3. SQL Functions on Composite Types
7 36.5.4. SQL Functions with Output Parameters
8 36.5.5. SQL Procedures with Output Parameters
9 36.5.6. SQL Functions with Variable Numbers of Arguments
10 36.5.7. SQL Functions with Default Values for Arguments
11 36.5.8. SQL Functions as Table Sources
12 36.5.9. SQL Functions Returning Sets
13 36.5.10. SQL Functions Returning TABLE
14 36.5.11. Polymorphic SQL Functions
15 36.5.12. SQL Functions with Collations
17 SQL functions execute an arbitrary list of SQL statements, returning
18 the result of the last query in the list. In the simple (non-set) case,
19 the first row of the last query's result will be returned. (Bear in
20 mind that “the first row” of a multirow result is not well-defined
21 unless you use ORDER BY.) If the last query happens to return no rows
22 at all, the null value will be returned.
24 Alternatively, an SQL function can be declared to return a set (that
25 is, multiple rows) by specifying the function's return type as SETOF
26 sometype, or equivalently by declaring it as RETURNS TABLE(columns). In
27 this case all rows of the last query's result are returned. Further
30 The body of an SQL function must be a list of SQL statements separated
31 by semicolons. A semicolon after the last statement is optional. Unless
32 the function is declared to return void, the last statement must be a
33 SELECT, or an INSERT, UPDATE, DELETE, or MERGE that has a RETURNING
36 Any collection of commands in the SQL language can be packaged together
37 and defined as a function. Besides SELECT queries, the commands can
38 include data modification queries (INSERT, UPDATE, DELETE, and MERGE),
39 as well as other SQL commands. (You cannot use transaction control
40 commands, e.g., COMMIT, SAVEPOINT, and some utility commands, e.g.,
41 VACUUM, in SQL functions.) However, the final command must be a SELECT
42 or have a RETURNING clause that returns whatever is specified as the
43 function's return type. Alternatively, if you want to define an SQL
44 function that performs actions but has no useful value to return, you
45 can define it as returning void. For example, this function removes
46 rows with negative salaries from the emp table:
47 CREATE FUNCTION clean_emp() RETURNS void AS '
59 You can also write this as a procedure, thus avoiding the issue of the
60 return type. For example:
61 CREATE PROCEDURE clean_emp() AS '
68 In simple cases like this, the difference between a function returning
69 void and a procedure is mostly stylistic. However, procedures offer
70 additional functionality such as transaction control that is not
71 available in functions. Also, procedures are SQL standard whereas
72 returning void is a PostgreSQL extension.
74 The syntax of the CREATE FUNCTION command requires the function body to
75 be written as a string constant. It is usually most convenient to use
76 dollar quoting (see Section 4.1.2.4) for the string constant. If you
77 choose to use regular single-quoted string constant syntax, you must
78 double single quote marks (') and backslashes (\) (assuming escape
79 string syntax) in the body of the function (see Section 4.1.2.1).
81 36.5.1. Arguments for SQL Functions #
83 Arguments of an SQL function can be referenced in the function body
84 using either names or numbers. Examples of both methods appear below.
86 To use a name, declare the function argument as having a name, and then
87 just write that name in the function body. If the argument name is the
88 same as any column name in the current SQL command within the function,
89 the column name will take precedence. To override this, qualify the
90 argument name with the name of the function itself, that is
91 function_name.argument_name. (If this would conflict with a qualified
92 column name, again the column name wins. You can avoid the ambiguity by
93 choosing a different alias for the table within the SQL command.)
95 In the older numeric approach, arguments are referenced using the
96 syntax $n: $1 refers to the first input argument, $2 to the second, and
97 so on. This will work whether or not the particular argument was
100 If an argument is of a composite type, then the dot notation, e.g.,
101 argname.fieldname or $1.fieldname, can be used to access attributes of
102 the argument. Again, you might need to qualify the argument's name with
103 the function name to make the form with an argument name unambiguous.
105 SQL function arguments can only be used as data values, not as
106 identifiers. Thus for example this is reasonable:
107 INSERT INTO mytable VALUES ($1);
109 but this will not work:
110 INSERT INTO $1 VALUES (42);
114 The ability to use names to reference SQL function arguments was added
115 in PostgreSQL 9.2. Functions to be used in older servers must use the
118 36.5.2. SQL Functions on Base Types #
120 The simplest possible SQL function has no arguments and simply returns
121 a base type, such as integer:
122 CREATE FUNCTION one() RETURNS integer AS $$
126 -- Alternative syntax for string literal:
127 CREATE FUNCTION one() RETURNS integer AS '
137 Notice that we defined a column alias within the function body for the
138 result of the function (with the name result), but this column alias is
139 not visible outside the function. Hence, the result is labeled one
142 It is almost as easy to define SQL functions that take base types as
144 CREATE FUNCTION add_em(x integer, y integer) RETURNS integer AS $$
148 SELECT add_em(1, 2) AS answer;
154 Alternatively, we could dispense with names for the arguments and use
156 CREATE FUNCTION add_em(integer, integer) RETURNS integer AS $$
160 SELECT add_em(1, 2) AS answer;
166 Here is a more useful function, which might be used to debit a bank
168 CREATE FUNCTION tf1 (accountno integer, debit numeric) RETURNS numeric AS $$
170 SET balance = balance - debit
171 WHERE accountno = tf1.accountno;
175 A user could execute this function to debit account 17 by $100.00 as
177 SELECT tf1(17, 100.0);
179 In this example, we chose the name accountno for the first argument,
180 but this is the same as the name of a column in the bank table. Within
181 the UPDATE command, accountno refers to the column bank.accountno, so
182 tf1.accountno must be used to refer to the argument. We could of course
183 avoid this by using a different name for the argument.
185 In practice one would probably like a more useful result from the
186 function than a constant 1, so a more likely definition is:
187 CREATE FUNCTION tf1 (accountno integer, debit numeric) RETURNS numeric AS $$
189 SET balance = balance - debit
190 WHERE accountno = tf1.accountno;
191 SELECT balance FROM bank WHERE accountno = tf1.accountno;
194 which adjusts the balance and returns the new balance. The same thing
195 could be done in one command using RETURNING:
196 CREATE FUNCTION tf1 (accountno integer, debit numeric) RETURNS numeric AS $$
198 SET balance = balance - debit
199 WHERE accountno = tf1.accountno
203 If the final SELECT or RETURNING clause in an SQL function does not
204 return exactly the function's declared result type, PostgreSQL will
205 automatically cast the value to the required type, if that is possible
206 with an implicit or assignment cast. Otherwise, you must write an
207 explicit cast. For example, suppose we wanted the previous add_em
208 function to return type float8 instead. It's sufficient to write
209 CREATE FUNCTION add_em(integer, integer) RETURNS float8 AS $$
213 since the integer sum can be implicitly cast to float8. (See Chapter 10
214 or CREATE CAST for more about casts.)
216 36.5.3. SQL Functions on Composite Types #
218 When writing functions with arguments of composite types, we must not
219 only specify which argument we want but also the desired attribute
220 (field) of that argument. For example, suppose that emp is a table
221 containing employee data, and therefore also the name of the composite
222 type of each row of the table. Here is a function double_salary that
223 computes what someone's salary would be if it were doubled:
231 INSERT INTO emp VALUES ('Bill', 4200, 45, '(2,1)');
233 CREATE FUNCTION double_salary(emp) RETURNS numeric AS $$
234 SELECT $1.salary * 2 AS salary;
237 SELECT name, double_salary(emp.*) AS dream
239 WHERE emp.cubicle ~= point '(2,1)';
245 Notice the use of the syntax $1.salary to select one field of the
246 argument row value. Also notice how the calling SELECT command uses
247 table_name.* to select the entire current row of a table as a composite
248 value. The table row can alternatively be referenced using just the
249 table name, like this:
250 SELECT name, double_salary(emp) AS dream
252 WHERE emp.cubicle ~= point '(2,1)';
254 but this usage is deprecated since it's easy to get confused. (See
255 Section 8.16.5 for details about these two notations for the composite
256 value of a table row.)
258 Sometimes it is handy to construct a composite argument value
259 on-the-fly. This can be done with the ROW construct. For example, we
260 could adjust the data being passed to the function:
261 SELECT name, double_salary(ROW(name, salary*1.1, age, cubicle)) AS dream
264 It is also possible to build a function that returns a composite type.
265 This is an example of a function that returns a single emp row:
266 CREATE FUNCTION new_emp() RETURNS emp AS $$
267 SELECT text 'None' AS name,
270 point '(2,2)' AS cubicle;
273 In this example we have specified each of the attributes with a
274 constant value, but any computation could have been substituted for
277 Note two important things about defining the function:
278 * The select list order in the query must be exactly the same as that
279 in which the columns appear in the composite type. (Naming the
280 columns, as we did above, is irrelevant to the system.)
281 * We must ensure each expression's type can be cast to that of the
282 corresponding column of the composite type. Otherwise we'll get
285 ERROR: return type mismatch in function declared to return emp
286 DETAIL: Final statement returns text instead of point at column 4.
289 As with the base-type case, the system will not insert explicit
290 casts automatically, only implicit or assignment casts.
292 A different way to define the same function is:
293 CREATE FUNCTION new_emp() RETURNS emp AS $$
294 SELECT ROW('None', 1000.0, 25, '(2,2)')::emp;
297 Here we wrote a SELECT that returns just a single column of the correct
298 composite type. This isn't really better in this situation, but it is a
299 handy alternative in some cases — for example, if we need to compute
300 the result by calling another function that returns the desired
301 composite value. Another example is that if we are trying to write a
302 function that returns a domain over composite, rather than a plain
303 composite type, it is always necessary to write it as returning a
304 single column, since there is no way to cause a coercion of the whole
307 We could call this function directly either by using it in a value
312 --------------------------
313 (None,1000.0,25,"(2,2)")
315 or by calling it as a table function:
316 SELECT * FROM new_emp();
318 name | salary | age | cubicle
319 ------+--------+-----+---------
320 None | 1000.0 | 25 | (2,2)
322 The second way is described more fully in Section 36.5.8.
324 When you use a function that returns a composite type, you might want
325 only one field (attribute) from its result. You can do that with syntax
327 SELECT (new_emp()).name;
333 The extra parentheses are needed to keep the parser from getting
334 confused. If you try to do it without them, you get something like
336 SELECT new_emp().name;
337 ERROR: syntax error at or near "."
338 LINE 1: SELECT new_emp().name;
341 Another option is to use functional notation for extracting an
343 SELECT name(new_emp());
349 As explained in Section 8.16.5, the field notation and functional
350 notation are equivalent.
352 Another way to use a function returning a composite type is to pass the
353 result to another function that accepts the correct row type as input:
354 CREATE FUNCTION getname(emp) RETURNS text AS $$
358 SELECT getname(new_emp());
364 36.5.4. SQL Functions with Output Parameters #
366 An alternative way of describing a function's results is to define it
367 with output parameters, as in this example:
368 CREATE FUNCTION add_em (IN x int, IN y int, OUT sum int)
378 This is not essentially different from the version of add_em shown in
379 Section 36.5.2. The real value of output parameters is that they
380 provide a convenient way of defining functions that return several
381 columns. For example,
382 CREATE FUNCTION sum_n_product (x int, y int, OUT sum int, OUT product int)
383 AS 'SELECT x + y, x * y'
386 SELECT * FROM sum_n_product(11,42);
392 What has essentially happened here is that we have created an anonymous
393 composite type for the result of the function. The above example has
394 the same end result as
395 CREATE TYPE sum_prod AS (sum int, product int);
397 CREATE FUNCTION sum_n_product (int, int) RETURNS sum_prod
398 AS 'SELECT $1 + $2, $1 * $2'
401 but not having to bother with the separate composite type definition is
402 often handy. Notice that the names attached to the output parameters
403 are not just decoration, but determine the column names of the
404 anonymous composite type. (If you omit a name for an output parameter,
405 the system will choose a name on its own.)
407 Notice that output parameters are not included in the calling argument
408 list when invoking such a function from SQL. This is because PostgreSQL
409 considers only the input parameters to define the function's calling
410 signature. That means also that only the input parameters matter when
411 referencing the function for purposes such as dropping it. We could
412 drop the above function with either of
413 DROP FUNCTION sum_n_product (x int, y int, OUT sum int, OUT product int);
414 DROP FUNCTION sum_n_product (int, int);
416 Parameters can be marked as IN (the default), OUT, INOUT, or VARIADIC.
417 An INOUT parameter serves as both an input parameter (part of the
418 calling argument list) and an output parameter (part of the result
419 record type). VARIADIC parameters are input parameters, but are treated
420 specially as described below.
422 36.5.5. SQL Procedures with Output Parameters #
424 Output parameters are also supported in procedures, but they work a bit
425 differently from functions. In CALL commands, output parameters must be
426 included in the argument list. For example, the bank account debiting
427 routine from earlier could be written like this:
428 CREATE PROCEDURE tp1 (accountno integer, debit numeric, OUT new_balance numeric)
431 SET balance = balance - debit
432 WHERE accountno = tp1.accountno
436 To call this procedure, an argument matching the OUT parameter must be
437 included. It's customary to write NULL:
438 CALL tp1(17, 100.0, NULL);
440 If you write something else, it must be an expression that is
441 implicitly coercible to the declared type of the parameter, just as for
442 input parameters. Note however that such an expression will not be
445 When calling a procedure from PL/pgSQL, instead of writing NULL you
446 must write a variable that will receive the procedure's output. See
447 Section 41.6.3 for details.
449 36.5.6. SQL Functions with Variable Numbers of Arguments #
451 SQL functions can be declared to accept variable numbers of arguments,
452 so long as all the “optional” arguments are of the same data type. The
453 optional arguments will be passed to the function as an array. The
454 function is declared by marking the last parameter as VARIADIC; this
455 parameter must be declared as being of an array type. For example:
456 CREATE FUNCTION mleast(VARIADIC arr numeric[]) RETURNS numeric AS $$
457 SELECT min($1[i]) FROM generate_subscripts($1, 1) g(i);
460 SELECT mleast(10, -1, 5, 4.4);
466 Effectively, all the actual arguments at or beyond the VARIADIC
467 position are gathered up into a one-dimensional array, as if you had
469 SELECT mleast(ARRAY[10, -1, 5, 4.4]); -- doesn't work
471 You can't actually write that, though — or at least, it will not match
472 this function definition. A parameter marked VARIADIC matches one or
473 more occurrences of its element type, not of its own type.
475 Sometimes it is useful to be able to pass an already-constructed array
476 to a variadic function; this is particularly handy when one variadic
477 function wants to pass on its array parameter to another one. Also,
478 this is the only secure way to call a variadic function found in a
479 schema that permits untrusted users to create objects; see
480 Section 10.3. You can do this by specifying VARIADIC in the call:
481 SELECT mleast(VARIADIC ARRAY[10, -1, 5, 4.4]);
483 This prevents expansion of the function's variadic parameter into its
484 element type, thereby allowing the array argument value to match
485 normally. VARIADIC can only be attached to the last actual argument of
488 Specifying VARIADIC in the call is also the only way to pass an empty
489 array to a variadic function, for example:
490 SELECT mleast(VARIADIC ARRAY[]::numeric[]);
492 Simply writing SELECT mleast() does not work because a variadic
493 parameter must match at least one actual argument. (You could define a
494 second function also named mleast, with no parameters, if you wanted to
497 The array element parameters generated from a variadic parameter are
498 treated as not having any names of their own. This means it is not
499 possible to call a variadic function using named arguments
500 (Section 4.3), except when you specify VARIADIC. For example, this will
502 SELECT mleast(VARIADIC arr => ARRAY[10, -1, 5, 4.4]);
505 SELECT mleast(arr => 10);
506 SELECT mleast(arr => ARRAY[10, -1, 5, 4.4]);
508 36.5.7. SQL Functions with Default Values for Arguments #
510 Functions can be declared with default values for some or all input
511 arguments. The default values are inserted whenever the function is
512 called with insufficiently many actual arguments. Since arguments can
513 only be omitted from the end of the actual argument list, all
514 parameters after a parameter with a default value have to have default
515 values as well. (Although the use of named argument notation could
516 allow this restriction to be relaxed, it's still enforced so that
517 positional argument notation works sensibly.) Whether or not you use
518 it, this capability creates a need for precautions when calling
519 functions in databases where some users mistrust other users; see
523 CREATE FUNCTION foo(a int, b int DEFAULT 2, c int DEFAULT 3)
530 SELECT foo(10, 20, 30);
548 SELECT foo(); -- fails since there is no default for the first argument
549 ERROR: function foo() does not exist
551 The = sign can also be used in place of the key word DEFAULT.
553 36.5.8. SQL Functions as Table Sources #
555 All SQL functions can be used in the FROM clause of a query, but it is
556 particularly useful for functions returning composite types. If the
557 function is defined to return a base type, the table function produces
558 a one-column table. If the function is defined to return a composite
559 type, the table function produces a column for each attribute of the
563 CREATE TABLE foo (fooid int, foosubid int, fooname text);
564 INSERT INTO foo VALUES (1, 1, 'Joe');
565 INSERT INTO foo VALUES (1, 2, 'Ed');
566 INSERT INTO foo VALUES (2, 1, 'Mary');
568 CREATE FUNCTION getfoo(int) RETURNS foo AS $$
569 SELECT * FROM foo WHERE fooid = $1;
572 SELECT *, upper(fooname) FROM getfoo(1) AS t1;
574 fooid | foosubid | fooname | upper
575 -------+----------+---------+-------
579 As the example shows, we can work with the columns of the function's
580 result just the same as if they were columns of a regular table.
582 Note that we only got one row out of the function. This is because we
583 did not use SETOF. That is described in the next section.
585 36.5.9. SQL Functions Returning Sets #
587 When an SQL function is declared as returning SETOF sometype, the
588 function's final query is executed to completion, and each row it
589 outputs is returned as an element of the result set.
591 This feature is normally used when calling the function in the FROM
592 clause. In this case each row returned by the function becomes a row of
593 the table seen by the query. For example, assume that table foo has the
594 same contents as above, and we say:
595 CREATE FUNCTION getfoo(int) RETURNS SETOF foo AS $$
596 SELECT * FROM foo WHERE fooid = $1;
599 SELECT * FROM getfoo(1) AS t1;
602 fooid | foosubid | fooname
603 -------+----------+---------
608 It is also possible to return multiple rows with the columns defined by
609 output parameters, like this:
610 CREATE TABLE tab (y int, z int);
611 INSERT INTO tab VALUES (1, 2), (3, 4), (5, 6), (7, 8);
613 CREATE FUNCTION sum_n_product_with_tab (x int, OUT sum int, OUT product int)
616 SELECT $1 + tab.y, $1 * tab.y FROM tab;
619 SELECT * FROM sum_n_product_with_tab(10);
628 The key point here is that you must write RETURNS SETOF record to
629 indicate that the function returns multiple rows instead of just one.
630 If there is only one output parameter, write that parameter's type
633 It is frequently useful to construct a query's result by invoking a
634 set-returning function multiple times, with the parameters for each
635 invocation coming from successive rows of a table or subquery. The
636 preferred way to do this is to use the LATERAL key word, which is
637 described in Section 7.2.1.5. Here is an example using a set-returning
638 function to enumerate elements of a tree structure:
650 CREATE FUNCTION listchildren(text) RETURNS SETOF text AS $$
651 SELECT name FROM nodes WHERE parent = $1
652 $$ LANGUAGE SQL STABLE;
654 SELECT * FROM listchildren('Top');
662 SELECT name, child FROM nodes, LATERAL listchildren(name) AS child;
672 This example does not do anything that we couldn't have done with a
673 simple join, but in more complex calculations the option to put some of
674 the work into a function can be quite convenient.
676 Functions returning sets can also be called in the select list of a
677 query. For each row that the query generates by itself, the
678 set-returning function is invoked, and an output row is generated for
679 each element of the function's result set. The previous example could
680 also be done with queries like these:
681 SELECT listchildren('Top');
689 SELECT name, listchildren(name) FROM nodes;
691 --------+--------------
699 In the last SELECT, notice that no output row appears for Child2,
700 Child3, etc. This happens because listchildren returns an empty set for
701 those arguments, so no result rows are generated. This is the same
702 behavior as we got from an inner join to the function result when using
705 PostgreSQL's behavior for a set-returning function in a query's select
706 list is almost exactly the same as if the set-returning function had
707 been written in a LATERAL FROM-clause item instead. For example,
708 SELECT x, generate_series(1,5) AS g FROM tab;
710 is almost equivalent to
711 SELECT x, g FROM tab, LATERAL generate_series(1,5) AS g;
713 It would be exactly the same, except that in this specific example, the
714 planner could choose to put g on the outside of the nested-loop join,
715 since g has no actual lateral dependency on tab. That would result in a
716 different output row order. Set-returning functions in the select list
717 are always evaluated as though they are on the inside of a nested-loop
718 join with the rest of the FROM clause, so that the function(s) are run
719 to completion before the next row from the FROM clause is considered.
721 If there is more than one set-returning function in the query's select
722 list, the behavior is similar to what you get from putting the
723 functions into a single LATERAL ROWS FROM( ... ) FROM-clause item. For
724 each row from the underlying query, there is an output row using the
725 first result from each function, then an output row using the second
726 result, and so on. If some of the set-returning functions produce fewer
727 outputs than others, null values are substituted for the missing data,
728 so that the total number of rows emitted for one underlying row is the
729 same as for the set-returning function that produced the most outputs.
730 Thus the set-returning functions run “in lockstep” until they are all
731 exhausted, and then execution continues with the next underlying row.
733 Set-returning functions can be nested in a select list, although that
734 is not allowed in FROM-clause items. In such cases, each level of
735 nesting is treated separately, as though it were a separate LATERAL
736 ROWS FROM( ... ) item. For example, in
737 SELECT srf1(srf2(x), srf3(y)), srf4(srf5(z)) FROM tab;
739 the set-returning functions srf2, srf3, and srf5 would be run in
740 lockstep for each row of tab, and then srf1 and srf4 would be applied
741 in lockstep to each row produced by the lower functions.
743 Set-returning functions cannot be used within conditional-evaluation
744 constructs, such as CASE or COALESCE. For example, consider
745 SELECT x, CASE WHEN x > 0 THEN generate_series(1, 5) ELSE 0 END FROM tab;
747 It might seem that this should produce five repetitions of input rows
748 that have x > 0, and a single repetition of those that do not; but
749 actually, because generate_series(1, 5) would be run in an implicit
750 LATERAL FROM item before the CASE expression is ever evaluated, it
751 would produce five repetitions of every input row. To reduce confusion,
752 such cases produce a parse-time error instead.
756 If a function's last command is INSERT, UPDATE, DELETE, or MERGE with
757 RETURNING, that command will always be executed to completion, even if
758 the function is not declared with SETOF or the calling query does not
759 fetch all the result rows. Any extra rows produced by the RETURNING
760 clause are silently dropped, but the commanded table modifications
761 still happen (and are all completed before returning from the
766 Before PostgreSQL 10, putting more than one set-returning function in
767 the same select list did not behave very sensibly unless they always
768 produced equal numbers of rows. Otherwise, what you got was a number of
769 output rows equal to the least common multiple of the numbers of rows
770 produced by the set-returning functions. Also, nested set-returning
771 functions did not work as described above; instead, a set-returning
772 function could have at most one set-returning argument, and each nest
773 of set-returning functions was run independently. Also, conditional
774 execution (set-returning functions inside CASE etc.) was previously
775 allowed, complicating things even more. Use of the LATERAL syntax is
776 recommended when writing queries that need to work in older PostgreSQL
777 versions, because that will give consistent results across different
778 versions. If you have a query that is relying on conditional execution
779 of a set-returning function, you may be able to fix it by moving the
780 conditional test into a custom set-returning function. For example,
781 SELECT x, CASE WHEN y > 0 THEN generate_series(1, z) ELSE 5 END FROM tab;
784 CREATE FUNCTION case_generate_series(cond bool, start int, fin int, els int)
785 RETURNS SETOF int AS $$
788 RETURN QUERY SELECT generate_series(start, fin);
790 RETURN QUERY SELECT els;
792 END$$ LANGUAGE plpgsql;
794 SELECT x, case_generate_series(y > 0, 1, z, 5) FROM tab;
796 This formulation will work the same in all versions of PostgreSQL.
798 36.5.10. SQL Functions Returning TABLE #
800 There is another way to declare a function as returning a set, which is
801 to use the syntax RETURNS TABLE(columns). This is equivalent to using
802 one or more OUT parameters plus marking the function as returning SETOF
803 record (or SETOF a single output parameter's type, as appropriate).
804 This notation is specified in recent versions of the SQL standard, and
805 thus may be more portable than using SETOF.
807 For example, the preceding sum-and-product example could also be done
809 CREATE FUNCTION sum_n_product_with_tab (x int)
810 RETURNS TABLE(sum int, product int) AS $$
811 SELECT $1 + tab.y, $1 * tab.y FROM tab;
814 It is not allowed to use explicit OUT or INOUT parameters with the
815 RETURNS TABLE notation — you must put all the output columns in the
818 36.5.11. Polymorphic SQL Functions #
820 SQL functions can be declared to accept and return the polymorphic
821 types described in Section 36.2.5. Here is a polymorphic function
822 make_array that builds up an array from two arbitrary data type
824 CREATE FUNCTION make_array(anyelement, anyelement) RETURNS anyarray AS $$
825 SELECT ARRAY[$1, $2];
828 SELECT make_array(1, 2) AS intarray, make_array('a'::text, 'b') AS textarray;
830 ----------+-----------
834 Notice the use of the typecast 'a'::text to specify that the argument
835 is of type text. This is required if the argument is just a string
836 literal, since otherwise it would be treated as type unknown, and array
837 of unknown is not a valid type. Without the typecast, you will get
839 ERROR: could not determine polymorphic type because input has type unknown
841 With make_array declared as above, you must provide two arguments that
842 are of exactly the same data type; the system will not attempt to
843 resolve any type differences. Thus for example this does not work:
844 SELECT make_array(1, 2.5) AS numericarray;
845 ERROR: function make_array(integer, numeric) does not exist
847 An alternative approach is to use the “common” family of polymorphic
848 types, which allows the system to try to identify a suitable common
850 CREATE FUNCTION make_array2(anycompatible, anycompatible)
851 RETURNS anycompatiblearray AS $$
852 SELECT ARRAY[$1, $2];
855 SELECT make_array2(1, 2.5) AS numericarray;
861 Because the rules for common type resolution default to choosing type
862 text when all inputs are of unknown types, this also works:
863 SELECT make_array2('a', 'b') AS textarray;
869 It is permitted to have polymorphic arguments with a fixed return type,
870 but the converse is not. For example:
871 CREATE FUNCTION is_greater(anyelement, anyelement) RETURNS boolean AS $$
875 SELECT is_greater(1, 2);
881 CREATE FUNCTION invalid_func() RETURNS anyelement AS $$
884 ERROR: cannot determine result data type
885 DETAIL: A result of type anyelement requires at least one input of type anyelem
886 ent, anyarray, anynonarray, anyenum, or anyrange.
888 Polymorphism can be used with functions that have output arguments. For
890 CREATE FUNCTION dup (f1 anyelement, OUT f2 anyelement, OUT f3 anyarray)
891 AS 'select $1, array[$1,$1]' LANGUAGE SQL;
893 SELECT * FROM dup(22);
899 Polymorphism can also be used with variadic functions. For example:
900 CREATE FUNCTION anyleast (VARIADIC anyarray) RETURNS anyelement AS $$
901 SELECT min($1[i]) FROM generate_subscripts($1, 1) g(i);
904 SELECT anyleast(10, -1, 5, 4);
910 SELECT anyleast('abc'::text, 'def');
916 CREATE FUNCTION concat_values(text, VARIADIC anyarray) RETURNS text AS $$
917 SELECT array_to_string($2, $1);
920 SELECT concat_values('|', 1, 4, 2);
926 36.5.12. SQL Functions with Collations #
928 When an SQL function has one or more parameters of collatable data
929 types, a collation is identified for each function call depending on
930 the collations assigned to the actual arguments, as described in
931 Section 23.2. If a collation is successfully identified (i.e., there
932 are no conflicts of implicit collations among the arguments) then all
933 the collatable parameters are treated as having that collation
934 implicitly. This will affect the behavior of collation-sensitive
935 operations within the function. For example, using the anyleast
936 function described above, the result of
937 SELECT anyleast('abc'::text, 'ABC');
939 will depend on the database's default collation. In C locale the result
940 will be ABC, but in many other locales it will be abc. The collation to
941 use can be forced by adding a COLLATE clause to any of the arguments,
943 SELECT anyleast('abc'::text, 'ABC' COLLATE "C");
945 Alternatively, if you wish a function to operate with a particular
946 collation regardless of what it is called with, insert COLLATE clauses
947 as needed in the function definition. This version of anyleast would
948 always use en_US locale to compare strings:
949 CREATE FUNCTION anyleast (VARIADIC anyarray) RETURNS anyelement AS $$
950 SELECT min($1[i] COLLATE "en_US") FROM generate_subscripts($1, 1) g(i);
953 But note that this will throw an error if applied to a non-collatable
956 If no common collation can be identified among the actual arguments,
957 then an SQL function treats its parameters as having their data types'
958 default collation (which is usually the database's default collation,
959 but could be different for parameters of domain types).
961 The behavior of collatable parameters can be thought of as a limited
962 form of polymorphism, applicable only to textual data types.