1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 31 32 33 34 35 36 37 38 39 40 41 42 43 44 45 46 47 48 49 50 51 52 53 54 55 56 57 58 59 60 61 62 63 64 65 66 67 68 69 70 71 72 73 74 75 76 77 78 79 80 81 82 83 84 85 86 87 88 89 90 91 92 93 94 95 96 97 98 99 100 101 102 103 104 105 106 107 108 109 110 111 112 113 114 115 116 117 118 119 120 121 122 123 124 125 126 127 128 129 130 131 132 133 134 135 136 137 138 139 140 141 142 143 144 145 146 147 148 149 150 151 152 153 154 155 156 157 158 159 160 161 162 163 164 165 166 167 168 169 170 171 172 173 174 175 176 177 178 179 180 181 182 183 184 185 186 187 188 189 190 191 192 193 194 195 196 197 198 199 200 201 202 203 204 205 206 207 208 209 210 211 212 213 214 215 216 217 218 219 220 221 222 223 224 225 226 227 228 229 230 231 232 233 234
|
<html>
<head>
<meta http-equiv="Content-Type" content="text/html; charset=ISO-8859-1">
<title>37.5.Database Access from PL/Tcl</title>
<link rel="stylesheet" href="stylesheet.css" type="text/css">
<link rev="made" href="pgsql-docs@postgresql.org">
<meta name="generator" content="DocBook XSL Stylesheets V1.70.0">
<link rel="start" href="index.html" title="PostgreSQL 8.1.4 Documentation">
<link rel="up" href="pltcl.html" title="Chapter37.PL/Tcl - Tcl Procedural Language">
<link rel="prev" href="pltcl-global.html" title="37.4.Global Data in PL/Tcl">
<link rel="next" href="pltcl-trigger.html" title="37.6.Trigger Procedures in PL/Tcl">
<link rel="copyright" href="ln-legalnotice.html" title="Legal Notice">
</head>
<body bgcolor="white" text="black" link="#0000FF" vlink="#840084" alink="#0000FF"><div class="sect1" lang="en">
<div class="titlepage"><div><div><h2 class="title" style="clear: both">
<a name="pltcl-dbaccess"></a>37.5.Database Access from PL/Tcl</h2></div></div></div>
<p> The following commands are available to access the database from
the body of a PL/Tcl function:
</p>
<div class="variablelist"><dl>
<dt><span class="term"><code class="literal"><code class="function">spi_exec</code>
?<span class="optional">-count <em class="replaceable"><code>n</code></em></span>?
?<span class="optional">-array <em class="replaceable"><code>name</code></em></span>?
<em class="replaceable"><code>command</code></em>
?<span class="optional"><em class="replaceable"><code>loop-body</code></em></span>?
</code></span></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 <code class="command">SELECT</code> statement, the
values of the selected columns are placed in Tcl variables as
described below.
</p>
<p> The optional <code class="literal">-count</code> 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 <code class="literal">FETCH <em class="replaceable"><code>n</code></em></code>.
</p>
<p> If the command is a <code class="command">SELECT</code> statement, the values of the
result columns are placed into Tcl variables named after the columns.
If the <code class="literal">-array</code> 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 <code class="command">SELECT</code> statement and no <em class="replaceable"><code>loop-body</code></em>
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 <code class="literal">$cnt</code> to the number of rows in
the <code class="structname">pg_proc</code> system catalog.
</p>
<p> If the optional <em class="replaceable"><code>loop-body</code></em> argument is given, it is
a piece of Tcl script that is executed once for each row in the
query result. (<em class="replaceable"><code>loop-body</code></em> is ignored if the given
command is not a <code class="command">SELECT</code>.) 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 <code class="literal">pg_class</code>. This
feature works similarly to other Tcl looping constructs; in
particular <code class="literal">continue</code> and <code class="literal">break</code> 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><span class="term"><code class="function">spi_prepare</code> <em class="replaceable"><code>query</code></em> <em class="replaceable"><code>typelist</code></em></span></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="id730097"></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 <code class="literal">$1</code> ... <code class="literal">$<em class="replaceable"><code>n</code></em></code>.
If the query uses parameters, the names of the parameter types
must be given as a Tcl list. (Write an empty list for
<em class="replaceable"><code>typelist</code></em> if no parameters are used.)
Presently, the parameter types must be identified by the internal
type names shown in the system table <code class="literal">pg_type</code>; for example <code class="literal">int4</code> not
<code class="literal">integer</code>.
</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><span class="term"><code class="literal"><code class="function">spi_execp</code>
?<span class="optional">-count <em class="replaceable"><code>n</code></em></span>?
?<span class="optional">-array <em class="replaceable"><code>name</code></em></span>?
?<span class="optional">-nulls <em class="replaceable"><code>string</code></em></span>?
<em class="replaceable"><code>queryid</code></em>
?<span class="optional"><em class="replaceable"><code>value-list</code></em></span>?
?<span class="optional"><em class="replaceable"><code>loop-body</code></em></span>?
</code></span></dt>
<dd>
<p> Executes a query previously prepared with <code class="function">spi_prepare</code>.
<em class="replaceable"><code>queryid</code></em> is the ID returned by
<code class="function">spi_prepare</code>. If the query references parameters,
a <em class="replaceable"><code>value-list</code></em> 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 <em class="replaceable"><code>value-list</code></em>
if the query has no parameters.
</p>
<p> The optional value for <code class="literal">-nulls</code> is a string of spaces and
<code class="literal">'n'</code> 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 <em class="replaceable"><code>value-list</code></em>. 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 <code class="literal">-count</code>, <code class="literal">-array</code>, and
<em class="replaceable"><code>loop-body</code></em> 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 >= \$1 AND num <= \$2" \
[ list int4 int4 ] ]
}
spi_execp -count 1 $GD(plan) [ list $1 $2 ]
return $cnt
$$ LANGUAGE pltcl;</pre>
<p>
We need backslashes inside the query string given to
<code class="function">spi_prepare</code> to ensure that the
<code class="literal">$<em class="replaceable"><code>n</code></em></code> markers will be passed
through to <code class="function">spi_prepare</code> as-is, and not replaced by Tcl
variable substitution.
</p>
</dd>
<dt><span class="term"><code class="function">spi_lastoid</code></span></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 <code class="command">INSERT</code> and the modified
table contained OIDs. (If not, you get zero.)
</p></dd>
<dt><span class="term"><code class="function">quote</code> <em class="replaceable"><code>string</code></em></span></dt>
<dd>
<p> 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 <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 <code class="literal">val</code> actually contains
<code class="literal">doesn't</code>. 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>.
To work properly, 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><span class="term"><code class="function">elog</code> <em class="replaceable"><code>level</code></em> <em class="replaceable"><code>msg</code></em></span></dt>
<dd><p> Emits a log or error message. Possible levels are
<code class="literal">DEBUG</code>, <code class="literal">LOG</code>, <code class="literal">INFO</code>,
<code class="literal">NOTICE</code>, <code class="literal">WARNING</code>, <code class="literal">ERROR</code>, and
<code class="literal">FATAL</code>. <code class="literal">ERROR</code>
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 <code class="literal">error</code> command.
<code class="literal">FATAL</code> 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
<a href="runtime-config-logging.html#guc-log-min-messages">log_min_messages</a> and
<a href="runtime-config-logging.html#guc-client-min-messages">client_min_messages</a> configuration
variables. See <a href="runtime-config.html" title="Chapter17.Server Configuration">Chapter17, <i>Server Configuration</i></a> for more
information.
</p></dd>
</dl></div>
<p>
</p>
</div></body>
</html>
|