1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 31 32 33 34 35 36 37 38 39 40 41 42 43 44 45 46 47 48 49 50 51 52 53 54 55 56 57 58 59 60 61 62 63 64 65 66 67 68 69 70 71 72 73 74 75 76 77 78 79 80 81 82 83 84 85 86 87 88 89 90 91 92 93 94 95 96 97 98 99 100 101 102 103 104 105 106 107 108 109 110 111 112 113 114 115 116 117 118 119 120 121 122 123 124 125 126 127 128 129 130 131 132 133 134 135 136 137 138 139 140 141 142 143 144 145 146 147 148 149 150 151 152 153 154 155 156 157 158 159 160 161 162 163 164 165 166 167 168 169 170 171 172 173 174 175 176 177 178 179 180 181 182 183 184 185 186 187 188 189 190 191 192 193 194 195 196 197 198 199 200 201 202 203 204 205 206 207 208 209 210 211 212 213 214 215 216 217 218 219 220 221 222 223 224 225 226 227 228 229 230 231 232 233 234 235 236 237 238 239 240 241 242 243 244 245 246 247 248 249 250 251 252 253 254 255 256 257 258 259 260 261 262 263 264 265 266 267 268 269 270 271 272 273 274 275 276 277 278 279 280 281 282 283 284 285 286 287 288 289 290 291 292 293 294 295 296 297 298 299 300 301 302 303 304 305 306 307 308 309 310 311 312 313 314 315 316 317 318 319 320 321 322 323 324 325 326 327 328 329 330 331 332 333 334 335 336 337 338 339 340 341 342 343 344 345 346 347 348 349 350 351 352 353 354 355 356 357 358 359 360 361 362 363 364 365 366 367 368 369 370 371 372 373 374 375 376 377 378 379 380 381 382 383 384 385 386 387 388 389 390 391 392 393 394 395 396 397 398 399 400 401 402 403 404 405 406 407 408 409 410 411 412 413 414 415 416 417 418 419 420 421 422 423 424 425 426 427 428 429 430 431 432 433 434 435 436 437 438 439 440 441 442 443 444 445 446 447 448 449 450 451 452 453 454 455 456 457 458 459 460 461 462 463 464 465 466 467 468 469 470 471 472 473 474 475 476 477 478 479 480 481 482 483 484 485 486 487 488 489 490 491 492 493 494 495 496 497 498 499 500 501 502 503 504 505 506 507 508 509 510 511 512 513 514 515 516 517 518 519 520 521 522 523 524 525 526 527 528 529 530 531 532 533 534 535 536 537 538 539 540 541 542 543 544 545 546 547 548 549 550 551 552 553 554 555 556 557 558 559 560 561 562 563 564 565 566 567 568 569 570 571 572 573 574 575 576 577 578 579 580 581 582 583 584 585 586 587 588 589 590 591 592 593 594 595 596 597 598 599 600 601 602 603 604 605 606 607 608 609 610 611 612 613 614 615 616 617 618 619 620 621 622 623 624 625 626 627 628 629 630 631 632 633 634
|
<html>
<head>
<meta http-equiv="Content-Type" content="text/html; charset=ISO-8859-1">
<title>32.4.Query Language (SQL) Functions</title>
<link rel="stylesheet" href="stylesheet.css" type="text/css">
<link rev="made" href="pgsql-docs@postgresql.org">
<meta name="generator" content="DocBook XSL Stylesheets V1.70.0">
<link rel="start" href="index.html" title="PostgreSQL 8.1.4 Documentation">
<link rel="up" href="extend.html" title="Chapter32.Extending SQL">
<link rel="prev" href="xfunc.html" title="32.3.User-Defined Functions">
<link rel="next" href="xfunc-overload.html" title="32.5.Function Overloading">
<link rel="copyright" href="ln-legalnotice.html" title="Legal Notice">
</head>
<body bgcolor="white" text="black" link="#0000FF" vlink="#840084" alink="#0000FF"><div class="sect1" lang="en">
<div class="titlepage"><div><div><h2 class="title" style="clear: both">
<a name="xfunc-sql"></a>32.4.Query Language (<acronym class="acronym">SQL</acronym>) Functions</h2></div></div></div>
<a name="id704141"></a><p> SQL functions execute an arbitrary list of SQL statements, returning
the result of the last query in the list.
In the simple (non-set)
case, the first row of the last query's result will be returned.
(Bear in mind that “<span class="quote">the first row</span>” of a multirow
result is not well-defined unless you use <code class="literal">ORDER BY</code>.)
If the last query happens
to return no rows at all, the null value will be returned.
</p>
<p> <a name="id704179"></a> Alternatively,
an SQL function may be declared to return a set, by specifying the
function's return type as <code class="literal">SETOF
<em class="replaceable"><code>sometype</code></em></code>. In this case all rows of the
last query's result are returned. Further details appear below.
</p>
<p> The body of an SQL function must be a list of SQL
statements separated by semicolons. A semicolon after the last
statement is optional. Unless the function is declared to return
<code class="type">void</code>, the last statement must be a <code class="command">SELECT</code>.
</p>
<p> Any collection of commands in the <acronym class="acronym">SQL</acronym>
language can be packaged together and defined as a function.
Besides <code class="command">SELECT</code> queries, the commands can include data
modification queries (<code class="command">INSERT</code>,
<code class="command">UPDATE</code>, and <code class="command">DELETE</code>), as well as
other SQL commands. (The only exception is that you can't put
<code class="command">BEGIN</code>, <code class="command">COMMIT</code>, <code class="command">ROLLBACK</code>, or
<code class="command">SAVEPOINT</code> commands into a <acronym class="acronym">SQL</acronym> function.)
However, the final command
must be a <code class="command">SELECT</code> that returns whatever is
specified as the function's return type. Alternatively, if you
want to define a SQL function that performs actions but has no
useful value to return, you can define it as returning <code class="type">void</code>.
In that case, the function body must not end with a <code class="command">SELECT</code>.
For example, this function removes rows with negative salaries from
the <code class="literal">emp</code> table:
</p>
<pre class="screen">CREATE FUNCTION clean_emp() RETURNS void AS '
DELETE FROM emp
WHERE salary < 0;
' LANGUAGE SQL;
SELECT clean_emp();
clean_emp
-----------
(1 row)</pre>
<p>
</p>
<p> The syntax of the <code class="command">CREATE FUNCTION</code> command requires
the function body to be written as a string constant. It is usually
most convenient to use dollar quoting (see <a href="sql-syntax.html#sql-syntax-dollar-quoting" title="4.1.2.2.Dollar-Quoted String Constants">Section4.1.2.2, “Dollar-Quoted String Constants”</a>) for the string constant.
If you choose to use regular single-quoted string constant syntax,
you must escape single quote marks (<code class="literal">'</code>) and backslashes
(<code class="literal">\</code>) used in the body of the function, typically by
doubling them (see <a href="sql-syntax.html#sql-syntax-strings" title="4.1.2.1.String Constants">Section4.1.2.1, “String Constants”</a>).
</p>
<p> Arguments to the SQL function are referenced in the function
body using the syntax <code class="literal">$<em class="replaceable"><code>n</code></em></code>: <code class="literal">$1</code>
refers to the first argument, <code class="literal">$2</code> to the second, and so on.
If an argument is of a composite type, then the dot notation,
e.g., <code class="literal">$1.name</code>, may be used to access attributes
of the argument. The arguments can only be used as data values,
not as identifiers. Thus for example this is reasonable:
</p>
<pre class="programlisting">INSERT INTO mytable VALUES ($1);</pre>
<p>
but this will not work:
</p>
<pre class="programlisting">INSERT INTO $1 VALUES (42);</pre>
<p>
</p>
<div class="sect2" lang="en">
<div class="titlepage"><div><div><h3 class="title">
<a name="xfunc-sql-base-functions"></a>32.4.1.<acronym class="acronym">SQL</acronym> Functions on Base Types</h3></div></div></div>
<p> The simplest possible <acronym class="acronym">SQL</acronym> function has no arguments and
simply returns a base type, such as <code class="type">integer</code>:
</p>
<pre class="screen">CREATE FUNCTION one() RETURNS integer AS $$
SELECT 1 AS result;
$$ LANGUAGE SQL;
-- Alternative syntax for string literal:
CREATE FUNCTION one() RETURNS integer AS '
SELECT 1 AS result;
' LANGUAGE SQL;
SELECT one();
one
-----
1</pre>
<p>
</p>
<p> Notice that we defined a column alias within the function body for the result of the function
(with the name <code class="literal">result</code>), but this column alias is not visible
outside the function. Hence, the result is labeled <code class="literal">one</code>
instead of <code class="literal">result</code>.
</p>
<p> It is almost as easy to define <acronym class="acronym">SQL</acronym> functions
that take base types as arguments. In the example below, notice
how we refer to the arguments within the function as <code class="literal">$1</code>
and <code class="literal">$2</code>.
</p>
<pre class="screen">CREATE FUNCTION add_em(integer, integer) RETURNS integer AS $$
SELECT $1 + $2;
$$ LANGUAGE SQL;
SELECT add_em(1, 2) AS answer;
answer
--------
3</pre>
<p>
</p>
<p> Here is a more useful function, which might be used to debit a
bank account:
</p>
<pre class="programlisting">CREATE FUNCTION tf1 (integer, numeric) RETURNS integer AS $$
UPDATE bank
SET balance = balance - $2
WHERE accountno = $1;
SELECT 1;
$$ LANGUAGE SQL;</pre>
<p>
A user could execute this function to debit account 17 by $100.00 as
follows:
</p>
<pre class="programlisting">SELECT tf1(17, 100.0);</pre>
<p>
</p>
<p> In practice one would probably like a more useful result from the
function than a constant 1, so a more likely definition
is
</p>
<pre class="programlisting">CREATE FUNCTION tf1 (integer, numeric) RETURNS numeric AS $$
UPDATE bank
SET balance = balance - $2
WHERE accountno = $1;
SELECT balance FROM bank WHERE accountno = $1;
$$ LANGUAGE SQL;</pre>
<p>
which adjusts the balance and returns the new balance.
</p>
</div>
<div class="sect2" lang="en">
<div class="titlepage"><div><div><h3 class="title">
<a name="id704549"></a>32.4.2.<acronym class="acronym">SQL</acronym> Functions on Composite Types</h3></div></div></div>
<p> When writing functions with arguments of composite
types, we must not only specify which
argument we want (as we did above with <code class="literal">$1</code> and <code class="literal">$2</code>) but
also the desired attribute (field) of that argument. For example,
suppose that
<code class="type">emp</code> is a table containing employee data, and therefore
also the name of the composite type of each row of the table. Here
is a function <code class="function">double_salary</code> that computes what someone's
salary would be if it were doubled:
</p>
<pre class="screen">CREATE TABLE emp (
name text,
salary numeric,
age integer,
cubicle point
);
CREATE FUNCTION double_salary(emp) RETURNS numeric AS $$
SELECT $1.salary * 2 AS salary;
$$ LANGUAGE SQL;
SELECT name, double_salary(emp.*) AS dream
FROM emp
WHERE emp.cubicle ~= point '(2,1)';
name | dream
------+-------
Bill | 8400</pre>
<p>
</p>
<p> Notice the use of the syntax <code class="literal">$1.salary</code>
to select one field of the argument row value. Also notice
how the calling <code class="command">SELECT</code> command uses <code class="literal">*</code>
to select
the entire current row of a table as a composite value. The table
row can alternatively be referenced using just the table name,
like this:
</p>
<pre class="screen">SELECT name, double_salary(emp) AS dream
FROM emp
WHERE emp.cubicle ~= point '(2,1)';</pre>
<p>
but this usage is deprecated since it's easy to get confused.
</p>
<p> Sometimes it is handy to construct a composite argument value
on-the-fly. This can be done with the <code class="literal">ROW</code> construct.
For example, we could adjust the data being passed to the function:
</p>
<pre class="screen">SELECT name, double_salary(ROW(name, salary*1.1, age, cubicle)) AS dream
FROM emp;</pre>
<p>
</p>
<p> It is also possible to build a function that returns a composite type.
This is an example of a function
that returns a single <code class="type">emp</code> row:
</p>
<pre class="programlisting">CREATE FUNCTION new_emp() RETURNS emp AS $$
SELECT text 'None' AS name,
1000.0 AS salary,
25 AS age,
point '(2,2)' AS cubicle;
$$ LANGUAGE SQL;</pre>
<p>
In this example we have specified each of the attributes
with a constant value, but any computation
could have been substituted for these constants.
</p>
<p> Note two important things about defining the function:
</p>
<div class="itemizedlist"><ul type="disc">
<li><p> The select list order in the query must be exactly the same as
that in which the columns appear in the table associated
with the composite type. (Naming the columns, as we did above,
is irrelevant to the system.)
</p></li>
<li>
<p> You must typecast the expressions to match the
definition of the composite type, or you will get errors like this:
</p>
<pre class="screen"><code class="computeroutput">ERROR: function declared to return emp returns varchar instead of text at column 1</code></pre>
<p>
</p>
</li>
</ul></div>
<p>
</p>
<p> A different way to define the same function is:
</p>
<pre class="programlisting">CREATE FUNCTION new_emp() RETURNS emp AS $$
SELECT ROW('None', 1000.0, 25, '(2,2)')::emp;
$$ LANGUAGE SQL;</pre>
<p>
Here we wrote a <code class="command">SELECT</code> that returns just a single
column of the correct composite type. This isn't really better
in this situation, but it is a handy alternative in some cases
[mdash ] for example, if we need to compute the result by calling
another function that returns the desired composite value.
</p>
<p> We could call this function directly in either of two ways:
</p>
<pre class="screen">SELECT new_emp();
new_emp
--------------------------
(None,1000.0,25,"(2,2)")
SELECT * FROM new_emp();
name | salary | age | cubicle
------+--------+-----+---------
None | 1000.0 | 25 | (2,2)</pre>
<p>
The second way is described more fully in <a href="xfunc-sql.html#xfunc-sql-table-functions" title="32.4.4.SQL Functions as Table Sources">Section32.4.4, “<acronym class="acronym">SQL</acronym> Functions as Table Sources”</a>.
</p>
<p> When you use a function that returns a composite type,
you might want only one field (attribute) from its result.
You can do that with syntax like this:
</p>
<pre class="screen">SELECT (new_emp()).name;
name
------
None</pre>
<p>
The extra parentheses are needed to keep the parser from getting
confused. If you try to do it without them, you get something like this:
</p>
<pre class="screen">SELECT new_emp().name;
ERROR: syntax error at or near "." at character 17
LINE 1: SELECT new_emp().name;
^</pre>
<p>
</p>
<p> Another option is to use
functional notation for extracting an attribute. The simple way
to explain this is that we can use the
notations <code class="literal">attribute(table)</code> and <code class="literal">table.attribute</code>
interchangeably.
</p>
<pre class="screen">SELECT name(new_emp());
name
------
None</pre>
<p>
</p>
<pre class="screen">-- This is the same as:
-- SELECT emp.name AS youngster FROM emp WHERE emp.age < 30;
SELECT name(emp) AS youngster FROM emp WHERE age(emp) < 30;
youngster
-----------
Sam
Andy</pre>
<p>
</p>
<div class="tip" style="margin-left: 0.5in; margin-right: 0.5in;">
<h3 class="title">Tip</h3>
<p> The equivalence between functional notation and attribute notation
makes it possible to use functions on composite types to emulate
“<span class="quote">computed fields</span>”.
<a name="id704830"></a>
<a name="id704838"></a>
For example, using the previous definition
for <code class="literal">double_salary(emp)</code>, we can write
</p>
<pre class="screen">SELECT emp.name, emp.double_salary FROM emp;</pre>
<p>
An application using this wouldn't need to be directly aware that
<code class="literal">double_salary</code> isn't a real column of the table.
(You can also emulate computed fields with views.)
</p>
</div>
<p> Another way to use a function returning a composite type is to pass the
result to another function that accepts the correct row type as input:
</p>
<pre class="screen">CREATE FUNCTION getname(emp) RETURNS text AS $$
SELECT $1.name;
$$ LANGUAGE SQL;
SELECT getname(new_emp());
getname
---------
None
(1 row)</pre>
<p>
</p>
<p> Still another way to use a function that returns a composite type is to
call it as a table function, as described in <a href="xfunc-sql.html#xfunc-sql-table-functions" title="32.4.4.SQL Functions as Table Sources">Section32.4.4, “<acronym class="acronym">SQL</acronym> Functions as Table Sources”</a>.
</p>
</div>
<div class="sect2" lang="en">
<div class="titlepage"><div><div><h3 class="title">
<a name="xfunc-output-parameters"></a>32.4.3.Functions with Output Parameters</h3></div></div></div>
<a name="id704909"></a><p> An alternative way of describing a function's results is to define it
with <em class="firstterm">output parameters</em>, as in this example:
</p>
<pre class="screen">CREATE FUNCTION add_em (IN x int, IN y int, OUT sum int)
AS 'SELECT $1 + $2'
LANGUAGE SQL;
SELECT add_em(3,7);
add_em
--------
10
(1 row)</pre>
<p>
This is not essentially different from the version of <code class="literal">add_em</code>
shown in <a href="xfunc-sql.html#xfunc-sql-base-functions" title="32.4.1.SQL Functions on Base Types">Section32.4.1, “<acronym class="acronym">SQL</acronym> Functions on Base Types”</a>. The real value of
output parameters is that they provide a convenient way of defining
functions that return several columns. For example,
</p>
<pre class="screen">CREATE FUNCTION sum_n_product (x int, y int, OUT sum int, OUT product int)
AS 'SELECT $1 + $2, $1 * $2'
LANGUAGE SQL;
SELECT * FROM sum_n_product(11,42);
sum | product
-----+---------
53 | 462
(1 row)</pre>
<p>
What has essentially happened here is that we have created an anonymous
composite type for the result of the function. The above example has
the same end result as
</p>
<pre class="screen">CREATE TYPE sum_prod AS (sum int, product int);
CREATE FUNCTION sum_n_product (int, int) RETURNS sum_prod
AS 'SELECT $1 + $2, $1 * $2'
LANGUAGE SQL;</pre>
<p>
but not having to bother with the separate composite type definition
is often handy.
</p>
<p> Notice that output parameters are not included in the calling argument
list when invoking such a function from SQL. This is because
<span class="productname">PostgreSQL</span> considers only the input
parameters to define the function's calling signature. That means
also that only the input parameters matter when referencing the function
for purposes such as dropping it. We could drop the above function
with either of
</p>
<pre class="screen">DROP FUNCTION sum_n_product (x int, y int, OUT sum int, OUT product int);
DROP FUNCTION sum_n_product (int, int);</pre>
<p>
</p>
<p> Parameters can be marked as <code class="literal">IN</code> (the default),
<code class="literal">OUT</code>, or <code class="literal">INOUT</code>. An <code class="literal">INOUT</code>
parameter serves as both an input parameter (part of the calling
argument list) and an output parameter (part of the result record type).
</p>
</div>
<div class="sect2" lang="en">
<div class="titlepage"><div><div><h3 class="title">
<a name="xfunc-sql-table-functions"></a>32.4.4.<acronym class="acronym">SQL</acronym> Functions as Table Sources</h3></div></div></div>
<p> All SQL functions may be used in the <code class="literal">FROM</code> clause of a query,
but it is particularly useful for functions returning composite types.
If the function is defined to return a base type, the table function
produces a one-column table. If the function is defined to return
a composite type, the table function produces a column for each attribute
of the composite type.
</p>
<p> Here is an example:
</p>
<pre class="screen">CREATE TABLE foo (fooid int, foosubid int, fooname text);
INSERT INTO foo VALUES (1, 1, 'Joe');
INSERT INTO foo VALUES (1, 2, 'Ed');
INSERT INTO foo VALUES (2, 1, 'Mary');
CREATE FUNCTION getfoo(int) RETURNS foo AS $$
SELECT * FROM foo WHERE fooid = $1;
$$ LANGUAGE SQL;
SELECT *, upper(fooname) FROM getfoo(1) AS t1;
fooid | foosubid | fooname | upper
-------+----------+---------+-------
1 | 1 | Joe | JOE
(1 row)</pre>
<p>
As the example shows, we can work with the columns of the function's
result just the same as if they were columns of a regular table.
</p>
<p> Note that we only got one row out of the function. This is because
we did not use <code class="literal">SETOF</code>. That is described in the next section.
</p>
</div>
<div class="sect2" lang="en">
<div class="titlepage"><div><div><h3 class="title">
<a name="id705091"></a>32.4.5.<acronym class="acronym">SQL</acronym> Functions Returning Sets</h3></div></div></div>
<p> When an SQL function is declared as returning <code class="literal">SETOF
<em class="replaceable"><code>sometype</code></em></code>, the function's final
<code class="command">SELECT</code> query is executed to completion, and each row it
outputs is returned as an element of the result set.
</p>
<p> This feature is normally used when calling the function in the <code class="literal">FROM</code>
clause. In this case each row returned by the function becomes
a row of the table seen by the query. For example, assume that
table <code class="literal">foo</code> has the same contents as above, and we say:
</p>
<pre class="programlisting">CREATE FUNCTION getfoo(int) RETURNS SETOF foo AS $$
SELECT * FROM foo WHERE fooid = $1;
$$ LANGUAGE SQL;
SELECT * FROM getfoo(1) AS t1;</pre>
<p>
Then we would get:
</p>
<pre class="screen"> fooid | foosubid | fooname
-------+----------+---------
1 | 1 | Joe
1 | 2 | Ed
(2 rows)</pre>
<p>
</p>
<p> Currently, functions returning sets may also be called in the select list
of a query. For each row that the query
generates by itself, the function returning set is invoked, and an output
row is generated for each element of the function's result set. Note,
however, that this capability is deprecated and may be removed in future
releases. The following is an example function returning a set from the
select list:
</p>
<pre class="screen">CREATE FUNCTION listchildren(text) RETURNS SETOF text AS $$
SELECT name FROM nodes WHERE parent = $1
$$ LANGUAGE SQL;
SELECT * FROM nodes;
name | parent
-----------+--------
Top |
Child1 | Top
Child2 | Top
Child3 | Top
SubChild1 | Child1
SubChild2 | Child1
(6 rows)
SELECT listchildren('Top');
listchildren
--------------
Child1
Child2
Child3
(3 rows)
SELECT name, listchildren(name) FROM nodes;
name | listchildren
--------+--------------
Top | Child1
Top | Child2
Top | Child3
Child1 | SubChild1
Child1 | SubChild2
(5 rows)</pre>
<p>
In the last <code class="command">SELECT</code>,
notice that no output row appears for <code class="literal">Child2</code>, <code class="literal">Child3</code>, etc.
This happens because <code class="function">listchildren</code> returns an empty set
for those arguments, so no result rows are generated.
</p>
</div>
<div class="sect2" lang="en">
<div class="titlepage"><div><div><h3 class="title">
<a name="id705221"></a>32.4.6.Polymorphic <acronym class="acronym">SQL</acronym> Functions</h3></div></div></div>
<p> <acronym class="acronym">SQL</acronym> functions may be declared to accept and
return the polymorphic types <code class="type">anyelement</code> and
<code class="type">anyarray</code>. See <a href="extend-type-system.html#extend-types-polymorphic" title="32.2.5.Polymorphic Types">Section32.2.5, “Polymorphic Types”</a> for a more detailed
explanation of polymorphic functions. Here is a polymorphic
function <code class="function">make_array</code> that builds up an array
from two arbitrary data type elements:
</p>
<pre class="screen">CREATE FUNCTION make_array(anyelement, anyelement) RETURNS anyarray AS $$
SELECT ARRAY[$1, $2];
$$ LANGUAGE SQL;
SELECT make_array(1, 2) AS intarray, make_array('a'::text, 'b') AS textarray;
intarray | textarray
----------+-----------
{1,2} | {a,b}
(1 row)</pre>
<p>
</p>
<p> Notice the use of the typecast <code class="literal">'a'::text</code>
to specify that the argument is of type <code class="type">text</code>. This is
required if the argument is just a string literal, since otherwise
it would be treated as type
<code class="type">unknown</code>, and array of <code class="type">unknown</code> is not a valid
type.
Without the typecast, you will get errors like this:
</p>
<pre class="screen"><code class="computeroutput">ERROR: could not determine "anyarray"/"anyelement" type because input has type "unknown"</code></pre>
<p>
</p>
<p> It is permitted to have polymorphic arguments with a fixed
return type, but the converse is not. For example:
</p>
<pre class="screen">CREATE FUNCTION is_greater(anyelement, anyelement) RETURNS boolean AS $$
SELECT $1 > $2;
$$ LANGUAGE SQL;
SELECT is_greater(1, 2);
is_greater
------------
f
(1 row)
CREATE FUNCTION invalid_func() RETURNS anyelement AS $$
SELECT 1;
$$ LANGUAGE SQL;
ERROR: cannot determine result data type
DETAIL: A function returning "anyarray" or "anyelement" must have at least one argument of either type.</pre>
<p>
</p>
<p> Polymorphism can be used with functions that have output arguments.
For example:
</p>
<pre class="screen">CREATE FUNCTION dup (f1 anyelement, OUT f2 anyelement, OUT f3 anyarray)
AS 'select $1, array[$1,$1]' LANGUAGE sql;
SELECT * FROM dup(22);
f2 | f3
----+---------
22 | {22,22}
(1 row)</pre>
<p>
</p>
</div>
</div></body>
</html>
|