postgresql/doc/src/sgml/plpgsql.sgml

3059 lines
94 KiB
Plaintext
Raw Normal View History

<!--
$Header: /cvsroot/pgsql/doc/src/sgml/plpgsql.sgml,v 1.3 2002/08/22 00:01:40 tgl Exp $
-->
<chapter id="plpgsql">
<title><application>PL/pgSQL</application> - <acronym>SQL</acronym> Procedural Language</title>
<indexterm zone="plpgsql">
<primary>PL/pgSQL</primary>
</indexterm>
<para>
<application>PL/pgSQL</application> is a loadable procedural language for the
<productname>PostgreSQL</productname> database system.
</para>
<para>
This package was originally written by Jan Wieck. This
2001-03-17 19:08:14 +01:00
documentation was in part written
by Roberto Mello (<email>rmello@fslc.usu.edu</email>).
</para>
<sect1 id="plpgsql-overview">
<title>Overview</title>
<para>
The design goals of <application>PL/pgSQL</> were to create a loadable procedural
language that
<itemizedlist>
<listitem>
<para>
can be used to create functions and trigger procedures,
</para>
</listitem>
<listitem>
<para>
adds control structures to the <acronym>SQL</acronym> language,
</para>
</listitem>
<listitem>
<para>
can perform complex computations,
</para>
</listitem>
<listitem>
<para>
inherits all user defined types, functions and operators,
</para>
</listitem>
<listitem>
<para>
can be defined to be trusted by the server,
</para>
</listitem>
<listitem>
<para>
is easy to use.
</para>
</listitem>
</itemizedlist>
</para>
<para>
The <application>PL/pgSQL</> call handler parses the function's source text and
produces an internal binary instruction tree the first time the
function is called (within any one backend process). The instruction tree
fully translates the
<application>PL/pgSQL</> statement structure, but individual
<acronym>SQL</acronym> expressions and <acronym>SQL</acronym> queries
used in the function are not translated immediately.
</para>
<para>
As each expression and <acronym>SQL</acronym> query is first used
in the function, the <application>PL/pgSQL</> interpreter creates a
prepared execution plan (using the <acronym>SPI</acronym> manager's
<function>SPI_prepare</function> and
<function>SPI_saveplan</function> functions). Subsequent visits
to that expression or query re-use 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 provide a considerable savings of parsing
activity. A disadvantage is that errors in a specific expression
or query may not be detected until that part of the function is
reached in execution.
</para>
<para>
Once <application>PL/pgSQL</> has made a query plan for a particular
query in a function, it will re-use 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:
2001-03-17 19:08:14 +01:00
<programlisting>
CREATE FUNCTION populate() RETURNS INTEGER AS '
DECLARE
-- Declarations
BEGIN
PERFORM my_function();
END;
2001-03-17 19:08:14 +01:00
' LANGUAGE 'plpgsql';
</programlisting>
If you execute the above function, it will reference the OID for
<function>my_function()</function> in the query plan produced for
the PERFORM statement. Later, if you
2001-03-17 19:08:14 +01:00
drop and re-create <function>my_function()</function>, then
<function>populate()</function> will not be able to find
<function>my_function()</function> anymore. You would then have to
re-create <function>populate()</function>, or at least start a new
database session so that it will be compiled afresh.
</para>
2001-03-17 19:08:14 +01:00
<para>
Because <application>PL/pgSQL</application> saves execution plans in this way, queries that appear
directly in a <application>PL/pgSQL</application> function must refer to the same tables and fields
on every execution; that is, you cannot use a parameter as the name of
a table or field in a query. To get around
this restriction, you can construct dynamic queries using the <application>PL/pgSQL</application>
EXECUTE statement --- at the price of constructing a new query plan
on every execution.
</para>
<para>
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 <application>PL/pgSQL</application>. It is possible to
create complex conditional computation functions and later use
them to define operators or use them in functional indexes.
</para>
<sect2 id="plpgsql-advantages">
<title>Advantages of Using <application>PL/pgSQL</application></title>
<itemizedlist>
<listitem>
<para>
2001-03-17 19:08:14 +01:00
Better performance (see <xref linkend="plpgsql-advantages-performance">)
</para>
</listitem>
2001-03-17 19:08:14 +01:00
<listitem>
<para>
2001-03-17 19:08:14 +01:00
SQL support (see <xref linkend="plpgsql-advantages-sqlsupport">)
</para>
</listitem>
2001-03-17 19:08:14 +01:00
<listitem>
<para>
2001-03-17 19:08:14 +01:00
Portability (see <xref linkend="plpgsql-advantages-portability">)
</para>
</listitem>
</itemizedlist>
<sect3 id="plpgsql-advantages-performance">
<title>Better Performance</title>
2001-03-17 19:08:14 +01:00
<para>
<acronym>SQL</acronym> is the language <productname>PostgreSQL</> (and
most other Relational Databases) use as query
language. It's portable and easy to learn. But every
<acronym>SQL</acronym> statement must be executed
individually by the database server.
</para>
2001-03-17 19:08:14 +01:00
<para>
That means that your client application must send each
query to the database server, wait for it to process it,
receive the results, do some computation, then send
other queries to the server. All this incurs inter-process communication
and may also incur network
overhead if your client is on a different machine than
the database server.
</para>
2001-03-17 19:08:14 +01:00
<para>
With <application>PL/pgSQL</application> you can group a block of computation and a
series of queries <emphasis>inside</emphasis> 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.
</para>
</sect3>
2001-03-17 19:08:14 +01:00
<sect3 id="plpgsql-advantages-sqlsupport">
<title>SQL Support</title>
2001-03-17 19:08:14 +01:00
<para>
<application>PL/pgSQL</application> adds the power of a procedural language to the
flexibility and ease of <acronym>SQL</acronym>. With
<application>PL/pgSQL</application> you can use all the data types, columns, operators
and functions of SQL.
</para>
</sect3>
2001-03-17 19:08:14 +01:00
<sect3 id="plpgsql-advantages-portability">
<title>Portability</title>
2001-03-17 19:08:14 +01:00
<para>
Because <application>PL/pgSQL</application> functions run inside <productname>PostgreSQL</>, these
functions will run on any platform where <productname>PostgreSQL</>
runs. Thus you can reuse code and have less development costs.
</para>
</sect3>
</sect2>
<sect2 id="plpgsql-overview-developing-in-plpgsql">
<title>Developing in <application>PL/pgSQL</application></title>
<para>
Developing in <application>PL/pgSQL</application> is pretty straight forward, especially
if you have developed in other database procedural languages,
such as Oracle's <application>PL/SQL</application>. Two good ways of developing in
<application>PL/pgSQL</application> are:
2001-03-17 19:08:14 +01:00
<itemizedlist>
<listitem>
<para>
Using a text editor and reloading the file with <command>psql</command>
</para>
</listitem>
2001-03-17 19:08:14 +01:00
<listitem>
<para>
Using <productname>PostgreSQL</>'s GUI Tool: <application>PgAccess</>
</para>
</listitem>
</itemizedlist>
</para>
2001-03-17 19:08:14 +01:00
<para>
One good way to develop in <application>PL/pgSQL</> is to simply use the text
editor of your choice to create your functions, and in another
console, use <command>psql</command> (PostgreSQL's interactive monitor) to load
those functions. If you are doing it this way, it is a good
idea to write the function using <command>CREATE OR REPLACE
FUNCTION</command>. That way you can reload the file to update
the function definition. For example:
2001-03-17 19:08:14 +01:00
<programlisting>
CREATE OR REPLACE FUNCTION testfunc(INTEGER) RETURNS INTEGER AS '
....
end;
2001-10-13 06:58:35 +02:00
' LANGUAGE 'plpgsql';
2001-03-17 19:08:14 +01:00
</programlisting>
</para>
2001-03-17 19:08:14 +01:00
<para>
While running <command>psql</command>, you can load or reload such a
function definition file with
2001-03-17 19:08:14 +01:00
<programlisting>
\i filename.sql
2001-03-17 19:08:14 +01:00
</programlisting>
and then immediately issue SQL commands to test the function.
2001-03-17 19:08:14 +01:00
</para>
2001-03-17 19:08:14 +01:00
<para>
Another good way to develop in <application>PL/pgSQL</> is using
<productname>PostgreSQL</>'s GUI tool: <application>PgAccess</>. It does some
nice things for you, like escaping single-quotes, and making
it easy to recreate and debug functions.
</para>
</sect2>
2001-03-17 19:08:14 +01:00
</sect1>
<sect1 id="plpgsql-structure">
<title>Structure of <application>PL/pgSQL</application></title>
<para>
<application>PL/pgSQL</application> is a <emphasis>block
structured</emphasis> language. The complete text of a function
definition must be a <firstterm>block</>. A block is defined as:
2001-03-17 19:08:14 +01:00
<synopsis>
<optional> &lt;&lt;label&gt;&gt; </optional>
<optional> DECLARE
<replaceable>declarations</replaceable> </optional>
BEGIN
<replaceable>statements</replaceable>
END;
2001-03-17 19:08:14 +01:00
</synopsis>
</para>
<para>
Any <firstterm>statement</> in the statement section of a block
can be a <firstterm>sub-block</>. Sub-blocks can be used for
logical grouping or to localize variables to a small group
of statements.
</para>
2001-03-17 19:08:14 +01:00
<para>
2001-03-17 19:08:14 +01:00
The variables declared in the declarations section preceding a
block are initialized to their default values every time the
block is entered, not only once per function call. For example:
<programlisting>
CREATE FUNCTION somefunc() RETURNS INTEGER AS '
DECLARE
quantity INTEGER := 30;
BEGIN
RAISE NOTICE ''Quantity here is %'',quantity; -- Quantity here is 30
quantity := 50;
--
-- Create a sub-block
--
DECLARE
quantity INTEGER := 80;
BEGIN
RAISE NOTICE ''Quantity here is %'',quantity; -- Quantity here is 80
END;
RAISE NOTICE ''Quantity here is %'',quantity; -- Quantity here is 50
2001-09-10 08:30:43 +02:00
RETURN quantity;
END;
2001-03-17 19:08:14 +01:00
' LANGUAGE 'plpgsql';
</programlisting>
</para>
<para>
It is important not to confuse the use of BEGIN/END for
grouping statements in <application>PL/pgSQL</> with the database commands for
transaction control. <application>PL/pgSQL</>'s BEGIN/END are only for grouping;
they do not start or end a transaction. Functions and trigger procedures
are always executed within a transaction established by an outer query
--- they cannot start or commit transactions, since
<productname>PostgreSQL</productname> does not have nested transactions.
</para>
<sect2>
<title>Lexical Details</title>
<para>
Each statement and declaration within a block is terminated
by a semicolon.
</para>
<para>
All keywords and identifiers can be written in mixed upper- and
lower-case. Identifiers are implicitly converted to lower-case
unless double-quoted.
</para>
<para>
There are two types of comments in <application>PL/pgSQL</>. A double dash <literal>--</literal>
starts a comment that extends to the end of the line. A <literal>/*</literal>
starts a block comment that extends to the next occurrence of <literal>*/</literal>.
Block comments cannot be nested, but double dash comments can be
enclosed into a block comment and a double dash can hide
the block comment delimiters <literal>/*</literal> and <literal>*/</literal>.
</para>
</sect2>
</sect1>
<sect1 id="plpgsql-declarations">
<title>Declarations</title>
<para>
All variables, rows and records used in a block must be declared in the
declarations section of the block.
(The only exception is that the loop variable of a FOR loop iterating
over a range of integer values is automatically declared as an integer
variable.)
2001-03-17 19:08:14 +01:00
</para>
<para>
<application>PL/pgSQL</> variables can have any SQL data type, such as
<type>INTEGER</type>, <type>VARCHAR</type> and
<type>CHAR</type>.
</para>
2001-03-17 19:08:14 +01:00
<para>
Here are some examples of variable declarations:
2001-03-17 19:08:14 +01:00
<programlisting>
user_id INTEGER;
quantity NUMERIC(5);
url VARCHAR;
myrow tablename%ROWTYPE;
myfield tablename.fieldname%TYPE;
arow RECORD;
2001-03-17 19:08:14 +01:00
</programlisting>
</para>
<para>
The general syntax of a variable declaration is:
2001-03-17 19:08:14 +01:00
<synopsis>
<replaceable>name</replaceable> <optional> CONSTANT </optional> <replaceable>type</replaceable> <optional> NOT NULL </optional> <optional> { DEFAULT | := } <replaceable>expression</replaceable> </optional>;
2001-03-17 19:08:14 +01:00
</synopsis>
</para>
<para>
The DEFAULT clause, if given, specifies the initial value assigned
to the variable when the block is entered. If the DEFAULT clause
is not given then the variable is initialized to the
<acronym>SQL</acronym> NULL value.
</para>
<para>
The CONSTANT option prevents the variable from being assigned to,
so that its value remains constant for the duration of the block.
If NOT NULL
2002-03-22 20:20:45 +01:00
is specified, an assignment of a NULL value results in a run-time
error. All variables declared as NOT NULL
must have a non-NULL default value specified.
</para>
2001-03-17 19:08:14 +01:00
<para>
The default value is evaluated every time the block is entered. So,
for example, assigning '<literal>now</literal>' to a variable of type
<type>timestamp</type> causes the variable to have the
time of the current function call, not when the function was
precompiled.
</para>
2001-03-17 19:08:14 +01:00
<para>
Examples:
2001-03-17 19:08:14 +01:00
<programlisting>
quantity INTEGER DEFAULT 32;
url varchar := ''http://mysite.com'';
user_id CONSTANT INTEGER := 10;
2001-03-17 19:08:14 +01:00
</programlisting>
</para>
<sect2 id="plpgsql-declaration-aliases">
<title>Aliases for Function Parameters</title>
<para>
<synopsis>
<replaceable>name</replaceable> ALIAS FOR <replaceable>$n</replaceable>;
</synopsis>
</para>
<para>
Parameters passed to functions are named with the identifiers
<literal>$1</literal>, <literal>$2</literal>,
etc. Optionally, aliases can be declared for <literal>$n</literal>
parameter names for increased readability. Either the alias or the
numeric identifier can then be used to refer to the parameter value.
Some examples:
2001-03-17 19:08:14 +01:00
<programlisting>
CREATE FUNCTION sales_tax(REAL) RETURNS REAL AS '
DECLARE
subtotal ALIAS FOR $1;
BEGIN
return subtotal * 0.06;
END;
2001-03-17 19:08:14 +01:00
' LANGUAGE 'plpgsql';
CREATE FUNCTION instr(VARCHAR,INTEGER) RETURNS INTEGER AS '
DECLARE
v_string ALIAS FOR $1;
index ALIAS FOR $2;
BEGIN
-- Some computations here
END;
2001-03-17 19:08:14 +01:00
' LANGUAGE 'plpgsql';
CREATE FUNCTION use_many_fields(tablename) RETURNS TEXT AS '
DECLARE
in_t ALIAS FOR $1;
BEGIN
RETURN in_t.f1 || in_t.f3 || in_t.f5 || in_t.f7;
END;
' LANGUAGE 'plpgsql';
2001-03-17 19:08:14 +01:00
</programlisting>
</para>
</sect2>
<sect2 id="plpgsql-declaration-rowtypes">
2002-03-22 20:20:45 +01:00
<title>Row Types</title>
<para>
<synopsis>
<replaceable>name</replaceable> <replaceable>tablename</replaceable><literal>%ROWTYPE</literal>;
</synopsis>
</para>
<para>
A variable of a composite type is called a <firstterm>row</>
2002-03-22 20:20:45 +01:00
variable (or <firstterm>row-type</> variable). Such a variable can hold a
whole row of a SELECT or FOR
query result, so long as that query's column set matches the declared
type of the variable. The individual fields of the row value are
accessed using the usual dot notation, for example
<literal>rowvar.field</literal>.
</para>
<para>
Presently, a row variable can only be declared using the
<literal>%ROWTYPE</literal> notation; although one might expect a
bare table name to work as a type declaration, it won't be accepted
within <application>PL/pgSQL</application> functions.
</para>
<para>
Parameters to a function can be
composite types (complete table rows). In that case, the
corresponding identifier $n will be a row variable, and fields can
be selected from it, for example <literal>$1.user_id</literal>.
</para>
<para>
Only the user-defined attributes of a table row are accessible in a
2002-03-22 20:20:45 +01:00
row-type variable, not OID or other system attributes (because the
row could be from a view). The fields of the row type inherit the
table's field size or precision for data types such as
<type>char(n)</type>.
<programlisting>
CREATE FUNCTION use_two_tables(tablename) RETURNS TEXT AS '
DECLARE
in_t ALIAS FOR $1;
use_t table2name%ROWTYPE;
BEGIN
SELECT * INTO use_t FROM table2name WHERE ... ;
RETURN in_t.f1 || use_t.f3 || in_t.f5 || use_t.f7;
END;
' LANGUAGE 'plpgsql';
</programlisting>
</para>
</sect2>
<sect2 id="plpgsql-declaration-records">
<title>Records</title>
<para>
<synopsis>
<replaceable>name</replaceable> RECORD;
</synopsis>
</para>
<para>
2002-03-22 20:20:45 +01:00
Record variables are similar to row-type variables, but they have no
predefined structure. They take on the actual row structure of the
row they are assigned during a SELECT or FOR command. The substructure
of a record variable can change each time it is assigned to.
A consequence of this is that until a record variable is first assigned
to, <emphasis>it has no</> substructure, and any attempt to access a
2002-03-22 20:20:45 +01:00
field in it will draw a run-time error.
</para>
<para>
2002-03-22 20:20:45 +01:00
Note that <literal>RECORD</> is not a true data type, only a placeholder.
Thus, for example, one cannot declare a function returning
<literal>RECORD</>.
</para>
</sect2>
<sect2 id="plpgsql-declaration-attributes">
<title>Attributes</title>
<para>
Using the <type>%TYPE</type> and <type>%ROWTYPE</type>
attributes, you can declare variables with the same
data type or structure as another database item (e.g: a
table field).
</para>
<variablelist>
<varlistentry>
<term>
<replaceable>variable</replaceable>%TYPE
</term>
<listitem>
<para>
<type>%TYPE</type> provides the data type of a
variable or database column. You can use this to
declare variables that will hold database
values. For example, let's say you have a column
named <type>user_id</type> in your
<type>users</type> table. To declare a variable with
the same data type as <structname>users</>.<structfield>user_id</> you write:
2001-03-17 19:08:14 +01:00
<programlisting>
user_id users.user_id%TYPE;
2001-03-17 19:08:14 +01:00
</programlisting>
</para>
<para>
By using <type>%TYPE</type> you don't need to know
the data type of the structure you are referencing,
and most important, if the data type of the
referenced item changes in the future (e.g: you
change your table definition of user_id from INTEGER to
REAL), you may not need to change your function
definition.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term>
<literal><replaceable>table</replaceable>%ROWTYPE</literal>
</term>
<listitem>
<para>
<type>%ROWTYPE</type> provides the composite data type corresponding
to a whole row of the specified table.
<replaceable>table</replaceable> must be an existing
table or view name of the database.
</para>
2001-03-17 19:08:14 +01:00
<programlisting>
DECLARE
users_rec users%ROWTYPE;
user_id users.user_id%TYPE;
BEGIN
user_id := users_rec.user_id;
...
CREATE FUNCTION does_view_exist(INTEGER) RETURNS bool AS '
DECLARE
key ALIAS FOR $1;
table_data cs_materialized_views%ROWTYPE;
BEGIN
SELECT INTO table_data * FROM cs_materialized_views
WHERE sort_key=key;
IF NOT FOUND THEN
RETURN false;
END IF;
RETURN true;
END;
2001-03-17 19:08:14 +01:00
' LANGUAGE 'plpgsql';
</programlisting>
</listitem>
</varlistentry>
</variablelist>
</sect2>
<sect2 id="plpgsql-declaration-renaming-vars">
<title>RENAME</title>
2001-03-17 19:08:14 +01:00
<para>
<synopsis>
RENAME <replaceable>oldname</replaceable> TO <replaceable>newname</replaceable>;
</synopsis>
Using the RENAME declaration you can change the name of a variable,
record or row. This is primarily useful if NEW or OLD should be
referenced by another name inside a trigger procedure. See also ALIAS.
</para>
2001-03-17 19:08:14 +01:00
<para>
Examples:
2001-03-17 19:08:14 +01:00
<programlisting>
RENAME id TO user_id;
RENAME this_var TO that_var;
2001-03-17 19:08:14 +01:00
</programlisting>
</para>
<note>
<para>
RENAME appears to be broken as of PostgreSQL 7.2. Fixing this is
of low priority, since ALIAS covers most of the practical uses of
RENAME.
</para>
</note>
</sect2>
</sect1>
<sect1 id="plpgsql-expressions">
<title>Expressions</title>
<para>
All expressions used in <application>PL/pgSQL</application> statements
are processed using the server's regular SQL executor. Expressions that
appear to contain
constants may in fact require run-time evaluation
(e.g. <literal>'now'</literal> for the
<type>timestamp</type> type) so
it is impossible for the <application>PL/pgSQL</application> parser
to identify real constant values other than the NULL keyword. All
expressions are evaluated internally by executing a query
2001-03-17 19:08:14 +01:00
<synopsis>
SELECT <replaceable>expression</replaceable>
2001-03-17 19:08:14 +01:00
</synopsis>
using the <acronym>SPI</acronym> manager. In the expression, occurrences
of <application>PL/pgSQL</application> variable
identifiers are replaced by parameters and the actual values from
the variables are passed to the executor in the parameter array.
This allows the query plan for the SELECT to be prepared just once
and then re-used for subsequent evaluations.
</para>
2001-03-17 19:08:14 +01:00
<para>
The evaluation done by the <productname>PostgreSQL</productname>
main parser has some side
effects on the interpretation of constant values. In detail there
is a difference between what these two functions do:
2001-03-17 19:08:14 +01:00
<programlisting>
CREATE FUNCTION logfunc1 (TEXT) RETURNS TIMESTAMP AS '
DECLARE
logtxt ALIAS FOR $1;
BEGIN
INSERT INTO logtable VALUES (logtxt, ''now'');
RETURN ''now'';
END;
' LANGUAGE 'plpgsql';
2001-03-17 19:08:14 +01:00
</programlisting>
and
2001-03-17 19:08:14 +01:00
<programlisting>
CREATE FUNCTION logfunc2 (TEXT) RETURNS TIMESTAMP AS '
DECLARE
logtxt ALIAS FOR $1;
curtime timestamp;
BEGIN
curtime := ''now'';
INSERT INTO logtable VALUES (logtxt, curtime);
RETURN curtime;
END;
' LANGUAGE 'plpgsql';
2001-03-17 19:08:14 +01:00
</programlisting>
In the case of <function>logfunc1()</function>, the
<productname>PostgreSQL</productname> main parser knows when
preparing the plan for the INSERT, that the string
<literal>'now'</literal> should be interpreted as
<type>timestamp</type> because the target field of <classname>logtable</classname>
is of that type. Thus, it will make a constant from it at this
time and this constant value is then used in all invocations of
<function>logfunc1()</function> during the lifetime of the
backend. Needless to say that this isn't what the
programmer wanted.
</para>
2001-03-17 19:08:14 +01:00
<para>
In the case of <function>logfunc2()</function>, the
<productname>PostgreSQL</productname> main parser does not know
what type <literal>'now'</literal> should become and therefore
it returns a data value of type <type>text</type> containing the string
<literal>'now'</literal>. During the ensuing assignment
to the local variable <varname>curtime</varname>, the
<application>PL/pgSQL</application> interpreter casts this
string to the <type>timestamp</type> type by calling the
<function>text_out()</function> and <function>timestamp_in()</function>
2002-03-22 20:20:45 +01:00
functions for the conversion. So, the computed time stamp is updated
on each execution as the programmer expects.
</para>
2001-03-17 19:08:14 +01:00
<para>
The mutable nature of record variables presents a problem in this
connection. When fields of a record variable are used in expressions or
statements, the data types of the
fields must not change between calls of one and the same expression,
2002-03-22 20:20:45 +01:00
since the expression will be planned using the data type that is present
when the expression is first reached.
Keep this in mind when writing trigger procedures that handle events
for more than one table. (EXECUTE can be used to get around this
problem when necessary.)
</para>
</sect1>
<sect1 id="plpgsql-statements">
<title>Basic Statements</title>
<para>
In this section and the following ones, we describe all the statement
types that are explicitly understood by
<application>PL/pgSQL</application>.
Anything not recognized as one of these statement types is presumed
to be an SQL query, and is sent to the main database engine to execute
(after substitution for any <application>PL/pgSQL</application> variables
used in the statement). Thus,
for example, SQL <command>INSERT</>, <command>UPDATE</>, and
<command>DELETE</> commands may be considered to be statements of
<application>PL/pgSQL</application>. But they are not specifically
listed here.
</para>
<sect2 id="plpgsql-statements-assignment">
<title>Assignment</title>
<para>
An assignment of a value to a variable or row/record field is
written as:
2001-03-17 19:08:14 +01:00
<synopsis>
<replaceable>identifier</replaceable> := <replaceable>expression</replaceable>;
2001-03-17 19:08:14 +01:00
</synopsis>
As explained above, the expression in such a statement is evaluated
by means of an SQL <command>SELECT</> command sent to the main
database engine. The expression must yield a single value.
</para>
<para>
If the expression's result data type doesn't match the variable's
data type, or the variable has a specific size/precision
(like <type>char(20)</type>), the result value will be implicitly
converted by the <application>PL/pgSQL</application> interpreter using
the result type's output-function and
the variable type's input-function. Note that this could potentially
2002-03-22 20:20:45 +01:00
result in run-time errors generated by the input function, if the
string form of the result value is not acceptable to the input function.
</para>
<para>
Examples:
2001-03-17 19:08:14 +01:00
<programlisting>
user_id := 20;
tax := subtotal * 0.06;
2001-03-17 19:08:14 +01:00
</programlisting>
</para>
</sect2>
<sect2 id="plpgsql-select-into">
<title>SELECT INTO</title>
<para>
The result of a SELECT command yielding multiple columns (but
2002-03-22 20:20:45 +01:00
only one row) can be assigned to a record variable, row-type
variable, or list of scalar variables. This is done by:
<synopsis>
SELECT INTO <replaceable>target</replaceable> <replaceable>expressions</replaceable> FROM ...;
</synopsis>
where <replaceable>target</replaceable> can be a record variable, a row
variable, or a comma-separated list of simple variables and
record/row fields. Note that this is quite different from
<productname>PostgreSQL</>'s normal interpretation of SELECT INTO, which is that the
INTO target is a newly created table. (If you want to create a
table from a SELECT result inside a <application>PL/pgSQL</application> function, use the
syntax <command>CREATE TABLE ... AS SELECT</command>.)
</para>
2001-03-17 19:08:14 +01:00
<para>
If a row or a variable list is used as target, the selected values
2002-03-22 20:20:45 +01:00
must exactly match the structure of the target(s), or a run-time error
occurs. When a record variable is the target, it automatically
2002-03-22 20:20:45 +01:00
configures itself to the row type of the query result columns.
</para>
<para>
Except for the INTO clause, the SELECT statement is the same as a normal
SQL SELECT query and can use the full power of SELECT.
</para>
<para>
If the SELECT query returns zero rows, NULLs are assigned to the
target(s). If the SELECT query returns multiple rows, the first
row is assigned to the target(s) and the rest are discarded.
(Note that <quote>the first row</> is not well-defined unless you've
used ORDER BY.)
</para>
<para>
At present, the INTO clause can appear almost anywhere in the SELECT
query, but it is recommended to place it immediately after the SELECT
keyword as depicted above. Future versions of
<application>PL/pgSQL</application> may be less forgiving about
placement of the INTO clause.
</para>
<para>
There is a special variable named <literal>FOUND</literal> of
type <type>boolean</type>. The initial value of
<literal>FOUND</literal> is false; it is set to true when one of
the following events occurs:
<itemizedlist>
<listitem>
<para>
A SELECT INTO statement is executed, and it returns one or
more rows.
</para>
</listitem>
<listitem>
<para>
A UPDATE, INSERT, or DELETE statement is executed, and it
affects one or more rows.
</para>
</listitem>
<listitem>
<para>
A PERFORM statement is executed, and it discards one or more
rows.
</para>
</listitem>
<listitem>
<para>
A FETCH statement is executed, and it returns an additional
row.
</para>
</listitem>
<listitem>
<para>
A FOR statement is executed, and it iterates one or more
times. This applies to all three variants of the FOR statement
(integer FOR loops, record-set FOR loops, and dynamic
record-set FOR loops). <literal>FOUND</literal> is only set
when the FOR loop exits: inside the execution of the loop,
<literal>FOUND</literal> is not modified, although it may be
set by the execution of other statements.
</para>
</listitem>
</itemizedlist>
If none of these events occur, <literal>FOUND</literal> is set to
false. <literal>FOUND</literal> is a local variable; any changes
to it effect only the current <application>PL/pgSQL</application>
function.
</para>
<para>
You can use <literal>FOUND</literal> immediately after a SELECT
INTO statement to determine whether the assignment was successful
(that is, at least one row was was returned by the SELECT
statement). For example:
<programlisting>
SELECT INTO myrec * FROM EMP WHERE empname = myname;
IF NOT FOUND THEN
RAISE EXCEPTION ''employee % not found'', myname;
END IF;
</programlisting>
Alternatively, you can use the IS NULL (or ISNULL) conditional to
test for NULLity of a RECORD/ROW result. Note that there is no
way to tell whether any additional rows might have been discarded.
</para>
<para>
<programlisting>
DECLARE
users_rec RECORD;
full_name varchar;
BEGIN
SELECT INTO users_rec * FROM users WHERE user_id=3;
IF users_rec.homepage IS NULL THEN
-- user entered no homepage, return "http://"
RETURN ''http://'';
END IF;
END;
</programlisting>
</para>
</sect2>
<sect2 id="plpgsql-statements-perform">
<title>Executing an expression or query with no result</title>
<para>
Sometimes one wishes to evaluate an expression or query but discard
the result (typically because one is calling a function that has
useful side-effects but no useful result value). To do this in
<application>PL/pgSQL</application>, use the PERFORM statement:
2001-03-17 19:08:14 +01:00
<synopsis>
PERFORM <replaceable>query</replaceable>;
2001-03-17 19:08:14 +01:00
</synopsis>
This executes a <literal>SELECT</literal>
<replaceable>query</replaceable> and discards the
result. <application>PL/pgSQL</application> variables are
substituted in the query as usual. Also, the special variable
<literal>FOUND</literal> is set to true if the query produced at
least one row, or false if it produced no rows.
</para>
<note>
<para>
One might expect that SELECT with no INTO clause would accomplish
this result, but at present the only accepted way to do it is PERFORM.
</para>
</note>
<para>
An example:
2001-03-17 19:08:14 +01:00
<programlisting>
PERFORM create_mv(''cs_session_page_requests_mv'', my_query);
2001-03-17 19:08:14 +01:00
</programlisting>
</para>
</sect2>
<sect2 id="plpgsql-statements-executing-dyn-queries">
<title>Executing dynamic queries</title>
<para>
Oftentimes you will want to generate dynamic queries inside
your <application>PL/pgSQL</application> functions, that is,
2002-03-22 20:20:45 +01:00
queries that will involve different tables or different data types
each time they are executed. <application>PL/pgSQL</application>'s
normal attempts to cache plans for queries will not work in such
scenarios. To handle this sort of problem, the EXECUTE statement
is provided:
2001-03-17 19:08:14 +01:00
<synopsis>
EXECUTE <replaceable class="command">query-string</replaceable>;
2001-03-17 19:08:14 +01:00
</synopsis>
where <replaceable>query-string</replaceable> is an expression
yielding a string (of type
<type>text</type>) containing the <replaceable>query</replaceable>
to be executed. This string is fed literally to the SQL engine.
</para>
<para>
Note in particular that no substitution of <application>PL/pgSQL</>
variables is done on the query string. The values of variables must
be inserted in the query string as it is constructed.
2001-03-17 19:08:14 +01:00
</para>
<para>
When working with dynamic queries you will have to face
escaping of single quotes in <application>PL/pgSQL</>. Please refer to the
table in <xref linkend="plpgsql-porting">
for a detailed explanation that will save you some effort.
</para>
2001-03-17 19:08:14 +01:00
<para>
Unlike all other queries in <application>PL/pgSQL</>, a
2001-03-17 19:08:14 +01:00
<replaceable>query</replaceable> run by an EXECUTE statement is
not prepared and saved just once during the life of the server.
Instead, the <replaceable>query</replaceable> is prepared each
time the statement is run. The
<replaceable>query-string</replaceable> can be dynamically
created within the procedure to perform actions on variable
tables and fields.
</para>
2001-03-17 19:08:14 +01:00
<para>
The results from SELECT queries are discarded by EXECUTE, and
SELECT INTO is not currently supported within EXECUTE. So, the
only way to extract a result from a dynamically-created SELECT is
to use the FOR-IN-EXECUTE form described later.
2001-03-17 19:08:14 +01:00
</para>
2001-03-17 19:08:14 +01:00
<para>
An example:
<informalexample>
<programlisting>
EXECUTE ''UPDATE tbl SET ''
|| quote_ident(fieldname)
|| '' = ''
|| quote_literal(newvalue)
|| '' WHERE ...'';
</programlisting>
</informalexample>
</para>
2001-03-17 19:08:14 +01:00
<para>
This example shows use of the functions
<function>quote_ident</function>(<type>TEXT</type>) and
<function>quote_literal</function>(<type>TEXT</type>).
Variables containing field and table identifiers should be
passed to function <function>quote_ident()</function>.
Variables containing literal elements of the dynamic query
string should be passed to
<function>quote_literal()</function>. Both take the
appropriate steps to return the input text enclosed in single
or double quotes and with any embedded special characters
properly escaped.
2001-03-17 19:08:14 +01:00
</para>
<para>
2001-03-17 19:08:14 +01:00
Here is a much larger example of a dynamic query and EXECUTE:
<programlisting>
CREATE FUNCTION cs_update_referrer_type_proc() RETURNS INTEGER AS '
DECLARE
referrer_keys RECORD; -- Declare a generic record to be used in a FOR
a_output varchar(4000);
BEGIN
a_output := ''CREATE FUNCTION cs_find_referrer_type(varchar,varchar,varchar)
RETURNS VARCHAR AS ''''
DECLARE
v_host ALIAS FOR $1;
v_domain ALIAS FOR $2;
v_url ALIAS FOR $3;
BEGIN '';
--
-- Notice how we scan through the results of a query in a FOR loop
-- using the FOR &lt;record&gt; construct.
--
2001-10-13 01:32:34 +02:00
FOR referrer_keys IN SELECT * FROM cs_referrer_keys ORDER BY try_order LOOP
a_output := a_output || '' IF v_'' || referrer_keys.kind || '' LIKE ''''''''''
|| referrer_keys.key_string || '''''''''' THEN RETURN ''''''
|| referrer_keys.referrer_type || ''''''; END IF;'';
END LOOP;
2001-10-13 01:32:34 +02:00
a_output := a_output || '' RETURN NULL; END; '''' LANGUAGE ''''plpgsql'''';'';
-- This works because we are not substituting any variables
-- Otherwise it would fail. Look at PERFORM for another way to run functions
EXECUTE a_output;
2001-10-13 01:32:34 +02:00
END;
2001-03-17 19:08:14 +01:00
' LANGUAGE 'plpgsql';
</programlisting>
</para>
</sect2>
<sect2 id="plpgsql-statements-diagnostics">
<title>Obtaining result status</title>
2001-03-17 19:08:14 +01:00
<para>
<synopsis>
GET DIAGNOSTICS <replaceable>variable</replaceable> = <replaceable>item</replaceable> <optional> , ... </optional> ;
2001-03-17 19:08:14 +01:00
</synopsis>
This command allows retrieval of system status indicators. Each
<replaceable>item</replaceable> is a keyword identifying a state
value to be assigned to the specified variable (which should be
of the right data type to receive it). The currently available
2001-03-17 19:08:14 +01:00
status items are <varname>ROW_COUNT</>, the number of rows
processed by the last <acronym>SQL</acronym> query sent down to
the <acronym>SQL</acronym> engine; and <varname>RESULT_OID</>,
2002-03-22 20:20:45 +01:00
the OID of the last row inserted by the most recent
2001-03-17 19:08:14 +01:00
<acronym>SQL</acronym> query. Note that <varname>RESULT_OID</>
is only useful after an INSERT query.
</para>
<para>
<informalexample>
<programlisting>
GET DIAGNOSTICS var_integer = ROW_COUNT;
</programlisting>
</informalexample>
</para>
</sect2>
</sect1>
<sect1 id="plpgsql-control-structures">
<title>Control Structures</title>
<para>
Control structures are probably the most useful (and
important) part of <application>PL/pgSQL</>. With
<application>PL/pgSQL</>'s control structures,
you can manipulate <productname>PostgreSQL</> data in a very
flexible and powerful way.
</para>
<sect2 id="plpgsql-statements-returning">
<title>Returning from a function</title>
<para>
2001-03-17 19:08:14 +01:00
<synopsis>
RETURN <replaceable>expression</replaceable>;
2001-03-17 19:08:14 +01:00
</synopsis>
2001-03-17 19:08:14 +01:00
The function terminates and the value of
<replaceable>expression</replaceable> will be returned to the
upper executor.
2002-03-22 20:20:45 +01:00
The expression's result will be automatically cast into the
function's return type as described for assignments.
2001-03-17 19:08:14 +01:00
</para>
<para>
The return value of a function cannot be left undefined. If control
reaches the end of the top-level block of
2002-03-22 20:20:45 +01:00
the function without hitting a RETURN statement, a run-time error
will occur.
2001-03-17 19:08:14 +01:00
</para>
</sect2>
<sect2 id="plpgsql-conditionals">
<title>Conditionals</title>
<para>
<function>IF</function> statements let you execute commands based on
certain conditions.
<application>PL/pgSQL</> has four forms of IF: IF-THEN, IF-THEN-ELSE,
IF-THEN-ELSE IF, and IF-THEN-ELSIF-THEN-ELSE.
</para>
<sect3>
<title>IF-THEN</title>
2001-03-17 19:08:14 +01:00
<para>
<synopsis>
IF <replaceable>boolean-expression</replaceable> THEN
<replaceable>statements</replaceable>
END IF;
</synopsis>
IF-THEN statements are the simplest form of IF. The
statements between THEN and END IF will be executed if
the condition is true. Otherwise, they are skipped.
2001-03-17 19:08:14 +01:00
<programlisting>
IF v_user_id &lt;&gt; 0 THEN
UPDATE users SET email = v_email WHERE user_id = v_user_id;
END IF;
2001-03-17 19:08:14 +01:00
</programlisting>
</para>
</sect3>
<sect3>
<title>IF-THEN-ELSE</title>
2001-03-17 19:08:14 +01:00
<para>
<synopsis>
IF <replaceable>boolean-expression</replaceable> THEN
<replaceable>statements</replaceable>
ELSE
<replaceable>statements</replaceable>
END IF;
</synopsis>
IF-THEN-ELSE statements add to IF-THEN by letting you
specify an alternative set of statements that should be executed if
the condition evaluates to FALSE.
2001-03-17 19:08:14 +01:00
<programlisting>
IF parentid IS NULL or parentid = ''''
THEN
return fullname;
ELSE
return hp_true_filename(parentid) || ''/'' || fullname;
END IF;
IF v_count > 0 THEN
INSERT INTO users_count(count) VALUES(v_count);
return ''t'';
ELSE
return ''f'';
END IF;
2001-03-17 19:08:14 +01:00
</programlisting>
</para>
</sect3>
<sect3>
<title>IF-THEN-ELSE IF</title>
2001-03-17 19:08:14 +01:00
<para>
IF statements can be nested, as in the following example:
2001-03-17 19:08:14 +01:00
<programlisting>
IF demo_row.sex = ''m'' THEN
pretty_sex := ''man'';
ELSE
IF demo_row.sex = ''f'' THEN
pretty_sex := ''woman'';
END IF;
END IF;
2001-03-17 19:08:14 +01:00
</programlisting>
</para>
<para>
When you use this form, you are actually
nesting an IF statement inside the ELSE part of an outer IF
statement. Thus you need one END IF statement for each
nested IF and one for the parent IF-ELSE.
This is workable but grows tedious when there are many
alternatives to be checked.
2001-03-17 19:08:14 +01:00
</para>
</sect3>
2001-05-22 15:52:27 +02:00
<sect3>
<title>IF-THEN-ELSIF-ELSE</title>
2001-05-22 15:52:27 +02:00
<para>
<synopsis>
IF <replaceable>boolean-expression</replaceable> THEN
<replaceable>statements</replaceable>
<optional> ELSIF <replaceable>boolean-expression</replaceable> THEN
<replaceable>statements</replaceable>
<optional> ELSIF <replaceable>boolean-expression</replaceable> THEN
<replaceable>statements</replaceable>
...
</optional>
</optional>
<optional> ELSE
<replaceable>statements</replaceable> </optional>
END IF;
</synopsis>
IF-THEN-ELSIF-ELSE provides a more convenient method of checking
many alternatives in one statement. Formally it is equivalent
to nested IF-THEN-ELSE-IF-THEN commands, but only one END IF
is needed.
2001-05-22 15:52:27 +02:00
</para>
<para>
Here is an example:
<programlisting>
IF number = 0 THEN
result := ''zero'';
ELSIF number &gt; 0 THEN
2001-11-16 01:40:11 +01:00
result := ''positive'';
ELSIF number &lt; 0 THEN
2001-05-22 15:52:27 +02:00
result := ''negative'';
ELSE
-- hmm, the only other possibility is that number IS NULL
2001-05-22 15:52:27 +02:00
result := ''NULL'';
END IF;
</programlisting>
</para>
<para>
The final ELSE section is optional.
</para>
2001-05-22 15:52:27 +02:00
</sect3>
</sect2>
<sect2 id="plpgsql-control-structures-loops">
<title>Simple Loops</title>
<para>
With the LOOP, EXIT, WHILE and FOR statements, you can arrange
for your <application>PL/pgSQL</application> function to repeat
a series of commands.
</para>
2001-03-17 19:08:14 +01:00
<sect3>
<title>LOOP</title>
2001-03-17 19:08:14 +01:00
<para>
2001-03-17 19:08:14 +01:00
<synopsis>
<optional>&lt;&lt;label&gt;&gt;</optional>
LOOP
<replaceable>statements</replaceable>
END LOOP;
2001-03-17 19:08:14 +01:00
</synopsis>
LOOP defines an unconditional loop that is repeated indefinitely
until terminated by an EXIT or RETURN statement.
The optional label can be used by
EXIT statements in nested loops to specify which level of
nesting should be terminated.
</para>
</sect3>
<sect3>
<title>EXIT</title>
2001-03-17 19:08:14 +01:00
<para>
2001-03-17 19:08:14 +01:00
<synopsis>
EXIT <optional> <replaceable>label</replaceable> </optional> <optional> WHEN <replaceable>expression</replaceable> </optional>;
2001-03-17 19:08:14 +01:00
</synopsis>
If no <replaceable>label</replaceable> is given,
the innermost loop is terminated and the
statement following END LOOP is executed next.
If <replaceable>label</replaceable> is given, it
must be the label of the current or some outer level of nested loop
or block. Then the named loop or block is terminated and control
continues with the statement after the loop's/block's corresponding
END.
</para>
2001-03-17 19:08:14 +01:00
<para>
If WHEN is present, loop exit occurs only if the specified condition
is true, otherwise control passes to the statement after EXIT.
</para>
<para>
Examples:
2001-03-17 19:08:14 +01:00
<programlisting>
LOOP
-- some computations
IF count > 0 THEN
EXIT; -- exit loop
END IF;
END LOOP;
LOOP
-- some computations
EXIT WHEN count > 0;
END LOOP;
BEGIN
-- some computations
IF stocks > 100000 THEN
EXIT; -- illegal. Can't use EXIT outside of a LOOP
END IF;
END;
2001-03-17 19:08:14 +01:00
</programlisting>
</para>
</sect3>
<sect3>
<title>WHILE</title>
2001-03-17 19:08:14 +01:00
<para>
2001-03-17 19:08:14 +01:00
<synopsis>
<optional>&lt;&lt;label&gt;&gt;</optional>
WHILE <replaceable>expression</replaceable> LOOP
<replaceable>statements</replaceable>
END LOOP;
2001-03-17 19:08:14 +01:00
</synopsis>
The WHILE statement repeats a
sequence of statements so long as the condition expression
evaluates to true. The condition is checked just before
each entry to the loop body.
</para>
<para>
For example:
2001-03-17 19:08:14 +01:00
<programlisting>
WHILE amount_owed > 0 AND gift_certificate_balance > 0 LOOP
-- some computations here
END LOOP;
WHILE NOT boolean_expression LOOP
-- some computations here
END LOOP;
2001-03-17 19:08:14 +01:00
</programlisting>
</para>
</sect3>
<sect3>
<title>FOR (integer for-loop)</title>
2001-03-17 19:08:14 +01:00
<para>
2001-03-17 19:08:14 +01:00
<synopsis>
<optional>&lt;&lt;label&gt;&gt;</optional>
FOR <replaceable>name</replaceable> IN <optional> REVERSE </optional> <replaceable>expression</replaceable> .. <replaceable>expression</replaceable> LOOP
<replaceable>statements</replaceable>
END LOOP;
2001-03-17 19:08:14 +01:00
</synopsis>
This form of FOR creates a loop that iterates over a range of integer
values. The variable
<replaceable>name</replaceable> is automatically defined as type
integer and exists only inside the loop. The two expressions giving
the lower and upper bound of the range are evaluated once when entering
the loop. The iteration step is normally 1, but is -1 when REVERSE is
specified.
</para>
2001-03-17 19:08:14 +01:00
<para>
Some examples of integer FOR loops:
2001-03-17 19:08:14 +01:00
<programlisting>
FOR i IN 1..10 LOOP
-- some expressions here
RAISE NOTICE ''i is %'',i;
END LOOP;
FOR i IN REVERSE 10..1 LOOP
-- some expressions here
END LOOP;
2001-03-17 19:08:14 +01:00
</programlisting>
</para>
</sect3>
</sect2>
2001-03-17 19:08:14 +01:00
<sect2 id="plpgsql-records-iterating">
<title>Looping Through Query Results</title>
<para>
Using a different type of FOR loop, you can iterate through
the results of a query and manipulate that data
accordingly. The syntax is:
2001-03-17 19:08:14 +01:00
<synopsis>
<optional>&lt;&lt;label&gt;&gt;</optional>
FOR <replaceable>record | row</replaceable> IN <replaceable>select_query</replaceable> LOOP
<replaceable>statements</replaceable>
END LOOP;
2001-03-17 19:08:14 +01:00
</synopsis>
The record or row variable is successively assigned all the rows
resulting from the SELECT query and the loop body is executed
for each row. Here is an example:
</para>
2001-03-17 19:08:14 +01:00
<para>
2001-03-17 19:08:14 +01:00
<programlisting>
2001-10-13 01:32:34 +02:00
CREATE FUNCTION cs_refresh_mviews () RETURNS INTEGER AS '
DECLARE
mviews RECORD;
BEGIN
PERFORM cs_log(''Refreshing materialized views...'');
FOR mviews IN SELECT * FROM cs_materialized_views ORDER BY sort_key LOOP
-- Now "mviews" has one record from cs_materialized_views
PERFORM cs_log(''Refreshing materialized view '' || quote_ident(mviews.mv_name) || ''...'');
EXECUTE ''TRUNCATE TABLE '' || quote_ident(mviews.mv_name);
EXECUTE ''INSERT INTO '' || quote_ident(mviews.mv_name) || '' '' || mviews.mv_query;
END LOOP;
PERFORM cs_log(''Done refreshing materialized views.'');
2001-10-13 01:32:34 +02:00
RETURN 1;
end;
2001-10-13 06:58:35 +02:00
' LANGUAGE 'plpgsql';
2001-03-17 19:08:14 +01:00
</programlisting>
If the loop is terminated by an EXIT statement, the last
assigned row value is still accessible after the loop.
</para>
2001-03-17 19:08:14 +01:00
<para>
The FOR-IN-EXECUTE statement is another way to iterate over
2001-03-17 19:08:14 +01:00
records:
<synopsis>
<optional>&lt;&lt;label&gt;&gt;</optional>
FOR <replaceable>record | row</replaceable> IN EXECUTE <replaceable>text_expression</replaceable> LOOP
<replaceable>statements</replaceable>
END LOOP;
2001-03-17 19:08:14 +01:00
</synopsis>
This is like the previous form, except that the source SELECT
statement is specified as a string expression, which is evaluated
and re-planned on each entry to the FOR loop. This allows the
programmer to choose the speed of a pre-planned query or the
flexibility of a dynamic query, just as with a plain EXECUTE
statement.
</para>
<note>
<para>
The <application>PL/pgSQL</> parser presently distinguishes the
two kinds of FOR loops (integer or record-returning) by checking
whether the target variable mentioned just after FOR has been
declared as a record/row variable. If not, it's presumed to be
2002-03-22 20:20:45 +01:00
an integer FOR loop. This can cause rather nonintuitive error
messages when the true problem is, say, that one has
misspelled the FOR variable name.
</para>
</note>
</sect2>
</sect1>
<sect1 id="plpgsql-cursors">
<title>Cursors</title>
<para>
Rather than executing a whole query at once, it is possible to set
up a <firstterm>cursor</> that encapsulates the query, and then read
the query result a few rows at a time. One reason for doing this is
to avoid memory overrun when the result contains a large number of
rows. (However, <application>PL/pgSQL</> users don't normally need
to worry about that, since FOR loops automatically use a cursor
internally to avoid memory problems.) A more interesting usage is to
return a reference to a cursor that it has created, allowing the
2002-04-09 05:08:25 +02:00
caller to read the rows. This provides a way to return row sets
from functions.
</para>
<sect2 id="plpgsql-cursor-declarations">
<title>Declaring Cursor Variables</title>
<para>
All access to cursors in <application>PL/pgSQL</> goes through
2002-03-22 20:20:45 +01:00
cursor variables, which are always of the special data type
<type>refcursor</>. One way to create a cursor variable
is just to declare it as a variable of type <type>refcursor</>.
Another way is to use the cursor declaration syntax,
which in general is:
<synopsis>
<replaceable>name</replaceable> CURSOR <optional> ( <replaceable>arguments</replaceable> ) </optional> FOR <replaceable>select_query</replaceable> ;
</synopsis>
(<literal>FOR</> may be replaced by <literal>IS</> for Oracle
compatibility.) <replaceable>arguments</replaceable>, if any,
are a comma-separated list of <replaceable>name</replaceable>
<replaceable>datatype</replaceable> pairs that define names to
be replaced by parameter values in the given query. The actual
values to substitute for these names will be specified later,
when the cursor is opened.
</para>
<para>
Some examples:
<programlisting>
DECLARE
curs1 refcursor;
curs2 CURSOR FOR SELECT * from tenk1;
curs3 CURSOR (key int) IS SELECT * from tenk1 where unique1 = key;
</programlisting>
2002-03-22 20:20:45 +01:00
All three of these variables have the data type <type>refcursor</>,
but the first may be used with any query, while the second has
a fully specified query already <firstterm>bound</> to it, and the last
has a parameterized query bound to it. (<literal>key</> will be
replaced by an integer parameter value when the cursor is opened.)
The variable <literal>curs1</>
is said to be <firstterm>unbound</> since it is not bound to
any particular query.
</para>
</sect2>
<sect2 id="plpgsql-cursor-opening">
<title>Opening Cursors</title>
<para>
Before a cursor can be used to retrieve rows, it must be
<firstterm>opened</>. (This is the equivalent action to the SQL
command <command>DECLARE CURSOR</>.) <application>PL/pgSQL</> has
four forms of the OPEN statement, two of which use unbound cursor
variables and the other two use bound cursor variables.
</para>
<sect3>
<title>OPEN FOR SELECT</title>
<para>
<synopsis>
OPEN <replaceable>unbound-cursor</replaceable> FOR SELECT ...;
</synopsis>
The cursor variable is opened and given the specified query
to execute. The cursor cannot be open already, and it must
have been declared as an unbound cursor (that is, as a simple
<type>refcursor</> variable). The SELECT query is treated
in the same way as other SELECTs in <application>PL/pgSQL</>:
<application>PL/pgSQL</> variable names are substituted,
and the query plan is cached for possible re-use.
<programlisting>
OPEN curs1 FOR SELECT * FROM foo WHERE key = mykey;
</programlisting>
</para>
</sect3>
<sect3>
<title>OPEN FOR EXECUTE</title>
<para>
<synopsis>
OPEN <replaceable>unbound-cursor</replaceable> FOR EXECUTE <replaceable class="command">query-string</replaceable>;
</synopsis>
The cursor variable is opened and given the specified query
to execute. The cursor cannot be open already, and it must
have been declared as an unbound cursor (that is, as a simple
<type>refcursor</> variable). The query is specified as a
string expression in the same way as in the EXECUTE command.
As usual, this gives flexibility so the query can vary
from one run to the next.
<programlisting>
OPEN curs1 FOR EXECUTE ''SELECT * FROM '' || quote_ident($1);
</programlisting>
</para>
</sect3>
<sect3>
<title>OPENing a bound cursor</title>
<para>
<synopsis>
OPEN <replaceable>bound-cursor</replaceable> <optional> ( <replaceable>argument_values</replaceable> ) </optional>;
</synopsis>
This form of OPEN is used to open a cursor variable whose query
was bound to it when it was declared.
The cursor cannot be open already. A list of actual argument
value expressions must appear if and only if the cursor was
declared to take arguments. These values will be substituted
in the query.
The query plan for a bound cursor is always considered
cacheable --- there is no equivalent of EXECUTE in this case.
<programlisting>
OPEN curs2;
OPEN curs3(42);
</programlisting>
</para>
</sect3>
</sect2>
<sect2 id="plpgsql-cursor-using">
<title>Using Cursors</title>
<para>
Once a cursor has been opened, it can be manipulated with the
statements described here.
</para>
<para>
These manipulations need not occur in the same function that
opened the cursor to begin with. You can return a <type>refcursor</>
value out of a function and let the caller operate on the cursor.
(Internally, a <type>refcursor</> value is simply the string name
of a Portal containing the active query for the cursor. This name
can be passed around, assigned to other <type>refcursor</> variables,
and so on, without disturbing the Portal.)
</para>
<para>
All Portals are implicitly closed at transaction end. Therefore
a <type>refcursor</> value is useful to reference an open cursor
only until the end of the transaction.
</para>
<sect3>
<title>FETCH</title>
<para>
<synopsis>
FETCH <replaceable>cursor</replaceable> INTO <replaceable>target</replaceable>;
</synopsis>
FETCH retrieves the next row from the cursor into a target,
which may be a row variable, a record variable, or a comma-separated
list of simple variables, just like SELECT INTO. As with
SELECT INTO, the special variable <literal>FOUND</literal> may be
checked to see whether a row was obtained or not.
<programlisting>
FETCH curs1 INTO rowvar;
FETCH curs2 INTO foo,bar,baz;
</programlisting>
</para>
</sect3>
<sect3>
<title>CLOSE</title>
<para>
<synopsis>
CLOSE <replaceable>cursor</replaceable>;
</synopsis>
CLOSE closes the Portal underlying an open cursor.
This can be used to release resources earlier than end of
transaction, or to free up the cursor variable to be opened again.
<programlisting>
CLOSE curs1;
</programlisting>
</para>
</sect3>
<sect3>
<title>Returning Cursors</title>
<para>
<application>PL/pgSQL</> functions can return cursors to the
caller. This is used to return multiple rows or columns from the
function. The function opens the cursor and returns the cursor
name to the caller. The caller can then FETCH rows from the
cursor. The cursor can be CLOSEd by the caller, or it will be
closed automatically when the transaction closes.
</para>
<para>
The cursor name returned by the function can be specified by the
caller or automatically generated. The following example shows
how a cursor name can be supplied by the caller:
<programlisting>
CREATE TABLE test (col text);
INSERT INTO test VALUES ('123');
CREATE FUNCTION reffunc(refcursor) RETURNS refcursor AS '
BEGIN
OPEN $1 FOR SELECT col FROM test;
RETURN $1;
END;
' LANGUAGE 'plpgsql';
BEGIN;
SELECT reffunc('funccursor');
FETCH ALL IN funccursor;
COMMIT;
</programlisting>
</para>
<para>
The following example uses automatic cursor name generation:
<programlisting>
CREATE FUNCTION reffunc2() RETURNS refcursor AS '
DECLARE
ref refcursor;
BEGIN
OPEN ref FOR SELECT col FROM test;
RETURN ref;
END;
' LANGUAGE 'plpgsql';
BEGIN;
SELECT reffunc2();
reffunc2
--------------------
2002-04-09 05:08:25 +02:00
&lt;unnamed cursor 1&gt;
(1 row)
2002-04-09 05:08:25 +02:00
FETCH ALL IN "&lt;unnamed cursor 1&gt;";
COMMIT;
</programlisting>
</para>
</sect3>
</sect2>
</sect1>
<sect1 id="plpgsql-errors-and-messages">
<title>Errors and Messages</title>
<para>
Use the RAISE statement to report messages and raise errors.
2001-03-17 19:08:14 +01:00
<synopsis>
RAISE <replaceable class="parameter">level</replaceable> '<replaceable class="parameter">format</replaceable>' <optional>, <replaceable class="parameter">variable</replaceable> <optional>...</optional></optional>;
2001-03-17 19:08:14 +01:00
</synopsis>
Possible levels are DEBUG (write the message into the postmaster log),
NOTICE (write the message into the postmaster log and forward it to
the client application) and EXCEPTION (raise an error,
aborting the transaction).
</para>
<para>
Inside the format string, <literal>%</literal> is replaced by the next
optional argument's external representation.
Write <literal>%%</literal> to emit a literal <literal>%</literal>.
Note that the optional arguments must presently
be simple variables, not expressions, and the format must be a simple
string literal.
</para>
2001-03-17 19:08:14 +01:00
<!--
This example should work, but does not:
RAISE NOTICE ''Id number '' || key || '' not found!'';
Put it back when we allow non-string-literal formats.
-->
<para>
Examples:
2001-03-17 19:08:14 +01:00
<programlisting>
RAISE NOTICE ''Calling cs_create_job(%)'',v_job_id;
2001-03-17 19:08:14 +01:00
</programlisting>
In this example, the value of v_job_id will replace the % in the
string.
</para>
2001-03-17 19:08:14 +01:00
<para>
2001-03-17 19:08:14 +01:00
<programlisting>
RAISE EXCEPTION ''Inexistent ID --> %'',user_id;
2001-03-17 19:08:14 +01:00
</programlisting>
This will abort the transaction with the given error message.
</para>
<sect2 id="plpgsql-exceptions">
<title>Exceptions</title>
<para>
<productname>PostgreSQL</productname> does not have a very smart
exception handling model. Whenever the parser, planner/optimizer
or executor decide that a statement cannot be processed any longer,
the whole transaction gets aborted and the system jumps back
into the main loop to get the next query from the client application.
</para>
2001-03-17 19:08:14 +01:00
<para>
It is possible to hook into the error mechanism to notice that this
happens. But currently it is impossible to tell what really
2002-01-07 03:29:15 +01:00
caused the abort (input/output conversion error, floating-point
error, parse error). And it is possible that the database backend
is in an inconsistent state at this point so returning to the upper
executor or issuing more commands might corrupt the whole database.
</para>
2001-03-17 19:08:14 +01:00
<para>
Thus, the only thing <application>PL/pgSQL</application> currently does when it encounters
an abort during execution of a function or trigger
procedure is to write some additional NOTICE level log messages
telling in which function and where (line number and type of
statement) this happened. The error always stops execution of
the function.
</para>
</sect2>
</sect1>
<sect1 id="plpgsql-trigger">
2001-03-17 19:08:14 +01:00
<title>Trigger Procedures</title>
2001-03-17 19:08:14 +01:00
<para>
<application>PL/pgSQL</application> can be used to define trigger
procedures. A trigger procedure is created with the <command>CREATE
FUNCTION</command> command as a function with no arguments and a return
type of <type>TRIGGER</type>. Note that the function must be declared
with no arguments even if it expects to receive arguments specified
in <command>CREATE TRIGGER</> --- trigger arguments are passed via
<varname>TG_ARGV</>, as described below.
2001-03-17 19:08:14 +01:00
</para>
<para>
When a <application>PL/pgSQL</application> function is called as a
trigger, several special variables are created automatically in the
top-level block. They are:
<variablelist>
<varlistentry>
<term><varname>NEW</varname></term>
<listitem>
<para>
Data type <type>RECORD</type>; variable holding the new database row for INSERT/UPDATE
operations in ROW level triggers.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><varname>OLD</varname></term>
<listitem>
<para>
Data type <type>RECORD</type>; variable holding the old database row for UPDATE/DELETE
operations in ROW level triggers.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><varname>TG_NAME</varname></term>
<listitem>
<para>
Data type <type>name</type>; variable that contains the name of the trigger actually
fired.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><varname>TG_WHEN</varname></term>
<listitem>
<para>
Data type <type>text</type>; a string of either
<literal>BEFORE</literal> or <literal>AFTER</literal>
depending on the trigger's definition.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><varname>TG_LEVEL</varname></term>
<listitem>
<para>
Data type <type>text</type>; a string of either
<literal>ROW</literal> or <literal>STATEMENT</literal> depending on the
trigger's definition.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><varname>TG_OP</varname></term>
<listitem>
<para>
Data type <type>text</type>; a string of
<literal>INSERT</literal>, <literal>UPDATE</literal>
or <literal>DELETE</literal> telling
for which operation the trigger is fired.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><varname>TG_RELID</varname></term>
<listitem>
<para>
Data type <type>oid</type>; the object ID of the table that caused the
trigger invocation.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><varname>TG_RELNAME</varname></term>
<listitem>
<para>
Data type <type>name</type>; the name of the table that caused the trigger
invocation.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><varname>TG_NARGS</varname></term>
<listitem>
<para>
Data type <type>integer</type>; the number of arguments given to the trigger
procedure in the <command>CREATE TRIGGER</command> statement.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><varname>TG_ARGV[]</varname></term>
<listitem>
<para>
Data type array of <type>text</type>; the arguments from
the <command>CREATE TRIGGER</command> statement.
The index counts from 0 and can be given as an expression. Invalid
indices (&lt; 0 or &gt;= tg_nargs) result in a NULL value.
</para>
</listitem>
</varlistentry>
</variablelist>
2001-03-17 19:08:14 +01:00
</para>
<para>
A trigger function must return either NULL or a record/row value
having exactly the structure of the table the trigger was fired for.
Triggers fired BEFORE may return NULL to signal the trigger manager
to skip the rest of the operation for this row (ie, subsequent triggers
are not fired, and the INSERT/UPDATE/DELETE does not occur for this
row). If a non-NULL value is returned then the operation proceeds with
that row value. Note that returning a row value different from the
original value of NEW alters the row that will be inserted or updated.
It is possible to replace single values directly
in NEW and return that, or to build a complete new record/row to
return.
</para>
<para>
The return value of a trigger fired AFTER is ignored; it may as well
always return a NULL value. But an AFTER trigger can still abort the
operation by raising an error.
</para>
<example>
<title>A <application>PL/pgSQL</application> Trigger Procedure Example</title>
<para>
This example trigger ensures that any time a row is inserted or updated
in the table, the current user name and time are stamped into the
row. And it ensures that an employee's name is given and that the
salary is a positive value.
2001-03-17 19:08:14 +01:00
<programlisting>
CREATE TABLE emp (
empname text,
salary integer,
last_date timestamp,
2001-03-17 19:08:14 +01:00
last_user text
);
CREATE FUNCTION emp_stamp () RETURNS TRIGGER AS '
BEGIN
-- Check that empname and salary are given
IF NEW.empname ISNULL THEN
RAISE EXCEPTION ''empname cannot be NULL value'';
END IF;
IF NEW.salary ISNULL THEN
RAISE EXCEPTION ''% cannot have NULL salary'', NEW.empname;
END IF;
-- Who works for us when she must pay for?
IF NEW.salary < 0 THEN
RAISE EXCEPTION ''% cannot have a negative salary'', NEW.empname;
END IF;
-- Remember who changed the payroll when
NEW.last_date := ''now'';
NEW.last_user := current_user;
RETURN NEW;
END;
' LANGUAGE 'plpgsql';
CREATE TRIGGER emp_stamp BEFORE INSERT OR UPDATE ON emp
FOR EACH ROW EXECUTE PROCEDURE emp_stamp();
2001-03-17 19:08:14 +01:00
</programlisting>
</para>
</example>
2001-03-17 19:08:14 +01:00
</sect1>
<!-- **** PL/pgSQL Examples **** -->
<sect1 id="plpgsql-examples">
<title>Examples</title>
<para>
Here are only a few functions to demonstrate how easy it is to
write <application>PL/pgSQL</>
functions. For more complex examples the programmer
might look at the regression test for <application>PL/pgSQL</>.
</para>
<para>
One painful detail in writing functions in <application>PL/pgSQL</application> is the handling
of single quotes. The function's source text in <command>CREATE FUNCTION</command> must
be a literal string. Single quotes inside of literal strings must be
either doubled or quoted with a backslash. We are still looking for
an elegant alternative. In the meantime, doubling the single quotes
as in the examples below should be used. Any solution for this
in future versions of <productname>PostgreSQL</productname> will be
forward compatible.
</para>
2001-03-17 19:08:14 +01:00
<para>
For a detailed explanation and examples of how to escape single
2001-03-17 19:08:14 +01:00
quotes in different situations, please see <xref linkend="plpgsql-quote">.
</para>
<example>
<title>A Simple <application>PL/pgSQL</application> Function to Increment an Integer</title>
<para>
The following two <application>PL/pgSQL</application> functions are identical to their
counterparts from the C language function discussion. This
function receives an <type>integer</type> and increments it by
one, returning the incremented value.
</para>
2001-03-17 19:08:14 +01:00
<programlisting>
CREATE FUNCTION add_one (integer) RETURNS INTEGER AS '
BEGIN
RETURN $1 + 1;
END;
' LANGUAGE 'plpgsql';
2001-03-17 19:08:14 +01:00
</programlisting>
</example>
<example>
<title>A Simple <application>PL/pgSQL</application> Function to Concatenate Text</title>
<para>
This function receives two <type>text</type> parameters and
returns the result of concatenating them.
</para>
2001-03-17 19:08:14 +01:00
<programlisting>
CREATE FUNCTION concat_text (TEXT, TEXT) RETURNS TEXT AS '
BEGIN
RETURN $1 || $2;
END;
' LANGUAGE 'plpgsql';
2001-03-17 19:08:14 +01:00
</programlisting>
</example>
<example>
<title>A <application>PL/pgSQL</application> Function on Composite Type</title>
<para>
In this example, we take <literal>EMP</> (a table) and an
2001-03-17 19:08:14 +01:00
<type>integer</type> as arguments to our function, which returns
a <type>boolean</type>. If the <structfield>salary</> field of the <structname>EMP</> table is
<literal>NULL</literal>, we return <literal>f</>. Otherwise we compare with
2001-03-17 19:08:14 +01:00
that field with the <type>integer</type> passed to the function
and return the <type>boolean</type> result of the comparison (t
or f). This is the <application>PL/pgSQL</application> equivalent to the example from the C
2001-03-17 19:08:14 +01:00
functions.
</para>
2001-03-17 19:08:14 +01:00
<programlisting>
CREATE FUNCTION c_overpaid (EMP, INTEGER) RETURNS BOOLEAN AS '
DECLARE
emprec ALIAS FOR $1;
sallim ALIAS FOR $2;
BEGIN
IF emprec.salary ISNULL THEN
RETURN ''f'';
END IF;
RETURN emprec.salary > sallim;
END;
' LANGUAGE 'plpgsql';
2001-03-17 19:08:14 +01:00
</programlisting>
</example>
</sect1>
<!-- **** Porting from Oracle PL/SQL **** -->
<sect1 id="plpgsql-porting">
<sect1info>
<date>
February 2001
</date>
<author>
<firstname>Roberto</firstname>
<surname>Mello</surname>
<affiliation>
<address>
<email>rmello@fslc.usu.edu</email>
</address>
</affiliation>
</author>
<!--
Breaks HTML manifest file
<legalnotice>
<para>
Except for portions of this document quoted from other sources,
this document is licensed under the BSD License.
</para>
</legalnotice>
-->
</sect1info>
<title>Porting from Oracle PL/SQL</title>
2001-11-09 00:41:12 +01:00
<indexterm zone="plpgsql-porting">
<primary>Oracle</primary>
</indexterm>
2001-11-09 00:41:12 +01:00
<indexterm zone="plpgsql-porting">
<primary>PL/SQL</primary>
</indexterm>
<note>
<title>Author</title>
<para>
Roberto Mello (<email>rmello@fslc.usu.edu</email>)
</para>
</note>
<para>
This section explains differences between Oracle's PL/SQL and
<productname>PostgreSQL</>'s <application>PL/pgSQL</application> languages in the hopes of helping developers
port applications from Oracle to <productname>PostgreSQL</>. Most of the code here
is from the <ulink url="http://www.arsdigita.com">ArsDigita</ulink>
<ulink url="http://www.arsdigita.com/asj/clickstream">Clickstream
module</ulink> that I ported to <productname>PostgreSQL</> when I took an
internship with <ulink url="http://www.openforce.net">OpenForce
Inc.</ulink> in the Summer of 2000.
</para>
<para>
<application>PL/pgSQL</application> is similar to PL/SQL in many aspects. It is a block
structured, imperative language (all variables have to be
declared). PL/SQL has many more features than its <productname>PostgreSQL</>
counterpart, but <application>PL/pgSQL</application> allows for a great deal of functionality
and it is being improved constantly.
</para>
<sect2>
<title>Main Differences</title>
<para>
Some things you should keep in mind when porting from Oracle to <productname>PostgreSQL</>:
<itemizedlist>
<listitem>
<para>
No default parameters in <productname>PostgreSQL</>.
</para>
</listitem>
<listitem>
<para>
You can overload functions in <productname>PostgreSQL</>. This is often used to work
around the lack of default parameters.
</para>
</listitem>
<listitem>
<para>
Assignments, loops and conditionals are similar.
</para>
</listitem>
<listitem>
<para>
No need for cursors in <productname>PostgreSQL</>, just put the query in the FOR
statement (see example below)
</para>
</listitem>
<listitem>
<para>
In <productname>PostgreSQL</> you <emphasis>need</emphasis> to escape single
2001-03-17 19:08:14 +01:00
quotes. See <xref linkend="plpgsql-quote">.
</para>
</listitem>
</itemizedlist>
</para>
<sect3 id="plpgsql-quote">
<title>Quote Me on That: Escaping Single Quotes</title>
<para>
In <productname>PostgreSQL</> you need to escape single quotes inside your
function definition. This can lead to quite amusing code at
times, especially if you are creating a function that generates
other function(s), as in
2001-03-17 19:08:14 +01:00
<xref linkend="plpgsql-porting-nastyquote">.
One thing to keep in mind
when escaping lots of single quotes is that, except for the
beginning/ending quotes, all the others will come in even
quantity.
</para>
<para>
2001-03-17 19:08:14 +01:00
<xref linkend="plpgsql-quoting-table"> gives the scoop. (You'll
love this little chart.)
</para>
<table id="plpgsql-quoting-table">
<title>Single Quotes Escaping Chart</title>
<tgroup cols="4">
<thead>
<row>
<entry>No. of Quotes</entry>
<entry>Usage</entry>
<entry>Example</entry>
<entry>Result</entry>
</row>
</thead>
<tbody>
<row>
<entry>1</entry>
<entry>To begin/terminate function bodies</entry>
<entry><programlisting>
CREATE FUNCTION foo() RETURNS INTEGER AS '...'
LANGUAGE 'plpgsql';
</programlisting></entry>
<entry>as is</entry>
</row>
<row>
<entry>2</entry>
<entry>In assignments, SELECTs, to delimit strings, etc.</entry>
<entry><programlisting>
a_output := ''Blah'';
SELECT * FROM users WHERE f_name=''foobar'';
</programlisting></entry>
<entry><literal>SELECT * FROM users WHERE f_name='foobar';</literal></entry>
</row>
<row>
<entry>4</entry>
<entry>
When you need two single quotes in your resulting string
without terminating that string.
</entry>
<entry><programlisting>
a_output := a_output || '' AND name
LIKE ''''foobar'''' AND ...''
</programlisting></entry>
<entry><literal>AND name LIKE 'foobar' AND ...</literal></entry>
</row>
<row>
<entry>6</entry>
<entry>
When you want double quotes in your resulting string
<emphasis>and</emphasis> terminate that string.
</entry>
<entry><programlisting>
a_output := a_output || '' AND name
LIKE ''''foobar''''''
</programlisting></entry>
<entry>
<literal>AND name LIKE 'foobar'</literal>
</entry>
</row>
<row>
<entry>10</entry>
<entry>
When you want two single quotes in the resulting string
(which accounts for 8 quotes) <emphasis>and</emphasis>
terminate that string (2 more). You will probably only need
that if you were using a function to generate other functions
2001-03-17 19:08:14 +01:00
(like in <xref linkend="plpgsql-porting-nastyquote">).
</entry>
<entry><programlisting>
a_output := a_output || '' if v_'' ||
referrer_keys.kind || '' like ''''''''''
|| referrer_keys.key_string || ''''''''''
then return '''''' || referrer_keys.referrer_type
|| ''''''; end if;'';
</programlisting></entry>
<entry>
<literal>if v_<...> like ''<...>'' then return ''<...>''; end if;</literal>
</entry>
</row>
</tbody>
</tgroup>
</table>
</sect3>
</sect2>
<sect2 id="plpgsql-porting-functions">
<title>
Porting Functions
</title>
<example>
<title>
A Simple Function
</title>
<para>
Here is an Oracle function:
<programlisting>
CREATE OR REPLACE FUNCTION cs_fmt_browser_version(v_name IN varchar, v_version IN varchar)
RETURN varchar IS
BEGIN
IF v_version IS NULL THEN
RETURN v_name;
END IF;
RETURN v_name || '/' || v_version;
END;
/
SHOW ERRORS;
</programlisting>
</para>
<para>
Let's go through this function and see the differences to <application>PL/pgSQL</>:
<itemizedlist>
<listitem>
<para>
<productname>PostgreSQL</productname> does not have named
parameters. You have to explicitly alias them inside your
function.
</para>
</listitem>
<listitem>
<para>
Oracle can have <literal>IN</literal>, <literal>OUT</literal>,
and <literal>INOUT</literal> parameters passed to functions.
The <literal>INOUT</literal>, for example, means that the
parameter will receive a value and return another. <productname>PostgreSQL</>
only has <quote>IN</quote> parameters and functions can return
only a single value.
</para>
</listitem>
<listitem>
<para>
The <literal>RETURN</literal> key word in the function
prototype (not the function body) becomes
<literal>RETURNS</literal> in <productname>PostgreSQL</>.
</para>
</listitem>
<listitem>
<para>
On <productname>PostgreSQL</> functions are created using single quotes as
delimiters, so you have to escape single quotes inside your
functions (which can be quite annoying at times; see <xref
2001-03-17 19:08:14 +01:00
linkend="plpgsql-quote">).
</para>
</listitem>
<listitem>
<para>
The <literal>/show errors</literal> command does not exist in
<productname>PostgreSQL</>.
</para>
</listitem>
</itemizedlist>
</para>
<para>
So let's see how this function would look when ported to
<productname>PostgreSQL</>:
<programlisting>
CREATE OR REPLACE FUNCTION cs_fmt_browser_version(VARCHAR, VARCHAR)
RETURNS VARCHAR AS '
DECLARE
v_name ALIAS FOR $1;
v_version ALIAS FOR $2;
BEGIN
IF v_version IS NULL THEN
return v_name;
END IF;
RETURN v_name || ''/'' || v_version;
END;
' LANGUAGE 'plpgsql';
</programlisting>
</para>
</example>
<example id="plpgsql-porting-nastyquote">
<title>
A Function that Creates Another Function
</title>
<para>
The following procedure grabs rows from a
<literal>SELECT</literal> statement and builds a large function
with the results in <literal>IF</literal> statements, for the
sake of efficiency. Notice particularly the differences in
cursors, <literal>FOR</literal> loops, and the need to escape
single quotes in <productname>PostgreSQL</>.
<programlisting>
2001-10-13 01:32:34 +02:00
CREATE OR REPLACE PROCEDURE cs_update_referrer_type_proc IS
CURSOR referrer_keys IS
SELECT * FROM cs_referrer_keys
ORDER BY try_order;
a_output VARCHAR(4000);
BEGIN
a_output := 'CREATE OR REPLACE FUNCTION cs_find_referrer_type(v_host IN VARCHAR, v_domain IN VARCHAR,
v_url IN VARCHAR) RETURN VARCHAR IS BEGIN';
FOR referrer_key IN referrer_keys LOOP
a_output := a_output || ' IF v_' || referrer_key.kind || ' LIKE ''' ||
referrer_key.key_string || ''' THEN RETURN ''' || referrer_key.referrer_type ||
'''; END IF;';
END LOOP;
a_output := a_output || ' RETURN NULL; END;';
EXECUTE IMMEDIATE a_output;
END;
/
show errors
</programlisting>
</para>
<para>
Here is how this function would end up in <productname>PostgreSQL</>:
<programlisting>
CREATE FUNCTION cs_update_referrer_type_proc() RETURNS INTEGER AS '
DECLARE
referrer_keys RECORD; -- Declare a generic record to be used in a FOR
a_output varchar(4000);
BEGIN
a_output := ''CREATE FUNCTION cs_find_referrer_type(VARCHAR,VARCHAR,VARCHAR)
RETURNS VARCHAR AS ''''
DECLARE
v_host ALIAS FOR $1;
v_domain ALIAS FOR $2;
v_url ALIAS FOR $3;
BEGIN '';
--
-- Notice how we scan through the results of a query in a FOR loop
-- using the FOR &lt;record&gt; construct.
--
2001-10-13 01:32:34 +02:00
FOR referrer_keys IN SELECT * FROM cs_referrer_keys ORDER BY try_order LOOP
a_output := a_output || '' IF v_'' || referrer_keys.kind || '' LIKE ''''''''''
|| referrer_keys.key_string || '''''''''' THEN RETURN ''''''
|| referrer_keys.referrer_type || ''''''; END IF;'';
END LOOP;
2001-10-13 01:32:34 +02:00
a_output := a_output || '' RETURN NULL; END; '''' LANGUAGE ''''plpgsql'''';'';
-- This works because we are not substituting any variables
-- Otherwise it would fail. Look at PERFORM for another way to run functions
EXECUTE a_output;
2001-10-13 01:32:34 +02:00
END;
' LANGUAGE 'plpgsql';
</programlisting>
</para>
</example>
<example>
<title>
A Procedure with a lot of String Manipulation and OUT Parameters
</title>
<para>
The following Oracle PL/SQL procedure is used to parse a URL and
return several elements (host, path and query). It is an
procedure because in <application>PL/pgSQL</application> functions only one value can be returned
2001-03-17 19:08:14 +01:00
(see <xref linkend="plpgsql-porting-procedures">). In
<productname>PostgreSQL</>, one way to work around this is to split the procedure
in three different functions: one to return the host, another for
the path and another for the query.
</para>
<programlisting>
2001-10-13 01:32:34 +02:00
CREATE OR REPLACE PROCEDURE cs_parse_url(
v_url IN VARCHAR,
v_host OUT VARCHAR, -- This will be passed back
v_path OUT VARCHAR, -- This one too
v_query OUT VARCHAR) -- And this one
is
2001-10-13 01:32:34 +02:00
a_pos1 INTEGER;
a_pos2 INTEGER;
begin
v_host := NULL;
v_path := NULL;
v_query := NULL;
a_pos1 := instr(v_url, '//'); -- <productname>PostgreSQL</> doesn't have an instr function
2001-10-13 01:32:34 +02:00
IF a_pos1 = 0 THEN
RETURN;
END IF;
a_pos2 := instr(v_url, '/', a_pos1 + 2);
2001-10-13 01:32:34 +02:00
IF a_pos2 = 0 THEN
v_host := substr(v_url, a_pos1 + 2);
v_path := '/';
2001-10-13 01:32:34 +02:00
RETURN;
END IF;
v_host := substr(v_url, a_pos1 + 2, a_pos2 - a_pos1 - 2);
a_pos1 := instr(v_url, '?', a_pos2 + 1);
2001-10-13 01:32:34 +02:00
IF a_pos1 = 0 THEN
v_path := substr(v_url, a_pos2);
2001-10-13 01:32:34 +02:00
RETURN;
END IF;
v_path := substr(v_url, a_pos2, a_pos1 - a_pos2);
v_query := substr(v_url, a_pos1 + 1);
2001-10-13 01:32:34 +02:00
END;
/
show errors;
</programlisting>
<para>
Here is how this procedure could be translated for <productname>PostgreSQL</>:
<programlisting>
CREATE OR REPLACE FUNCTION cs_parse_url_host(VARCHAR) RETURNS VARCHAR AS '
2001-10-13 01:32:34 +02:00
DECLARE
2001-03-17 19:08:14 +01:00
v_url ALIAS FOR $1;
2001-10-13 01:32:34 +02:00
v_host VARCHAR;
v_path VARCHAR;
a_pos1 INTEGER;
a_pos2 INTEGER;
a_pos3 INTEGER;
BEGIN
2001-03-17 19:08:14 +01:00
v_host := NULL;
a_pos1 := instr(v_url,''//'');
2001-10-13 01:32:34 +02:00
IF a_pos1 = 0 THEN
RETURN ''''; -- Return a blank
END IF;
2001-03-17 19:08:14 +01:00
a_pos2 := instr(v_url,''/'',a_pos1 + 2);
2001-10-13 01:32:34 +02:00
IF a_pos2 = 0 THEN
2001-03-17 19:08:14 +01:00
v_host := substr(v_url, a_pos1 + 2);
v_path := ''/'';
2001-10-13 01:32:34 +02:00
RETURN v_host;
END IF;
2001-03-17 19:08:14 +01:00
v_host := substr(v_url, a_pos1 + 2, a_pos2 - a_pos1 - 2 );
2001-10-13 01:32:34 +02:00
RETURN v_host;
END;
' LANGUAGE 'plpgsql';
</programlisting>
</para>
</example>
<note>
<para>
<productname>PostgreSQL</> does not have an <function>instr</function> function,
so you can work around it using a combination of other functions.
I got tired of doing this and created my own
<function>instr</function> functions that behave exactly like
Oracle's (it makes life easier). See the <xref
2001-03-17 19:08:14 +01:00
linkend="plpgsql-porting-appendix"> for the code.
</para>
</note>
</sect2>
<sect2 id="plpgsql-porting-procedures">
<title>
Procedures
</title>
<para>
Oracle procedures give a little more flexibility to the developer
because nothing needs to be explicitly returned, but it can be
through the use of <literal>INOUT</> or <literal>OUT</> parameters.
</para>
<para>
An example:
<programlisting>
2001-10-13 01:32:34 +02:00
CREATE OR REPLACE PROCEDURE cs_create_job(v_job_id IN INTEGER) IS
a_running_job_count INTEGER;
PRAGMA AUTONOMOUS_TRANSACTION;<co id="co.plpgsql-porting-pragma">
BEGIN
LOCK TABLE cs_jobs IN EXCLUSIVE MODE;<co id="co.plpgsql-porting-locktable">
2001-10-13 01:32:34 +02:00
SELECT count(*) INTO a_running_job_count
FROM cs_jobs
WHERE end_stamp IS NULL;
2001-10-13 01:32:34 +02:00
IF a_running_job_count > 0 THEN
COMMIT; -- free lock<co id="co.plpgsql-porting-commit">
raise_application_error(-20000, 'Unable to create a new job: a job is currently running.');
2001-10-13 01:32:34 +02:00
END IF;
2001-10-13 01:32:34 +02:00
DELETE FROM cs_active_job;
INSERT INTO cs_active_job(job_id) VALUES (v_job_id);
2001-10-13 01:32:34 +02:00
BEGIN
INSERT INTO cs_jobs (job_id, start_stamp) VALUES (v_job_id, sysdate);
EXCEPTION WHEN dup_val_on_index THEN NULL; -- don't worry if it already exists<co id="co.plpgsql-porting-exception">
END;
COMMIT;
END;
/
show errors
</programlisting>
</para>
<para>
Procedures like this can be easily converted into <productname>PostgreSQL</>
functions returning an <type>INTEGER</type>. This procedure in
particular is interesting because it can teach us some things:
<calloutlist>
<callout arearefs="co.plpgsql-porting-pragma">
<para>
There is no <literal>pragma</literal> statement in <productname>PostgreSQL</>.
</para>
</callout>
<callout arearefs="co.plpgsql-porting-locktable">
<para>
If you do a <literal>LOCK TABLE</literal> in <application>PL/pgSQL</>, the lock
will not be released until the calling transaction is finished.
</para>
</callout>
<callout arearefs="co.plpgsql-porting-commit">
<para>
You also cannot have transactions in <application>PL/pgSQL</application> procedures. The
entire function (and other functions called from therein) is
executed in a transaction and <productname>PostgreSQL</> rolls back the results if
something goes wrong. Therefore only one
<literal>BEGIN</literal> statement is allowed.
</para>
</callout>
<callout arearefs="co.plpgsql-porting-exception">
<para>
The exception when would have to be replaced by an
<literal>IF</literal> statement.
</para>
</callout>
</calloutlist>
</para>
<para>
So let's see one of the ways we could port this procedure to <application>PL/pgSQL</>:
<programlisting>
CREATE OR REPLACE FUNCTION cs_create_job(INTEGER) RETURNS INTEGER AS '
DECLARE
v_job_id ALIAS FOR $1;
a_running_job_count INTEGER;
2001-10-13 01:32:34 +02:00
a_num INTEGER;
-- PRAGMA AUTONOMOUS_TRANSACTION;
BEGIN
LOCK TABLE cs_jobs IN EXCLUSIVE MODE;
SELECT count(*) INTO a_running_job_count
FROM cs_jobs
WHERE end_stamp IS NULL;
IF a_running_job_count > 0
THEN
-- COMMIT; -- free lock
RAISE EXCEPTION ''Unable to create a new job: a job is currently running.'';
END IF;
DELETE FROM cs_active_job;
INSERT INTO cs_active_job(job_id) VALUES (v_job_id);
SELECT count(*) into a_num
FROM cs_jobs
WHERE job_id=v_job_id;
IF NOT FOUND THEN -- If nothing was returned in the last query
-- This job is not in the table so lets insert it.
INSERT INTO cs_jobs(job_id, start_stamp) VALUES (v_job_id, sysdate());
RETURN 1;
ELSE
RAISE NOTICE ''Job already running.'';<co id="co.plpgsql-porting-raise">
END IF;
RETURN 0;
END;
' LANGUAGE 'plpgsql';
</programlisting>
<calloutlist>
<callout arearefs="co.plpgsql-porting-raise">
<para>
Notice how you can raise notices (or errors) in <application>PL/pgSQL</>.
</para>
</callout>
</calloutlist>
</para>
</sect2>
<sect2 id="plpgsql-porting-packages">
<title>
Packages
</title>
<note>
<para>
I haven't done much with packages myself, so if there are
mistakes here, please let me know.
</para>
</note>
<para>
Packages are a way Oracle gives you to encapsulate PL/SQL
statements and functions into one entity, like Java classes, where
you define methods and objects. You can access these
objects/methods with a <quote><literal>.</literal></quote>
(dot). Here is an example of an Oracle package from ACS 4 (the
<ulink url="http://www.arsdigita.com/doc/">ArsDigita Community
System</ulink>):
<programlisting>
2001-10-13 01:32:34 +02:00
CREATE OR REPLACE PACKAGE BODY acs
AS
FUNCTION add_user (
user_id IN users.user_id%TYPE DEFAULT NULL,
object_type IN acs_objects.object_type%TYPE DEFAULT 'user',
creation_date IN acs_objects.creation_date%TYPE DEFAULT sysdate,
creation_user IN acs_objects.creation_user%TYPE DEFAULT NULL,
creation_ip IN acs_objects.creation_ip%TYPE DEFAULT NULL,
...
2001-10-13 01:32:34 +02:00
) RETURN users.user_id%TYPE
IS
v_user_id users.user_id%TYPE;
v_rel_id membership_rels.rel_id%TYPE;
2001-10-13 01:32:34 +02:00
BEGIN
v_user_id := acs_user.new (user_id, object_type, creation_date,
2001-10-13 01:32:34 +02:00
creation_user, creation_ip, email, ...
RETURN v_user_id;
END;
END acs;
/
show errors
</programlisting>
</para>
<para>
We port this to <productname>PostgreSQL</> by creating the different objects of
the Oracle package as functions with a standard naming
convention. We have to pay attention to some other details, like
the lack of default parameters in <productname>PostgreSQL</> functions. The above
package would become something like this:
<programlisting>
CREATE FUNCTION acs__add_user(INTEGER,INTEGER,VARCHAR,TIMESTAMP,INTEGER,INTEGER,...)
RETURNS INTEGER AS '
DECLARE
user_id ALIAS FOR $1;
object_type ALIAS FOR $2;
creation_date ALIAS FOR $3;
creation_user ALIAS FOR $4;
creation_ip ALIAS FOR $5;
...
v_user_id users.user_id%TYPE;
v_rel_id membership_rels.rel_id%TYPE;
BEGIN
v_user_id := acs_user__new(user_id,object_type,creation_date,creation_user,creation_ip, ...);
...
RETURN v_user_id;
END;
' LANGUAGE 'plpgsql';
</programlisting>
</para>
</sect2>
<sect2 id="plpgsql-porting-other">
<title>
Other Things to Watch For
</title>
<sect3>
<title>EXECUTE</title>
<para>
The <productname>PostgreSQL</> version of <literal>EXECUTE</literal> works
nicely, but you have to remember to use
<function>quote_literal(TEXT)</function> and
<function>quote_string(TEXT)</function> as described in <xref
2001-03-17 19:08:14 +01:00
linkend="plpgsql-statements-executing-dyn-queries">. Constructs of the type
<literal>EXECUTE ''SELECT * from $1'';</literal> will not work
unless you use these functions.
</para>
</sect3>
<sect3 id="plpgsql-porting-optimization">
<title>Optimizing <application>PL/pgSQL</application> Functions</title>
<para>
<productname>PostgreSQL</> gives you two function creation modifiers to optimize
execution: <literal>iscachable</literal> (function always returns
the same result when given the same arguments) and
<literal>isstrict</literal> (function returns NULL if any
argument is NULL). Consult the <command>CREATE
FUNCTION</command> reference for details.
</para>
<para>
To make use of these optimization attributes, you have to use the
<literal>WITH</literal> modifier in your <command>CREATE
FUNCTION</command> statement. Something like:
<programlisting>
CREATE FUNCTION foo(...) RETURNS INTEGER AS '
...
' LANGUAGE 'plpgsql'
WITH (isstrict, iscachable);
</programlisting>
</para>
</sect3>
</sect2>
<sect2 id="plpgsql-porting-appendix">
<title>
Appendix
</title>
<sect3>
<title>
Code for my <function>instr</function> functions
</title>
<comment>
This function should probably be integrated into the core.
</comment>
<programlisting>
--
-- instr functions that mimic Oracle's counterpart
-- Syntax: instr(string1,string2,[n],[m]) where [] denotes optional params.
--
-- Searches string1 beginning at the nth character for the mth
-- occurrence of string2. If n is negative, search backwards. If m is
-- not passed, assume 1 (search starts at first character).
--
-- by Roberto Mello (rmello@fslc.usu.edu)
-- modified by Robert Gaszewski (graszew@poland.com)
-- Licensed under the GPL v2 or later.
--
CREATE FUNCTION instr(VARCHAR,VARCHAR) RETURNS INTEGER AS '
DECLARE
pos integer;
BEGIN
pos:= instr($1,$2,1);
RETURN pos;
END;
2001-10-13 01:32:34 +02:00
' LANGUAGE 'plpgsql';
CREATE FUNCTION instr(VARCHAR,VARCHAR,INTEGER) RETURNS INTEGER AS '
DECLARE
string ALIAS FOR $1;
string_to_search ALIAS FOR $2;
beg_index ALIAS FOR $3;
pos integer NOT NULL DEFAULT 0;
2001-10-13 01:32:34 +02:00
temp_str VARCHAR;
beg INTEGER;
length INTEGER;
ss_length INTEGER;
BEGIN
IF beg_index > 0 THEN
temp_str := substring(string FROM beg_index);
pos := position(string_to_search IN temp_str);
IF pos = 0 THEN
RETURN 0;
ELSE
RETURN pos + beg_index - 1;
END IF;
ELSE
ss_length := char_length(string_to_search);
length := char_length(string);
beg := length + beg_index - ss_length + 2;
WHILE beg > 0 LOOP
temp_str := substring(string FROM beg FOR ss_length);
pos := position(string_to_search IN temp_str);
IF pos > 0 THEN
RETURN beg;
END IF;
beg := beg - 1;
END LOOP;
RETURN 0;
END IF;
END;
2001-10-13 06:58:35 +02:00
' LANGUAGE 'plpgsql';
--
-- Written by Robert Gaszewski (graszew@poland.com)
-- Licensed under the GPL v2 or later.
--
CREATE FUNCTION instr(VARCHAR,VARCHAR,INTEGER,INTEGER) RETURNS INTEGER AS '
DECLARE
string ALIAS FOR $1;
string_to_search ALIAS FOR $2;
beg_index ALIAS FOR $3;
occur_index ALIAS FOR $4;
pos integer NOT NULL DEFAULT 0;
2001-10-13 01:32:34 +02:00
occur_number INTEGER NOT NULL DEFAULT 0;
temp_str VARCHAR;
beg INTEGER;
i INTEGER;
length INTEGER;
ss_length INTEGER;
BEGIN
IF beg_index > 0 THEN
beg := beg_index;
temp_str := substring(string FROM beg_index);
FOR i IN 1..occur_index LOOP
pos := position(string_to_search IN temp_str);
IF i = 1 THEN
beg := beg + pos - 1;
ELSE
beg := beg + pos;
END IF;
temp_str := substring(string FROM beg + 1);
END LOOP;
IF pos = 0 THEN
RETURN 0;
ELSE
RETURN beg;
END IF;
ELSE
ss_length := char_length(string_to_search);
length := char_length(string);
beg := length + beg_index - ss_length + 2;
WHILE beg > 0 LOOP
temp_str := substring(string FROM beg FOR ss_length);
pos := position(string_to_search IN temp_str);
IF pos > 0 THEN
occur_number := occur_number + 1;
IF occur_number = occur_index THEN
RETURN beg;
END IF;
END IF;
beg := beg - 1;
END LOOP;
RETURN 0;
END IF;
END;
' LANGUAGE 'plpgsql';
2001-03-17 19:08:14 +01:00
</programlisting>
</sect3>
</sect2>
</sect1>
</chapter>
<!-- Keep this comment at the end of the file
Local variables:
mode:sgml
sgml-omittag:nil
sgml-shorttag:t
sgml-minimize-attributes:nil
sgml-always-quote-attributes:t
sgml-indent-step:1
sgml-indent-data:t
sgml-parent-document:nil
sgml-default-dtd-file:"./reference.ced"
sgml-exposed-tags:nil
sgml-local-catalogs:("/usr/lib/sgml/catalog")
sgml-local-ecat-files:nil
End:
-->