Commit 62651c01 authored by Tom Lane's avatar Tom Lane

Editorial work on xfunc chapter --- better explanations about SQL

functions handling composite types and sets, various minor cleanups.
parent b93939a6
<!-- <!--
$Header: /cvsroot/pgsql/doc/src/sgml/dfunc.sgml,v 1.14 2001/05/19 09:01:10 petere Exp $ $Header: /cvsroot/pgsql/doc/src/sgml/dfunc.sgml,v 1.15 2001/10/26 19:58:12 tgl Exp $
--> -->
<sect2 id="dfunc"> <sect2 id="dfunc">
...@@ -7,9 +7,9 @@ $Header: /cvsroot/pgsql/doc/src/sgml/dfunc.sgml,v 1.14 2001/05/19 09:01:10 peter ...@@ -7,9 +7,9 @@ $Header: /cvsroot/pgsql/doc/src/sgml/dfunc.sgml,v 1.14 2001/05/19 09:01:10 peter
<para> <para>
Before you are able to use your Before you are able to use your
<productname>PostgreSQL</productname> extension function written in <productname>PostgreSQL</productname> extension functions written in
C they need to be compiled and linked in a special way in order to C, they must be compiled and linked in a special way to produce a file
allow it to be dynamically loaded as needed by the server. To be that can be dynamically loaded by the server. To be
precise, a <firstterm>shared library</firstterm> needs to be created. precise, a <firstterm>shared library</firstterm> needs to be created.
</para> </para>
...@@ -31,7 +31,7 @@ $Header: /cvsroot/pgsql/doc/src/sgml/dfunc.sgml,v 1.14 2001/05/19 09:01:10 peter ...@@ -31,7 +31,7 @@ $Header: /cvsroot/pgsql/doc/src/sgml/dfunc.sgml,v 1.14 2001/05/19 09:01:10 peter
be created as <firstterm>position-independent code</firstterm> be created as <firstterm>position-independent code</firstterm>
(<acronym>PIC</acronym>), which conceptually means that they can be (<acronym>PIC</acronym>), which conceptually means that they can be
placed at an arbitrary location in memory when they are loaded by the placed at an arbitrary location in memory when they are loaded by the
executable. (Object files intended for executables are not compiled executable. (Object files intended for executables are usually not compiled
that way.) The command to link a shared library contains special that way.) The command to link a shared library contains special
flags to distinguish it from linking an executable. --- At least flags to distinguish it from linking an executable. --- At least
this is the theory. On some systems the practice is much uglier. this is the theory. On some systems the practice is much uglier.
...@@ -263,16 +263,14 @@ gcc -shared -o foo.so foo.o ...@@ -263,16 +263,14 @@ gcc -shared -o foo.so foo.o
The resulting shared library file can then be loaded into The resulting shared library file can then be loaded into
<productname>Postgres</productname>. When specifying the file name <productname>Postgres</productname>. When specifying the file name
to the <command>CREATE FUNCTION</command> command, one must give it to the <command>CREATE FUNCTION</command> command, one must give it
the name of the shared library file (ending in the name of the shared library file, not the intermediate object file.
<filename>.so</filename>) rather than the intermediate object file. Note that the system's standard shared-library extension (usually
<literal>.so</literal> or <literal>.sl</literal>) can be omitted from
<note> the <command>CREATE FUNCTION</command> command, and normally should
<para> be omitted for best portability.
Actually, <productname>Postgres</productname> does not care what </para>
you name the file as long as it is a shared library file.
</para>
</note>
<para>
Refer back to <xref linkend="xfunc-c-dynload"> about where the Refer back to <xref linkend="xfunc-c-dynload"> about where the
server expects to find the shared library files. server expects to find the shared library files.
</para> </para>
......
<!-- <!--
$Header: /cvsroot/pgsql/doc/src/sgml/ref/load.sgml,v 1.9 2001/09/03 12:57:50 petere Exp $ $Header: /cvsroot/pgsql/doc/src/sgml/ref/load.sgml,v 1.10 2001/10/26 19:58:12 tgl Exp $
--> -->
<refentry id="SQL-LOAD"> <refentry id="SQL-LOAD">
...@@ -10,7 +10,7 @@ $Header: /cvsroot/pgsql/doc/src/sgml/ref/load.sgml,v 1.9 2001/09/03 12:57:50 pet ...@@ -10,7 +10,7 @@ $Header: /cvsroot/pgsql/doc/src/sgml/ref/load.sgml,v 1.9 2001/09/03 12:57:50 pet
<refnamediv> <refnamediv>
<refname>LOAD</refname> <refname>LOAD</refname>
<refpurpose>load or reload a shared object file</refpurpose> <refpurpose>load or reload a shared library file</refpurpose>
</refnamediv> </refnamediv>
<refsynopsisdiv> <refsynopsisdiv>
...@@ -23,13 +23,22 @@ LOAD '<replaceable class="PARAMETER">filename</replaceable>' ...@@ -23,13 +23,22 @@ LOAD '<replaceable class="PARAMETER">filename</replaceable>'
<title>Description</title> <title>Description</title>
<para> <para>
Loads a shared object file into the PostgreSQL backend's address Loads a shared library file into the PostgreSQL backend's address
space. If the file had been loaded previously, it is first space. If the file had been loaded previously, it is first
unloaded. This command is primarily useful to unload and reload a unloaded. This command is primarily useful to unload and reload a
shared object file if it has been changed. To make use of the shared library file that has been changed since the backend first
shared object, a function needs to be declared using the <xref loaded it. To make use of the
shared library, function(s) in it need to be declared using the <xref
linkend="sql-createfunction"> command. linkend="sql-createfunction"> command.
</para> </para>
<para>
The filename is specified in the same way as for shared library
names in <xref linkend="sql-createfunction">; in particular, one
may rely on a search path and automatic addition of the system's standard
shared library filename extension. See the
<citetitle>Programmer's Guide</citetitle> for more detail.
</para>
</refsect1> </refsect1>
<refsect1 id="sql-load-compat"> <refsect1 id="sql-load-compat">
......
<!-- <!--
$Header: /cvsroot/pgsql/doc/src/sgml/xfunc.sgml,v 1.38 2001/09/16 16:11:09 petere Exp $ $Header: /cvsroot/pgsql/doc/src/sgml/xfunc.sgml,v 1.39 2001/10/26 19:58:12 tgl Exp $
--> -->
<chapter id="xfunc"> <chapter id="xfunc">
...@@ -72,19 +72,30 @@ $Header: /cvsroot/pgsql/doc/src/sgml/xfunc.sgml,v 1.38 2001/09/16 16:11:09 peter ...@@ -72,19 +72,30 @@ $Header: /cvsroot/pgsql/doc/src/sgml/xfunc.sgml,v 1.38 2001/09/16 16:11:09 peter
<para> <para>
SQL functions execute an arbitrary list of SQL statements, returning SQL functions execute an arbitrary list of SQL statements, returning
the results of the last query in the list. SQL functions in general the results of the last query in the list. In the simple (non-set)
return sets. If their returntype is not specified as a case, the first row of the last query's result will be returned.
<literal>SETOF</literal>, (Bear in mind that <quote>the first row</quote> is not well-defined
then an arbitrary element of the last query's result will be returned. unless you use <literal>ORDER BY</>.) If the last query happens
to return no rows at all, NULL will be returned.
</para>
<para>
Alternatively, an SQL function may be declared to return a set,
by specifying the function's return type
as <literal>SETOF</literal> <replaceable>sometype</>. In this case
all rows of the last query's result are returned. Further details
appear below.
</para> </para>
<para> <para>
The body of an SQL function should be a list of one or more SQL The body of an SQL function should be a list of one or more SQL
statements separated by semicolons. Note that because the syntax statements separated by semicolons. Note that because the syntax
of the <command>CREATE FUNCTION</command> requires the body of the of the <command>CREATE FUNCTION</command> command requires the body of the
function to be enclosed in single quotes, single quote marks used function to be enclosed in single quotes, single quote marks
(<literal>'</>) used
in the body of the function must be escaped, by writing two single in the body of the function must be escaped, by writing two single
quotes where one is desired. quotes (<literal>''</>) or a backslash (<literal>\'</>) where each
quote is desired.
</para> </para>
<para> <para>
...@@ -93,7 +104,7 @@ $Header: /cvsroot/pgsql/doc/src/sgml/xfunc.sgml,v 1.38 2001/09/16 16:11:09 peter ...@@ -93,7 +104,7 @@ $Header: /cvsroot/pgsql/doc/src/sgml/xfunc.sgml,v 1.38 2001/09/16 16:11:09 peter
the first argument, $2 to the second, and so on. If an argument the first argument, $2 to the second, and so on. If an argument
is of a composite type, then the <quote>dot notation</quote>, is of a composite type, then the <quote>dot notation</quote>,
e.g., <literal>$1.emp</literal>, may be used to access attributes e.g., <literal>$1.emp</literal>, may be used to access attributes
of the argument or to invoke functions. of the argument.
</para> </para>
<sect2> <sect2>
...@@ -104,11 +115,11 @@ $Header: /cvsroot/pgsql/doc/src/sgml/xfunc.sgml,v 1.38 2001/09/16 16:11:09 peter ...@@ -104,11 +115,11 @@ $Header: /cvsroot/pgsql/doc/src/sgml/xfunc.sgml,v 1.38 2001/09/16 16:11:09 peter
which might be used to debit a bank account: which might be used to debit a bank account:
<programlisting> <programlisting>
CREATE FUNCTION tp1 (integer, double precision) RETURNS integer AS ' CREATE FUNCTION tp1 (integer, numeric) RETURNS integer AS '
UPDATE bank UPDATE bank
SET balance = bank.balance - $2 SET balance = balance - $2
WHERE bank.acctountno = $1; WHERE accountno = $1;
SELECT 1; SELECT 1;
' LANGUAGE SQL; ' LANGUAGE SQL;
</programlisting> </programlisting>
...@@ -121,16 +132,47 @@ SELECT tp1(17, 100.0); ...@@ -121,16 +132,47 @@ SELECT tp1(17, 100.0);
</para> </para>
<para> <para>
The following more interesting example takes a single argument of In practice one would probably like a more useful result from the
type <type>EMP</type>, which is really a table that contains data function than a constant <quote>1</>, so a more likely definition
about employees, and retrieves multiple results: is
<programlisting> <programlisting>
CREATE FUNCTION hobbies (EMP) RETURNS SETOF hobbies AS ' CREATE FUNCTION tp1 (integer, numeric) RETURNS numeric AS '
SELECT hobbies.* FROM hobbies UPDATE bank
WHERE $1.name = hobbies.person SET balance = balance - $2
WHERE accountno = $1;
SELECT balance FROM bank WHERE accountno = $1;
' LANGUAGE SQL; ' LANGUAGE SQL;
</programlisting> </programlisting>
which adjusts the balance and returns the new balance.
</para>
<para>
Any collection of commands in the <acronym>SQL</acronym>
language can be packaged together and defined as a function.
The commands can include data modification (i.e.,
<command>INSERT</command>, <command>UPDATE</command>, and
<command>DELETE</command>) as well
as <command>SELECT</command> queries. However, the final command
must be a <command>SELECT</command> that returns whatever is
specified as the function's return type.
<programlisting>
CREATE FUNCTION clean_EMP () RETURNS integer AS '
DELETE FROM EMP
WHERE EMP.salary &lt;= 0;
SELECT 1 AS ignore_this;
' LANGUAGE SQL;
SELECT clean_EMP();
</programlisting>
<screen>
x
---
1
</screen>
</para> </para>
</sect2> </sect2>
...@@ -146,21 +188,21 @@ CREATE FUNCTION one() RETURNS integer AS ' ...@@ -146,21 +188,21 @@ CREATE FUNCTION one() RETURNS integer AS '
SELECT 1 as RESULT; SELECT 1 as RESULT;
' LANGUAGE SQL; ' LANGUAGE SQL;
SELECT one() AS answer; SELECT one();
</programlisting> </programlisting>
<screen> <screen>
answer one
-------- -----
1 1
</screen> </screen>
</para> </para>
<para> <para>
Notice that we defined a column alias within the function body for the result of the function Notice that we defined a column alias within the function body for the result of the function
(with the name <literal>RESULT</>), but this column alias is not visible (with the name <literal>RESULT</>), but this column alias is not visible
outside the function. Hence, the result is labelled <literal>answer</> outside the function. Hence, the result is labelled <literal>one</>
instead of <literal>one</>. instead of <literal>RESULT</>.
</para> </para>
<para> <para>
...@@ -190,10 +232,12 @@ SELECT add_em(1, 2) AS answer; ...@@ -190,10 +232,12 @@ SELECT add_em(1, 2) AS answer;
<para> <para>
When specifying functions with arguments of composite When specifying functions with arguments of composite
types (such as <type>EMP</type>), we must not only specify which types, we must not only specify which
argument we want (as we did above with <literal>$1</> and <literal>$2</literal>) but argument we want (as we did above with <literal>$1</> and <literal>$2</literal>) but
also the attributes of that argument. For example, also the attributes of that argument. For example, suppose that
take the function <function>double_salary</function> that computes what your <type>EMP</type> 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 <function>double_salary</function> that computes what your
salary would be if it were doubled: salary would be if it were doubled:
<programlisting> <programlisting>
...@@ -214,36 +258,17 @@ SELECT name, double_salary(EMP) AS dream ...@@ -214,36 +258,17 @@ SELECT name, double_salary(EMP) AS dream
</para> </para>
<para> <para>
Notice the use of the syntax <literal>$1.salary</literal>. Notice the use of the syntax <literal>$1.salary</literal>
Before launching into the subject of functions that to select one field of the argument row value. Also notice
return composite types, we must first introduce the how the calling SELECT command uses a table name to denote
function notation for projecting attributes. The simple way the entire current row of that table as a composite value.
to explain this is that we can usually use the
notations <literal>attribute(table)</> and <literal>table.attribute</> interchangably:
<programlisting>
--
-- this is the same as:
-- SELECT EMP.name AS youngster FROM EMP WHERE EMP.age &lt; 30
--
SELECT name(EMP) AS youngster
FROM EMP
WHERE age(EMP) &lt; 30;
</programlisting>
<screen>
youngster
-----------
Sam
</screen>
</para> </para>
<para> <para>
As we shall see, however, this is not always the case. It is also possible to build a function that returns a composite type.
This function notation is important when we want to use (However, as we'll see below, there are some
a function that returns a single row. We do this unfortunate restrictions on how the function may be used.)
by assembling the entire row within the function, This is an example of a function
attribute by attribute. This is an example of a function
that returns a single <type>EMP</type> row: that returns a single <type>EMP</type> row:
<programlisting> <programlisting>
...@@ -260,15 +285,14 @@ CREATE FUNCTION new_emp() RETURNS EMP AS ' ...@@ -260,15 +285,14 @@ CREATE FUNCTION new_emp() RETURNS EMP AS '
In this case we have specified each of the attributes In this case we have specified each of the attributes
with a constant value, but any computation or expression with a constant value, but any computation or expression
could have been substituted for these constants. could have been substituted for these constants.
Defining a function like this can be tricky. Some of Note two important things about defining the function:
the more important caveats are as follows:
<itemizedlist> <itemizedlist>
<listitem> <listitem>
<para> <para>
The target list order must be exactly the same as The target list order must be exactly the same as
that in which the attributes appear in the <command>CREATE that in which the columns appear in the table associated
TABLE</command> statement that defined the table underlying the composite type. with the composite type.
</para> </para>
</listitem> </listitem>
<listitem> <listitem>
...@@ -282,65 +306,144 @@ ERROR: function declared to return emp returns varchar instead of text at colum ...@@ -282,65 +306,144 @@ ERROR: function declared to return emp returns varchar instead of text at colum
</screen> </screen>
</para> </para>
</listitem> </listitem>
<listitem> </itemizedlist>
<para> </para>
When calling a function that returns a row, we
cannot retrieve the entire row. We must either <para>
project an attribute out of the row or pass the In the present release of <productname>PostgreSQL</productname>
entire row into another function. there are some unpleasant restrictions on how functions returning
composite types can be used. Briefly, when calling a function that
returns a row, we cannot retrieve the entire row. We must either
project a single attribute out of the row or pass the entire row into
another function. (Trying to display the entire row value will yield
a meaningless number.) For example,
<programlisting> <programlisting>
SELECT name(new_emp()) AS nobody; SELECT name(new_emp());
</programlisting> </programlisting>
<screen> <screen>
nobody name
-------- ------
None None
</screen> </screen>
</para> </para>
</listitem>
<listitem> <para>
<para> This example makes use of the
function notation for projecting attributes. The simple way
to explain this is that we can usually use the
notations <literal>attribute(table)</> and <literal>table.attribute</>
interchangeably:
<programlisting>
--
-- this is the same as:
-- SELECT EMP.name AS youngster FROM EMP WHERE EMP.age &lt; 30
--
SELECT name(EMP) AS youngster
FROM EMP
WHERE age(EMP) &lt; 30;
</programlisting>
<screen>
youngster
-----------
Sam
</screen>
</para>
<para>
The reason why, in general, we must use the function The reason why, in general, we must use the function
syntax for projecting attributes of function return syntax for projecting attributes of function return
values is that the parser just doesn't understand values is that the parser just doesn't understand
the other (dot) syntax for projection when combined the dot syntax for projection when combined
with function calls. with function calls.
<screen> <screen>
SELECT new_emp().name AS nobody; SELECT new_emp().name AS nobody;
NOTICE:parser: syntax error at or near "." ERROR: parser: parse error at or near "."
</screen> </screen>
</para> </para>
</listitem>
</itemizedlist>
</para>
<para> <para>
Any collection of commands in the <acronym>SQL</acronym> Another way to use a function returning a row result is to declare a
language can be packaged together and defined as a function. second function accepting a rowtype parameter, and pass the function
The commands can include data modification (i.e., result to it:
<command>INSERT</command>, <command>UPDATE</command>, and
<command>DELETE</command>) as well
as <command>SELECT</command> queries. However, the final command
must be a <command>SELECT</command> that returns whatever is
specified as the function's return type.
<programlisting> <programlisting>
CREATE FUNCTION clean_EMP () RETURNS integer AS ' CREATE FUNCTION getname(emp) RETURNS text AS
DELETE FROM EMP 'SELECT $1.name;'
WHERE EMP.salary &lt;= 0; LANGUAGE SQL;
SELECT 1 AS ignore_this; </programlisting>
' LANGUAGE SQL;
SELECT clean_EMP(); <screen>
SELECT getname(new_emp());
getname
---------
None
(1 row)
</screen>
</para>
</sect2>
<sect2>
<title><acronym>SQL</acronym> Functions Returning Sets</title>
<para>
As previously mentioned, an SQL function may be declared as
returning <literal>SETOF</literal> <replaceable>sometype</>.
In this case the function's final SELECT query is executed to
completion, and each row it outputs is returned as an element
of the set.
</para>
<para>
Functions returning sets may only be called in the target list
of a SELECT query. For each row that the SELECT generates by itself,
the function returning set is invoked, and an output row is generated
for each element of the function's result set. An example:
<programlisting>
CREATE FUNCTION listchildren(text) RETURNS SETOF text AS
'SELECT name FROM nodes WHERE parent = $1'
LANGUAGE SQL;
</programlisting> </programlisting>
<screen> <screen>
x SELECT * FROM nodes;
--- name | parent
1 -----------+--------
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)
</screen> </screen>
Notice that no output row appears for Child2, Child3, etc.
This happens because listchildren() returns an empty set
for those inputs, so no output rows are generated.
</para> </para>
</sect2> </sect2>
</sect1> </sect1>
...@@ -412,8 +515,12 @@ CREATE FUNCTION square_root(double precision) RETURNS double precision ...@@ -412,8 +515,12 @@ CREATE FUNCTION square_root(double precision) RETURNS double precision
User-defined functions can be written in C (or a language that can User-defined functions can be written in C (or a language that can
be made compatible with C, such as C++). Such functions are be made compatible with C, such as C++). Such functions are
compiled into dynamically loadable objects (also called shared compiled into dynamically loadable objects (also called shared
libraries) and are loaded by the server on demand. This libraries) and are loaded by the server on demand. The dynamic
distinguishes them from internal functions. loading feature is what distinguishes <quote>C language</> functions
from <quote>internal</> functions --- the actual coding conventions
are essentially the same for both. (Hence, the standard internal
function library is a rich source of coding examples for user-defined
C functions.)
</para> </para>
<para> <para>
...@@ -440,15 +547,6 @@ CREATE FUNCTION square_root(double precision) RETURNS double precision ...@@ -440,15 +547,6 @@ CREATE FUNCTION square_root(double precision) RETURNS double precision
object file, and the C name (link symbol) of the specific function to call object file, and the C name (link symbol) of the specific function to call
within that object file. If the C name is not explicitly specified then within that object file. If the C name is not explicitly specified then
it is assumed to be the same as the SQL function name. it is assumed to be the same as the SQL function name.
<note>
<para>
After it is used for the first time, a dynamically loaded user
function is retained in memory, and future calls to the function
in the same session will only incur the small overhead of a symbol table
lookup.
</para>
</note>
</para> </para>
<para> <para>
...@@ -459,22 +557,22 @@ CREATE FUNCTION square_root(double precision) RETURNS double precision ...@@ -459,22 +557,22 @@ CREATE FUNCTION square_root(double precision) RETURNS double precision
<orderedlist> <orderedlist>
<listitem> <listitem>
<para> <para>
If the name is an absolute file name, the given file is loaded. If the name is an absolute path, the given file is loaded.
</para> </para>
</listitem> </listitem>
<listitem> <listitem>
<para> <para>
If the name starts with the string <literal>$libdir</literal>, If the name starts with the string <literal>$libdir</literal>,
that part is replaced by the PostgreSQL package library directory, that part is replaced by the PostgreSQL package library directory
which is determined at build time. name, which is determined at build time.
</para> </para>
</listitem> </listitem>
<listitem> <listitem>
<para> <para>
If the name does not contain a directory part, the file is If the name does not contain a directory part, the file is
searched the path specified by the configuration variable searched for in the path specified by the configuration variable
<varname>dynamic_library_path</varname>. <varname>dynamic_library_path</varname>.
</para> </para>
</listitem> </listitem>
...@@ -506,12 +604,33 @@ CREATE FUNCTION square_root(double precision) RETURNS double precision ...@@ -506,12 +604,33 @@ CREATE FUNCTION square_root(double precision) RETURNS double precision
</note> </note>
<para> <para>
In any case, the file name that is specified in the In any case, the file name that is given in the
<command>CREATE FUNCTION</command> command is recorded literally <command>CREATE FUNCTION</command> command is recorded literally
in the system catalogs, so if the file needs to be loaded again in the system catalogs, so if the file needs to be loaded again
the same procedure is applied. the same procedure is applied.
</para> </para>
<note>
<para>
<application>PostgreSQL</application> will not compile a C function
automatically. The object file must be compiled before it is referenced
in a <command>CREATE
FUNCTION</> command. See <xref linkend="dfunc"> for additional
information.
</para>
</note>
<note>
<para>
After it is used for the first time, a dynamically loaded object
file is retained in memory. Future calls in the same session to the
function(s) in that file will only incur the small overhead of a symbol
table lookup. If you need to force a reload of an object file, for
example after recompiling it, use the <command>LOAD</> command or
begin a fresh session.
</para>
</note>
<para> <para>
It is recommended to locate shared libraries either relative to It is recommended to locate shared libraries either relative to
<literal>$libdir</literal> or through the dynamic library path. <literal>$libdir</literal> or through the dynamic library path.
...@@ -523,11 +642,15 @@ CREATE FUNCTION square_root(double precision) RETURNS double precision ...@@ -523,11 +642,15 @@ CREATE FUNCTION square_root(double precision) RETURNS double precision
<note> <note>
<para> <para>
<application>PostgreSQL</application> will not compile a function Before <application>PostgreSQL</application> release 7.2, only exact
automatically; it must be compiled before it is used in a CREATE absolute paths to object files could be specified in <command>CREATE
FUNCTION command. See <xref linkend="dfunc"> for additional information. FUNCTION</>. This approach is now deprecated since it makes the
function definition unnecessarily unportable. It's best to specify
just the shared library name with no path nor extension, and let
the search mechanism provide that information instead.
</para> </para>
</note> </note>
</sect2> </sect2>
<sect2> <sect2>
...@@ -931,39 +1054,42 @@ concat_text(text *arg1, text *arg2) ...@@ -931,39 +1054,42 @@ concat_text(text *arg1, text *arg2)
<programlisting> <programlisting>
CREATE FUNCTION add_one(int4) RETURNS int4 CREATE FUNCTION add_one(int4) RETURNS int4
AS '<replaceable>PGROOT</replaceable>/tutorial/funcs.so' LANGUAGE 'c' AS '<replaceable>PGROOT</replaceable>/tutorial/funcs' LANGUAGE 'c'
WITH (isStrict); WITH (isStrict);
-- note overloading of SQL function name add_one() -- note overloading of SQL function name add_one()
CREATE FUNCTION add_one(float8) RETURNS float8 CREATE FUNCTION add_one(float8) RETURNS float8
AS '<replaceable>PGROOT</replaceable>/tutorial/funcs.so', AS '<replaceable>PGROOT</replaceable>/tutorial/funcs',
'add_one_float8' 'add_one_float8'
LANGUAGE 'c' WITH (isStrict); LANGUAGE 'c' WITH (isStrict);
CREATE FUNCTION makepoint(point, point) RETURNS point CREATE FUNCTION makepoint(point, point) RETURNS point
AS '<replaceable>PGROOT</replaceable>/tutorial/funcs.so' LANGUAGE 'c' AS '<replaceable>PGROOT</replaceable>/tutorial/funcs' LANGUAGE 'c'
WITH (isStrict); WITH (isStrict);
CREATE FUNCTION copytext(text) RETURNS text CREATE FUNCTION copytext(text) RETURNS text
AS '<replaceable>PGROOT</replaceable>/tutorial/funcs.so' LANGUAGE 'c' AS '<replaceable>PGROOT</replaceable>/tutorial/funcs' LANGUAGE 'c'
WITH (isStrict); WITH (isStrict);
CREATE FUNCTION concat_text(text, text) RETURNS text CREATE FUNCTION concat_text(text, text) RETURNS text
AS '<replaceable>PGROOT</replaceable>/tutorial/funcs.so' LANGUAGE 'c' AS '<replaceable>PGROOT</replaceable>/tutorial/funcs' LANGUAGE 'c'
WITH (isStrict); WITH (isStrict);
</programlisting> </programlisting>
</para> </para>
<para> <para>
Here <replaceable>PGROOT</replaceable> stands for the full path to Here <replaceable>PGROOT</replaceable> stands for the full path to
the <productname>Postgres</productname> source tree. Note that the <productname>Postgres</productname> source tree. (Better style would
depending on your system, the filename for a shared object might be to use just <literal>'funcs'</> in the <literal>AS</> clause,
not end in <literal>.so</literal>, but in <literal>.sl</literal> after having added <replaceable>PGROOT</replaceable><literal>/tutorial</>
or something else; adapt accordingly. to the search path. In any case, we may omit the system-specific
extension for a shared library, commonly <literal>.so</literal> or
<literal>.sl</literal>.)
</para> </para>
<para> <para>
Notice that we have specified the functions as <quote>strict</quote>, meaning that Notice that we have specified the functions as <quote>strict</quote>,
meaning that
the system should automatically assume a NULL result if any input the system should automatically assume a NULL result if any input
value is NULL. By doing this, we avoid having to check for NULL inputs value is NULL. By doing this, we avoid having to check for NULL inputs
in the function code. Without this, we'd have to check for NULLs in the function code. Without this, we'd have to check for NULLs
...@@ -998,8 +1124,8 @@ PG_FUNCTION_INFO_V1(funcname); ...@@ -998,8 +1124,8 @@ PG_FUNCTION_INFO_V1(funcname);
</programlisting> </programlisting>
must appear in the same source file (conventionally it's written must appear in the same source file (conventionally it's written
just before the function itself). This macro call is not needed just before the function itself). This macro call is not needed
for <literal>internal</>-language functions, since Postgres currently assumes for <literal>internal</>-language functions, since Postgres currently
all internal functions are version-1. However, it is assumes all internal functions are version-1. However, it is
<emphasis>required</emphasis> for dynamically-loaded functions. <emphasis>required</emphasis> for dynamically-loaded functions.
</para> </para>
...@@ -1131,7 +1257,10 @@ concat_text(PG_FUNCTION_ARGS) ...@@ -1131,7 +1257,10 @@ concat_text(PG_FUNCTION_ARGS)
this is only necessary in functions not declared <quote>strict</>). this is only necessary in functions not declared <quote>strict</>).
As with the As with the
<function>PG_GETARG_<replaceable>xxx</replaceable>()</function> macros, <function>PG_GETARG_<replaceable>xxx</replaceable>()</function> macros,
the input arguments are counted beginning at zero. the input arguments are counted beginning at zero. Note that one
should refrain from executing
<function>PG_GETARG_<replaceable>xxx</replaceable>()</function> until
one has verified that the argument isn't NULL.
To return a NULL result, execute <function>PG_RETURN_NULL()</function>; To return a NULL result, execute <function>PG_RETURN_NULL()</function>;
this works in both strict and non-strict functions. this works in both strict and non-strict functions.
</para> </para>
...@@ -1229,7 +1358,7 @@ c_overpaid(PG_FUNCTION_ARGS) ...@@ -1229,7 +1358,7 @@ c_overpaid(PG_FUNCTION_ARGS)
<programlisting> <programlisting>
CREATE FUNCTION c_overpaid(emp, int4) CREATE FUNCTION c_overpaid(emp, int4)
RETURNS bool RETURNS bool
AS '<replaceable>PGROOT</replaceable>/tutorial/obj/funcs.so' AS '<replaceable>PGROOT</replaceable>/tutorial/obj/funcs'
LANGUAGE 'c'; LANGUAGE 'c';
</programlisting> </programlisting>
</para> </para>
...@@ -1238,6 +1367,7 @@ LANGUAGE 'c'; ...@@ -1238,6 +1367,7 @@ LANGUAGE 'c';
While there are ways to construct new rows or modify While there are ways to construct new rows or modify
existing rows from within a C function, these existing rows from within a C function, these
are far too complex to discuss in this manual. are far too complex to discuss in this manual.
Consult the backend source code for examples.
</para> </para>
</sect2> </sect2>
...@@ -1359,7 +1489,7 @@ LANGUAGE 'c'; ...@@ -1359,7 +1489,7 @@ LANGUAGE 'c';
<title>Function Overloading</title> <title>Function Overloading</title>
<para> <para>
More than one function may be defined with the same name, so long More than one function may be defined with the same SQL name, so long
as the arguments they take are different. In other words, as the arguments they take are different. In other words,
function names can be <firstterm>overloaded</firstterm>. When a function names can be <firstterm>overloaded</firstterm>. When a
query is executed, the server will determine which function to query is executed, the server will determine which function to
...@@ -1428,9 +1558,9 @@ CREATE FUNCTION test(int, int) RETURNS int ...@@ -1428,9 +1558,9 @@ CREATE FUNCTION test(int, int) RETURNS int
<para> <para>
All calls to functions that are written in a language other than All calls to functions that are written in a language other than
the current <quote>version 1</quote> interface for compiled the current <quote>version 1</quote> interface for compiled
languages, in particular in user-defined procedural languages, but languages (this includes functions in user-defined procedural languages,
also functions written in SQL or the version 0 compiled language functions written in SQL, and functions using the version 0 compiled
interface, go through a <firstterm>call handler</firstterm> language interface), go through a <firstterm>call handler</firstterm>
function for the specific language. It is the responsibility of function for the specific language. It is the responsibility of
the call handler to execute the function in a meaningful way, such the call handler to execute the function in a meaningful way, such
as by interpreting the supplied source text. This section as by interpreting the supplied source text. This section
...@@ -1580,7 +1710,7 @@ plsample_call_handler(PG_FUNCTION_ARGS) ...@@ -1580,7 +1710,7 @@ plsample_call_handler(PG_FUNCTION_ARGS)
language: language:
<programlisting> <programlisting>
CREATE FUNCTION plsample_call_handler () RETURNS opaque CREATE FUNCTION plsample_call_handler () RETURNS opaque
AS '/usr/local/pgsql/lib/plsample.so' AS '/usr/local/pgsql/lib/plsample'
LANGUAGE C; LANGUAGE C;
CREATE LANGUAGE plsample CREATE LANGUAGE plsample
HANDLER plsample_call_handler; HANDLER plsample_call_handler;
......
Markdown is supported
0% or
You are about to add 0 people to the discussion. Proceed with caution.
Finish editing this message first!
Please register or to comment