784 lines
29 KiB
Plaintext
784 lines
29 KiB
Plaintext
<!--
|
|
doc/src/sgml/ref/create_function.sgml
|
|
-->
|
|
|
|
<refentry id="SQL-CREATEFUNCTION">
|
|
<refmeta>
|
|
<refentrytitle>CREATE FUNCTION</refentrytitle>
|
|
<manvolnum>7</manvolnum>
|
|
<refmiscinfo>SQL - Language Statements</refmiscinfo>
|
|
</refmeta>
|
|
|
|
<refnamediv>
|
|
<refname>CREATE FUNCTION</refname>
|
|
<refpurpose>define a new function</refpurpose>
|
|
</refnamediv>
|
|
|
|
<indexterm zone="sql-createfunction">
|
|
<primary>CREATE FUNCTION</primary>
|
|
</indexterm>
|
|
|
|
<refsynopsisdiv>
|
|
<synopsis>
|
|
CREATE [ OR REPLACE ] FUNCTION
|
|
<replaceable class="parameter">name</replaceable> ( [ [ <replaceable class="parameter">argmode</replaceable> ] [ <replaceable class="parameter">argname</replaceable> ] <replaceable class="parameter">argtype</replaceable> [ { DEFAULT | = } <replaceable class="parameter">default_expr</replaceable> ] [, ...] ] )
|
|
[ RETURNS <replaceable class="parameter">rettype</replaceable>
|
|
| RETURNS TABLE ( <replaceable class="parameter">column_name</replaceable> <replaceable class="parameter">column_type</replaceable> [, ...] ) ]
|
|
{ LANGUAGE <replaceable class="parameter">lang_name</replaceable>
|
|
| WINDOW
|
|
| IMMUTABLE | STABLE | VOLATILE | [ NOT ] LEAKPROOF
|
|
| CALLED ON NULL INPUT | RETURNS NULL ON NULL INPUT | STRICT
|
|
| [ EXTERNAL ] SECURITY INVOKER | [ EXTERNAL ] SECURITY DEFINER
|
|
| COST <replaceable class="parameter">execution_cost</replaceable>
|
|
| ROWS <replaceable class="parameter">result_rows</replaceable>
|
|
| SET <replaceable class="parameter">configuration_parameter</replaceable> { TO <replaceable class="parameter">value</replaceable> | = <replaceable class="parameter">value</replaceable> | FROM CURRENT }
|
|
| AS '<replaceable class="parameter">definition</replaceable>'
|
|
| AS '<replaceable class="parameter">obj_file</replaceable>', '<replaceable class="parameter">link_symbol</replaceable>'
|
|
} ...
|
|
[ WITH ( <replaceable class="parameter">attribute</replaceable> [, ...] ) ]
|
|
</synopsis>
|
|
</refsynopsisdiv>
|
|
|
|
<refsect1 id="sql-createfunction-description">
|
|
<title>Description</title>
|
|
|
|
<para>
|
|
<command>CREATE FUNCTION</command> defines a new function.
|
|
<command>CREATE OR REPLACE FUNCTION</command> will either create a
|
|
new function, or replace an existing definition.
|
|
To be able to define a function, the user must have the
|
|
<literal>USAGE</literal> privilege on the language.
|
|
</para>
|
|
|
|
<para>
|
|
If a schema name is included, then the function is created in the
|
|
specified schema. Otherwise it is created in the current schema.
|
|
The name of the new function must not match any existing function
|
|
with the same input argument types in the same schema. However,
|
|
functions of different argument types can share a name (this is
|
|
called <firstterm>overloading</>).
|
|
</para>
|
|
|
|
<para>
|
|
To replace the current definition of an existing function, use
|
|
<command>CREATE OR REPLACE FUNCTION</command>. It is not possible
|
|
to change the name or argument types of a function this way (if you
|
|
tried, you would actually be creating a new, distinct function).
|
|
Also, <command>CREATE OR REPLACE FUNCTION</command> will not let
|
|
you change the return type of an existing function. To do that,
|
|
you must drop and recreate the function. (When using <literal>OUT</>
|
|
parameters, that means you cannot change the types of any
|
|
<literal>OUT</> parameters except by dropping the function.)
|
|
</para>
|
|
|
|
<para>
|
|
When <command>CREATE OR REPLACE FUNCTION</> is used to replace an
|
|
existing function, the ownership and permissions of the function
|
|
do not change. All other function properties are assigned the
|
|
values specified or implied in the command. You must own the function
|
|
to replace it (this includes being a member of the owning role).
|
|
</para>
|
|
|
|
<para>
|
|
If you drop and then recreate a function, the new function is not
|
|
the same entity as the old; you will have to drop existing rules, views,
|
|
triggers, etc. that refer to the old function. Use
|
|
<command>CREATE OR REPLACE FUNCTION</command> to change a function
|
|
definition without breaking objects that refer to the function.
|
|
Also, <command>ALTER FUNCTION</> can be used to change most of the
|
|
auxiliary properties of an existing function.
|
|
</para>
|
|
|
|
<para>
|
|
The user that creates the function becomes the owner of the function.
|
|
</para>
|
|
|
|
<para>
|
|
To be able to create a function, you must have <literal>USAGE</literal>
|
|
privilege on the argument types and the return type.
|
|
</para>
|
|
</refsect1>
|
|
|
|
<refsect1>
|
|
<title>Parameters</title>
|
|
|
|
<variablelist>
|
|
|
|
<varlistentry>
|
|
<term><replaceable class="parameter">name</replaceable></term>
|
|
|
|
<listitem>
|
|
<para>
|
|
The name (optionally schema-qualified) of the function to create.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><replaceable class="parameter">argmode</replaceable></term>
|
|
|
|
<listitem>
|
|
<para>
|
|
The mode of an argument: <literal>IN</>, <literal>OUT</>,
|
|
<literal>INOUT</>, or <literal>VARIADIC</>.
|
|
If omitted, the default is <literal>IN</>.
|
|
Only <literal>OUT</> arguments can follow a <literal>VARIADIC</> one.
|
|
Also, <literal>OUT</> and <literal>INOUT</> arguments cannot be used
|
|
together with the <literal>RETURNS TABLE</> notation.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><replaceable class="parameter">argname</replaceable></term>
|
|
|
|
<listitem>
|
|
<para>
|
|
The name of an argument. Some languages (currently only PL/pgSQL) let
|
|
you use the name in the function body. For other languages the
|
|
name of an input argument is just extra documentation, so far as
|
|
the function itself is concerned; but you can use input argument names
|
|
when calling a function to improve readability (see <xref
|
|
linkend="sql-syntax-calling-funcs">). In any case, the name
|
|
of an output argument is significant, because it defines the column
|
|
name in the result row type. (If you omit the name for an output
|
|
argument, the system will choose a default column name.)
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><replaceable class="parameter">argtype</replaceable></term>
|
|
|
|
<listitem>
|
|
<para>
|
|
The data type(s) of the function's arguments (optionally
|
|
schema-qualified), if any. The argument types can be base, composite,
|
|
or domain types, or can reference the type of a table column.
|
|
</para>
|
|
<para>
|
|
Depending on the implementation language it might also be allowed
|
|
to specify <quote>pseudotypes</> such as <type>cstring</>.
|
|
Pseudotypes indicate that the actual argument type is either
|
|
incompletely specified, or outside the set of ordinary SQL data types.
|
|
</para>
|
|
<para>
|
|
The type of a column is referenced by writing
|
|
<literal><replaceable
|
|
class="parameter">table_name</replaceable>.<replaceable
|
|
class="parameter">column_name</replaceable>%TYPE</literal>.
|
|
Using this feature can sometimes help make a function independent of
|
|
changes to the definition of a table.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><replaceable class="parameter">default_expr</replaceable></term>
|
|
|
|
<listitem>
|
|
<para>
|
|
An expression to be used as default value if the parameter is
|
|
not specified. The expression has to be coercible to the
|
|
argument type of the parameter.
|
|
Only input (including <literal>INOUT</>) parameters can have a default
|
|
value. All input parameters following a
|
|
parameter with a default value must have default values as well.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><replaceable class="parameter">rettype</replaceable></term>
|
|
|
|
<listitem>
|
|
<para>
|
|
The return data type (optionally schema-qualified). The return type
|
|
can be a base, composite, or domain type,
|
|
or can reference the type of a table column.
|
|
Depending on the implementation language it might also be allowed
|
|
to specify <quote>pseudotypes</> such as <type>cstring</>.
|
|
If the function is not supposed to return a value, specify
|
|
<type>void</> as the return type.
|
|
</para>
|
|
<para>
|
|
When there are <literal>OUT</> or <literal>INOUT</> parameters,
|
|
the <literal>RETURNS</> clause can be omitted. If present, it
|
|
must agree with the result type implied by the output parameters:
|
|
<literal>RECORD</> if there are multiple output parameters, or
|
|
the same type as the single output parameter.
|
|
</para>
|
|
<para>
|
|
The <literal>SETOF</literal>
|
|
modifier indicates that the function will return a set of
|
|
items, rather than a single item.
|
|
</para>
|
|
<para>
|
|
The type of a column is referenced by writing
|
|
<literal><replaceable
|
|
class="parameter">table_name</replaceable>.<replaceable
|
|
class="parameter">column_name</replaceable>%TYPE</literal>.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><replaceable class="parameter">column_name</replaceable></term>
|
|
|
|
<listitem>
|
|
<para>
|
|
The name of an output column in the <literal>RETURNS TABLE</>
|
|
syntax. This is effectively another way of declaring a named
|
|
<literal>OUT</> parameter, except that <literal>RETURNS TABLE</>
|
|
also implies <literal>RETURNS SETOF</>.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><replaceable class="parameter">column_type</replaceable></term>
|
|
|
|
<listitem>
|
|
<para>
|
|
The data type of an output column in the <literal>RETURNS TABLE</>
|
|
syntax.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><replaceable class="parameter">lang_name</replaceable></term>
|
|
|
|
<listitem>
|
|
<para>
|
|
The name of the language that the function is implemented in.
|
|
Can be <literal>SQL</literal>, <literal>C</literal>,
|
|
<literal>internal</literal>, or the name of a user-defined
|
|
procedural language. For backward compatibility,
|
|
the name can be enclosed by single quotes.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><literal>WINDOW</literal></term>
|
|
|
|
<listitem>
|
|
<para><literal>WINDOW</literal> indicates that the function is a
|
|
<firstterm>window function</> rather than a plain function.
|
|
This is currently only useful for functions written in C.
|
|
The <literal>WINDOW</> attribute cannot be changed when
|
|
replacing an existing function definition.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><literal>IMMUTABLE</literal></term>
|
|
<term><literal>STABLE</literal></term>
|
|
<term><literal>VOLATILE</literal></term>
|
|
|
|
<listitem>
|
|
<para>
|
|
These attributes inform the query optimizer about the behavior
|
|
of the function. At most one choice
|
|
can be specified. If none of these appear,
|
|
<literal>VOLATILE</literal> is the default assumption.
|
|
</para>
|
|
|
|
<para><literal>IMMUTABLE</literal> indicates that the function
|
|
cannot modify the database and always
|
|
returns the same result when given the same argument values; that
|
|
is, it does not do database lookups or otherwise use information not
|
|
directly present in its argument list. If this option is given,
|
|
any call of the function with all-constant arguments can be
|
|
immediately replaced with the function value.
|
|
</para>
|
|
|
|
<para><literal>STABLE</literal> indicates that the function
|
|
cannot modify the database,
|
|
and that within a single table scan it will consistently
|
|
return the same result for the same argument values, but that its
|
|
result could change across SQL statements. This is the appropriate
|
|
selection for functions whose results depend on database lookups,
|
|
parameter variables (such as the current time zone), etc. (It is
|
|
inappropriate for <literal>AFTER</> triggers that wish to
|
|
query rows modified by the current command.) Also note
|
|
that the <function>current_timestamp</> family of functions qualify
|
|
as stable, since their values do not change within a transaction.
|
|
</para>
|
|
|
|
<para><literal>VOLATILE</literal> indicates that the function value can
|
|
change even within a single table scan, so no optimizations can be
|
|
made. Relatively few database functions are volatile in this sense;
|
|
some examples are <literal>random()</>, <literal>currval()</>,
|
|
<literal>timeofday()</>. But note that any function that has
|
|
side-effects must be classified volatile, even if its result is quite
|
|
predictable, to prevent calls from being optimized away; an example is
|
|
<literal>setval()</>.
|
|
</para>
|
|
|
|
<para>
|
|
For additional details see <xref linkend="xfunc-volatility">.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><literal>LEAKPROOF</literal></term>
|
|
<listitem>
|
|
<para>
|
|
<literal>LEAKPROOF</literal> indicates that the function has no side
|
|
effects. It reveals no information about its arguments other than by
|
|
its return value. For example, a function which throws an error message
|
|
for some argument values but not others, or which includes the argument
|
|
values in any error message, is not leakproof. The query planner may
|
|
push leakproof functions (but not others) into views created with the
|
|
<literal>security_barrier</literal> option. See
|
|
<xref linkend="sql-createview"> and <xref linkend="rules-privileges">.
|
|
This option can only be set by the superuser.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><literal>CALLED ON NULL INPUT</literal></term>
|
|
<term><literal>RETURNS NULL ON NULL INPUT</literal></term>
|
|
<term><literal>STRICT</literal></term>
|
|
|
|
<listitem>
|
|
<para><literal>CALLED ON NULL INPUT</literal> (the default) indicates
|
|
that the function will be called normally when some of its
|
|
arguments are null. It is then the function author's
|
|
responsibility to check for null values if necessary and respond
|
|
appropriately.
|
|
</para>
|
|
|
|
<para><literal>RETURNS NULL ON NULL INPUT</literal> or
|
|
<literal>STRICT</literal> indicates that the function always
|
|
returns null whenever any of its arguments are null. If this
|
|
parameter is specified, the function is not executed when there
|
|
are null arguments; instead a null result is assumed
|
|
automatically.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><literal><optional>EXTERNAL</optional> SECURITY INVOKER</literal></term>
|
|
<term><literal><optional>EXTERNAL</optional> SECURITY DEFINER</literal></term>
|
|
|
|
<listitem>
|
|
<para><literal>SECURITY INVOKER</literal> indicates that the function
|
|
is to be executed with the privileges of the user that calls it.
|
|
That is the default. <literal>SECURITY DEFINER</literal>
|
|
specifies that the function is to be executed with the
|
|
privileges of the user that created it.
|
|
</para>
|
|
|
|
<para>
|
|
The key word <literal>EXTERNAL</literal> is allowed for SQL
|
|
conformance, but it is optional since, unlike in SQL, this feature
|
|
applies to all functions not only external ones.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><replaceable class="parameter">execution_cost</replaceable></term>
|
|
|
|
<listitem>
|
|
<para>
|
|
A positive number giving the estimated execution cost for the function,
|
|
in units of <xref linkend="guc-cpu-operator-cost">. If the function
|
|
returns a set, this is the cost per returned row. If the cost is
|
|
not specified, 1 unit is assumed for C-language and internal functions,
|
|
and 100 units for functions in all other languages. Larger values
|
|
cause the planner to try to avoid evaluating the function more often
|
|
than necessary.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><replaceable class="parameter">result_rows</replaceable></term>
|
|
|
|
<listitem>
|
|
<para>
|
|
A positive number giving the estimated number of rows that the planner
|
|
should expect the function to return. This is only allowed when the
|
|
function is declared to return a set. The default assumption is
|
|
1000 rows.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><replaceable>configuration_parameter</replaceable></term>
|
|
<term><replaceable>value</replaceable></term>
|
|
<listitem>
|
|
<para>
|
|
The <literal>SET</> clause causes the specified configuration
|
|
parameter to be set to the specified value when the function is
|
|
entered, and then restored to its prior value when the function exits.
|
|
<literal>SET FROM CURRENT</> saves the session's current value of
|
|
the parameter as the value to be applied when the function is entered.
|
|
</para>
|
|
|
|
<para>
|
|
If a <literal>SET</> clause is attached to a function, then
|
|
the effects of a <command>SET LOCAL</> command executed inside the
|
|
function for the same variable are restricted to the function: the
|
|
configuration parameter's prior value is still restored at function exit.
|
|
However, an ordinary
|
|
<command>SET</> command (without <literal>LOCAL</>) overrides the
|
|
<literal>SET</> clause, much as it would do for a previous <command>SET
|
|
LOCAL</> command: the effects of such a command will persist after
|
|
function exit, unless the current transaction is rolled back.
|
|
</para>
|
|
|
|
<para>
|
|
See <xref linkend="sql-set"> and
|
|
<xref linkend="runtime-config">
|
|
for more information about allowed parameter names and values.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><replaceable class="parameter">definition</replaceable></term>
|
|
|
|
<listitem>
|
|
<para>
|
|
A string constant defining the function; the meaning depends on the
|
|
language. It can be an internal function name, the path to an
|
|
object file, an SQL command, or text in a procedural language.
|
|
</para>
|
|
|
|
<para>
|
|
It is often helpful to use dollar quoting (see <xref
|
|
linkend="sql-syntax-dollar-quoting">) to write the function definition
|
|
string, rather than the normal single quote syntax. Without dollar
|
|
quoting, any single quotes or backslashes in the function definition must
|
|
be escaped by doubling them.
|
|
</para>
|
|
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><literal><replaceable class="parameter">obj_file</replaceable>, <replaceable class="parameter">link_symbol</replaceable></literal></term>
|
|
|
|
<listitem>
|
|
<para>
|
|
This form of the <literal>AS</literal> clause is used for
|
|
dynamically loadable C language functions when the function name
|
|
in the C language source code is not the same as the name of
|
|
the SQL function. The string <replaceable
|
|
class="parameter">obj_file</replaceable> is the name of the
|
|
file containing the dynamically loadable object, and
|
|
<replaceable class="parameter">link_symbol</replaceable> is the
|
|
function's link symbol, that is, the name of the function in the C
|
|
language source code. If the link symbol is omitted, it is assumed
|
|
to be the same as the name of the SQL function being defined.
|
|
</para>
|
|
|
|
<para>
|
|
When repeated <command>CREATE FUNCTION</command> calls refer to
|
|
the same object file, the file is only loaded once per session.
|
|
To unload and
|
|
reload the file (perhaps during development), start a new session.
|
|
</para>
|
|
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><replaceable class="parameter">attribute</replaceable></term>
|
|
|
|
<listitem>
|
|
<para>
|
|
The historical way to specify optional pieces of information
|
|
about the function. The following attributes can appear here:
|
|
|
|
<variablelist>
|
|
<varlistentry>
|
|
<term><literal>isStrict</></term>
|
|
<listitem>
|
|
<para>
|
|
Equivalent to <literal>STRICT</literal> or <literal>RETURNS NULL ON NULL INPUT</literal>.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><literal>isCachable</></term>
|
|
<listitem>
|
|
<para><literal>isCachable</literal> is an obsolete equivalent of
|
|
<literal>IMMUTABLE</literal>; it's still accepted for
|
|
backwards-compatibility reasons.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
</variablelist>
|
|
|
|
Attribute names are not case-sensitive.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
</variablelist>
|
|
|
|
<para>
|
|
Refer to <xref linkend="xfunc"> for further information on writing
|
|
functions.
|
|
</para>
|
|
|
|
</refsect1>
|
|
|
|
<refsect1 id="sql-createfunction-overloading">
|
|
<title>Overloading</title>
|
|
|
|
<para>
|
|
<productname>PostgreSQL</productname> allows function
|
|
<firstterm>overloading</firstterm>; that is, the same name can be
|
|
used for several different functions so long as they have distinct
|
|
input argument types. However, the C names of all functions must be
|
|
different, so you must give overloaded C functions different C
|
|
names (for example, use the argument types as part of the C
|
|
names).
|
|
</para>
|
|
|
|
<para>
|
|
Two functions are considered the same if they have the same names and
|
|
<emphasis>input</> argument types, ignoring any <literal>OUT</>
|
|
parameters. Thus for example these declarations conflict:
|
|
<programlisting>
|
|
CREATE FUNCTION foo(int) ...
|
|
CREATE FUNCTION foo(int, out text) ...
|
|
</programlisting>
|
|
</para>
|
|
|
|
<para>
|
|
Functions that have different argument type lists will not be considered
|
|
to conflict at creation time, but if defaults are provided they might
|
|
conflict in use. For example, consider
|
|
<programlisting>
|
|
CREATE FUNCTION foo(int) ...
|
|
CREATE FUNCTION foo(int, int default 42) ...
|
|
</programlisting>
|
|
A call <literal>foo(10)</> will fail due to the ambiguity about which
|
|
function should be called.
|
|
</para>
|
|
|
|
</refsect1>
|
|
|
|
<refsect1 id="sql-createfunction-notes">
|
|
<title>Notes</title>
|
|
|
|
<para>
|
|
The full <acronym>SQL</acronym> type syntax is allowed for
|
|
input arguments and return value. However, some details of the
|
|
type specification (e.g., the precision field for
|
|
type <type>numeric</type>) are the responsibility of the
|
|
underlying function implementation and are silently swallowed
|
|
(i.e., not recognized or
|
|
enforced) by the <command>CREATE FUNCTION</command> command.
|
|
</para>
|
|
|
|
<para>
|
|
When replacing an existing function with <command>CREATE OR REPLACE
|
|
FUNCTION</>, there are restrictions on changing parameter names.
|
|
You cannot change the name already assigned to any input parameter
|
|
(although you can add names to parameters that had none before).
|
|
If there is more than one output parameter, you cannot change the
|
|
names of the output parameters, because that would change the
|
|
column names of the anonymous composite type that describes the
|
|
function's result. These restrictions are made to ensure that
|
|
existing calls of the function do not stop working when it is replaced.
|
|
</para>
|
|
|
|
<para>
|
|
If a function is declared <literal>STRICT</> with a <literal>VARIADIC</>
|
|
argument, the strictness check tests that the variadic array <emphasis>as
|
|
a whole</> is non-null. The function will still be called if the
|
|
array has null elements.
|
|
</para>
|
|
|
|
</refsect1>
|
|
|
|
<refsect1 id="sql-createfunction-examples">
|
|
<title>Examples</title>
|
|
|
|
<para>
|
|
Here are some trivial examples to help you get started. For more
|
|
information and examples, see <xref linkend="xfunc">.
|
|
<programlisting>
|
|
CREATE FUNCTION add(integer, integer) RETURNS integer
|
|
AS 'select $1 + $2;'
|
|
LANGUAGE SQL
|
|
IMMUTABLE
|
|
RETURNS NULL ON NULL INPUT;
|
|
</programlisting>
|
|
</para>
|
|
|
|
<para>
|
|
Increment an integer, making use of an argument name, in
|
|
<application>PL/pgSQL</application>:
|
|
<programlisting>
|
|
CREATE OR REPLACE FUNCTION increment(i integer) RETURNS integer AS $$
|
|
BEGIN
|
|
RETURN i + 1;
|
|
END;
|
|
$$ LANGUAGE plpgsql;
|
|
</programlisting>
|
|
</para>
|
|
|
|
<para>
|
|
Return a record containing multiple output parameters:
|
|
<programlisting>
|
|
CREATE FUNCTION dup(in int, out f1 int, out f2 text)
|
|
AS $$ SELECT $1, CAST($1 AS text) || ' is text' $$
|
|
LANGUAGE SQL;
|
|
|
|
SELECT * FROM dup(42);
|
|
</programlisting>
|
|
You can do the same thing more verbosely with an explicitly named
|
|
composite type:
|
|
<programlisting>
|
|
CREATE TYPE dup_result AS (f1 int, f2 text);
|
|
|
|
CREATE FUNCTION dup(int) RETURNS dup_result
|
|
AS $$ SELECT $1, CAST($1 AS text) || ' is text' $$
|
|
LANGUAGE SQL;
|
|
|
|
SELECT * FROM dup(42);
|
|
</programlisting>
|
|
Another way to return multiple columns is to use a <literal>TABLE</>
|
|
function:
|
|
<programlisting>
|
|
CREATE FUNCTION dup(int) RETURNS TABLE(f1 int, f2 text)
|
|
AS $$ SELECT $1, CAST($1 AS text) || ' is text' $$
|
|
LANGUAGE SQL;
|
|
|
|
SELECT * FROM dup(42);
|
|
</programlisting>
|
|
However, a <literal>TABLE</> function is different from the
|
|
preceding examples, because it actually returns a <emphasis>set</>
|
|
of records, not just one record.
|
|
</para>
|
|
</refsect1>
|
|
|
|
<refsect1 id="sql-createfunction-security">
|
|
<title>Writing <literal>SECURITY DEFINER</literal> Functions Safely</title>
|
|
|
|
<indexterm>
|
|
<primary><varname>search_path</varname> configuration parameter</>
|
|
<secondary>use in securing functions</>
|
|
</indexterm>
|
|
|
|
<para>
|
|
Because a <literal>SECURITY DEFINER</literal> function is executed
|
|
with the privileges of the user that created it, care is needed to
|
|
ensure that the function cannot be misused. For security,
|
|
<xref linkend="guc-search-path"> should be set to exclude any schemas
|
|
writable by untrusted users. This prevents
|
|
malicious users from creating objects that mask objects used by the
|
|
function. Particularly important in this regard is the
|
|
temporary-table schema, which is searched first by default, and
|
|
is normally writable by anyone. A secure arrangement can be had
|
|
by forcing the temporary schema to be searched last. To do this,
|
|
write <literal>pg_temp</><indexterm><primary>pg_temp</><secondary>securing functions</></> as the last entry in <varname>search_path</>.
|
|
This function illustrates safe usage:
|
|
</para>
|
|
|
|
<programlisting>
|
|
CREATE FUNCTION check_password(uname TEXT, pass TEXT)
|
|
RETURNS BOOLEAN AS $$
|
|
DECLARE passed BOOLEAN;
|
|
BEGIN
|
|
SELECT (pwd = $2) INTO passed
|
|
FROM pwds
|
|
WHERE username = $1;
|
|
|
|
RETURN passed;
|
|
END;
|
|
$$ LANGUAGE plpgsql
|
|
SECURITY DEFINER
|
|
-- Set a secure search_path: trusted schema(s), then 'pg_temp'.
|
|
SET search_path = admin, pg_temp;
|
|
</programlisting>
|
|
|
|
<para>
|
|
Before <productname>PostgreSQL</productname> version 8.3, the
|
|
<literal>SET</> option was not available, and so older functions may
|
|
contain rather complicated logic to save, set, and restore
|
|
<varname>search_path</>. The <literal>SET</> option is far easier
|
|
to use for this purpose.
|
|
</para>
|
|
|
|
<para>
|
|
Another point to keep in mind is that by default, execute privilege
|
|
is granted to <literal>PUBLIC</> for newly created functions
|
|
(see <xref linkend="sql-grant"> for more
|
|
information). Frequently you will wish to restrict use of a security
|
|
definer function to only some users. To do that, you must revoke
|
|
the default <literal>PUBLIC</> privileges and then grant execute
|
|
privilege selectively. To avoid having a window where the new function
|
|
is accessible to all, create it and set the privileges within a single
|
|
transaction. For example:
|
|
</para>
|
|
|
|
<programlisting>
|
|
BEGIN;
|
|
CREATE FUNCTION check_password(uname TEXT, pass TEXT) ... SECURITY DEFINER;
|
|
REVOKE ALL ON FUNCTION check_password(uname TEXT, pass TEXT) FROM PUBLIC;
|
|
GRANT EXECUTE ON FUNCTION check_password(uname TEXT, pass TEXT) TO admins;
|
|
COMMIT;
|
|
</programlisting>
|
|
|
|
</refsect1>
|
|
|
|
<refsect1 id="sql-createfunction-compat">
|
|
<title>Compatibility</title>
|
|
|
|
<para>
|
|
A <command>CREATE FUNCTION</command> command is defined in SQL:1999 and later.
|
|
The <productname>PostgreSQL</productname> version is similar but
|
|
not fully compatible. The attributes are not portable, neither are the
|
|
different available languages.
|
|
</para>
|
|
|
|
<para>
|
|
For compatibility with some other database systems,
|
|
<replaceable class="parameter">argmode</replaceable> can be written
|
|
either before or after <replaceable class="parameter">argname</replaceable>.
|
|
But only the first way is standard-compliant.
|
|
</para>
|
|
|
|
<para>
|
|
The SQL standard does not specify parameter defaults. The syntax
|
|
with the <literal>DEFAULT</literal> key word is from Oracle, and it
|
|
is somewhat in the spirit of the standard: SQL/PSM uses it for
|
|
variable default values. The syntax with <literal>=</literal> is
|
|
used in T-SQL and Firebird.
|
|
</para>
|
|
</refsect1>
|
|
|
|
|
|
<refsect1>
|
|
<title>See Also</title>
|
|
|
|
<simplelist type="inline">
|
|
<member><xref linkend="sql-alterfunction"></member>
|
|
<member><xref linkend="sql-dropfunction"></member>
|
|
<member><xref linkend="sql-grant"></member>
|
|
<member><xref linkend="sql-load"></member>
|
|
<member><xref linkend="sql-revoke"></member>
|
|
<member><xref linkend="app-createlang"></member>
|
|
</simplelist>
|
|
</refsect1>
|
|
|
|
</refentry>
|