More minor updates and copy-editing.

This commit is contained in:
Tom Lane 2004-12-30 21:45:37 +00:00
parent 1fbdb6bc9f
commit 883ac5ca7a
8 changed files with 517 additions and 398 deletions

View File

@ -1,5 +1,5 @@
<!--
$PostgreSQL: pgsql/doc/src/sgml/plhandler.sgml,v 1.2 2003/11/29 19:51:37 pgsql Exp $
$PostgreSQL: pgsql/doc/src/sgml/plhandler.sgml,v 1.3 2004/12/30 21:45:36 tgl Exp $
-->
<chapter id="plhandler">
@ -154,6 +154,12 @@ CREATE LANGUAGE plsample
</programlisting>
</para>
<para>
The procedural languages included in the standard distribution
are good references when trying to write your own call handler.
Look into the <filename>src/pl</> subdirectory of the source tree.
</para>
</chapter>
<!-- Keep this comment at the end of the file

View File

@ -1,5 +1,5 @@
<!--
$PostgreSQL: pgsql/doc/src/sgml/plperl.sgml,v 2.34 2004/12/13 18:05:08 petere Exp $
$PostgreSQL: pgsql/doc/src/sgml/plperl.sgml,v 2.35 2004/12/30 21:45:36 tgl Exp $
-->
<chapter id="plperl">
@ -132,9 +132,66 @@ CREATE FUNCTION empcomp(employee) RETURNS integer AS $$
return $emp-&gt;{basesalary} + $emp-&gt;{bonus};
$$ LANGUAGE plperl;
SELECT name, empcomp(employee) FROM employee;
SELECT name, empcomp(employee.*) FROM employee;
</programlisting>
</para>
<para>
A PL/Perl function can return a composite-type result using the same
approach: return a reference to a hash that has the required attributes.
For example,
<programlisting>
CREATE TYPE testrowperl AS (f1 integer, f2 text, f3 text);
CREATE OR REPLACE FUNCTION perl_row() RETURNS testrowperl AS $$
return {f2 =&gt; 'hello', f1 =&gt; 1, f3 =&gt; 'world'};
$$ LANGUAGE plperl;
SELECT * FROM perl_row();
</programlisting>
Any columns in the declared result data type that are not present in the
hash will be returned as NULLs.
</para>
<para>
PL/Perl functions can also return sets of either scalar or composite
types. To do this, return a reference to an array that contains
either scalars or references to hashes, respectively. Here are
some simple examples:
<programlisting>
CREATE OR REPLACE FUNCTION perl_set_int(int) RETURNS SETOF INTEGER AS $$
return [0..$_[0]];
$$ LANGUAGE plperl;
SELECT * FROM perl_set_int(5);
CREATE OR REPLACE FUNCTION perl_set() RETURNS SETOF testrowperl AS $$
return [
{ f1 =&gt; 1, f2 =&gt; 'Hello', f3 =&gt; 'World' },
{ f1 =&gt; 2, f2 =&gt; 'Hello', f3 =&gt; 'PostgreSQL' },
{ f1 =&gt; 3, f2 =&gt; 'Hello', f3 =&gt; 'PL/Perl' }
];
$$ LANGUAGE plperl;
SELECT * FROM perl_set();
</programlisting>
Note that when you do this, Perl will have to build the entire array in
memory; therefore the technique does not scale to very large result sets.
</para>
<para>
<application>PL/Perl</> does not currently have full support for
domain types: it treats a domain the same as the underlying scalar
type. This means that constraints associated with the domain will
not be enforced. This is not an issue for function arguments, but
it is a hazard if you declare a <application>PL/Perl</> function
as returning a domain type.
</para>
</sect1>
<sect1 id="plperl-database">
@ -204,53 +261,9 @@ $res = $rv-&gt;{status};
$nrows = $rv-&gt;{processed};
</programlisting>
</para>
</listitem>
</varlistentry>
<varlistentry>
<indexterm>
<primary>elog</primary>
<secondary>in PL/Perl</secondary>
</indexterm>
<term><literal><function>elog</>(<replaceable>level</replaceable>, <replaceable>msg</replaceable>)</literal></term>
<listitem>
<para>
Emit a log or error message. Possible levels are
<literal>DEBUG</>, <literal>LOG</>, <literal>INFO</>,
<literal>NOTICE</>, <literal>WARNING</>, and <literal>ERROR</>.
<literal>ERROR</>
raises an error condition; if this is not trapped by the surrounding
Perl code, the error propagates out to the calling query, causing
the current transaction or subtransaction to be aborted. This
is effectively the same as the Perl <literal>die</> command.
The other levels simply report the message to the system log
and/or client.
</para>
</listitem>
</varlistentry>
</variablelist>
</para>
</sect1>
<sect1 id="plperl-data">
<title>Data Values in PL/Perl</title>
<para>
The argument values supplied to a PL/Perl function's code are
simply the input arguments converted to text form (just as if they
had been displayed by a <command>SELECT</command> statement).
Conversely, the <literal>return</> command will accept any string
that is acceptable input format for the function's declared return
type. So, the PL/Perl programmer can manipulate data values as if
they were just text.
</para>
<para>
PL/Perl can also return row sets and composite types, and row sets
of composite types. Here is an example of a PL/Perl function
returning a row set of a row type. Note that a composite type is
always represented as a hash reference.
Here is a complete example:
<programlisting>
CREATE TABLE test (
i int,
@ -278,36 +291,53 @@ $$ LANGUAGE plperl;
SELECT * FROM test_munge();
</programlisting>
</para>
</listitem>
</varlistentry>
<varlistentry>
<indexterm>
<primary>elog</primary>
<secondary>in PL/Perl</secondary>
</indexterm>
<term><literal><function>elog</>(<replaceable>level</replaceable>, <replaceable>msg</replaceable>)</literal></term>
<listitem>
<para>
Emit a log or error message. Possible levels are
<literal>DEBUG</>, <literal>LOG</>, <literal>INFO</>,
<literal>NOTICE</>, <literal>WARNING</>, and <literal>ERROR</>.
<literal>ERROR</>
raises an error condition; if this is not trapped by the surrounding
Perl code, the error propagates out to the calling query, causing
the current transaction or subtransaction to be aborted. This
is effectively the same as the Perl <literal>die</> command.
The other levels only generate messages of different
priority levels.
Whether messages of a particular priority are reported to the client,
written to the server log, or both is controlled by the
<xref linkend="guc-log-min-messages"> and
<xref linkend="guc-client-min-messages"> configuration
variables. See <xref linkend="runtime-config"> for more
information.
</para>
</listitem>
</varlistentry>
</variablelist>
</para>
</sect1>
<sect1 id="plperl-data">
<title>Data Values in PL/Perl</title>
<para>
Here is an example of a PL/Perl function returning a composite
type:
<programlisting>
CREATE TYPE testrowperl AS (f1 integer, f2 text, f3 text);
CREATE OR REPLACE FUNCTION perl_row() RETURNS testrowperl AS $$
return {f2 =&gt; 'hello', f1 =&gt; 1, f3 =&gt; 'world'};
$$ LANGUAGE plperl;
</programlisting>
</para>
<para>
Here is an example of a PL/Perl function returning a row set of a
composite type. Since a row set is always a reference to an array
and a composite type is always a reference to a hash, a row set of a
composite type is a reference to an array of hash references.
<programlisting>
CREATE TYPE testsetperl AS (f1 integer, f2 text, f3 text);
CREATE OR REPLACE FUNCTION perl_set() RETURNS SETOF testsetperl AS $$
return [
{ f1 =&gt; 1, f2 =&gt; 'Hello', f3 =&gt; 'World' },
{ f1 =&gt; 2, f2 =&gt; 'Hello', f3 =&gt; 'PostgreSQL' },
{ f1 =&gt; 3, f2 =&gt; 'Hello', f3 =&gt; 'PL/Perl' }
];
$$ LANGUAGE plperl;
</programlisting>
The argument values supplied to a PL/Perl function's code are
simply the input arguments converted to text form (just as if they
had been displayed by a <command>SELECT</command> statement).
Conversely, the <literal>return</> command will accept any string
that is acceptable input format for the function's declared return
type. So, within the PL/Perl function,
all values are just text strings.
</para>
</sect1>
@ -317,8 +347,7 @@ $$ LANGUAGE plperl;
<para>
You can use the global hash <varname>%_SHARED</varname> to store
data, including code references, between function calls for the
lifetime of the current session, which is bounded from below by
the lifetime of the current transaction.
lifetime of the current session.
</para>
<para>
@ -360,12 +389,12 @@ SELECT myfuncs(); /* initializes the function */
CREATE OR REPLACE FUNCTION use_quote(TEXT) RETURNS text AS $$
my $text_to_quote = shift;
my $qfunc = $_SHARED{myquote};
return &$qfunc($text_to_quote);
return &amp;$qfunc($text_to_quote);
$$ LANGUAGE plperl;
</programlisting>
(You could have replaced the above with the one-liner
<literal>return $_SHARED{myquote}->($_[0]);</literal>
<literal>return $_SHARED{myquote}-&gt;($_[0]);</literal>
at the expense of readability.)
</para>
</sect1>
@ -619,9 +648,7 @@ CREATE TRIGGER test_valid_id_trig
<para>
In the current implementation, if you are fetching or returning
very large data sets, you should be aware that these will all go
into memory. Future features will help with this. In the
meantime, we suggest that you not use PL/Perl if you will fetch
or return very large result sets.
into memory.
</para>
</listitem>
</itemizedlist>

View File

@ -1,5 +1,5 @@
<!--
$PostgreSQL: pgsql/doc/src/sgml/plpgsql.sgml,v 1.53 2004/12/19 22:10:41 tgl Exp $
$PostgreSQL: pgsql/doc/src/sgml/plpgsql.sgml,v 1.54 2004/12/30 21:45:36 tgl Exp $
-->
<chapter id="plpgsql">
@ -150,7 +150,7 @@ $$ LANGUAGE plpgsql;
<para>
<acronym>SQL</acronym> is the language <productname>PostgreSQL</>
(and most other relational databases) use as query language. It's
and most other relational databases use as query language. It's
portable and easy to learn. But every <acronym>SQL</acronym>
statement must be executed individually by the database server.
</para>
@ -214,6 +214,15 @@ $$ LANGUAGE plpgsql;
Finally, a <application>PL/pgSQL</> function may be declared to return
<type>void</> if it has no useful return value.
</para>
<para>
<application>PL/pgSQL</> does not currently have full support for
domain types: it treats a domain the same as the underlying scalar
type. This means that constraints associated with the domain will
not be enforced. This is not an issue for function arguments, but
it is a hazard if you declare a <application>PL/pgSQL</> function
as returning a domain type.
</para>
</sect2>
</sect1>
@ -267,7 +276,8 @@ $$ LANGUAGE plpgsql;
the code can become downright incomprehensible, because you can
easily find yourself needing half a dozen or more adjacent quote marks.
It's recommended that you instead write the function body as a
<quote>dollar-quoted</> string literal. In the dollar-quoting
<quote>dollar-quoted</> string literal (see <xref
linkend="sql-syntax-dollar-quoting">). In the dollar-quoting
approach, you never double any quote marks, but instead take care to
choose a different dollar-quoting delimiter for each level of
nesting you need. For example, you might write the <command>CREATE
@ -437,8 +447,10 @@ END;
<para>
Each declaration and each statement within a block is terminated
by a semicolon, although the final <literal>END</literal> that
concludes a function body does not require one.
by a semicolon. A block that appears within another block must
have a semicolon after <literal>END</literal>, as shown above;
however the final <literal>END</literal> that
concludes a function body does not require a semicolon.
</para>
<para>
@ -503,7 +515,7 @@ $$ LANGUAGE plpgsql;
transaction, since there would be no context for them to execute in.
However, a block containing an <literal>EXCEPTION</> clause effectively
forms a subtransaction that can be rolled back without affecting the
outer transaction. For more details see <xref
outer transaction. For more about that see <xref
linkend="plpgsql-error-trapping">.
</para>
</sect1>
@ -556,7 +568,7 @@ arow RECORD;
<para>
The default value is evaluated every time the block is entered. So,
for example, assigning <literal>'now'</literal> to a variable of type
for example, assigning <literal>now()</literal> to a variable of type
<type>timestamp</type> causes the variable to have the
time of the current function call, not the time when the function was
precompiled.
@ -581,6 +593,9 @@ user_id CONSTANT integer := 10;
<literal>$<replaceable>n</replaceable></literal>
parameter names for increased readability. Either the alias or the
numeric identifier can then be used to refer to the parameter value.
</para>
<para>
There are two ways to create an alias. The preferred way is to give a
name to the parameter in the <command>CREATE FUNCTION</command> command,
for example:
@ -827,17 +842,11 @@ RENAME this_var TO that_var;
<para>
All expressions used in <application>PL/pgSQL</application>
statements are processed using the server's regular
<acronym>SQL</acronym> executor. Expressions that appear to
contain constants may in fact require run-time evaluation
(e.g., <literal>'now'</literal> for the <type>timestamp</type>
type) so it is impossible for the
<application>PL/pgSQL</application> parser to identify real
constant values other than the key word <literal>NULL</>. All expressions are
evaluated internally by executing a query
<acronym>SQL</acronym> executor. In effect, a query like
<synopsis>
SELECT <replaceable>expression</replaceable>
</synopsis>
using the <acronym>SPI</acronym> manager. For evaluation,
is executed using the <acronym>SPI</acronym> manager. Before evaluation,
occurrences of <application>PL/pgSQL</application> variable
identifiers are replaced by parameters, and the actual values from
the variables are passed to the executor in the parameter array.
@ -1013,6 +1022,14 @@ SELECT INTO <replaceable>target</replaceable> <replaceable>select_expressions</r
and can use its full power.
</para>
<para>
The <literal>INTO</> clause can appear almost anywhere in the
<command>SELECT</command> statement. Customarily it is written
either just after <literal>SELECT</> as shown above, or
just before <literal>FROM</> &mdash; that is, either just before
or just after the list of <replaceable>select_expressions</replaceable>.
</para>
<para>
If the query returns zero rows, null values are assigned to the
target(s). If the query returns multiple rows, the first
@ -1022,14 +1039,11 @@ SELECT INTO <replaceable>target</replaceable> <replaceable>select_expressions</r
</para>
<para>
The <literal>INTO</> clause can appear almost anywhere in the <command>SELECT</command>
statement.
</para>
<para>
You can use <literal>FOUND</literal> immediately after a <command>SELECT
INTO</command> statement to determine whether the assignment was successful
(that is, at least one row was was returned by the query). For example:
You can check the special <literal>FOUND</literal> variable (see
<xref linkend="plpgsql-statements-diagnostics">) after a
<command>SELECT INTO</command> statement to determine whether the
assignment was successful, that is, at least one row was was returned by
the query. For example:
<programlisting>
SELECT INTO myrec * FROM emp WHERE empname = myname;
@ -1175,22 +1189,13 @@ EXECUTE <replaceable class="command">command-string</replaceable>;
be inserted in the command string as it is constructed.
</para>
<para>
When working with dynamic commands you will often have to handle escaping
of single quotes. The recommended method for quoting fixed text in your
function body is dollar quoting. If you have legacy code that does
not use dollar quoting, please refer to the
overview in <xref linkend="plpgsql-quote-tips">, which can save you
some effort when translating said code to a more reasonable scheme.
</para>
<para>
Unlike all other commands in <application>PL/pgSQL</>, a command
run by an <command>EXECUTE</command> statement is not prepared
and saved just once during the life of the session. Instead, the
command is prepared each time the statement is run. The command
string can be dynamically created within the function to perform
actions on variable tables and columns.
actions on different tables and columns.
</para>
<para>
@ -1207,6 +1212,18 @@ EXECUTE <replaceable class="command">command-string</replaceable>;
</para>
<para>
When working with dynamic commands you will often have to handle escaping
of single quotes. The recommended method for quoting fixed text in your
function body is dollar quoting. (If you have legacy code that does
not use dollar quoting, please refer to the
overview in <xref linkend="plpgsql-quote-tips">, which can save you
some effort when translating said code to a more reasonable scheme.)
</para>
<para>
Dynamic values that are to be inserted into the constructed
query require special handling since they might themselves contain
quote characters.
An example (this assumes that you are using dollar quoting for the
function as a whole, so the quote marks need not be doubled):
<programlisting>
@ -1333,17 +1350,18 @@ GET DIAGNOSTICS integer_var = ROW_COUNT;
all three variants of the <command>FOR</> statement (integer
<command>FOR</> loops, record-set <command>FOR</> loops, and
dynamic record-set <command>FOR</>
loops). <literal>FOUND</literal> is only set when the
<command>FOR</> loop exits: inside the execution of the loop,
loops). <literal>FOUND</literal> is set this way when the
<command>FOR</> loop exits; inside the execution of the loop,
<literal>FOUND</literal> is not modified by the
<command>FOR</> statement, although it may be changed by the
execution of other statements within the loop body.
</para>
</listitem>
</itemizedlist>
<literal>FOUND</literal> is a local variable; any changes
to it affect only the current <application>PL/pgSQL</application>
function.
<literal>FOUND</literal> is a local variable within each
<application>PL/pgSQL</application> function; so any changes
to it affect only the current function.
</para>
</sect2>
@ -1434,15 +1452,14 @@ RETURN NEXT <replaceable>expression</replaceable>;
SELECT * FROM some_func();
</programlisting>
That is, the function is used as a table source in a <literal>FROM</literal>
clause.
That is, the function must be used as a table source in a
<literal>FROM</literal> clause.
</para>
<para>
<command>RETURN NEXT</command> does not actually return from the
function; it simply saves away the value of the expression (or
record or row variable, as appropriate for the data type being
returned). Execution then continues with the next statement in
function; it simply saves away the value of the expression.
Execution then continues with the next statement in
the <application>PL/pgSQL</> function. As successive
<command>RETURN NEXT</command> commands are executed, the result
set is built up. A final <command>RETURN</command>, which should
@ -1727,7 +1744,7 @@ END LOOP;
BEGIN
-- some computations
IF stocks &gt; 100000 THEN
EXIT; -- invalid; cannot use EXIT outside of LOOP
EXIT; -- causes exit from the BEGIN block
END IF;
END;
</programlisting>
@ -1821,8 +1838,9 @@ FOR <replaceable>record_or_row</replaceable> IN <replaceable>query</replaceable>
END LOOP;
</synopsis>
The record or row variable is successively assigned each row
resulting from the query (which must be a <command>SELECT</command>
command) and the loop body is executed for each row. Here is an example:
resulting from the <replaceable>query</replaceable> (which must be a
<command>SELECT</command> command) and the loop body is executed for each
row. Here is an example:
<programlisting>
CREATE FUNCTION cs_refresh_mviews() RETURNS integer AS $$
DECLARE
@ -1874,7 +1892,7 @@ END LOOP;
<literal>IN</> and <literal>LOOP</>. If <literal>..</> is not seen then
the loop is presumed to be a loop over rows. Mistyping the <literal>..</>
is thus likely to lead to a complaint along the lines of
<quote>loop variable of loop over rows must be a record or row</>,
<quote>loop variable of loop over rows must be a record or row variable</>,
rather than the simple syntax error one might expect to get.
</para>
</note>
@ -1902,7 +1920,7 @@ EXCEPTION
<replaceable>handler_statements</replaceable>
<optional> WHEN <replaceable>condition</replaceable> <optional> OR <replaceable>condition</replaceable> ... </optional> THEN
<replaceable>handler_statements</replaceable>
... </optional>
... </optional>
END;
</synopsis>
</para>
@ -2060,7 +2078,7 @@ DECLARE
<title><command>OPEN FOR SELECT</command></title>
<synopsis>
OPEN <replaceable>unbound-cursor</replaceable> FOR SELECT ...;
OPEN <replaceable>unbound_cursor</replaceable> FOR SELECT ...;
</synopsis>
<para>
@ -2086,7 +2104,7 @@ OPEN curs1 FOR SELECT * FROM foo WHERE key = mykey;
<title><command>OPEN FOR EXECUTE</command></title>
<synopsis>
OPEN <replaceable>unbound-cursor</replaceable> FOR EXECUTE <replaceable class="command">query-string</replaceable>;
OPEN <replaceable>unbound_cursor</replaceable> FOR EXECUTE <replaceable class="command">query_string</replaceable>;
</synopsis>
<para>
@ -2111,7 +2129,7 @@ OPEN curs1 FOR EXECUTE 'SELECT * FROM ' || quote_ident($1);
<title>Opening a Bound Cursor</title>
<synopsis>
OPEN <replaceable>bound-cursor</replaceable> <optional> ( <replaceable>argument_values</replaceable> ) </optional>;
OPEN <replaceable>bound_cursor</replaceable> <optional> ( <replaceable>argument_values</replaceable> ) </optional>;
</synopsis>
<para>
@ -2312,8 +2330,8 @@ RAISE <replaceable class="parameter">level</replaceable> '<replaceable class="pa
priority levels.
Whether messages of a particular priority are reported to the client,
written to the server log, or both is controlled by the
<varname>log_min_messages</varname> and
<varname>client_min_messages</varname> configuration
<xref linkend="guc-log-min-messages"> and
<xref linkend="guc-client-min-messages"> configuration
variables. See <xref linkend="runtime-config"> for more
information.
</para>
@ -2573,11 +2591,8 @@ CREATE TRIGGER emp_stamp BEFORE INSERT OR UPDATE ON emp
<para>
Another way to log changes to a table involves creating a new table that
holds a row for each insert, update, delete that occurs. This approach can
be thought of as auditing changes to a table.
</para>
<para>
holds a row for each insert, update, or delete that occurs. This approach
can be thought of as auditing changes to a table.
<xref linkend="plpgsql-trigger-audit-example"> shows an example of an
audit trigger procedure in <application>PL/pgSQL</application>.
</para>
@ -2606,7 +2621,7 @@ CREATE TABLE emp_audit(
salary integer
);
CREATE OR REPLACE FUNCTION process_emp_audit() RETURNS TRIGGER AS $emp_audit$
CREATE OR REPLACE FUNCTION process_emp_audit() RETURNS TRIGGER AS $emp_audit$
BEGIN
--
-- Create a row in emp_audit to reflect the operation performed on emp,
@ -2622,14 +2637,13 @@ CREATE OR REPLACE FUNCTION process_emp_audit() RETURNS TRIGGER AS $emp_audit$
INSERT INTO emp_audit SELECT 'I', now(), user, NEW.*;
RETURN NEW;
END IF;
RETURN NULL; -- result is ignored since this is an AFTER trigger
END;
$emp_audit$ language plpgsql;
CREATE TRIGGER emp_audit
AFTER INSERT OR UPDATE OR DELETE ON emp
FOR EACH ROW EXECUTE PROCEDURE process_emp_audit()
;
FOR EACH ROW EXECUTE PROCEDURE process_emp_audit();
</programlisting>
</example>
</sect1>

