mirror of
https://github.com/postgres/postgres.git
synced 2025-08-27 07:42:10 +03:00
operations are now run as subtransactions, so that errors in them can be reported as ordinary Perl or Tcl errors and caught by the normal error handling convention of those languages. Also do some minor code cleanup in pltcl.c: extract a large chunk of duplicated code in pltcl_SPI_execute and pltcl_SPI_execute_plan into a shared subroutine.
719 lines
26 KiB
Plaintext
719 lines
26 KiB
Plaintext
<!--
|
|
$PostgreSQL: pgsql/doc/src/sgml/pltcl.sgml,v 2.32 2004/11/21 21:17:02 tgl Exp $
|
|
-->
|
|
|
|
<chapter id="pltcl">
|
|
<title>PL/Tcl - Tcl Procedural Language</title>
|
|
|
|
<indexterm zone="pltcl">
|
|
<primary>PL/Tcl</primary>
|
|
</indexterm>
|
|
|
|
<indexterm zone="pltcl">
|
|
<primary>Tcl</primary>
|
|
</indexterm>
|
|
|
|
<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
|
|
trigger procedures.
|
|
</para>
|
|
|
|
<!-- **** PL/Tcl overview **** -->
|
|
|
|
<sect1 id="pltcl-overview">
|
|
<title>Overview</title>
|
|
|
|
<para>
|
|
PL/Tcl offers most of the capabilities a function
|
|
writer has in the C language, except for some restrictions.
|
|
</para>
|
|
<para>
|
|
The good restriction is that everything is executed in a safe
|
|
Tcl interpreter. In addition to the limited command set of safe Tcl, only
|
|
a few commands are available to access the database via SPI and to raise
|
|
messages via <function>elog()</>. There is no way to access internals of the
|
|
database server or to gain OS-level access under the permissions of the
|
|
<productname>PostgreSQL</productname> server process, as a C function can do.
|
|
Thus, any unprivileged database user may be
|
|
permitted to use this language.
|
|
</para>
|
|
<para>
|
|
The other, implementation restriction is that Tcl functions cannot
|
|
be used to create input/output functions for new data types.
|
|
</para>
|
|
<para>
|
|
Sometimes it is desirable to write Tcl functions that are not restricted
|
|
to safe Tcl. For example, one might want a Tcl function that sends
|
|
email. To handle these cases, there is a variant of <application>PL/Tcl</> called <literal>PL/TclU</>
|
|
(for untrusted Tcl). This is the exact same language except that a full
|
|
Tcl interpreter is used. <emphasis>If <application>PL/TclU</> is used, it must be
|
|
installed as an untrusted procedural language</emphasis> so that only
|
|
database superusers can create functions in it. The writer of a <application>PL/TclU</>
|
|
function must take care that the function cannot be used to do anything
|
|
unwanted, since it will be able to do anything that could be done by
|
|
a user logged in as the database administrator.
|
|
</para>
|
|
<para>
|
|
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
|
|
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
|
|
<literal>createlang pltcl <replaceable>dbname</></literal> or
|
|
<literal>createlang pltclu <replaceable>dbname</></literal>.
|
|
</para>
|
|
</sect1>
|
|
|
|
<!-- **** PL/Tcl description **** -->
|
|
|
|
<sect1 id="pltcl-functions">
|
|
<title>PL/Tcl Functions and Arguments</title>
|
|
|
|
<para>
|
|
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 $$
|
|
# PL/Tcl function body
|
|
$$ LANGUAGE pltcl;
|
|
</programlisting>
|
|
|
|
<application>PL/TclU</> is the same, except that the language has to be specified as
|
|
<literal>pltclu</>.
|
|
</para>
|
|
|
|
<para>
|
|
The body of the function is simply a piece of Tcl script.
|
|
When the function is called, the argument values are passed as
|
|
variables <literal>$1</literal> ... <literal>$<replaceable>n</replaceable></literal> to the
|
|
Tcl script. The result is returned
|
|
from the Tcl code in the usual way, with a <literal>return</literal>
|
|
statement.
|
|
</para>
|
|
|
|
<para>
|
|
For example, a function
|
|
returning the greater of two integer values could be defined as:
|
|
|
|
<programlisting>
|
|
CREATE FUNCTION tcl_max(integer, integer) RETURNS integer AS $$
|
|
if {$1 > $2} {return $1}
|
|
return $2
|
|
$$ LANGUAGE pltcl STRICT;
|
|
</programlisting>
|
|
|
|
Note the clause <literal>STRICT</>, which saves us from
|
|
having to think about null input values: if a null value is passed, the
|
|
function will not be called at all, but will just return a null
|
|
result automatically.
|
|
</para>
|
|
|
|
<para>
|
|
In a nonstrict function,
|
|
if the actual value of an argument is null, the corresponding
|
|
<literal>$<replaceable>n</replaceable></literal> variable will be set to an empty string.
|
|
To detect whether a particular argument is null, use the function
|
|
<literal>argisnull</>. For example, suppose that we wanted <function>tcl_max</function>
|
|
with one null and one nonnull argument to return the nonnull
|
|
argument, rather than null:
|
|
|
|
<programlisting>
|
|
CREATE FUNCTION tcl_max(integer, integer) RETURNS integer AS $$
|
|
if {[argisnull 1]} {
|
|
if {[argisnull 2]} { return_null }
|
|
return $2
|
|
}
|
|
if {[argisnull 2]} { return $1 }
|
|
if {$1 > $2} {return $1}
|
|
return $2
|
|
$$ LANGUAGE pltcl;
|
|
</programlisting>
|
|
</para>
|
|
|
|
<para>
|
|
As shown above,
|
|
to return a null value from a PL/Tcl function, execute
|
|
<literal>return_null</literal>. This can be done whether the
|
|
function is strict or not.
|
|
</para>
|
|
|
|
<para>
|
|
Composite-type arguments are passed to the function as Tcl
|
|
arrays. The element names of the array are the attribute names
|
|
of the composite type. If an attribute in the passed row has the
|
|
null value, it will not appear in the array. Here is an example:
|
|
|
|
<programlisting>
|
|
CREATE TABLE employee (
|
|
name text,
|
|
salary integer,
|
|
age integer
|
|
);
|
|
|
|
CREATE FUNCTION overpaid(employee) RETURNS boolean AS $$
|
|
if {200000.0 < $1(salary)} {
|
|
return "t"
|
|
}
|
|
if {$1(age) < 30 && 100000.0 < $1(salary)} {
|
|
return "t"
|
|
}
|
|
return "f"
|
|
$$ LANGUAGE pltcl;
|
|
</programlisting>
|
|
</para>
|
|
|
|
<para>
|
|
There is currently no support for returning a composite-type
|
|
result value.
|
|
</para>
|
|
|
|
</sect1>
|
|
|
|
<sect1 id="pltcl-data">
|
|
<title>Data Values in PL/Tcl</title>
|
|
|
|
<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</>
|
|
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.
|
|
</para>
|
|
|
|
</sect1>
|
|
|
|
<sect1 id="pltcl-global">
|
|
<title>Global Data in PL/Tcl</title>
|
|
|
|
<indexterm zone="pltcl-global">
|
|
<primary>global data</primary>
|
|
<secondary>in PL/Tcl</secondary>
|
|
</indexterm>
|
|
|
|
<para>
|
|
Sometimes it
|
|
is useful to have some global data that is held between two
|
|
calls to a function or is shared between different functions.
|
|
This is easily done since
|
|
all PL/Tcl functions executed in one session share the same
|
|
safe Tcl interpreter. So, any global Tcl variable is accessible to
|
|
all PL/Tcl function calls and will persist for the duration of the
|
|
SQL session. (Note that <application>PL/TclU</> functions likewise share
|
|
global data, but they are in a different Tcl interpreter and cannot
|
|
communicate with PL/Tcl functions.)
|
|
</para>
|
|
<para>
|
|
To help protect PL/Tcl functions from unintentionally interfering
|
|
with each other, a global
|
|
array is made available to each function via the <function>upvar</>
|
|
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.
|
|
</para>
|
|
|
|
<para>
|
|
An example of using <literal>GD</> appears in the
|
|
<function>spi_execp</function> example below.
|
|
</para>
|
|
</sect1>
|
|
|
|
<sect1 id="pltcl-dbaccess">
|
|
<title>Database Access from PL/Tcl</title>
|
|
|
|
<para>
|
|
The following commands are available to access the database from
|
|
the body of a PL/Tcl function:
|
|
|
|
<variablelist>
|
|
|
|
<varlistentry>
|
|
<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.
|
|
</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</></>.
|
|
</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 <literal>-array</> option is given, the column values are
|
|
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,
|
|
|
|
<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.
|
|
</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,
|
|
|
|
<programlisting>
|
|
spi_exec -array C "SELECT * FROM pg_class" {
|
|
elog DEBUG "have table $C(relname)"
|
|
}
|
|
</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.
|
|
</para>
|
|
<para>
|
|
If a column of a query result is null, the target
|
|
variable for it is <quote>unset</> rather than being set.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<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</></>
|
|
</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</>.
|
|
</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.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<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.
|
|
</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.
|
|
</para>
|
|
<para>
|
|
Except for the way in which the query and its parameters are specified,
|
|
<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.
|
|
</para>
|
|
<para>
|
|
Here's an example of a PL/Tcl function using a prepared plan:
|
|
|
|
<programlisting>
|
|
CREATE FUNCTION t1_count(integer, integer) RETURNS integer AS $$
|
|
if {![ info exists GD(plan) ]} {
|
|
# prepare the saved plan on the first call
|
|
set GD(plan) [ spi_prepare \
|
|
"SELECT count(*) AS cnt FROM t1 WHERE num >= \$1 AND num <= \$2" \
|
|
[ list int4 int4 ] ]
|
|
}
|
|
spi_execp -count 1 $GD(plan) [ list $1 $2 ]
|
|
return $cnt
|
|
$$ LANGUAGE pltcl;
|
|
</programlisting>
|
|
|
|
We need backslashes inside the query string given to
|
|
<function>spi_prepare</> to ensure that the
|
|
<literal>$<replaceable>n</replaceable></> markers will be passed
|
|
through to <function>spi_prepare</> as-is, and not replaced by Tcl
|
|
variable substitution.
|
|
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<indexterm>
|
|
<primary>spi_lastoid</primary>
|
|
</indexterm>
|
|
<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.)
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<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
|
|
|
|
<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
|
|
|
|
<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
|
|
|
|
<programlisting>
|
|
SELECT 'doesn''t' AS ret
|
|
</programlisting>
|
|
|
|
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.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<indexterm>
|
|
<primary>elog</primary>
|
|
<secondary>in PL/Tcl</secondary>
|
|
</indexterm>
|
|
<term><function>elog</> <replaceable>level</replaceable> <replaceable>msg</replaceable></term>
|
|
<listitem>
|
|
<para>
|
|
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</>
|
|
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
|
|
is effectively the same as the Tcl <literal>error</> command.
|
|
<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.)
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
</variablelist>
|
|
</para>
|
|
|
|
</sect1>
|
|
|
|
<sect1 id="pltcl-trigger">
|
|
<title>Trigger Procedures in PL/Tcl</title>
|
|
|
|
<indexterm>
|
|
<primary>trigger</primary>
|
|
<secondary>in PL/Tcl</secondary>
|
|
</indexterm>
|
|
|
|
<para>
|
|
Trigger procedures can be written in PL/Tcl.
|
|
<productname>PostgreSQL</productname> requires that a procedure that is to be called
|
|
as a trigger must be declared as a function with no arguments
|
|
and a return type of <literal>trigger</>.
|
|
</para>
|
|
<para>
|
|
The information from the trigger manager is passed to the procedure body
|
|
in the following variables:
|
|
|
|
<variablelist>
|
|
|
|
<varlistentry>
|
|
<term><varname>$TG_name</varname></term>
|
|
<listitem>
|
|
<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>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><varname>$TG_relatts</varname></term>
|
|
<listitem>
|
|
<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>
|
|
</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>
|
|
</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>
|
|
</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>
|
|
</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>
|
|
</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>
|
|
</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>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
</variablelist>
|
|
</para>
|
|
|
|
<para>
|
|
The return value from a trigger procedure can be one of the strings
|
|
<literal>OK</> or <literal>SKIP</>, or a list as returned by the
|
|
<literal>array get</> Tcl command. If the return value is <literal>OK</>,
|
|
the operation (<command>INSERT</>/<command>UPDATE</>/<command>DELETE</>) that fired the trigger will proceed
|
|
normally. <literal>SKIP</> tells the trigger manager to silently suppress
|
|
the operation for this row. If a list is returned, it tells PL/Tcl to
|
|
return a modified row to the trigger manager that will be inserted
|
|
instead of the one given in <varname>$NEW</>. (This works for <command>INSERT</> and <command>UPDATE</>
|
|
only.) Needless to say that all this is only meaningful when the trigger
|
|
is <literal>BEFORE</> and <command>FOR EACH ROW</>; otherwise the return value is ignored.
|
|
</para>
|
|
<para>
|
|
Here's a little example trigger procedure that forces an integer value
|
|
in a table to keep track of the number of updates that are performed on the
|
|
row. For new rows inserted, the value is initialized to 0 and then
|
|
incremented on every update operation.
|
|
|
|
<programlisting>
|
|
CREATE FUNCTION trigfunc_modcount() RETURNS trigger AS $$
|
|
switch $TG_op {
|
|
INSERT {
|
|
set NEW($1) 0
|
|
}
|
|
UPDATE {
|
|
set NEW($1) $OLD($1)
|
|
incr NEW($1)
|
|
}
|
|
default {
|
|
return OK
|
|
}
|
|
}
|
|
return [array get NEW]
|
|
$$ LANGUAGE pltcl;
|
|
|
|
CREATE TABLE mytab (num integer, description text, modcnt integer);
|
|
|
|
CREATE TRIGGER trig_mytab_modcount BEFORE INSERT OR UPDATE ON mytab
|
|
FOR EACH ROW EXECUTE PROCEDURE trigfunc_modcount('modcnt');
|
|
</programlisting>
|
|
|
|
Notice that the trigger procedure itself does not know the column
|
|
name; that's supplied from the trigger arguments. This lets the
|
|
trigger procedure be reused with different tables.
|
|
</para>
|
|
</sect1>
|
|
|
|
<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.
|
|
</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.
|
|
</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.
|
|
</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.
|
|
</para>
|
|
</sect1>
|
|
|
|
<sect1 id="pltcl-procnames">
|
|
<title>Tcl Procedure Names</title>
|
|
|
|
<para>
|
|
In <productname>PostgreSQL</productname>, one and the
|
|
same function name can be used for
|
|
different functions as long as the number of arguments or their types
|
|
differ. Tcl, however, requires all procedure names to be distinct.
|
|
PL/Tcl deals with this by making the internal Tcl procedure names contain
|
|
the object
|
|
ID of the function from the system table <structname>pg_proc</> as part of their name. Thus,
|
|
<productname>PostgreSQL</productname> functions with the same name
|
|
and different argument types will be different Tcl procedures, too. This
|
|
is not normally a concern for a PL/Tcl programmer, but it might be visible
|
|
when debugging.
|
|
</para>
|
|
|
|
</sect1>
|
|
</chapter>
|
|
|
|
<!-- Keep this comment at the end of the file
|
|
Local variables:
|
|
mode:sgml
|
|
sgml-omittag:nil
|
|
sgml-shorttag:t
|
|
sgml-minimize-attributes:nil
|
|
sgml-always-quote-attributes:t
|
|
sgml-indent-step:1
|
|
sgml-indent-data:t
|
|
sgml-parent-document:nil
|
|
sgml-default-dtd-file:"./reference.ced"
|
|
sgml-exposed-tags:nil
|
|
sgml-local-catalogs:("/usr/lib/sgml/catalog")
|
|
sgml-local-ecat-files:nil
|
|
End:
|
|
-->
|