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 235 236 237 238 239 240 241 242 243 244 245 246 247 248 249 250 251 252
|
<html>
<head>
<meta http-equiv="Content-Type" content="text/html; charset=ISO-8859-1">
<title>Chapter36.PL/pgSQL - SQL Procedural Language</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="server-programming.html" title="PartV.Server Programming">
<link rel="prev" href="xplang.html" title="Chapter35.Procedural Languages">
<link rel="next" href="plpgsql-development-tips.html" title="36.2.Tips for Developing in PL/pgSQL">
<link rel="copyright" href="ln-legalnotice.html" title="Legal Notice">
</head>
<body bgcolor="white" text="black" link="#0000FF" vlink="#840084" alink="#0000FF"><div class="chapter" lang="en" id="plpgsql">
<div class="titlepage"><div><div><h2 class="title">
<a name="plpgsql"></a>Chapter36.<span class="application">PL/pgSQL</span> - <acronym class="acronym">SQL</acronym> Procedural Language</h2></div></div></div>
<div class="toc">
<p><b>Table of Contents</b></p>
<dl>
<dt><span class="sect1"><a href="plpgsql.html#plpgsql-overview">36.1. Overview</a></span></dt>
<dd><dl>
<dt><span class="sect2"><a href="plpgsql.html#plpgsql-advantages">36.1.1. Advantages of Using <span class="application">PL/pgSQL</span></a></span></dt>
<dt><span class="sect2"><a href="plpgsql.html#plpgsql-args-results">36.1.2. Supported Argument and Result Data Types</a></span></dt>
</dl></dd>
<dt><span class="sect1"><a href="plpgsql-development-tips.html">36.2. Tips for Developing in <span class="application">PL/pgSQL</span></a></span></dt>
<dd><dl><dt><span class="sect2"><a href="plpgsql-development-tips.html#plpgsql-quote-tips">36.2.1. Handling of Quotation Marks</a></span></dt></dl></dd>
<dt><span class="sect1"><a href="plpgsql-structure.html">36.3. Structure of <span class="application">PL/pgSQL</span></a></span></dt>
<dt><span class="sect1"><a href="plpgsql-declarations.html">36.4. Declarations</a></span></dt>
<dd><dl>
<dt><span class="sect2"><a href="plpgsql-declarations.html#plpgsql-declaration-aliases">36.4.1. Aliases for Function Parameters</a></span></dt>
<dt><span class="sect2"><a href="plpgsql-declarations.html#plpgsql-declaration-type">36.4.2. Copying Types</a></span></dt>
<dt><span class="sect2"><a href="plpgsql-declarations.html#plpgsql-declaration-rowtypes">36.4.3. Row Types</a></span></dt>
<dt><span class="sect2"><a href="plpgsql-declarations.html#plpgsql-declaration-records">36.4.4. Record Types</a></span></dt>
<dt><span class="sect2"><a href="plpgsql-declarations.html#plpgsql-declaration-renaming-vars">36.4.5. <code class="literal">RENAME</code></a></span></dt>
</dl></dd>
<dt><span class="sect1"><a href="plpgsql-expressions.html">36.5. Expressions</a></span></dt>
<dt><span class="sect1"><a href="plpgsql-statements.html">36.6. Basic Statements</a></span></dt>
<dd><dl>
<dt><span class="sect2"><a href="plpgsql-statements.html#plpgsql-statements-assignment">36.6.1. Assignment</a></span></dt>
<dt><span class="sect2"><a href="plpgsql-statements.html#plpgsql-select-into">36.6.2. <code class="command">SELECT INTO</code></a></span></dt>
<dt><span class="sect2"><a href="plpgsql-statements.html#plpgsql-statements-perform">36.6.3. Executing an Expression or Query With No Result</a></span></dt>
<dt><span class="sect2"><a href="plpgsql-statements.html#plpgsql-statements-null">36.6.4. Doing Nothing At All</a></span></dt>
<dt><span class="sect2"><a href="plpgsql-statements.html#plpgsql-statements-executing-dyn">36.6.5. Executing Dynamic Commands</a></span></dt>
<dt><span class="sect2"><a href="plpgsql-statements.html#plpgsql-statements-diagnostics">36.6.6. Obtaining the Result Status</a></span></dt>
</dl></dd>
<dt><span class="sect1"><a href="plpgsql-control-structures.html">36.7. Control Structures</a></span></dt>
<dd><dl>
<dt><span class="sect2"><a href="plpgsql-control-structures.html#plpgsql-statements-returning">36.7.1. Returning From a Function</a></span></dt>
<dt><span class="sect2"><a href="plpgsql-control-structures.html#plpgsql-conditionals">36.7.2. Conditionals</a></span></dt>
<dt><span class="sect2"><a href="plpgsql-control-structures.html#plpgsql-control-structures-loops">36.7.3. Simple Loops</a></span></dt>
<dt><span class="sect2"><a href="plpgsql-control-structures.html#plpgsql-records-iterating">36.7.4. Looping Through Query Results</a></span></dt>
<dt><span class="sect2"><a href="plpgsql-control-structures.html#plpgsql-error-trapping">36.7.5. Trapping Errors</a></span></dt>
</dl></dd>
<dt><span class="sect1"><a href="plpgsql-cursors.html">36.8. Cursors</a></span></dt>
<dd><dl>
<dt><span class="sect2"><a href="plpgsql-cursors.html#plpgsql-cursor-declarations">36.8.1. Declaring Cursor Variables</a></span></dt>
<dt><span class="sect2"><a href="plpgsql-cursors.html#plpgsql-cursor-opening">36.8.2. Opening Cursors</a></span></dt>
<dt><span class="sect2"><a href="plpgsql-cursors.html#plpgsql-cursor-using">36.8.3. Using Cursors</a></span></dt>
</dl></dd>
<dt><span class="sect1"><a href="plpgsql-errors-and-messages.html">36.9. Errors and Messages</a></span></dt>
<dt><span class="sect1"><a href="plpgsql-trigger.html">36.10. Trigger Procedures</a></span></dt>
<dt><span class="sect1"><a href="plpgsql-porting.html">36.11. Porting from <span class="productname">Oracle</span> PL/SQL</a></span></dt>
<dd><dl>
<dt><span class="sect2"><a href="plpgsql-porting.html#id728100">36.11.1. Porting Examples</a></span></dt>
<dt><span class="sect2"><a href="plpgsql-porting.html#plpgsql-porting-other">36.11.2. Other Things to Watch For</a></span></dt>
<dt><span class="sect2"><a href="plpgsql-porting.html#plpgsql-porting-appendix">36.11.3. Appendix</a></span></dt>
</dl></dd>
</dl>
</div>
<a name="id720494"></a><p> <span class="application">PL/pgSQL</span> is a loadable procedural
language for the <span class="productname">PostgreSQL</span> database
system. The design goals of <span class="application">PL/pgSQL</span> were to create
a loadable procedural language that
</p>
<div class="itemizedlist"><ul type="disc">
<li><p> can be used to create functions and trigger procedures,
</p></li>
<li><p> adds control structures to the <acronym class="acronym">SQL</acronym> language,
</p></li>
<li><p> can perform complex computations,
</p></li>
<li><p> inherits all user-defined types, functions, and operators,
</p></li>
<li><p> can be defined to be trusted by the server,
</p></li>
<li><p> is easy to use.
</p></li>
</ul></div>
<p>
</p>
<p> Except for input/output conversion and calculation functions
for user-defined types, anything that can be defined in C language
functions can also be done with <span class="application">PL/pgSQL</span>.
For example, it is possible to
create complex conditional computation functions and later use
them to define operators or use them in index expressions.
</p>
<div class="sect1" lang="en">
<div class="titlepage"><div><div><h2 class="title" style="clear: both">
<a name="plpgsql-overview"></a>36.1.Overview</h2></div></div></div>
<p> The <span class="application">PL/pgSQL</span> call handler parses the function's source text and
produces an internal binary instruction tree the first time the
function is called (within each session). The instruction tree
fully translates the
<span class="application">PL/pgSQL</span> statement structure, but individual
<acronym class="acronym">SQL</acronym> expressions and <acronym class="acronym">SQL</acronym> commands
used in the function are not translated immediately.
</p>
<p> As each expression and <acronym class="acronym">SQL</acronym> command is first
used in the function, the <span class="application">PL/pgSQL</span> interpreter
creates a prepared execution plan (using the
<acronym class="acronym">SPI</acronym> manager's <code class="function">SPI_prepare</code>
and <code class="function">SPI_saveplan</code>
functions).<a name="id720650"></a> Subsequent visits to that expression or command
reuse the prepared plan. Thus, a function with conditional code
that contains many statements for which execution plans might be
required will only prepare and save those plans that are really
used during the lifetime of the database connection. This can
substantially reduce the total amount of time required to parse
and generate execution plans for the statements in a
<span class="application">PL/pgSQL</span> function. A disadvantage is that errors
in a specific expression or command may not be detected until that
part of the function is reached in execution.
</p>
<p> Once <span class="application">PL/pgSQL</span> has made an execution plan for a particular
command in a function, it will reuse that plan for the life of the
database connection. This is usually a win for performance, but it
can cause some problems if you dynamically
alter your database schema. For example:
</p>
<pre class="programlisting">CREATE FUNCTION populate() RETURNS integer AS $$
DECLARE
-- declarations
BEGIN
PERFORM my_function();
END;
$$ LANGUAGE plpgsql;</pre>
<p>
If you execute the above function, it will reference the OID for
<code class="function">my_function()</code> in the execution plan produced for
the <code class="command">PERFORM</code> statement. Later, if you
drop and recreate <code class="function">my_function()</code>, then
<code class="function">populate()</code> will not be able to find
<code class="function">my_function()</code> anymore. You would then have to
recreate <code class="function">populate()</code>, or at least start a new
database session so that it will be compiled afresh. Another way
to avoid this problem is to use <code class="command">CREATE OR REPLACE
FUNCTION</code> when updating the definition of
<code class="function">my_function</code> (when a function is
“<span class="quote">replaced</span>”, its OID is not changed).
</p>
<p> Because <span class="application">PL/pgSQL</span> saves execution plans
in this way, SQL commands that appear directly in a
<span class="application">PL/pgSQL</span> function must refer to the
same tables and columns on every execution; that is, you cannot use
a parameter as the name of a table or column in an SQL command. To get
around this restriction, you can construct dynamic commands using
the <span class="application">PL/pgSQL</span> <code class="command">EXECUTE</code>
statement [mdash ] at the price of constructing a new execution plan on
every execution.
</p>
<div class="note" style="margin-left: 0.5in; margin-right: 0.5in;">
<h3 class="title">Note</h3>
<p> The <span class="application">PL/pgSQL</span>
<code class="command">EXECUTE</code> statement is not related to the
<a href="sql-execute.html">EXECUTE</a> SQL
statement supported by the
<span class="productname">PostgreSQL</span> server. The server's
<code class="command">EXECUTE</code> statement cannot be used within
<span class="application">PL/pgSQL</span> functions (and is not needed).
</p>
</div>
<div class="sect2" lang="en">
<div class="titlepage"><div><div><h3 class="title">
<a name="plpgsql-advantages"></a>36.1.1.Advantages of Using <span class="application">PL/pgSQL</span></h3></div></div></div>
<p> <acronym class="acronym">SQL</acronym> is the language <span class="productname">PostgreSQL</span>
and most other relational databases use as query language. It's
portable and easy to learn. But every <acronym class="acronym">SQL</acronym>
statement must be executed individually by the database server.
</p>
<p> That means that your client application must send each query to
the database server, wait for it to be processed, receive the
results, do some computation, then send other queries to the
server. All this incurs interprocess communication and may also
incur network overhead if your client is on a different machine
than the database server.
</p>
<p> With <span class="application">PL/pgSQL</span> you can group a block of computation and a
series of queries <span class="emphasis"><em>inside</em></span> the
database server, thus having the power of a procedural
language and the ease of use of SQL, but saving lots of
time because you don't have the whole client/server
communication overhead. This can make for a
considerable performance increase.
</p>
<p> Also, with <span class="application">PL/pgSQL</span> you can use all
the data types, operators and functions of SQL.
</p>
</div>
<div class="sect2" lang="en">
<div class="titlepage"><div><div><h3 class="title">
<a name="plpgsql-args-results"></a>36.1.2.Supported Argument and Result Data Types</h3></div></div></div>
<p> Functions written in <span class="application">PL/pgSQL</span> can accept
as arguments any scalar or array data type supported by the server,
and they can return a result of any of these types. They can also
accept or return any composite type (row type) specified by name.
It is also possible to declare a <span class="application">PL/pgSQL</span>
function as returning <code class="type">record</code>, which means that the result
is a row type whose columns are determined by specification in the
calling query, as discussed in <a href="queries-table-expressions.html#queries-tablefunctions" title="7.2.1.4.Table Functions">Section7.2.1.4, “Table Functions”</a>.
</p>
<p> <span class="application">PL/pgSQL</span> functions may also be declared to accept
and return the polymorphic types
<code class="type">anyelement</code> and <code class="type">anyarray</code>. The actual
data types handled by a polymorphic function can vary from call to
call, as discussed in <a href="extend-type-system.html#extend-types-polymorphic" title="32.2.5.Polymorphic Types">Section32.2.5, “Polymorphic Types”</a>.
An example is shown in <a href="plpgsql-declarations.html#plpgsql-declaration-aliases" title="36.4.1.Aliases for Function Parameters">Section36.4.1, “Aliases for Function Parameters”</a>.
</p>
<p> <span class="application">PL/pgSQL</span> functions can also be declared to return
a “<span class="quote">set</span>”, or table, of any data type they can return a single
instance of. Such a function generates its output by executing
<code class="literal">RETURN NEXT</code> for each desired element of the result set.
</p>
<p> Finally, a <span class="application">PL/pgSQL</span> function may be declared to return
<code class="type">void</code> if it has no useful return value.
</p>
<div class="note" style="margin-left: 0.5in; margin-right: 0.5in;">
<h3 class="title">Note</h3>
<p> <span class="application">PL/pgSQL</span> 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 <span class="application">PL/pgSQL</span> function
as returning a domain type.
</p>
</div>
<p> <span class="application">PL/pgSQL</span> functions can also be declared with output
parameters in place of an explicit specification of the return type.
This does not add any fundamental capability to the language, but
it is often convenient, especially for returning multiple values.
</p>
<p> Specific examples appear in
<a href="plpgsql-declarations.html#plpgsql-declaration-aliases" title="36.4.1.Aliases for Function Parameters">Section36.4.1, “Aliases for Function Parameters”</a> and
<a href="plpgsql-control-structures.html#plpgsql-statements-returning" title="36.7.1.Returning From a Function">Section36.7.1, “Returning From a Function”</a>.
</p>
</div>
</div>
</div></body>
</html>
|