View File

@ -1,4 +1,4 @@
<!-- $PostgreSQL: pgsql/doc/src/sgml/plpython.sgml,v 1.25 2004/12/17 02:14:44 tgl Exp $ -->
<!-- $PostgreSQL: pgsql/doc/src/sgml/plpython.sgml,v 1.26 2004/12/30 21:45:36 tgl Exp $ -->
<chapter id="plpython">
<title>PL/Python - Python Procedural Language</title>
@ -46,15 +46,16 @@
<title>PL/Python Functions</title>
<para>
The Python code you write gets transformed into a Python function.
For example,
Functions in PL/Python are declared in the usual way, for example
<programlisting>
CREATE FUNCTION myfunc(text) RETURNS text
AS 'return args[0]'
LANGUAGE plpythonu;
</programlisting>
gets transformed into
The Python code that is given as the body of the function definition
gets transformed into a Python function.
For example, the above results in
<programlisting>
def __plpython_procedure_myfunc_23456():
@ -151,19 +152,23 @@ def __plpython_procedure_myfunc_23456():
<literal>plpy.notice(<replaceable>msg</>)</literal>,
<literal>plpy.warning(<replaceable>msg</>)</literal>,
<literal>plpy.error(<replaceable>msg</>)</literal>, and
<literal>plpy.fatal(<replaceable>msg</>)</literal>.
These are mostly equivalent to calling
<literal>elog(<replaceable>level</>, <replaceable>msg</>)</literal>
from C code.<indexterm><primary>elog</><secondary>in
PL/Python</></indexterm> <function>plpy.error</function> and
<literal>plpy.fatal(<replaceable>msg</>)</literal>.<indexterm><primary>elog</><secondary>in PL/Python</></indexterm>
<function>plpy.error</function> and
<function>plpy.fatal</function> actually raise a Python exception
which, if uncaught, causes the PL/Python module to call
<literal>elog(ERROR, msg)</literal> when the function handler
returns from the Python interpreter. <literal>raise
plpy.ERROR(<replaceable>msg</>)</literal> and <literal>raise
plpy.FATAL(<replaceable>msg</>)</literal> are equivalent to calling
which, if uncaught, propagates out to the calling query, causing
the current transaction or subtransaction to be aborted.
<literal>raise plpy.ERROR(<replaceable>msg</>)</literal> and
<literal>raise plpy.FATAL(<replaceable>msg</>)</literal> are
equivalent to calling
<function>plpy.error</function> and
<function>plpy.fatal</function>, respectively.
The other functions only generate messages of different
priority levels.
Whether messages of a particular priority are reported to the client,
written to the server log, or both is controlled by the
<xref linkend="guc-log-min-messages"> and
<xref linkend="guc-client-min-messages"> configuration
variables. See <xref linkend="runtime-config"> for more information.
</para>
<para>

