<!-- $Header: /cvsroot/pgsql/doc/src/sgml/ref/create_function.sgml,v 1.16 2000/08/24 23:36:29 tgl Exp $ Postgres documentation --> <refentry id="SQL-CREATEFUNCTION"> <refmeta> <refentrytitle id="sql-createfunction-title"> CREATE FUNCTION </refentrytitle> <refmiscinfo>SQL - Language Statements</refmiscinfo> </refmeta> <refnamediv> <refname> CREATE FUNCTION </refname> <refpurpose> Defines a new function </refpurpose> </refnamediv> <refsynopsisdiv> <refsynopsisdivinfo> <date>2000-03-25</date> </refsynopsisdivinfo> <synopsis> CREATE FUNCTION <replaceable class="parameter">name</replaceable> ( [ <replaceable class="parameter">ftype</replaceable> [, ...] ] ) RETURNS <replaceable class="parameter">rtype</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">ftype</replaceable> [, ...] ] ) RETURNS <replaceable class="parameter">rtype</replaceable> AS <replaceable class="parameter">obj_file</replaceable> , <replaceable class="parameter">link_symbol</replaceable> LANGUAGE 'langname' [ WITH ( <replaceable class="parameter">attribute</replaceable> [, ...] ) ] </synopsis> <refsect2 id="R2-SQL-CREATEFUNCTION-1"> <refsect2info> <date>2000-03-25</date> </refsect2info> <title> Inputs </title> <para> <variablelist> <varlistentry> <term><replaceable class="parameter">name</replaceable></term> <listitem> <para> The name of a function to create. </para> </listitem> </varlistentry> <varlistentry> <term><replaceable class="parameter">ftype</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 <firstterm>opaque</firstterm>. <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">rtype</replaceable></term> <listitem> <para> The return data type. The output type may be specified as a base type, complex type, <literal>setof <replaceable class="parameter">type</replaceable></literal>, or <literal>opaque</literal>. The <literal>setof</literal> modifier indicates that the function will return a set of items, rather than a single item. </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> <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 <command>AS</command> 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>newC</literal>', '<literal>internal</literal>', '<literal>newinternal</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-title" endterm="sql-createlanguage-title"> for details. </para> </listitem> </varlistentry> </variablelist> </para> </refsect2> <refsect2 id="R2-SQL-CREATEFUNCTION-2"> <refsect2info> <date>2000-03-25</date> </refsect2info> <title> Outputs </title> <para> <variablelist> <varlistentry> <term><computeroutput> CREATE </computeroutput></term> <listitem> <para> This is returned if the command completes successfully. </para> </listitem> </varlistentry> </variablelist> </para> </refsect2> </refsynopsisdiv> <refsect1 id="R1-SQL-CREATEFUNCTION-1"> <refsect1info> <date>2000-03-25</date> </refsect1info> <title> Description </title> <para> <command>CREATE FUNCTION</command> allows a <productname>Postgres</productname> user to register a function with the database. Subsequently, this user is considered the owner of the function. </para> <refsect2 id="R2-SQL-CREATEFUNCTION-3"> <refsect2info> <date>2000-08-24</date> </refsect2info> <title> Function Attributes </title> <para> The following items may appear in the WITH clause: <variablelist> <varlistentry> <literal>iscachable</literal> <listitem> <para> <literal>iscachable</literal> 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 <literal>iscachable</literal> to know whether it is safe to pre-evaluate a call of the function. </para> </listitem> </varlistentry> <varlistentry> <literal>isstrict</literal> <listitem> <para> <literal>isstrict</literal> 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 <literal>isstrict</literal> 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> </refsect2> <refsect2 id="R2-SQL-CREATEFUNCTION-4"> <refsect2info> <date>2000-03-25</date> </refsect2info> <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>SQL92</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 "overloading"; 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> or <literal>newinternal</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> </refsect2> </refsect1> <refsect1 id="R1-SQL-CREATEFUNCTION-2"> <title> Usage </title> <para> To create a simple SQL function: <programlisting> CREATE FUNCTION one() RETURNS int4 AS 'SELECT 1 AS RESULT' LANGUAGE 'sql'; SELECT one() AS answer; <computeroutput> answer -------- 1 </computeroutput> </programlisting> </para> <para> This 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 contraint. </para> <programlisting> CREATE FUNCTION ean_checkdigit(bpchar, bpchar) RETURNS bool 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> 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>Postgres</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: </para> <programlisting> CREATE FUNCTION point(complex) RETURNS point AS '/home/bernie/pgsql/lib/complex.so', 'complex_to_point' LANGUAGE 'c'; </programlisting> <para> The C declaration of the function is: </para> <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> </refsect1> <refsect1 id="R1-SQL-CREATEFUNCTION-4"> <title> Compatibility </title> <refsect2 id="R2-SQL-CREATEFUNCTION-5"> <refsect2info> <date>2000-03-25</date> </refsect2info> <title> SQL92 </title> <para> <command>CREATE FUNCTION</command> is a <productname>Postgres</productname> language extension. </para> </refsect2> <refsect2 id="R2-SQL-CREATEFUNCTION-6"> <refsect2info> <date>2000-03-25</date> </refsect2info> <title> SQL/PSM </title> <para> <note> <para> PSM stands for Persistent Stored Modules. It is a procedural language and it was originally hoped that PSM would be ratified as an official standard by late 1996. As of mid-1998, this has not yet happened, but it is hoped that PSM will eventually become a standard. </para> </note> SQL/PSM <command>CREATE FUNCTION</command> has the following syntax: <synopsis> CREATE FUNCTION <replaceable class="parameter">name</replaceable> ( [ [ IN | OUT | INOUT ] <replaceable class="parameter">type</replaceable> [, ...] ] ) RETURNS <replaceable class="parameter">rtype</replaceable> LANGUAGE '<replaceable class="parameter">langname</replaceable>' ESPECIFIC <replaceable class="parameter">routine</replaceable> <replaceable class="parameter">SQL-statement</replaceable> </synopsis> </para> </refsect2> </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: -->