Sophie

Sophie

distrib > Mandriva > 10.0 > i586 > by-pkgid > db7d48fed1469a51f3fb965d5b5b2ac1 > files > 321

postgresql-docs-7.4.1-2.5.100mdk.i586.rpm

<!DOCTYPE HTML PUBLIC "-//W3C//DTD HTML 4.01 Transitional//EN">
<HTML
><HEAD
><TITLE
>Database Access from PL/Tcl</TITLE
><META
NAME="GENERATOR"
CONTENT="Modular DocBook HTML Stylesheet Version 1.7"><LINK
REV="MADE"
HREF="mailto:pgsql-docs@postgresql.org"><LINK
REL="HOME"
TITLE="PostgreSQL 7.4.1 Documentation"
HREF="index.html"><LINK
REL="UP"
TITLE="PL/Tcl - Tcl Procedural Language"
HREF="pltcl.html"><LINK
REL="PREVIOUS"
TITLE="Global Data in PL/Tcl"
HREF="pltcl-global.html"><LINK
REL="NEXT"
TITLE="Trigger Procedures in PL/Tcl"
HREF="pltcl-trigger.html"><LINK
REL="STYLESHEET"
TYPE="text/css"
HREF="stylesheet.css"><META
NAME="creation"
CONTENT="2003-12-22T03:48:47"></HEAD
><BODY
CLASS="SECT1"
><DIV
CLASS="NAVHEADER"
><TABLE
SUMMARY="Header navigation table"
WIDTH="100%"
BORDER="0"
CELLPADDING="0"
CELLSPACING="0"
><TR
><TH
COLSPAN="5"
ALIGN="center"
VALIGN="bottom"
>PostgreSQL 7.4.1 Documentation</TH
></TR
><TR
><TD
WIDTH="10%"
ALIGN="left"
VALIGN="top"
><A
HREF="pltcl-global.html"
ACCESSKEY="P"
>Prev</A
></TD
><TD
WIDTH="10%"
ALIGN="left"
VALIGN="top"
><A
HREF="pltcl.html"
>Fast Backward</A
></TD
><TD
WIDTH="60%"
ALIGN="center"
VALIGN="bottom"
>Chapter 38. PL/Tcl - Tcl Procedural Language</TD
><TD
WIDTH="10%"
ALIGN="right"
VALIGN="top"
><A
HREF="pltcl.html"
>Fast Forward</A
></TD
><TD
WIDTH="10%"
ALIGN="right"
VALIGN="top"
><A
HREF="pltcl-trigger.html"
ACCESSKEY="N"
>Next</A
></TD
></TR
></TABLE
><HR
ALIGN="LEFT"
WIDTH="100%"></DIV
><DIV
CLASS="SECT1"
><H1
CLASS="SECT1"
><A
NAME="PLTCL-DBACCESS"
>38.5. Database Access from PL/Tcl</A
></H1
><P
>     The following commands are available to access the database from
     the body of a PL/Tcl function:

    <P
></P
></P><DIV
CLASS="VARIABLELIST"
><DL
><DT
><TT
CLASS="LITERAL"
><CODE
CLASS="FUNCTION"
>spi_exec</CODE
> ?<SPAN
CLASS="OPTIONAL"
>-count <VAR
CLASS="REPLACEABLE"
>n</VAR
></SPAN
>? ?<SPAN
CLASS="OPTIONAL"
>-array <VAR
CLASS="REPLACEABLE"
>name</VAR
></SPAN
>? <VAR
CLASS="REPLACEABLE"
>command</VAR
> ?<SPAN
CLASS="OPTIONAL"
><VAR
CLASS="REPLACEABLE"
>loop-body</VAR
></SPAN
>?</TT
></DT
><DD
><P
>	Executes an SQL command given as a string.  An error in the command
	causes an error to be raised.  Otherwise, the return value of <CODE
CLASS="FUNCTION"
>spi_exec</CODE
>
	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 <TT
