summaryrefslogtreecommitdiff
diff options
context:
space:
mode:
authorTom Lane <tgl@sss.pgh.pa.us>2002-01-23 21:08:17 +0000
committerTom Lane <tgl@sss.pgh.pa.us>2002-01-23 21:08:17 +0000
commitcf77a2a034d68b05c3f6c12d4bc5dc6e51da1d73 (patch)
tree8f0a9f1851b9507162df9676d2cfb9f4c1d884e5
parent35a5129a08729b528019988a732d33126676e71e (diff)
downloadpostgresql-cf77a2a034d68b05c3f6c12d4bc5dc6e51da1d73.tar.gz
Overhaul PL/Tcl documentation.
-rw-r--r--doc/src/sgml/pltcl.sgml681
1 files changed, 412 insertions, 269 deletions
diff --git a/doc/src/sgml/pltcl.sgml b/doc/src/sgml/pltcl.sgml
index 8234f1d68b..395861a81f 100644
--- a/doc/src/sgml/pltcl.sgml
+++ b/doc/src/sgml/pltcl.sgml
@@ -1,5 +1,5 @@
<!--
-$Header: /cvsroot/pgsql/doc/src/sgml/pltcl.sgml,v 2.17 2001/11/21 05:53:41 thomas Exp $
+$Header: /cvsroot/pgsql/doc/src/sgml/pltcl.sgml,v 2.18 2002/01/23 21:08:17 tgl Exp $
-->
<chapter id="pltcl">
@@ -16,7 +16,7 @@ $Header: /cvsroot/pgsql/doc/src/sgml/pltcl.sgml,v 2.17 2001/11/21 05:53:41 thoma
<para>
PL/Tcl is a loadable procedural language for the
<productname>PostgreSQL</productname> database system
- that enables the Tcl language to be used to create functions and
+ that enables the Tcl language to be used to write functions and
trigger procedures.
</para>
@@ -66,7 +66,9 @@ $Header: /cvsroot/pgsql/doc/src/sgml/pltcl.sgml,v 2.17 2001/11/21 05:53:41 thoma
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
- <filename>createlang</filename> script.
+ <filename>createlang</filename> script, for example
+ <literal>createlang pltcl <replaceable>dbname</></literal> or
+ <literal>createlang pltclu <replaceable>dbname</></literal>.
</para>
</sect1>
@@ -76,23 +78,7 @@ $Header: /cvsroot/pgsql/doc/src/sgml/pltcl.sgml,v 2.17 2001/11/21 05:53:41 thoma
<title>Description</title>
<sect2>
- <title><productname>PostgreSQL</productname> Functions and 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. 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 <productname>PostgreSQL</productname>
- function are different for Tcl too.
- </para>
-
- </sect2>
-
- <sect2>
- <title>Defining Functions in PL/Tcl</title>
+ <title>PL/Tcl Functions and Arguments</title>
<para>
To create a function in the PL/Tcl language, use the standard syntax
@@ -103,32 +89,68 @@ CREATE FUNCTION <replaceable>funcname</replaceable> (<replaceable>argument-types
' LANGUAGE 'pltcl';
</programlisting>
- When the function is called, the arguments are given as
+ PL/TclU is the same, except that the language should 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>$n</literal> to the
- Tcl procedure body. The result is returned
+ Tcl script. The result is returned
from the Tcl code in the usual way, with a <literal>return</literal>
statement. For example, a function
- returning the higher of two int4 values could be defined as:
+ returning the greater of two integer values could be defined as:
<programlisting>
-CREATE FUNCTION tcl_max (int4, int4) RETURNS int4 AS '
+CREATE FUNCTION tcl_max (integer, integer) RETURNS integer AS '
+ if {$1 > $2} {return $1}
+ return $2
+' LANGUAGE 'pltcl' WITH (isStrict);
+ </programlisting>
+
+ Note the clause <literal>WITH (isStrict)</>, which saves us from
+ having to think about NULL input values: if a NULL is passed, the
+ function will not be called at all, but will just return a NULL
+ result automatically.
+ </para>
+
+ <para>
+ In a non-strict function,
+ if the actual value of an argument is NULL, the corresponding
+ <literal>$n</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 tcl_max
+ with one null and one non-null argument to return the non-null
+ 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>
- To return a NULL value from a PL/Tcl function, execute
- <literal>return_null</literal>.
+ <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 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
+ Composite-type arguments are passed to the procedure 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 that defines the overpaid_2 function (as found in the
- older <productname>PostgreSQL</productname> documentation) in PL/Tcl
+ older <productname>PostgreSQL</productname> documentation) in PL/Tcl:
<programlisting>
CREATE FUNCTION overpaid_2 (EMP) RETURNS bool AS '
@@ -143,27 +165,298 @@ CREATE FUNCTION overpaid_2 (EMP) RETURNS bool AS '
</programlisting>
</para>
+ <para>
+ There is not currently any support for returning a composite-type
+ result value.
+ </para>
+
+ </sect2>
+
+ <sect2>
+ <title>Data Values in PL/Tcl</title>
+
+ <para>
+ The argument values supplied to a PL/Tcl function's script are simply
+ the input arguments converted to text form (just as if they had been
+ displayed by a 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>
+
</sect2>
<sect2>
<title>Global Data in PL/Tcl</title>
<para>
- Sometimes (especially when using the SPI functions described later) it
+ Sometimes it
is useful to have some global status data that is held between two
- calls to a procedure. This is easily done since
+ calls to a procedure or is shared between different procedures.
+ This is easily done since
all PL/Tcl procedures executed in one backend share the same
- safe Tcl interpreter.
+ safe Tcl interpreter. So, any global Tcl variable is accessible to
+ all PL/Tcl procedure calls, and will persist for the duration of the
+ SQL client connection. (Note that 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 procedures from unwanted side effects,
- an array is made available to each procedure via the <function>upvar</>
+ To help protect PL/Tcl procedures from unintentionally interfering
+ with each other, a global
+ array is made available to each procedure via the <function>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
+ name and the local name is <literal>GD</>. It is recommended that
+ <literal>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.
</para>
+
+ <para>
+ An example of using <literal>GD</> appears in the
+ <function>spi_execp</function> example below.
+ </para>
+ </sect2>
+
+ <sect2>
+ <title>Database Access from PL/Tcl</title>
+
+ <para>
+ The following commands are available to access the database from
+ the body of a PL/Tcl procedure:
+ </para>
+
+ <variablelist>
+
+ <varlistentry>
+ <term><function>spi_exec</function> <literal>?-count <replaceable>n</replaceable>? ?-array <replaceable>name</replaceable>? <replaceable>query</replaceable> ?<replaceable>loop-body</replaceable>?</literal></term>
+ <listitem>
+ <para>
+ Execute an SQL query given as a string. An error in the query
+ causes an error to be raised. Otherwise, the command's return value
+ is the number of rows processed (selected, inserted, updated, or
+ deleted) by the query, or zero if the query is a utility
+ statement. In addition, if the query is a 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 query. The effect of this is comparable to
+ setting up the query as a cursor and then saying <literal>FETCH n</>.
+ </para>
+ <para>
+ If the query is a SELECT statement, the values of the SELECT's
+ 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 SELECT
+ column names used as array indexes.
+ </para>
+ <para>
+ If the query is a 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 store occurs
+ if the
+ SELECT 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 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
+ SELECT result (note: <replaceable>loop-body</> is ignored if the given
+ query is not a SELECT). The values of the current row's fields
+ 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 DEBUG log message for every row of 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 field of a SELECT 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 backend.
+ </para>
+ <para>
+ The query may use <firstterm>arguments</>, which are placeholders for
+ values to be supplied whenever the plan is actually executed.
+ In the query string, refer to arguments
+ by the symbols <literal>$1</literal> ... <literal>$n</literal>.
+ If the query uses arguments, the names of the argument types
+ must be given as a Tcl list. (Write an empty list for
+ <replaceable>typelist</replaceable> if no arguments are used.)
+ Presently, the argument types must be identified by the internal
+ type names shown in 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><function>spi_execp</> <literal>?-count <replaceable>n</replaceable>? ?-array <replaceable>name</replaceable>? ?-nulls <replaceable>string</replaceable>? <replaceable>queryid</replaceable> ?<replaceable>value-list</replaceable>? ?<replaceable>loop-body</replaceable>?</literal></term>
+ <listitem>
+ <para>
+ Execute a query previously prepared with <function>spi_prepare</>.
+ <replaceable>queryid</replaceable> is the ID returned by
+ <function>spi_prepare</>. If the query references arguments,
+ a <replaceable>value-list</replaceable> must be supplied: this
+ is a Tcl list of actual values for the arguments. This must be
+ the same length as the argument type list previously given to
+ <function>spi_prepare</>. Omit <replaceable>value-list</replaceable>
+ if the query has no arguments.
+ </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 arguments are NULLs. If given, it must have exactly the
+ same length as the <replaceable>value-list</replaceable>. If it
+ is not given, all the argument values are non-NULL.
+ </para>
+ <para>
+ Except for the way in which the query and its arguments 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 &gt;= \\$1 AND num &lt;= \\$2" \\
+ [ list int4 int4 ] ]
+ }
+ spi_execp -count 1 $GD(plan) [ list $1 $2 ]
+ return $cnt
+' LANGUAGE 'pltcl';
+ </programlisting>
+
+ Note that each backslash that Tcl should see must be doubled when
+ we type in the function, since the main parser processes
+ backslashes too in CREATE FUNCTION. We need backslashes inside
+ the query string given to <function>spi_prepare</> to ensure that
+ the <literal>$n</> 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</>'d or <function>spi_execp</>'d query,
+ if that query was a single-row INSERT. (If not, you get zero.)
+ </para>
+ </listitem>
+ </varlistentry>
+
+ <varlistentry>
+ <term><function>quote</> <replaceable>string</replaceable></term>
+ <listitem>
+ <para>
+ Duplicates 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 queries given
+ to <function>spi_exec</function> or
+ <function>spi_prepare</function>.
+ For example, think about a query string like
+
+<programlisting>
+"SELECT '$val' AS ret"
+</programlisting>
+
+ where the Tcl variable val actually contains
+ <literal>doesn't</literal>. This would result
+ in the final query string
+
+<programlisting>
+SELECT 'doesn't' AS ret
+</programlisting>
+
+ which would cause a parse error during
+ <function>spi_exec</function> or
+ <function>spi_prepare</function>.
+ The submitted query should contain
+
+<programlisting>
+SELECT 'doesn''t' AS ret
+</programlisting>
+
+ which can be formed in PL/Tcl as
+
+<programlisting>
+"SELECT '[ quote $val ]' AS ret"
+</programlisting>
+
+ One advantage of <function>spi_execp</function> is that you don't
+ have to quote argument values like this, since the arguments are never
+ parsed as part of an SQL query string.
+ </para>
+ </listitem>
+ </varlistentry>
+
+ <varlistentry>
+ <indexterm>
+ <primary>elog</primary>
+ </indexterm>
+ <term><function>elog</> <replaceable>level</replaceable> <replaceable>msg</replaceable></term>
+ <listitem>
+ <para>
+ Emit a log or error message. Possible levels are <literal>DEBUG</>,
+ <literal>NOTICE</>, <literal>ERROR</>, and <literal>FATAL</>.
+ <literal>DEBUG</> and <literal>NOTICE</> simply emit the given message
+ into the postmaster log (and send it to the client too, in the case of
+ <literal>NOTICE</>). <literal>ERROR</> raises an error condition:
+ further execution of the function is abandoned, and the current
+ transaction is aborted. <literal>FATAL</> aborts the transaction and
+ causes the current backend 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>
+
</sect2>
<sect2>
@@ -175,13 +468,13 @@ CREATE FUNCTION overpaid_2 (EMP) RETURNS bool AS '
</indexterm>
<para>
- Trigger procedures are defined in <productname>PostgreSQL</productname>
- as functions without
- arguments and a return type of opaque. And so are they in the PL/Tcl
- language.
+ Trigger procedures can be written in PL/Tcl. As is customary in
+ <productname>PostgreSQL</productname>, a procedure that's to be called
+ as a trigger must be declared as a function with no arguments
+ and a return type of <literal>opaque</>.
</para>
<para>
- The information from the trigger manager is given to the procedure body
+ The information from the trigger manager is passed to the procedure body
in the following variables:
<variablelist>
@@ -209,10 +502,11 @@ CREATE FUNCTION overpaid_2 (EMP) RETURNS bool AS '
<term><replaceable class="Parameter">$TG_relatts</replaceable></term>
<listitem>
<para>
- 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 <function>lsearch</> Tcl command
- returns the same positive number starting from 1 as the fields are numbered
- in the pg_attribute system catalog.
+ A Tcl list of the table field names, prefixed with an empty list
+ element. So looking up an element name in the list with Tcl's
+ <function>lsearch</> command returns the element's number starting
+ with 1 for the first column, the same way the fields are customarily
+ numbered in <productname>PostgreSQL</productname>.
</para>
</listitem>
</varlistentry>
@@ -221,7 +515,8 @@ CREATE FUNCTION overpaid_2 (EMP) RETURNS bool AS '
<term><replaceable class="Parameter">$TG_when</replaceable></term>
<listitem>
<para>
- The string BEFORE or AFTER depending on the event of the trigger call.
+ The string <literal>BEFORE</> or <literal>AFTER</> depending on the
+ type of trigger call.
</para>
</listitem>
</varlistentry>
@@ -230,7 +525,8 @@ CREATE FUNCTION overpaid_2 (EMP) RETURNS bool AS '
<term><replaceable class="Parameter">$TG_level</replaceable></term>
<listitem>
<para>
- The string ROW or STATEMENT depending on the event of the trigger call.
+ The string <literal>ROW</> or <literal>STATEMENT</> depending on the
+ type of trigger call.
</para>
</listitem>
</varlistentry>
@@ -239,8 +535,8 @@ CREATE FUNCTION overpaid_2 (EMP) RETURNS bool AS '
<term><replaceable class="Parameter">$TG_op</replaceable></term>
<listitem>
<para>
- The string INSERT, UPDATE or DELETE depending on the event of the
- trigger call.
+ The string <literal>INSERT</>, <literal>UPDATE</> or
+ <literal>DELETE</> depending on the type of trigger call.
</para>
</listitem>
</varlistentry>
@@ -249,8 +545,9 @@ CREATE FUNCTION overpaid_2 (EMP) RETURNS bool AS '
<term><replaceable class="Parameter">$NEW</replaceable></term>
<listitem>
<para>
- An array containing the values of the new table row on INSERT/UPDATE
- actions, or empty on DELETE.
+ An associative array containing the values of the new table row for
+ INSERT/UPDATE actions, or empty for DELETE. The array is indexed
+ by field name. Fields that are NULL will not appear in the array!
</para>
</listitem>
</varlistentry>
@@ -259,17 +556,9 @@ CREATE FUNCTION overpaid_2 (EMP) RETURNS bool AS '
<term><replaceable class="Parameter">$OLD</replaceable></term>
<listitem>
<para>
- An array containing the values of the old table row on UPDATE/DELETE
- actions, or empty on INSERT.
- </para>
- </listitem>
- </varlistentry>
-
- <varlistentry>
- <term><replaceable class="Parameter">$GD</replaceable></term>
- <listitem>
- <para>
- The global status data array as described above.
+ An associative array containing the values of the old table row for
+ UPDATE/DELETE actions, or empty for INSERT. The array is indexed
+ by field name. Fields that are NULL will not appear in the array!
</para>
</listitem>
</varlistentry>
@@ -279,8 +568,8 @@ CREATE FUNCTION overpaid_2 (EMP) RETURNS bool AS '
<listitem>
<para>
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.
+ CREATE TRIGGER statement. These arguments are also accessible as
+ <literal>$1</literal> ... <literal>$n</literal> in the procedure body.
</para>
</listitem>
</varlistentry>
@@ -289,14 +578,16 @@ CREATE FUNCTION overpaid_2 (EMP) RETURNS bool AS '
</para>
<para>
- 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.
+ 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 (INSERT/UPDATE/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 $NEW (this works for INSERT/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.
</para>
<para>
Here's a little example trigger procedure that forces an integer value
@@ -321,222 +612,74 @@ CREATE FUNCTION trigfunc_modcount() RETURNS OPAQUE AS '
return [array get NEW]
' LANGUAGE 'pltcl';
-CREATE TABLE mytab (num int4, modcnt int4, description text);
+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 re-used with different tables.
</para>
</sect2>
<sect2>
- <title>Database Access from PL/Tcl</title>
-
- <para>
- The following commands are available to access the database from
- the body of a PL/Tcl procedure:
- </para>
-
- <variablelist>
-
- <varlistentry>
- <indexterm>
- <primary>elog</primary>
- </indexterm>
- <term><function>elog</> <replaceable>level</replaceable> <replaceable>msg</replaceable></term>
- <listitem>
- <para>
- Fire a log message. Possible levels are NOTICE, ERROR,
- FATAL, and DEBUG
- as for the <function>elog</function> C function.
- </para>
- </listitem>
- </varlistentry>
-
- <varlistentry>
- <term><function>quote</> <replaceable>string</replaceable></term>
- <listitem>
- <para>
- Duplicates all occurrences of single quote and backslash characters.
- It should be used when variables are used in the query string given
- to <function>spi_exec</function> or
- <function>spi_prepare</function> (not for the value list on
- <function>spi_execp</function>).
- Think about a query string like
-
-<programlisting>
-"SELECT '$val' AS ret"
-</programlisting>
-
- where the Tcl variable val actually contains <literal>doesn't</literal>. This would result
- in the final query string
-
-<programlisting>
-SELECT 'doesn't' AS ret
-</programlisting>
-
- which would cause a parse error during
- <function>spi_exec</function> or
- <function>spi_prepare</function>.
- It should contain
-
-<programlisting>
-SELECT 'doesn''t' AS ret
-</programlisting>
-
- and has to be written as
-
-<programlisting>
-SELECT '[ quote $val ]' AS ret
-</programlisting>
- </para>
- </listitem>
- </varlistentry>
-
- <varlistentry>
- <indexterm>
- <primary>spi_lastoid</primary>
- </indexterm>
- <term><function>spi_lastoid</></term>
- <listitem>
- <para>
- Returns the OID of the last query if it was an INSERT.
- </para>
- </listitem>
- </varlistentry>
-
- <varlistentry>
- <term><function>spi_exec</function> <literal>?-count <replaceable>n</replaceable>? ?-array <replaceable>name</replaceable>? <replaceable>query</replaceable> ?<replaceable>loop-body</replaceable>?</literal></term>
- <listitem>
- <para>
- Call parser/planner/optimizer/executor for query.
- The optional -count value tells <function>spi_exec</function>
- the maximum number of rows
- to be processed by the query.
- </para>
- <para>
- 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
-
- <programlisting>
-spi_exec "SELECT count(*) AS cnt FROM pg_proc"
- </programlisting>
-
- 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.
-
- <programlisting>
-spi_exec -array C "SELECT * FROM pg_class" {
- elog DEBUG "have table $C(relname)"
-}
- </programlisting>
-
- will print a DEBUG log message for every row of pg_class. The return value
- of <function>spi_exec</function> is the number of rows
- affected by the query as found in
- the global variable SPI_processed.
- </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. 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.
- </para>
- <para>
- If the query references arguments, the type names must be given as a Tcl
- list. 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 a sample.
- </para>
- </listitem>
- </varlistentry>
-
- <varlistentry>
- <term><function>spi_execp</> <literal>?-count <replaceable>n</replaceable>? ?-array<replaceable>name</replaceable>? ?-nulls<replaceable>string</replaceable>? <replaceable>queryid</replaceable> ?<replaceable>value-list</replaceable>? ?<replaceable>loop-body</replaceable>?</literal></term>
- <listitem>
- <para>
- Execute a prepared plan from <function>spi_prepare</> with variable substitution.
- The optional <literal>-count</literal> value tells <function>spi_execp</> the maximum number of rows
- to be processed by the query.
- </para>
+ <title> Modules and the <function>unknown</> command</title>
<para>
- The optional value for <literal>-nulls</> is a string of spaces and 'n' characters
- telling <function>spi_execp</function> which of the values are NULL's. If given, it must
- have exactly the length of the number of values.
+ PL/Tcl has support for auto-loading 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>
- The <parameter>queryid</> is the ID returned by the <function>spi_prepare</function> call.
+ While the <literal>unknown</> module could actually contain any
+ initialization script you need, it normally defines a Tcl
+ <quote>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 <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>
- If there was a <parameter>typelist</> given to <function>spi_prepare</function>, 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.
+ 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
+ unknown module <filename>share/unknown.pltcl</>. This module
+ must be loaded
+ into each database initially to support the autoloading mechanism.
</para>
<para>
- If the query is a SELECT statement, the same as described for <function>spi_exec</>
- happens for the loop-body and the variables for the fields selected.
+ 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>
- <para>
- Here's an example for a PL/Tcl function using a prepared plan:
-
- <programlisting>
-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 &gt;= \\$1 AND num &lt;= \\$2" \\
- int4 ]
- }
- spi_execp -count 1 $GD(plan) [ list $1 $2 ]
- return $cnt
-' LANGUAGE 'pltcl';
- </programlisting>
-
- 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 <function>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.
- </para>
- </listitem>
- </varlistentry>
-
-
- </variablelist>
-
</sect2>
<sect2>
- <title> Modules and the <function>unknown</> command</title>
- <para>
- PL/Tcl has a special support for things often used. It
- recognizes two magic tables, <literal>pltcl_modules</> and
- <literal>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.
- </para>
- <para>
- There are support scripts to maintain these tables:
- <command>pltcl_loadmod</>,<command>pltcl_listmod</>,
- <command>pltcl_delmod</> and source for the
- unknown module <filename>share/unknown.pltcl</> that must be loaded
- into database initially for getting unknown support.
- </para>
+ <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 procedure's pg_proc row 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>
+
</sect2>
</sect1>