View File

@ -1,5 +1,5 @@
<!--
$PostgreSQL: pgsql/doc/src/sgml/pltcl.sgml,v 2.32 2004/11/21 21:17:02 tgl Exp $
$PostgreSQL: pgsql/doc/src/sgml/pltcl.sgml,v 2.33 2004/12/30 21:45:37 tgl Exp $
-->
<chapter id="pltcl">
@ -16,7 +16,8 @@ $PostgreSQL: pgsql/doc/src/sgml/pltcl.sgml,v 2.32 2004/11/21 21:17:02 tgl Exp $
<para>
PL/Tcl is a loadable procedural language for the
<productname>PostgreSQL</productname> database system
that enables the Tcl language to be used to write functions and
that enables the <ulink url="http://www.tcl.tk/">Tcl</ulink>
language to be used to write functions and
trigger procedures.
</para>
@ -59,7 +60,7 @@ $PostgreSQL: pgsql/doc/src/sgml/pltcl.sgml,v 2.32 2004/11/21 21:17:02 tgl Exp $
The shared object for the <application>PL/Tcl</> and <application>PL/TclU</> call handlers is
automatically built and installed in the
<productname>PostgreSQL</productname>
library directory if Tcl/Tk support is specified
library directory if Tcl support is specified
in the configuration step of the installation procedure. To install
<application>PL/Tcl</> and/or <application>PL/TclU</> in a particular database, use the
<command>createlang</command> program, for example
@ -77,8 +78,7 @@ $PostgreSQL: pgsql/doc/src/sgml/pltcl.sgml,v 2.32 2004/11/21 21:17:02 tgl Exp $
To create a function in the <application>PL/Tcl</> language, use the standard syntax:
<programlisting>
CREATE FUNCTION <replaceable>funcname</replaceable>
(<replaceable>argument-types</replaceable>) RETURNS <replaceable>return-type</replaceable> AS $$
CREATE FUNCTION <replaceable>funcname</replaceable> (<replaceable>argument-types</replaceable>) RETURNS <replaceable>return-type</replaceable> AS $$
# PL/Tcl function body
$$ LANGUAGE pltcl;
</programlisting>
@ -169,7 +169,16 @@ $$ LANGUAGE pltcl;
<para>
There is currently no support for returning a composite-type
result value.
result value, nor for returning sets.
</para>
<para>
<application>PL/Tcl</> does not currently have full support for
domain types: it treats a domain the same as the underlying scalar
type. This means that constraints associated with the domain will
not be enforced. This is not an issue for function arguments, but
it is a hazard if you declare a <application>PL/Tcl</> function
as returning a domain type.
</para>
</sect1>
@ -180,10 +189,11 @@ $$ LANGUAGE pltcl;
<para>
The argument values supplied to a PL/Tcl function's code are simply
the input arguments converted to text form (just as if they had been
displayed by a <command>SELECT</> statement). Conversely, the <literal>return</>
displayed by a <command>SELECT</> statement). Conversely, the
<literal>return</>
command will accept any string that is acceptable input format for
the function's declared return type. So, the PL/Tcl programmer can
manipulate data values as if they were just text.
the function's declared return type. So, within the PL/Tcl function,
all values are just text strings.
</para>
</sect1>
@ -215,9 +225,9 @@ $$ LANGUAGE pltcl;
command. The global name of this variable is the function's internal
name, and the local name is <literal>GD</>. It is recommended that
<literal>GD</> be used
for private data of a function. Use regular Tcl global variables
only for values that you specifically intend to be shared among multiple
functions.
for persistent private data of a function. Use regular Tcl global
variables only for values that you specifically intend to be shared among
multiple functions.
</para>
<para>
@ -239,48 +249,48 @@ $$ LANGUAGE pltcl;
<term><literal><function>spi_exec</function> <optional role="tcl">-count <replaceable>n</replaceable></optional> <optional role="tcl">-array <replaceable>name</replaceable></optional> <replaceable>command</replaceable> <optional role="tcl"><replaceable>loop-body</replaceable></optional></literal></term>
<listitem>
<para>
Executes an SQL command given as a string. An error in the command
causes an error to be raised. Otherwise, the return value of <function>spi_exec</function>
is the number of rows processed (selected, inserted, updated, or
deleted) by the command, or zero if the command is a utility
statement. In addition, if the command is a <command>SELECT</> statement, the
values of the selected columns are placed in Tcl variables as
described below.
Executes an SQL command given as a string. An error in the command
causes an error to be raised. Otherwise, the return value of <function>spi_exec</function>
is the number of rows processed (selected, inserted, updated, or
deleted) by the command, or zero if the command is a utility
statement. In addition, if the command is a <command>SELECT</> statement, the
values of the selected columns are placed in Tcl variables as
described below.
</para>
<para>
The optional <literal>-count</> value tells
<function>spi_exec</function> the maximum number of rows
to process in the command. The effect of this is comparable to
setting up a query as a cursor and then saying <literal>FETCH <replaceable>n</></>.
The optional <literal>-count</> value tells
<function>spi_exec</function> the maximum number of rows
to process in the command. The effect of this is comparable to
setting up a query as a cursor and then saying <literal>FETCH <replaceable>n</></>.
</para>
<para>
If the command is a <command>SELECT</> statement, the values of the
result columns are placed into Tcl variables named after the columns.
If the command is a <command>SELECT</> statement, the values of the
result columns are placed into Tcl variables named after the columns.
If the <literal>-array</> option is given, the column values are
instead stored into the named associative array, with the
column names used as array indexes.
instead stored into the named associative array, with the
column names used as array indexes.
</para>
<para>
If the command is a <command>SELECT</> statement and no <replaceable>loop-body</>
script is given, then only the first row of results are stored into
Tcl variables; remaining rows, if any, are ignored. No storing occurs
if the
query returns no rows. (This case can be detected by checking the
result of <function>spi_exec</function>.) For example,
script is given, then only the first row of results are stored into
Tcl variables; remaining rows, if any, are ignored. No storing occurs
if the
query returns no rows. (This case can be detected by checking the
result of <function>spi_exec</function>.) For example,
<programlisting>
spi_exec "SELECT count(*) AS cnt FROM pg_proc"
</programlisting>
will set the Tcl variable <literal>$cnt</> to the number of rows in
the <structname>pg_proc</> system catalog.
will set the Tcl variable <literal>$cnt</> to the number of rows in
the <structname>pg_proc</> system catalog.
</para>
<para>
If the optional <replaceable>loop-body</> argument is given, it is
a piece of Tcl script that is executed once for each row in the
query result. (<replaceable>loop-body</> is ignored if the given
command is not a <command>SELECT</>.) The values of the current row's columns
are stored into Tcl variables before each iteration. For example,
a piece of Tcl script that is executed once for each row in the
query result. (<replaceable>loop-body</> is ignored if the given
command is not a <command>SELECT</>.) The values of the current row's columns
are stored into Tcl variables before each iteration. For example,
<programlisting>
spi_exec -array C "SELECT * FROM pg_class" {
@ -288,14 +298,14 @@ spi_exec -array C "SELECT * FROM pg_class" {
}
</programlisting>
will print a log message for every row of <literal>pg_class</>. This
feature works similarly to other Tcl looping constructs; in
particular <literal>continue</> and <literal>break</> work in the
usual way inside the loop body.
will print a log message for every row of <literal>pg_class</>. This
feature works similarly to other Tcl looping constructs; in
particular <literal>continue</> and <literal>break</> work in the
usual way inside the loop body.
</para>
<para>
If a column of a query result is null, the target
variable for it is <quote>unset</> rather than being set.
variable for it is <quote>unset</> rather than being set.
</para>
</listitem>
</varlistentry>
@ -304,27 +314,27 @@ spi_exec -array C "SELECT * FROM pg_class" {
<term><function>spi_prepare</function> <replaceable>query</replaceable> <replaceable>typelist</replaceable></term>
<listitem>
<para>
Prepares and saves a query plan for later execution. The
saved plan will be retained for the life of the current
session.<indexterm><primary>preparing a query</><secondary>in
PL/Tcl</></>
Prepares and saves a query plan for later execution. The
saved plan will be retained for the life of the current
session.<indexterm><primary>preparing a query</><secondary>in
PL/Tcl</></>
</para>
<para>
The query may use parameters, that is, placeholders for
values to be supplied whenever the plan is actually executed.
In the query string, refer to parameters
by the symbols <literal>$1</literal> ... <literal>$<replaceable>n</replaceable></literal>.
If the query uses parameters, the names of the parameter types
must be given as a Tcl list. (Write an empty list for
<replaceable>typelist</replaceable> if no parameters are used.)
Presently, the parameter types must be identified by the internal
type names shown in the system table <literal>pg_type</>; for example <literal>int4</> not
<literal>integer</>.
values to be supplied whenever the plan is actually executed.
In the query string, refer to parameters
by the symbols <literal>$1</literal> ... <literal>$<replaceable>n</replaceable></literal>.
If the query uses parameters, the names of the parameter types
must be given as a Tcl list. (Write an empty list for
<replaceable>typelist</replaceable> if no parameters are used.)
Presently, the parameter types must be identified by the internal
type names shown in the system table <literal>pg_type</>; for example <literal>int4</> not
<literal>integer</>.
</para>
<para>
The return value from <function>spi_prepare</function> is a query ID
to be used in subsequent calls to <function>spi_execp</function>. See
<function>spi_execp</function> for an example.
to be used in subsequent calls to <function>spi_execp</function>. See
<function>spi_execp</function> for an example.
</para>
</listitem>
</varlistentry>
@ -333,31 +343,31 @@ spi_exec -array C "SELECT * FROM pg_class" {
<term><literal><function>spi_execp</> <optional role="tcl">-count <replaceable>n</replaceable></optional> <optional role="tcl">-array <replaceable>name</replaceable></optional> <optional role="tcl">-nulls <replaceable>string</replaceable></optional> <replaceable>queryid</replaceable> <optional role="tcl"><replaceable>value-list</replaceable></optional> <optional role="tcl"><replaceable>loop-body</replaceable></optional></literal></term>
<listitem>
<para>
Executes a query previously prepared with <function>spi_prepare</>.
<replaceable>queryid</replaceable> is the ID returned by
<function>spi_prepare</>. If the query references parameters,
a <replaceable>value-list</replaceable> must be supplied. This
is a Tcl list of actual values for the parameters. The list must be
the same length as the parameter type list previously given to
<function>spi_prepare</>. Omit <replaceable>value-list</replaceable>
if the query has no parameters.
Executes a query previously prepared with <function>spi_prepare</>.
<replaceable>queryid</replaceable> is the ID returned by
<function>spi_prepare</>. If the query references parameters,
a <replaceable>value-list</replaceable> must be supplied. This
is a Tcl list of actual values for the parameters. The list must be
the same length as the parameter type list previously given to
<function>spi_prepare</>. Omit <replaceable>value-list</replaceable>
if the query has no parameters.
</para>
<para>
The optional value for <literal>-nulls</> is a string of spaces and
<literal>'n'</> characters telling <function>spi_execp</function>
which of the parameters are null values. If given, it must have exactly the
same length as the <replaceable>value-list</replaceable>. If it
is not given, all the parameter values are nonnull.
The optional value for <literal>-nulls</> is a string of spaces and
<literal>'n'</> characters telling <function>spi_execp</function>
which of the parameters are null values. If given, it must have exactly the
same length as the <replaceable>value-list</replaceable>. If it
is not given, all the parameter values are nonnull.
</para>
<para>
Except for the way in which the query and its parameters are specified,
<function>spi_execp</> works just like <function>spi_exec</>.
<function>spi_execp</> works just like <function>spi_exec</>.
The <literal>-count</>, <literal>-array</>, and
<replaceable>loop-body</replaceable> options are the same,
and so is the result value.
<replaceable>loop-body</replaceable> options are the same,
and so is the result value.
</para>
<para>
Here's an example of a PL/Tcl function using a prepared plan:
Here's an example of a PL/Tcl function using a prepared plan:
<programlisting>
CREATE FUNCTION t1_count(integer, integer) RETURNS integer AS $$
@ -389,9 +399,9 @@ $$ LANGUAGE pltcl;
<term><function>spi_lastoid</></term>
<listitem>
<para>
Returns the OID of the row inserted by the last
<function>spi_exec</> or <function>spi_execp</>,
if the command was a single-row <command>INSERT</>. (If not, you get zero.)
Returns the OID of the row inserted by the last
<function>spi_exec</> or <function>spi_execp</>,
if the command was a single-row <command>INSERT</>. (If not, you get zero.)
</para>
</listitem>
</varlistentry>
@ -400,43 +410,43 @@ $$ LANGUAGE pltcl;
<term><function>quote</> <replaceable>string</replaceable></term>
<listitem>
<para>
Doubles all occurrences of single quote and backslash characters
in the given string. This may be used to safely quote strings
that are to be inserted into SQL commands given
to <function>spi_exec</function> or
<function>spi_prepare</function>.
For example, think about an SQL command string like
Doubles all occurrences of single quote and backslash characters
in the given string. This may be used to safely quote strings
that are to be inserted into SQL commands given
to <function>spi_exec</function> or
<function>spi_prepare</function>.
For example, think about an SQL command string like
<programlisting>
"SELECT '$val' AS ret"
</programlisting>
where the Tcl variable <literal>val</> actually contains
<literal>doesn't</literal>. This would result
in the final command string
where the Tcl variable <literal>val</> actually contains
<literal>doesn't</literal>. This would result
in the final command string
<programlisting>
SELECT 'doesn't' AS ret
</programlisting>
which would cause a parse error during
<function>spi_exec</function> or
<function>spi_prepare</function>.
To work properly, the submitted command should contain
which would cause a parse error during
<function>spi_exec</function> or
<function>spi_prepare</function>.
To work properly, the submitted command should contain
<programlisting>
SELECT 'doesn''t' AS ret
</programlisting>
which can be formed in PL/Tcl using
which can be formed in PL/Tcl using
<programlisting>
"SELECT '[ quote $val ]' AS ret"
</programlisting>
One advantage of <function>spi_execp</function> is that you don't
have to quote parameter values like this, since the parameters are never
parsed as part of an SQL command string.
have to quote parameter values like this, since the parameters are never
parsed as part of an SQL command string.
</para>
</listitem>
</varlistentry>
@ -452,8 +462,7 @@ SELECT 'doesn''t' AS ret
Emits a log or error message. Possible levels are
<literal>DEBUG</>, <literal>LOG</>, <literal>INFO</>,
<literal>NOTICE</>, <literal>WARNING</>, <literal>ERROR</>, and
<literal>FATAL</>. Most simply emit the given message just like
the <literal>elog</> C function. <literal>ERROR</>
<literal>FATAL</>. <literal>ERROR</>
raises an error condition; if this is not trapped by the surrounding
Tcl code, the error propagates out to the calling query, causing
the current transaction or subtransaction to be aborted. This
@ -461,7 +470,14 @@ SELECT 'doesn''t' AS ret
<literal>FATAL</> aborts the transaction and causes the current
session to shut down. (There is probably no good reason to use
this error level in PL/Tcl functions, but it's provided for
completeness.)
completeness.) The other levels only generate messages of different
priority levels.
Whether messages of a particular priority are reported to the client,
written to the server log, or both is controlled by the
<xref linkend="guc-log-min-messages"> and
<xref linkend="guc-client-min-messages"> configuration
variables. See <xref linkend="runtime-config"> for more
information.
</para>
</listitem>
</varlistentry>
@ -494,100 +510,100 @@ SELECT 'doesn''t' AS ret
<varlistentry>
<term><varname>$TG_name</varname></term>
<listitem>
<para>
The name of the trigger from the <command>CREATE TRIGGER</command> statement.
</para>
<para>
The name of the trigger from the <command>CREATE TRIGGER</command> statement.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><varname>$TG_relid</varname></term>
<listitem>
<para>
The object ID of the table that caused the trigger procedure
to be invoked.
</para>
<para>
The object ID of the table that caused the trigger procedure
to be invoked.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><varname>$TG_relatts</varname></term>
<listitem>
<para>
A Tcl list of the table column names, prefixed with an empty list
<para>
A Tcl list of the table column names, prefixed with an empty list
element. So looking up a column name in the list with <application>Tcl</>'s
<function>lsearch</> command returns the element's number starting
with 1 for the first column, the same way the columns are customarily
numbered in <productname>PostgreSQL</productname>. (Empty list
elements also appear in the positions of columns that have been
dropped, so that the attribute numbering is correct for columns
to their right.)
</para>
with 1 for the first column, the same way the columns are customarily
numbered in <productname>PostgreSQL</productname>. (Empty list
elements also appear in the positions of columns that have been
dropped, so that the attribute numbering is correct for columns
to their right.)
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><varname>$TG_when</varname></term>
<listitem>
<para>
The string <literal>BEFORE</> or <literal>AFTER</> depending on the
type of trigger call.
</para>
<para>
The string <literal>BEFORE</> or <literal>AFTER</> depending on the
type of trigger call.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><varname>$TG_level</varname></term>
<listitem>
<para>
The string <literal>ROW</> or <literal>STATEMENT</> depending on the
type of trigger call.
</para>
<para>
The string <literal>ROW</> or <literal>STATEMENT</> depending on the
type of trigger call.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><varname>$TG_op</varname></term>
<listitem>
<para>
The string <literal>INSERT</>, <literal>UPDATE</>, or
<literal>DELETE</> depending on the type of trigger call.
</para>
<para>
The string <literal>INSERT</>, <literal>UPDATE</>, or
<literal>DELETE</> depending on the type of trigger call.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><varname>$NEW</varname></term>
<listitem>
<para>
An associative array containing the values of the new table
row for <command>INSERT</> or <command>UPDATE</> actions, or
empty for <command>DELETE</>. The array is indexed by column
name. Columns that are null will not appear in the array.
</para>
<para>
An associative array containing the values of the new table
row for <command>INSERT</> or <command>UPDATE</> actions, or
empty for <command>DELETE</>. The array is indexed by column
name. Columns that are null will not appear in the array.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><varname>$OLD</varname></term>
<listitem>
<para>
An associative array containing the values of the old table
row for <command>UPDATE</> or <command>DELETE</> actions, or
empty for <command>INSERT</>. The array is indexed by column
name. Columns that are null will not appear in the array.
</para>
<para>
An associative array containing the values of the old table
row for <command>UPDATE</> or <command>DELETE</> actions, or
empty for <command>INSERT</>. The array is indexed by column
name. Columns that are null will not appear in the array.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><varname>$args</varname></term>
<listitem>
<para>
A Tcl list of the arguments to the procedure as given in the
<command>CREATE TRIGGER</command> statement. These arguments are also accessible as
<literal>$1</literal> ... <literal>$<replaceable>n</replaceable></literal> in the procedure body.
</para>
<para>
A Tcl list of the arguments to the procedure as given in the
<command>CREATE TRIGGER</command> statement. These arguments are also accessible as
<literal>$1</literal> ... <literal>$<replaceable>n</replaceable></literal> in the procedure body.
</para>
</listitem>
</varlistentry>
@ -644,39 +660,39 @@ CREATE TRIGGER trig_mytab_modcount BEFORE INSERT OR UPDATE ON mytab
<sect1 id="pltcl-unknown">
<title>Modules and the <function>unknown</> command</title>
<para>
PL/Tcl has support for autoloading Tcl code when used.
It recognizes a special table, <literal>pltcl_modules</>, which
is presumed to contain modules of Tcl code. If this table
exists, the module <literal>unknown</> is fetched from the table
and loaded into the Tcl interpreter immediately after creating
the interpreter.
PL/Tcl has support for autoloading Tcl code when used.
It recognizes a special table, <literal>pltcl_modules</>, which
is presumed to contain modules of Tcl code. If this table
exists, the module <literal>unknown</> is fetched from the table
and loaded into the Tcl interpreter immediately after creating
the interpreter.
</para>
<para>
While the <literal>unknown</> module could actually contain any
initialization script you need, it normally defines a Tcl
<function>unknown</> procedure that is invoked whenever Tcl does
not recognize an invoked procedure name. <application>PL/Tcl</>'s standard version
of this procedure tries to find a module in <literal>pltcl_modules</>
that will define the required procedure. If one is found, it is
loaded into the interpreter, and then execution is allowed to
proceed with the originally attempted procedure call. A
secondary table <literal>pltcl_modfuncs</> provides an index of
which functions are defined by which modules, so that the lookup
is reasonably quick.
initialization script you need, it normally defines a Tcl
<function>unknown</> procedure that is invoked whenever Tcl does
not recognize an invoked procedure name. <application>PL/Tcl</>'s standard version
of this procedure tries to find a module in <literal>pltcl_modules</>
that will define the required procedure. If one is found, it is
loaded into the interpreter, and then execution is allowed to
proceed with the originally attempted procedure call. A
secondary table <literal>pltcl_modfuncs</> provides an index of
which functions are defined by which modules, so that the lookup
is reasonably quick.
</para>
<para>
The <productname>PostgreSQL</productname> distribution includes
support scripts to maintain these tables:
<command>pltcl_loadmod</>, <command>pltcl_listmod</>,
<command>pltcl_delmod</>, as well as source for the standard
<literal>unknown</> module in <filename>share/unknown.pltcl</>. This module
must be loaded
into each database initially to support the autoloading mechanism.
support scripts to maintain these tables:
<command>pltcl_loadmod</>, <command>pltcl_listmod</>,
<command>pltcl_delmod</>, as well as source for the standard
<literal>unknown</> module in <filename>share/unknown.pltcl</>. This module
must be loaded
into each database initially to support the autoloading mechanism.
</para>
<para>
The tables <literal>pltcl_modules</> and <literal>pltcl_modfuncs</>
must be readable by all, but it is wise to make them owned and
writable only by the database administrator.
must be readable by all, but it is wise to make them owned and
writable only by the database administrator.
</para>
</sect1>

View File

@ -1,5 +1,5 @@
<!--
$PostgreSQL: pgsql/doc/src/sgml/spi.sgml,v 1.36 2004/12/13 18:05:09 petere Exp $
$PostgreSQL: pgsql/doc/src/sgml/spi.sgml,v 1.37 2004/12/30 21:45:37 tgl Exp $
-->
<chapter id="spi">
@ -23,8 +23,8 @@ $PostgreSQL: pgsql/doc/src/sgml/spi.sgml,v 1.36 2004/12/13 18:05:09 petere Exp $
<note>
<para>
The available procedural languages provide various means to
execute SQL commands from procedures. Some of these are based on or
modelled after SPI, so this documentation might be of use for users
execute SQL commands from procedures. Most of these facilities are
based on SPI, so this documentation might be of use for users
of those languages as well.
</para>
</note>
@ -37,15 +37,15 @@ $PostgreSQL: pgsql/doc/src/sgml/spi.sgml,v 1.36 2004/12/13 18:05:09 petere Exp $
</para>
<para>
Note that if during the execution of a procedure the transaction is
aborted because of an error in a command, then control will not be
returned to your procedure. Rather, all work will be rolled back
and the server will wait for the next command from the client. A
related restriction is the inability to execute
<command>BEGIN</command>, <command>COMMIT</command>, and
<command>ROLLBACK</command> (transaction control statements) inside
a procedure. Both of these restrictions will probably be changed in
the future.
Note that if a command invoked via SPI fails, then control will not be
returned to your procedure. Rather, the
transaction or subtransaction in which your procedure executes will be
rolled back. (This may seem surprising given that the SPI functions mostly
have documented error-return conventions. Those conventions only apply
for errors detected within the SPI functions themselves, however.)
It is possible to recover control after an error by establishing your own
subtransaction surrounding SPI calls that might fail. This is not currently
documented because the mechanisms required are still in flux.
</para>
<para>
@ -104,6 +104,7 @@ int SPI_connect(void)
<acronym>SPI</acronym>, directly nested calls to
<function>SPI_connect</function> and
<function>SPI_finish</function> are forbidden.
(But see <function>SPI_push</function> and <function>SPI_pop</function>.)
</para>
</refsect1>
@ -206,7 +207,7 @@ int SPI_finish(void)
<refnamediv>
<refname>SPI_push</refname>
<refpurpose>pushes SPI stack to allow recursive SPI usage</refpurpose>
<refpurpose>push SPI stack to allow recursive SPI usage</refpurpose>
</refnamediv>
<indexterm><primary>SPI_push</primary></indexterm>
@ -253,7 +254,7 @@ void SPI_push(void)
<refnamediv>
<refname>SPI_pop</refname>
<refpurpose>pops SPI stack to return from recursive SPI usage</refpurpose>
<refpurpose>pop SPI stack to return from recursive SPI usage</refpurpose>
</refnamediv>
<indexterm><primary>SPI_pop</primary></indexterm>
@ -322,8 +323,8 @@ SPI_execute("INSERT INTO foo SELECT * FROM bar", false, 5);
</para>
<para>
You may pass multiple commands in one string, and the commands may
be rewritten by rules. <function>SPI_execute</function> returns the
You may pass multiple commands in one string.
<function>SPI_execute</function> returns the
result for the command executed last. The <parameter>count</parameter>
limit applies to each command separately, but it is not applied to
hidden commands generated by rules.
@ -693,7 +694,7 @@ void * SPI_prepare(const char * <parameter>command</parameter>, int <parameter>n
<para>
The plan returned by <function>SPI_prepare</function> can be used
only in the current invocation of the procedure since
only in the current invocation of the procedure, since
<function>SPI_finish</function> frees memory allocated for a plan.
But a plan can be saved for longer using the function
<function>SPI_saveplan</function>.
@ -770,7 +771,7 @@ void * SPI_prepare(const char * <parameter>command</parameter>, int <parameter>n
<refnamediv>
<refname>SPI_getargcount</refname>
<refpurpose>returns the number of arguments needed by a plan
<refpurpose>return the number of arguments needed by a plan
prepared by <function>SPI_prepare</function></refpurpose>
</refnamediv>
@ -825,7 +826,7 @@ int SPI_getargcount(void * <parameter>plan</parameter>)
<refnamediv>
<refname>SPI_getargtypeid</refname>
<refpurpose>returns the expected <parameter>typeid</parameter> for the specified argument of
<refpurpose>return the data type OID for an argument of
a plan prepared by <function>SPI_prepare</function></refpurpose>
</refnamediv>
@ -892,7 +893,7 @@ Oid SPI_getargtypeid(void * <parameter>plan</parameter>, int <parameter>argIndex
<refnamediv>
<refname>SPI_is_cursor_plan</refname>
<refpurpose>returns <symbol>true</symbol> if a plan
<refpurpose>return <symbol>true</symbol> if a plan
prepared by <function>SPI_prepare</function> can be used with
<function>SPI_cursor_open</function></refpurpose>
</refnamediv>
@ -954,7 +955,7 @@ bool SPI_is_cursor_plan(void * <parameter>plan</parameter>)
<refnamediv>
<refname>SPI_execute_plan</refname>
<refpurpose>executes a plan prepared by <function>SPI_prepare</function></refpurpose>
<refpurpose>execute a plan prepared by <function>SPI_prepare</function></refpurpose>
</refnamediv>
<indexterm><primary>SPI_execute_plan</primary></indexterm>
@ -1096,7 +1097,7 @@ int SPI_execute_plan(void * <parameter>plan</parameter>, Datum * <parameter>valu
<refnamediv>
<refname>SPI_execp</refname>
<refpurpose>executes a plan in read/write mode</refpurpose>
<refpurpose>execute a plan in read/write mode</refpurpose>
</refnamediv>
<indexterm><primary>SPI_execp</primary></indexterm>
@ -1677,7 +1678,7 @@ char * SPI_fname(TupleDesc <parameter>rowdesc</parameter>, int <parameter>colnum
<title>Description</title>
<para>
<function>SPI_fname</function> returns the column name of the
<function>SPI_fname</function> returns a copy of the column name of the
specified column. (You can use <function>pfree</function> to
release the copy of the name when you don't need it anymore.)
</para>
@ -1992,7 +1993,7 @@ char * SPI_gettype(TupleDesc <parameter>rowdesc</parameter>, int <parameter>coln
<title>Description</title>
<para>
<function>SPI_gettype</function> returns the data type name of the
<function>SPI_gettype</function> returns a copy of the data type name of the
specified column. (You can use <function>pfree</function> to
release the copy of the name when you don't need it anymore.)
</para>
@ -2122,7 +2123,7 @@ char * SPI_getrelname(Relation <parameter>rel</parameter>)
<title>Description</title>
<para>
<function>SPI_getrelname</function> returns the name of the
<function>SPI_getrelname</function> returns a copy of the name of the
specified relation. (You can use <function>pfree</function> to
release the copy of the name when you don't need it anymore.)
</para>
@ -2190,7 +2191,7 @@ char * SPI_getrelname(Relation <parameter>rel</parameter>)
object. <function>SPI_palloc</function> allocates memory in the
<quote>upper executor context</quote>, that is, the memory context
that was current when <function>SPI_connect</function> was called,
which is precisely the right context for return a value from your
which is precisely the right context for a value returned from your
procedure.
</para>
@ -2600,7 +2601,7 @@ HeapTuple SPI_modifytuple(Relation <parameter>rel</parameter>, HeapTuple <parame
<listitem>
<para>
array of the numbers of the columns that are to be changed
(count starts at 1)
(column numbers start at 1)
</para>
</listitem>
</varlistentry>
@ -2674,7 +2675,7 @@ HeapTuple SPI_modifytuple(Relation <parameter>rel</parameter>, HeapTuple <parame
<refnamediv>
<refname>SPI_freetuple</refname>
<refpurpose>frees a row allocated in the upper executor context</refpurpose>
<refpurpose>free a row allocated in the upper executor context</refpurpose>
</refnamediv>
<indexterm><primary>SPI_freetuple</primary></indexterm>
@ -2833,16 +2834,15 @@ int SPI_freeplan(void *<parameter>plan</parameter>)
<title>Visibility of Data Changes</title>
<para>
The following two rules govern the visibility of data changes in
The following rules govern the visibility of data changes in
functions that use SPI (or any other C function):
<itemizedlist>
<listitem>
<para>
During the execution of an SQL command, any data changes made by
the command (or by function called by the command, including
trigger functions) are invisible to the command. For
example, in command
the command are invisible to the command itself. For
example, in
<programlisting>
INSERT INTO a SELECT * FROM a;
</programlisting>
@ -2858,6 +2858,29 @@ INSERT INTO a SELECT * FROM a;
(during the execution of C) or after C is done.
</para>
</listitem>
<listitem>
<para>
Commands executed via SPI inside a function called by an SQL command
(either an ordinary function or a trigger) follow one or the
other of the above rules depending on the read/write flag passed
to SPI. Commands executed in read-only mode follow the first
rule: they can't see changes of the calling command. Commands executed
in read-write mode follow the second rule: they can see all changes made
so far.
</para>
</listitem>
<listitem>
<para>
All standard procedural languages set the SPI read-write mode
depending on the volatility attribute of the function. Commands of
<literal>STABLE</> and <literal>IMMUTABLE</> functions are done in
read-only mode, while commands of <literal>VOLATILE</> functions are
done in read-write mode. While authors of C functions are able to
violate this convention, it's unlikely to be a good idea to do so.
</para>
</listitem>
</itemizedlist>
</para>
@ -2934,7 +2957,7 @@ execq(text *sql, int cnt)
<para>
(This function uses call convention version 0, to make the example
easier to understand. In real applications you should user the new
easier to understand. In real applications you should use the new
version 1 interface.)
</para>

View File

@ -1,5 +1,5 @@
<!--
$PostgreSQL: pgsql/doc/src/sgml/xfunc.sgml,v 1.91 2004/12/30 03:13:56 tgl Exp $
$PostgreSQL: pgsql/doc/src/sgml/xfunc.sgml,v 1.92 2004/12/30 21:45:37 tgl Exp $
-->
<sect1 id="xfunc">
@ -823,23 +823,15 @@ CREATE FUNCTION test(int, int) RETURNS int
<title>Procedural Language Functions</title>
<para>
<productname>PostgreSQL</productname> allows user-defined functions
to be written in other languages besides SQL and C. These other
languages are generically called <firstterm>procedural
languages</firstterm> (<acronym>PL</>s).
Procedural languages aren't built into the
<productname>PostgreSQL</productname> server; they are offered
by loadable modules. Please refer to the documentation of the
procedural language in question for details about the syntax and how the
function body is interpreted for each language.
</para>
<para>
There are currently four procedural languages available in the
standard <productname>PostgreSQL</productname> distribution:
<application>PL/pgSQL</application>, <application>PL/Tcl</application>,
<application>PL/Perl</application>, and
<application>PL/Python</application>.
Refer to <xref linkend="xplang"> for more information.
Other languages can be defined by users.
The basics of developing a new procedural language are covered in <xref
linkend="plhandler">.
by loadable modules.
See <xref linkend="xplang"> and following chapters for more
information.
</para>
</sect1>

View File

@ -1,5 +1,5 @@
<!--
$PostgreSQL: pgsql/doc/src/sgml/xplang.sgml,v 1.27 2004/12/30 03:13:56 tgl Exp $
$PostgreSQL: pgsql/doc/src/sgml/xplang.sgml,v 1.28 2004/12/30 21:45:37 tgl Exp $
-->
<chapter id="xplang">
@ -10,27 +10,32 @@ $PostgreSQL: pgsql/doc/src/sgml/xplang.sgml,v 1.27 2004/12/30 03:13:56 tgl Exp $
</indexterm>
<para>
<productname>PostgreSQL</productname> allows users to add new
programming languages to be available for writing functions and
procedures. These are called <firstterm>procedural
languages</firstterm> (PL). In the case of a function or trigger
procedure written in a procedural language, the database server has
<productname>PostgreSQL</productname> allows user-defined functions
to be written in other languages besides SQL and C. These other
languages are generically called <firstterm>procedural
languages</firstterm> (<acronym>PL</>s). For a function
written in a procedural language, the database server has
no built-in knowledge about how to interpret the function's source
text. Instead, the task is passed to a special handler that knows
the details of the language. The handler could either do all the
work of parsing, syntax analysis, execution, etc. itself, or it
could serve as <quote>glue</quote> between
<productname>PostgreSQL</productname> and an existing implementation
of a programming language. The handler itself is a special
of a programming language. The handler itself is a
C language function compiled into a shared object and
loaded on demand.
loaded on demand, just like any other C function.
</para>
<para>
Writing a handler for a new procedural language is described in
<xref linkend="plhandler">. Several procedural languages are
available in the core <productname>PostgreSQL</productname>
distribution, which can serve as examples.
There are currently four procedural languages available in the
standard <productname>PostgreSQL</productname> distribution:
<application>PL/pgSQL</application> (<xref linkend="plpgsql">),
<application>PL/Tcl</application> (<xref linkend="pltcl">),
<application>PL/Perl</application> (<xref linkend="plperl">), and
<application>PL/Python</application> (<xref linkend="plpython">).
Other languages can be defined by users.
The basics of developing a new procedural language are covered in <xref
linkend="plhandler">.
</para>
<para>
@ -46,14 +51,16 @@ $PostgreSQL: pgsql/doc/src/sgml/xplang.sgml,v 1.27 2004/12/30 03:13:56 tgl Exp $
A procedural language must be <quote>installed</quote> into each
database where it is to be used. But procedural languages installed in
the database <literal>template1</> are automatically available in all
subsequently created databases. So the database administrator can
subsequently created databases, since their entries in
<literal>template1</> will be copied by <command>CREATE DATABASE</>.
So the database administrator can
decide which languages are available in which databases and can make
some languages available by default if he chooses.
</para>
<para>
For the languages supplied with the standard distribution, the
program <command>createlang</command> may be used to install the
program <xref linkend="app-createlang"> may be used to install the
language instead of carrying out the details by hand. For
example, to install the language
<application>PL/pgSQL</application> into the database
@ -72,23 +79,24 @@ createlang plpgsql template1
</title>
<para>
A procedural language is installed in a database in three steps,
A procedural language is installed in a database in four steps,
which must be carried out by a database superuser. The
<command>createlang</command> program automates <xref
linkend="xplang-install-cr1"> and <xref
linkend="xplang-install-cr2">.
<command>createlang</command> program automates all but <xref
linkend="xplang-install-cr1">.
</para>
<step performance="required">
<step performance="required" id="xplang-install-cr1">
<para>
The shared object for the language handler must be compiled and
installed into an appropriate library directory. This works in the same
way as building and installing modules with regular user-defined C
functions does; see <xref linkend="dfunc">.
functions does; see <xref linkend="dfunc">. Often, the language
handler will depend on an external library that provides the actual
programming language engine; if so, that must be installed as well.
</para>
</step>
<step performance="required" id="xplang-install-cr1">
<step performance="required" id="xplang-install-cr2">
<para>
The handler must be declared with the command
<synopsis>
@ -104,12 +112,29 @@ CREATE FUNCTION <replaceable>handler_function_name</replaceable>()
</para>
</step>
<step performance="required" id="xplang-install-cr2">
<step performance="optional" id="xplang-install-cr3">
<para>
Optionally, the language handler may provide a <quote>validator</>
function that checks a function definition for correctness without
actually executing it. The validator function is called by
<command>CREATE FUNCTION</> if it exists. If a validator function
is provided by the handler, declare it with a command like
<synopsis>
CREATE FUNCTION <replaceable>validator_function_name</replaceable>(oid)
RETURNS void
AS '<replaceable>path-to-shared-object</replaceable>'
LANGUAGE C;
</synopsis>
</para>
</step>
<step performance="required" id="xplang-install-cr4">
<para>
The PL must be declared with the command
<synopsis>
CREATE <optional>TRUSTED</optional> <optional>PROCEDURAL</optional> LANGUAGE <replaceable>language-name</replaceable>
HANDLER <replaceable>handler_function_name</replaceable>;
HANDLER <replaceable>handler_function_name</replaceable>
<optional>VALIDATOR <replaceable>validator_function_name</replaceable></optional> ;
</synopsis>
The optional key word <literal>TRUSTED</literal> specifies that
ordinary database users that have no superuser privileges should
@ -150,13 +175,24 @@ CREATE FUNCTION plpgsql_call_handler() RETURNS language_handler AS
</programlisting>
</para>
<para>
<application>PL/pgSQL</application> has a validator function,
so we declare that too:
<programlisting>
CREATE FUNCTION plpgsql_validator(oid) RETURNS void AS
'$libdir/plpgsql' LANGUAGE C;
</programlisting>
</para>
<para>
The command
<programlisting>
CREATE TRUSTED PROCEDURAL LANGUAGE plpgsql
HANDLER plpgsql_call_handler;
HANDLER plpgsql_call_handler
VALIDATOR plpgsql_validator;
</programlisting>
then defines that the previously declared call handler function
then defines that the previously declared functions
should be invoked for functions and trigger procedures where the
language attribute is <literal>plpgsql</literal>.
</para>
@ -166,7 +202,7 @@ CREATE TRUSTED PROCEDURAL LANGUAGE plpgsql
In a default <productname>PostgreSQL</productname> installation,
the handler for the <application>PL/pgSQL</application> language
is built and installed into the <quote>library</quote>
directory. If <application>Tcl/Tk</> support is configured in, the handlers for
directory. If <application>Tcl</> support is configured in, the handlers for
<application>PL/Tcl</> and <application>PL/TclU</> are also built and installed in the same
location. Likewise, the <application>PL/Perl</> and <application>PL/PerlU</> handlers are built
and installed if Perl support is configured, and <application>PL/PythonU</> is