PL/Tcl - Tcl Procedural Language PL/Tcl Tcl PL/Tcl is a loadable procedural language for the Postgres database system that enables the Tcl language to be used to create functions and trigger procedures. This package was originally written by Jan Wieck. Overview PL/Tcl offers most of the capabilities a function writer has in the C language, except for some restrictions. 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 elog(). There is no way to access internals of the database backend or to gain OS-level access under the permissions of the Postgres user ID, as a C function can do. Thus, any unprivileged database user may be permitted to use this language. The other, implementation restriction is that Tcl procedures cannot 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 mail. 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 for the PL/Tcl and PL/TclU call handlers is automatically built and installed in the Postgres library directory if Tcl/Tk 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 script. Description <productname>Postgres</productname> Functions and Tcl Procedure Names In Postgres, one and the same function name can be used for different functions as long as the number of arguments or their types differ. This would collide with Tcl procedure names. To offer the same flexibility in PL/Tcl, the internal Tcl procedure names contain the object ID of the procedure's pg_proc row as part of their name. Thus, different argtype versions of the same Postgres function are different for Tcl too. Defining Functions in PL/Tcl 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'; When the function is called, the arguments are given as variables $1 ... $n to the Tcl procedure body. The result is returned from the Tcl code in the usual way, with a return statement. For example, a function returning the higher of two int4 values could be defined as: CREATE FUNCTION tcl_max (int4, int4) RETURNS int4 AS ' if {$1 > $2} {return $1} return $2 ' LANGUAGE 'pltcl'; To return a NULL value from a PL/Tcl function, execute return_null. Composite type arguments are given to the procedure as Tcl arrays. The element names in the array are the attribute names of the composite type. If an attribute in the actual row has the NULL value, it will not appear in the array! Here is an example that defines the overpaid_2 function (as found in the older Postgres documentation) in PL/Tcl CREATE FUNCTION overpaid_2 (EMP) RETURNS bool AS ' if {200000.0 < $1(salary)} { return "t" } if {$1(age) < 30 && 100000.0 < $1(salary)} { return "t" } return "f" ' LANGUAGE 'pltcl'; Global Data in PL/Tcl Sometimes (especially when using the SPI functions described later) it is useful to have some global status data that is held between two calls to a procedure. This is easily done since all PL/Tcl procedures executed in one backend share the same safe Tcl interpreter. To help protect PL/Tcl procedures from unwanted side effects, an array is made available to each procedure via the upvar command. The global name of this variable is the procedure's internal name and the local name is GD. It is recommended that GD be used for private status data of a procedure. Use regular Tcl global variables only for values that you specifically intend to be shared among multiple procedures. Trigger Procedures in PL/Tcl triggers in PL/Tcl Trigger procedures are defined in Postgres as functions without arguments and a return type of opaque. And so are they in the PL/Tcl language. The information from the trigger manager is given 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 tables field names prefixed with an empty list element. So looking up an element name in the list with the lsearch Tcl command returns the same positive number starting from 1 as the fields are numbered in the pg_attribute system catalog. $TG_when The string BEFORE or AFTER depending on the event of the trigger call. $TG_level The string ROW or STATEMENT depending on the event of the trigger call. $TG_op The string INSERT, UPDATE or DELETE depending on the event of the trigger call. $NEW An array containing the values of the new table row on INSERT/UPDATE actions, or empty on DELETE. $OLD An array containing the values of the old table row on UPDATE/DELETE actions, or empty on INSERT. $GD The global status data array as described above. $args A Tcl list of the arguments to the procedure as given in the CREATE TRIGGER statement. The arguments are also accessible as $1 ... $n in the procedure body. The return value from a trigger procedure is 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 normal operation (INSERT/UPDATE/DELETE) that fired this trigger will take place. Obviously, SKIP tells the trigger manager to silently suppress the operation. The list from 'array get' tells PL/Tcl to return a modified row to the trigger manager that will be inserted instead of the one given in $NEW (INSERT/UPDATE only). Needless to say that all this is only meaningful when the trigger is BEFORE and FOR EACH ROW. 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 OPAQUE 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 int4, modcnt int4, description text); CREATE TRIGGER trig_mytab_modcount BEFORE INSERT OR UPDATE ON mytab FOR EACH ROW EXECUTE PROCEDURE trigfunc_modcount('modcnt'); Database Access from PL/Tcl The following commands are available to access the database from the body of a PL/Tcl procedure: elog elog level msg Fire a log message. Possible levels are NOTICE, ERROR, FATAL, and DEBUG as for the elog C function. quote string Duplicates all occurrences of single quote and backslash characters. It should be used when variables are used in the query string given to spi_exec or spi_prepare (not for the value list on spi_execp). Think about a query string like "SELECT '$val' AS ret" where the Tcl variable val actually contains "doesn't". This would result in the final query string "SELECT 'doesn't' AS ret" which would cause a parse error during spi_exec or spi_prepare. It should contain "SELECT 'doesn''t' AS ret" and has to be written as "SELECT '[ quote $val ]' AS ret" spi_lastoid spi_lastoid Returns the OID of the last query if it was an INSERT. spi_exec ?-count n? ?-array name? query ?loop-body? Call parser/planner/optimizer/executor for query. The optional -count value tells spi_exec the maximum number of rows to be processed by the query. If the query is a SELECT statement and the optional loop-body (a body of Tcl commands like in a foreach statement) is given, it is evaluated for each row selected and behaves like expected on continue/break. The values of selected fields are put into variables named as the column names. So a spi_exec "SELECT count(*) AS cnt FROM pg_proc" will set the variable $cnt to the number of rows in the pg_proc system catalog. If the option -array is given, the column values are stored in the associative array named 'name' indexed by the column name instead of individual variables. spi_exec -array C "SELECT * FROM pg_class" { elog DEBUG "have table $C(relname)" } will print a DEBUG log message for every row of pg_class. The return value of spi_exec is the number of rows affected by the query as found in the global variable SPI_processed. spi_prepare query typelist Prepares AND SAVES a query plan for later execution. It is a bit different from the C level SPI_prepare in that the plan is automatically copied to the top-level memory context. Thus, there is currently no way of preparing a plan without saving it. If the query references arguments, the type names must be given as a Tcl list. The return value from spi_prepare is a query ID to be used in subsequent calls to spi_execp. See spi_execp for a sample. spi_exec ?-count n? ?-arrayname? ?-nullsstring? queryid ?value-list? ?loop-body? Execute a prepared plan from spi_prepare with variable substitution. The optional -count value tells spi_execp the maximum number of rows to be processed by the query. The optional value for -nulls is a string of spaces and 'n' characters telling spi_execp which of the values are NULL's. If given, it must have exactly the length of the number of values. The queryid is the ID returned by the spi_prepare call. If there was a typelist given to spi_prepare, a Tcl list of values of exactly the same length must be given to spi_execp after the query. If the type list on spi_prepare was empty, this argument must be omitted. If the query is a SELECT statement, the same as described for spi_exec happens for the loop-body and the variables for the fields selected. Here's an example for a PL/Tcl function using a prepared plan: CREATE FUNCTION t1_count(int4, int4) RETURNS int4 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" \\ int4 ] } spi_execp -count 1 $GD(plan) [ list $1 $2 ] return $cnt ' LANGUAGE 'pltcl'; Note that each backslash that Tcl should see must be doubled in the query creating the function, since the main parser processes backslashes too on CREATE FUNCTION. Inside the query string given to spi_prepare should really be dollar signs to mark the parameter positions and to not let $1 be substituted by the value given in the first function call. Modules and the unknown command PL/Tcl has a special support for things often used. It recognizes two magic tables, pltcl_modules and pltcl_modfuncs. If these exist, the module 'unknown' is loaded into the interpreter right after creation. Whenever an unknown Tcl procedure is called, the unknown proc is asked to check if the procedure is defined in one of the modules. If this is true, the module is loaded on demand. To enable this behavior, the PostgreSQL must be configured with the option . There are support scripts to maintain these tables in the modules subdirectory of the PL/Tcl source including the source for the unknown module that must get installed initially.