mirror of
https://github.com/postgres/postgres.git
synced 2025-05-05 09:19:17 +03:00
362 lines
11 KiB
Plaintext
362 lines
11 KiB
Plaintext
<!--
|
|
$Header: /cvsroot/pgsql/doc/src/sgml/ref/create_function.sgml,v 1.23 2001/05/19 09:01:10 petere Exp $
|
|
-->
|
|
|
|
<refentry id="SQL-CREATEFUNCTION">
|
|
<refmeta>
|
|
<refentrytitle>CREATE FUNCTION</refentrytitle>
|
|
<refmiscinfo>SQL - Language Statements</refmiscinfo>
|
|
</refmeta>
|
|
|
|
<refnamediv>
|
|
<refname>CREATE FUNCTION</refname>
|
|
<refpurpose>Defines a new function</refpurpose>
|
|
</refnamediv>
|
|
|
|
<refsynopsisdiv>
|
|
<synopsis>
|
|
CREATE FUNCTION <replaceable class="parameter">name</replaceable> ( [ <replaceable class="parameter">argtype</replaceable> [, ...] ] )
|
|
RETURNS <replaceable class="parameter">rettype</replaceable>
|
|
AS '<replaceable class="parameter">definition</replaceable>'
|
|
LANGUAGE '<replaceable class="parameter">langname</replaceable>'
|
|
[ WITH ( <replaceable class="parameter">attribute</replaceable> [, ...] ) ]
|
|
CREATE FUNCTION <replaceable class="parameter">name</replaceable> ( [ <replaceable class="parameter">argtype</replaceable> [, ...] ] )
|
|
RETURNS <replaceable class="parameter">rettype</replaceable>
|
|
AS '<replaceable class="parameter">obj_file</replaceable>', '<replaceable class="parameter">link_symbol</replaceable>'
|
|
LANGUAGE '<replaceable class="parameter">langname</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.
|
|
|
|
<variablelist>
|
|
<title>Parameters</title>
|
|
|
|
<varlistentry>
|
|
<term><replaceable class="parameter">name</replaceable></term>
|
|
|
|
<listitem>
|
|
<para>
|
|
The name of a function to create. The name need not be unique,
|
|
because functions may be overloaded, but functions with the
|
|
same name must have different argument types.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><replaceable class="parameter">argtype</replaceable></term>
|
|
|
|
<listitem>
|
|
<para>
|
|
The data type(s) of the function's arguments, if any. The
|
|
input types may be base or complex types, or
|
|
<literal>opaque</literal>. <literal>Opaque</literal> indicates
|
|
that the function accepts arguments of a non-SQL type such as
|
|
<type>char *</type>.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><replaceable class="parameter">rettype</replaceable></term>
|
|
|
|
<listitem>
|
|
<para>
|
|
The return data type. The output type may be specified as a
|
|
base type, complex type, <literal>setof</literal> type, or
|
|
<literal>opaque</literal>. The <literal>setof</literal>
|
|
modifier indicates that the function will return a set of
|
|
items, rather than a single item. Functions with a declared
|
|
return type of <literal>opaque</literal> do not return a value.
|
|
These cannot be called directly; trigger functions make use of
|
|
this feature.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><replaceable class="parameter">definition</replaceable></term>
|
|
|
|
<listitem>
|
|
<para>
|
|
A string defining the function; the meaning depends on the
|
|
language. It may be an internal function name, the path to an
|
|
object file, an SQL query, or text in a procedural language.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><replaceable class="parameter">obj_file</replaceable>, <replaceable class="parameter">link_symbol</replaceable></term>
|
|
|
|
<listitem>
|
|
<para>
|
|
This form of the <literal>AS</literal> clause is used for
|
|
dynamically linked 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
|
|
object's link symbol, that is, the name of the function in the C
|
|
language source code.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><replaceable class="parameter">langname</replaceable></term>
|
|
|
|
<listitem>
|
|
<para>
|
|
May be '<literal>sql</literal>', '<literal>C</literal>',
|
|
'<literal>internal</literal>', or '<replaceable
|
|
class="parameter">plname</replaceable>', where '<replaceable
|
|
class="parameter">plname</replaceable>' is the name of a
|
|
created procedural language. See
|
|
<xref linkend="sql-createlanguage">
|
|
for details.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><replaceable class="parameter">attribute</replaceable></term>
|
|
|
|
<listitem>
|
|
<para>
|
|
An optional piece of information about the function, used for
|
|
optimization. See below for details.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
</variablelist>
|
|
</para>
|
|
|
|
<para>
|
|
The user that creates the function becomes the owner of the function.
|
|
</para>
|
|
|
|
<para>
|
|
The following attributes may appear in the WITH clause:
|
|
|
|
<variablelist>
|
|
<varlistentry>
|
|
<term>iscachable</term>
|
|
<listitem>
|
|
<para>
|
|
<option>Iscachable</option> indicates that the function always
|
|
returns the same result when given the same argument values (i.e.,
|
|
it does not do database lookups or otherwise use information not
|
|
directly present in its parameter list). The optimizer uses
|
|
<option>iscachable</option> to know whether it is safe to
|
|
pre-evaluate a call of the function.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term>isstrict</term>
|
|
<listitem>
|
|
<para>
|
|
<option>isstrict</option> indicates that the function always
|
|
returns NULL whenever any of its arguments are NULL. If this
|
|
attribute is specified, the function is not executed when there
|
|
are NULL arguments; instead a NULL result is assumed automatically.
|
|
When <option>isstrict</option> is not specified, the function will
|
|
be called for NULL inputs. It is then the function author's
|
|
responsibility to check for NULLs if necessary and respond
|
|
appropriately.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
</variablelist>
|
|
</para>
|
|
|
|
</refsect1>
|
|
|
|
<refsect1 id="sql-createfunction-notes">
|
|
<title>Notes</title>
|
|
|
|
<para>
|
|
Refer to the chapter in the
|
|
<citetitle>PostgreSQL Programmer's Guide</citetitle>
|
|
on the topic of extending
|
|
<productname>Postgres</productname> via functions
|
|
for further information on writing external functions.
|
|
</para>
|
|
|
|
<para>
|
|
Use <command>DROP FUNCTION</command>
|
|
to remove user-defined functions.
|
|
</para>
|
|
|
|
<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>numeric</type> types) 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>
|
|
<productname>Postgres</productname> allows function <firstterm>overloading</firstterm>;
|
|
that is, the same name can be used for several different functions
|
|
so long as they have distinct argument types. This facility must
|
|
be used with caution for internal and C-language functions, however.
|
|
</para>
|
|
|
|
<para>
|
|
Two <literal>internal</literal>
|
|
functions cannot have the same C name without causing
|
|
errors at link time. To get around that, give them different C names
|
|
(for example, use the argument types as part of the C names), then
|
|
specify those names in the AS clause of <command>CREATE FUNCTION</command>.
|
|
If the AS clause is left empty, then <command>CREATE FUNCTION</command>
|
|
assumes the C name of the function is the same as the SQL name.
|
|
</para>
|
|
|
|
<para>
|
|
Similarly, when overloading SQL function names with multiple C-language
|
|
functions, give
|
|
each C-language instance of the function a distinct name, then use
|
|
the alternative form of the <command>AS</command> clause in the
|
|
<command>CREATE FUNCTION</command> syntax to select the appropriate
|
|
C-language implementation of each overloaded SQL function.
|
|
</para>
|
|
|
|
<para>
|
|
When repeated <command>CREATE FUNCTION</command> calls refer to
|
|
the same object file, the file is only loaded once. To unload and
|
|
reload the file (perhaps during development), use the <xref
|
|
linkend="sql-load"> command.
|
|
</para>
|
|
|
|
</refsect1>
|
|
|
|
|
|
<refsect1 id="sql-createfunction-examples">
|
|
<title>Examples</title>
|
|
|
|
<para>
|
|
To create a simple SQL function:
|
|
|
|
<programlisting>
|
|
CREATE FUNCTION one() RETURNS integer
|
|
AS 'SELECT 1 AS RESULT;'
|
|
LANGUAGE 'sql';
|
|
|
|
SELECT one() AS answer;
|
|
<computeroutput>
|
|
answer
|
|
--------
|
|
1
|
|
</computeroutput>
|
|
</programlisting>
|
|
</para>
|
|
|
|
<para>
|
|
The next example creates a C function by calling a routine from a
|
|
user-created shared library. This particular routine calculates a
|
|
check digit and returns TRUE if the check digit in the function
|
|
parameters is correct. It is intended for use in a CHECK
|
|
constraint.
|
|
|
|
<programlisting>
|
|
CREATE FUNCTION ean_checkdigit(char, char) RETURNS boolean
|
|
AS '/usr1/proj/bray/sql/funcs.so' LANGUAGE 'c';
|
|
|
|
CREATE TABLE product (
|
|
id char(8) PRIMARY KEY,
|
|
eanprefix char(8) CHECK (eanprefix ~ '[0-9]{2}-[0-9]{5}')
|
|
REFERENCES brandname(ean_prefix),
|
|
eancode char(6) CHECK (eancode ~ '[0-9]{6}'),
|
|
CONSTRAINT ean CHECK (ean_checkdigit(eanprefix, eancode))
|
|
);
|
|
</programlisting>
|
|
</para>
|
|
|
|
<para>
|
|
This example creates a function that does type conversion between the
|
|
user-defined type complex, and the internal type point. The
|
|
function is implemented by a dynamically loaded object that was
|
|
compiled from C source. For <productname>PostgreSQL</productname> to
|
|
find a type conversion function automatically, the SQL function has
|
|
to have the same name as the return type, and so overloading is
|
|
unavoidable. The function name is overloaded by using the second
|
|
form of the <command>AS</command> clause in the SQL definition:
|
|
|
|
<programlisting>
|
|
CREATE FUNCTION point(complex) RETURNS point
|
|
AS '/home/bernie/pgsql/lib/complex.so', 'complex_to_point'
|
|
LANGUAGE 'c';
|
|
</programlisting>
|
|
|
|
The C declaration of the function could be:
|
|
|
|
<programlisting>
|
|
Point * complex_to_point (Complex *z)
|
|
{
|
|
Point *p;
|
|
|
|
p = (Point *) palloc(sizeof(Point));
|
|
p->x = z->x;
|
|
p->y = z->y;
|
|
|
|
return p;
|
|
}
|
|
</programlisting>
|
|
</para>
|
|
</refsect1>
|
|
|
|
|
|
<refsect1 id="sql-createfunction-compat">
|
|
<title>Compatibility</title>
|
|
|
|
<para>
|
|
A <command>CREATE FUNCTION</command> command is defined in SQL99.
|
|
The <application>PostgreSQL</application> version is similar but
|
|
not compatible. The attributes are not portable, neither are the
|
|
different available languages.
|
|
</para>
|
|
</refsect1>
|
|
|
|
|
|
<refsect1 id="sql-createfunction-seealso">
|
|
<title>See Also</title>
|
|
|
|
<para>
|
|
<xref linkend="sql-dropfunction">,
|
|
<xref linkend="sql-load">,
|
|
<citetitle>PostgreSQL Programmer's Guide</citetitle>
|
|
</para>
|
|
</refsect1>
|
|
|
|
</refentry>
|
|
|
|
<!-- Keep this comment at the end of the file
|
|
Local variables:
|
|
mode:sgml
|
|
sgml-omittag:nil
|
|
sgml-shorttag:t
|
|
sgml-minimize-attributes:nil
|
|
sgml-always-quote-attributes:t
|
|
sgml-indent-step:1
|
|
sgml-indent-data:t
|
|
sgml-parent-document:nil
|
|
sgml-default-dtd-file:"../reference.ced"
|
|
sgml-exposed-tags:nil
|
|
sgml-local-catalogs:("/usr/lib/sgml/catalog")
|
|
sgml-local-ecat-files:nil
|
|
End:
|
|
-->
|