CLASS="COMMAND"
>SELECT</TT
> statement, the
	values of the selected columns are placed in Tcl variables as
	described below.
       </P
><P
>	The optional <TT
CLASS="LITERAL"
>-count</TT
> value tells
	<CODE
CLASS="FUNCTION"
>spi_exec</CODE
> 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 <TT
CLASS="LITERAL"
>FETCH <VAR
CLASS="REPLACEABLE"
>n</VAR
></TT
>.
       </P
><P
>	If the command is a <TT
CLASS="COMMAND"
>SELECT</TT
> statement, the values of the
	result columns are placed into Tcl variables named after the columns.
        If the <TT
CLASS="LITERAL"
>-array</TT
> option is given, the column values are
	instead stored into the named associative array, with the
	column names used as array indexes.
       </P
><P
>        If the command is a <TT
CLASS="COMMAND"
>SELECT</TT
> statement and no <VAR
CLASS="REPLACEABLE"
>loop-body</VAR
>
	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 <CODE
CLASS="FUNCTION"
>spi_exec</CODE
>.)  For example,

</P><PRE
CLASS="PROGRAMLISTING"
>spi_exec "SELECT count(*) AS cnt FROM pg_proc"</PRE
><P>

	will set the Tcl variable <TT
CLASS="LITERAL"
>$cnt</TT
> to the number of rows in
	the <TT
CLASS="STRUCTNAME"
>pg_proc</TT
> system catalog.
       </P
><P
>        If the optional <VAR
CLASS="REPLACEABLE"
>loop-body</VAR
> argument is given, it is
	a piece of Tcl script that is executed once for each row in the
	query result.  (<VAR
CLASS="REPLACEABLE"
>loop-body</VAR
> is ignored if the given
	command is not a <TT
CLASS="COMMAND"
>SELECT</TT
>.)  The values of the current row's columns
	are stored into Tcl variables before each iteration.  For example,

</P><PRE
CLASS="PROGRAMLISTING"
>spi_exec -array C "SELECT * FROM pg_class" {
    elog DEBUG "have table $C(relname)"
}</PRE
><P>

	will print a log message for every row of <TT
CLASS="LITERAL"
>pg_class</TT
>.  This
	feature works similarly to other Tcl looping constructs; in
	particular <TT
CLASS="LITERAL"
>continue</TT
> and <TT
CLASS="LITERAL"
>break</TT
> work in the
	usual way inside the loop body.
       </P
><P
>        If a column of a query result is null, the target
	variable for it is <SPAN
CLASS="QUOTE"
>"unset"</SPAN
> rather than being set.
       </P
></DD
><DT
><CODE
CLASS="FUNCTION"
>spi_prepare</CODE
> <VAR
CLASS="REPLACEABLE"
>query</VAR
> <VAR
CLASS="REPLACEABLE"
>typelist</VAR
></DT
><DD
><P
>	Prepares and saves a query plan for later execution.  The
	saved plan will be retained for the life of the current
	session.<A
NAME="AEN32660"
></A
>
       </P
><P
>        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 <TT
CLASS="LITERAL"
>$1</TT
> ... <TT
CLASS="LITERAL"
>$<VAR
CLASS="REPLACEABLE"
>n</VAR
></TT
>.
	If the query uses parameters, the names of the parameter types
	must be given as a Tcl list.  (Write an empty list for
	<VAR
CLASS="REPLACEABLE"
>typelist</VAR
> if no parameters are used.)
	Presently, the parameter types must be identified by the internal
	type names shown in the system table <TT
CLASS="LITERAL"
>pg_type</TT
>; for example <TT
CLASS="LITERAL"
>int4</TT
> not
	<TT
CLASS="LITERAL"
>integer</TT
>.
       </P
><P
>        The return value from <CODE
CLASS="FUNCTION"
>spi_prepare</CODE
> is a query ID
	to be used in subsequent calls to <CODE
