PL/Tcl - Tcl Procedural Language
PL/Tcl
Tcl
PL/Tcl is a loadable procedural language for the
PostgreSQL database system
that enables the
Tcl language to be used to write functions and
trigger procedures.
Overview
PL/Tcl offers most of the capabilities a function writer has in
the C language, with a few restrictions, and with the addition of
the powerful string processing libraries that are available for
Tcl.
One compelling good restriction is that
everything is executed from within the safety of the context of a
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 elog()>. PL/Tcl
provides no way to access internals of the database server or to
gain OS-level access under the permissions of the
PostgreSQL server process, as a C
function can do. Thus, unprivileged database users may be trusted
to use this language; it does not give them unlimited authority.
The other notable implementation restriction is that Tcl functions
may not be used to create input/output functions for new data
types.
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 PL/Tcl> called PL/TclU>
(for untrusted Tcl). This is the exact same language except that a full
Tcl interpreter is used. If PL/TclU> is used, it must be
installed as an untrusted procedural language so that only
database superusers can create functions in it. The writer of a 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.
The shared object code for the PL/Tcl> and
PL/TclU> call handlers is automatically built and
installed in the PostgreSQL library
directory if Tcl support is specified in the configuration step of
the installation procedure. To install PL/Tcl>
and/or PL/TclU> in a particular database, use the
createlang program, for example
createlang pltcl dbname> or
createlang pltclu dbname>.
PL/Tcl Functions and Arguments
To create a function in the PL/Tcl> language, use
the standard syntax:
CREATE FUNCTION funcname (argument-types) RETURNS return-type AS $$
# PL/Tcl function body
$$ LANGUAGE pltcl;
PL/TclU> is the same, except that the language has to be specified as
pltclu>.
The body of the function is simply a piece of Tcl script.
When the function is called, the argument values are passed as
variables $1 ... $n to the
Tcl script. The result is returned
from the Tcl code in the usual way, with a return
statement.
For example, a function
returning the greater of two integer values could be defined as:
CREATE FUNCTION tcl_max(integer, integer) RETURNS integer AS $$
if {$1 > $2} {return $1}
return $2
$$ LANGUAGE pltcl STRICT;
Note the clause 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.
In a nonstrict function,
if the actual value of an argument is null, the corresponding
$n variable will be set to an empty string.
To detect whether a particular argument is null, use the function
argisnull>. For example, suppose that we wanted tcl_max
with one null and one nonnull argument to return the nonnull
argument, rather than null:
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;
As shown above,
to return a null value from a PL/Tcl function, execute
return_null. This can be done whether the
function is strict or not.
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:
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;
There is currently no support for returning a composite-type
result value, nor for returning sets.
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 PL/Tcl> function
as returning a domain type.
Data Values in PL/Tcl
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 SELECT> statement). Conversely, the
return>
command will accept any string that is acceptable input format for
the function's declared return type. So, within the PL/Tcl function,
all values are just text strings.
Global Data in PL/Tcl
global data
in PL/Tcl
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 PL/TclU> functions likewise share
global data, but they are in a different Tcl interpreter and cannot
communicate with PL/Tcl functions.)
To help protect PL/Tcl functions from unintentionally interfering
with each other, a global
array is made available to each function via the upvar>
command. The global name of this variable is the function's internal
name, and the local name is GD>. It is recommended that
GD> be used
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.
An example of using GD> appears in the
spi_execp example below.
Database Access from PL/Tcl
The following commands are available to access the database from
the body of a PL/Tcl function:
spi_exec -count n -array name command loop-body
Executes an SQL command given as a string. An error in the command
causes an error to be raised. Otherwise, the return value of spi_exec
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 SELECT> statement, the
values of the selected columns are placed in Tcl variables as
described below.
The optional -count> value tells
spi_exec 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 FETCH n>>.
If the command is a SELECT> statement, the values of the
result columns are placed into Tcl variables named after the columns.
If the -array> option is given, the column values are
instead stored into the named associative array, with the
column names used as array indexes.
If the command is a SELECT> statement and no 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 spi_exec.) For example,
spi_exec "SELECT count(*) AS cnt FROM pg_proc"
will set the Tcl variable $cnt> to the number of rows in
the pg_proc> system catalog.
If the optional loop-body> argument is given, it is
a piece of Tcl script that is executed once for each row in the
query result. (loop-body> is ignored if the given
command is not a SELECT>.) The values of the current row's columns
are stored into Tcl variables before each iteration. For example,
spi_exec -array C "SELECT * FROM pg_class" {
elog DEBUG "have table $C(relname)"
}
will print a log message for every row of pg_class>. This
feature works similarly to other Tcl looping constructs; in
particular continue> and break> work in the
usual way inside the loop body.
If a column of a query result is null, the target
variable for it is unset> rather than being set.
spi_prepare query typelist
Prepares and saves a query plan for later execution. The
saved plan will be retained for the life of the current
session.preparing a query>in
PL/Tcl>>
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 $1 ... $n.
If the query uses parameters, the names of the parameter types
must be given as a Tcl list. (Write an empty list for
typelist if no parameters are used.)
Presently, the parameter types must be identified by the internal
type names shown in the system table pg_type>; for example int4> not
integer>.
The return value from spi_prepare is a query ID
to be used in subsequent calls to spi_execp. See
spi_execp for an example.
spi_execp> -count n -array name -nulls string queryid value-list loop-body
Executes a query previously prepared with spi_prepare>.
queryid is the ID returned by
spi_prepare>. If the query references parameters,
a value-list 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
spi_prepare>. Omit value-list
if the query has no parameters.
The optional value for -nulls> is a string of spaces and
'n'> characters telling spi_execp
which of the parameters are null values. If given, it must have exactly the
same length as the value-list. If it
is not given, all the parameter values are nonnull.
Except for the way in which the query and its parameters are specified,
spi_execp> works just like spi_exec>.
The -count>, -array>, and
loop-body options are the same,
and so is the result value.
Here's an example of a PL/Tcl function using a prepared plan:
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;
We need backslashes inside the query string given to
spi_prepare> to ensure that the
$n> markers will be passed
through to spi_prepare> as-is, and not replaced by Tcl
variable substitution.
spi_lastoid
spi_lastoid>
Returns the OID of the row inserted by the last
spi_exec> or spi_execp>, if the
command was a single-row INSERT> and the modified
table contained OIDs. (If not, you get zero.)
quote> string
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 spi_exec or
spi_prepare.
For example, think about an SQL command string like
"SELECT '$val' AS ret"
where the Tcl variable val> actually contains
doesn't. This would result
in the final command string
SELECT 'doesn't' AS ret
which would cause a parse error during
spi_exec or
spi_prepare.
To work properly, the submitted command should contain
SELECT 'doesn''t' AS ret
which can be formed in PL/Tcl using
"SELECT '[ quote $val ]' AS ret"
One advantage of spi_execp 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.
elog
in PL/Tcl
elog> level msg
Emits a log or error message. Possible levels are
DEBUG>, LOG>, INFO>,
NOTICE>, WARNING>, ERROR>, and
FATAL>. 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 error> command.
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.) 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
and
configuration
variables. See for more
information.
Trigger Procedures in PL/Tcl
trigger
in PL/Tcl
Trigger procedures can be written in PL/Tcl.
PostgreSQL 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 trigger>.
The information from the trigger manager is passed to the procedure body
in the following variables:
$TG_name
The name of the trigger from the CREATE TRIGGER statement.
$TG_relid
The object ID of the table that caused the trigger procedure
to be invoked.
$TG_relatts
A Tcl list of the table column names, prefixed with an empty list
element. So looking up a column name in the list with Tcl>'s
lsearch> command returns the element's number starting
with 1 for the first column, the same way the columns are customarily
numbered in PostgreSQL. (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.)
$TG_when
The string BEFORE> or AFTER> depending on the
type of trigger call.
$TG_level
The string ROW> or STATEMENT> depending on the
type of trigger call.
$TG_op
The string INSERT>, UPDATE>, or
DELETE> depending on the type of trigger call.
$NEW
An associative array containing the values of the new table
row for INSERT> or UPDATE> actions, or
empty for DELETE>. The array is indexed by column
name. Columns that are null will not appear in the array.
$OLD
An associative array containing the values of the old table
row for UPDATE> or DELETE> actions, or
empty for INSERT>. The array is indexed by column
name. Columns that are null will not appear in the array.
$args
A Tcl list of the arguments to the procedure as given in the
CREATE TRIGGER statement. These arguments are also accessible as
$1 ... $n in the procedure body.
The return value from a trigger procedure can be one of the strings
OK> or SKIP>, or a list as returned by the
array get> Tcl command. If the return value is OK>,
the operation (INSERT>/UPDATE>/DELETE>) that fired the trigger will proceed
normally. 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 $NEW>. (This works for INSERT> and UPDATE>
only.) Needless to say that all this is only meaningful when the trigger
is BEFORE> and FOR EACH ROW>; otherwise the return value is ignored.
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.
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');
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.
Modules and the unknown> command
PL/Tcl has support for autoloading Tcl code when used.
It recognizes a special table, pltcl_modules>, which
is presumed to contain modules of Tcl code. If this table
exists, the module unknown> is fetched from the table
and loaded into the Tcl interpreter immediately after creating
the interpreter.
While the unknown> module could actually contain any
initialization script you need, it normally defines a Tcl
unknown> procedure that is invoked whenever Tcl does
not recognize an invoked procedure name. PL/Tcl>'s standard version
of this procedure tries to find a module in 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 pltcl_modfuncs> provides an index of
which functions are defined by which modules, so that the lookup
is reasonably quick.
The PostgreSQL distribution includes
support scripts to maintain these tables:
pltcl_loadmod>, pltcl_listmod>,
pltcl_delmod>, as well as source for the standard
unknown> module in share/unknown.pltcl>. This module
must be loaded
into each database initially to support the autoloading mechanism.
The tables pltcl_modules> and pltcl_modfuncs>
must be readable by all, but it is wise to make them owned and
writable only by the database administrator.
Tcl Procedure Names
In PostgreSQL, 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 pg_proc> as part of their name. Thus,
PostgreSQL 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.