CLASS="FUNCTION"
>spi_execp</CODE
>. See
	<CODE
CLASS="FUNCTION"
>spi_execp</CODE
> for an example.
       </P
></DD
><DT
><TT
CLASS="LITERAL"
><CODE
CLASS="FUNCTION"
>spi_execp</CODE
> ?<SPAN
CLASS="OPTIONAL"
>-count <VAR
CLASS="REPLACEABLE"
>n</VAR
></SPAN
>? ?<SPAN
CLASS="OPTIONAL"
>-array <VAR
CLASS="REPLACEABLE"
>name</VAR
></SPAN
>? ?<SPAN
CLASS="OPTIONAL"
>-nulls <VAR
CLASS="REPLACEABLE"
>string</VAR
></SPAN
>? <VAR
CLASS="REPLACEABLE"
>queryid</VAR
> ?<SPAN
CLASS="OPTIONAL"
><VAR
CLASS="REPLACEABLE"
>value-list</VAR
></SPAN
>? ?<SPAN
CLASS="OPTIONAL"
><VAR
CLASS="REPLACEABLE"
>loop-body</VAR
></SPAN
>?</TT
></DT
><DD
><P
>	Executes a query previously prepared with <CODE
CLASS="FUNCTION"
>spi_prepare</CODE
>.
	<VAR
CLASS="REPLACEABLE"
>queryid</VAR
> is the ID returned by
	<CODE
CLASS="FUNCTION"
>spi_prepare</CODE
>.  If the query references parameters,
	a <VAR
CLASS="REPLACEABLE"
>value-list</VAR
> 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
	<CODE
CLASS="FUNCTION"
>spi_prepare</CODE
>.  Omit <VAR
CLASS="REPLACEABLE"
>value-list</VAR
>
	if the query has no parameters.
       </P
><P
>	The optional value for <TT
CLASS="LITERAL"
>-nulls</TT
> is a string of spaces and
	<TT
CLASS="LITERAL"
>'n'</TT
> characters telling <CODE
CLASS="FUNCTION"
>spi_execp</CODE
>
	which of the parameters are null values. If given, it must have exactly the
	same length as the <VAR
CLASS="REPLACEABLE"
>value-list</VAR
>.  If it
	is not given, all the parameter values are nonnull.
       </P
><P
>        Except for the way in which the query and its parameters are specified,
	<CODE
CLASS="FUNCTION"
>spi_execp</CODE
> works just like <CODE
CLASS="FUNCTION"
>spi_exec</CODE
>.
        The <TT
CLASS="LITERAL"
>-count</TT
>, <TT
CLASS="LITERAL"
>-array</TT
>, and
	<VAR
CLASS="REPLACEABLE"
>loop-body</VAR
> options are the same,
	and so is the result value.
       </P
><P
>	Here's an example of a PL/Tcl function using a prepared plan:

</P><PRE
CLASS="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;</PRE
><P>

	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 <TT
CLASS="COMMAND"
>CREATE FUNCTION</TT
>.  We need backslashes inside
	the query string given to <CODE
CLASS="FUNCTION"
>spi_prepare</CODE
> to ensure that
	the <TT
CLASS="LITERAL"
>$<VAR
CLASS="REPLACEABLE"
>n</VAR
></TT
> markers will be passed through to
	<CODE
CLASS="FUNCTION"
>spi_prepare</CODE
> as-is, and not
	replaced by Tcl variable substitution.
       </P
></DD
><DT
><CODE
CLASS="FUNCTION"
>spi_lastoid</CODE
></DT
><DD
><P
>	Returns the OID of the row inserted by the last
	<CODE
CLASS="FUNCTION"
>spi_exec</CODE
> or <CODE
CLASS="FUNCTION"
>spi_execp</CODE
>,
	if the command was a single-row <TT
CLASS="COMMAND"
>INSERT</TT
>.  (If not, you get zero.)
       </P
></DD
><DT
><CODE
CLASS="FUNCTION"
>quote</CODE
> <VAR
CLASS="REPLACEABLE"
>string</VAR
></DT
><DD
><P
>	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 commands given
	to <CODE
CLASS="FUNCTION"
>spi_exec</CODE
> or
	<CODE
CLASS="FUNCTION"
>spi_prepare</CODE
>.
	For example, think about an SQL command string like

</P><PRE
CLASS="PROGRAMLISTING"
>"SELECT '$val' AS ret"</PRE
><P>

	where the Tcl variable <TT
CLASS="LITERAL"
>val</TT
> actually contains
	<TT
CLASS="LITERAL"
>doesn't</TT
>. This would result
	in the final command string

</P><PRE
CLASS="PROGRAMLISTING"
>SELECT 'doesn't' AS ret</PRE
><P>

	which would cause a parse error during
	<CODE
CLASS="FUNCTION"
>spi_exec</CODE
> or
	<CODE
CLASS="FUNCTION"
>spi_prepare</CODE
>.
	The submitted command should contain

</P><PRE
CLASS="PROGRAMLISTING"
>SELECT 'doesn''t' AS ret</PRE
><P>

	which can be formed in PL/Tcl using

</P><PRE
CLASS="PROGRAMLISTING"
>"SELECT '[ quote $val ]' AS ret"</PRE
><P>

        One advantage of <CODE
CLASS="FUNCTION"
>spi_execp</CODE
> 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.
       </P
></DD
><DT
><CODE
CLASS="FUNCTION"
>elog</CODE
> <VAR
CLASS="REPLACEABLE"
>level</VAR
> <VAR
CLASS="REPLACEABLE"
>msg</VAR
></DT
><DD
><P
>	Emits a log or error message. Possible levels are
	<TT
CLASS="LITERAL"
>DEBUG</TT
>, <TT
CLASS="LITERAL"
>LOG</TT
>, <TT
CLASS="LITERAL"
>INFO</TT
>,
	<TT
CLASS="LITERAL"
>NOTICE</TT
>, <TT
CLASS="LITERAL"
>WARNING</TT
>, <TT
CLASS="LITERAL"
>ERROR</TT
>, and
	<TT
CLASS="LITERAL"
>FATAL</TT
>. Most simply emit the given message just like
	the <TT
CLASS="LITERAL"
>elog</TT
> C function. <TT
CLASS="LITERAL"
>ERROR</TT
>
	raises an error condition: further execution of the function is
	abandoned, and the current transaction is aborted.
	<TT
CLASS="LITERAL"
>FATAL</TT
> 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.)
       </P
></DD
></DL
></DIV
><P>
    </P
></DIV
><DIV
CLASS="NAVFOOTER"
><HR
ALIGN="LEFT"
WIDTH="100%"><TABLE
SUMMARY="Footer navigation table"
WIDTH="100%"
BORDER="0"
CELLPADDING="0"
CELLSPACING="0"
><TR
><TD
WIDTH="33%"
ALIGN="left"
VALIGN="top"
><A
HREF="pltcl-global.html"
ACCESSKEY="P"
>Prev</A
></TD
><TD
WIDTH="34%"
ALIGN="center"
VALIGN="top"
><A
HREF="index.html"
ACCESSKEY="H"
>Home</A
></TD
><TD
WIDTH="33%"
ALIGN="right"
VALIGN="top"
><A
HREF="pltcl-trigger.html"
ACCESSKEY="N"
>Next</A
></TD
></TR
><TR
><TD
WIDTH="33%"
ALIGN="left"
VALIGN="top"
>Global Data in PL/Tcl</TD
><TD
WIDTH="34%"
ALIGN="center"
VALIGN="top"
><A
HREF="pltcl.html"
ACCESSKEY="U"
>Up</A
></TD
><TD
WIDTH="33%"
ALIGN="right"
VALIGN="top"
>Trigger Procedures in PL/Tcl</TD
></TR
></TABLE
></DIV
></BODY
></HTML
>