
via a tuplestore instead of value-per-call. Refactor a few things to reduce ensuing code duplication with nodeFunctionscan.c. This represents the reasonably noncontroversial part of my proposed patch to switch SQL functions over to returning tuplestores. For the moment, SQL functions still do things the old way. However, this change enables PL SRFs to be called in targetlists (observe changes in plperl regression results).
4746 lines
168 KiB
Plaintext
4746 lines
168 KiB
Plaintext
<!-- $PostgreSQL: pgsql/doc/src/sgml/plpgsql.sgml,v 1.135 2008/10/28 22:02:05 tgl Exp $ -->
|
|
|
|
<chapter id="plpgsql">
|
|
<title><application>PL/pgSQL</application> - <acronym>SQL</acronym> Procedural Language</title>
|
|
|
|
<indexterm zone="plpgsql">
|
|
<primary>PL/pgSQL</primary>
|
|
</indexterm>
|
|
|
|
<sect1 id="plpgsql-overview">
|
|
<title>Overview</title>
|
|
|
|
<para>
|
|
<application>PL/pgSQL</application> is a loadable procedural
|
|
language for the <productname>PostgreSQL</productname> database
|
|
system. 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>
|
|
Functions created with <application>PL/pgSQL</application> can be
|
|
used anywhere that built-in functions could be used.
|
|
For example, it is possible to
|
|
create complex conditional computation functions and later use
|
|
them to define operators or use them in index expressions.
|
|
</para>
|
|
|
|
<sect2 id="plpgsql-advantages">
|
|
<title>Advantages of Using <application>PL/pgSQL</application></title>
|
|
|
|
<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>
|
|
|
|
<para>
|
|
That means that your client application must send each query to
|
|
the database server, wait for it to be processed, receive and
|
|
process the results, do some computation, then send further
|
|
queries to the server. All this incurs interprocess
|
|
communication and will also incur network overhead if your client
|
|
is on a different machine than the database server.
|
|
</para>
|
|
|
|
<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 with considerable
|
|
savings of client/server communication overhead.
|
|
</para>
|
|
<itemizedlist>
|
|
|
|
<listitem><para> Extra round trips between
|
|
client and server are eliminated </para></listitem>
|
|
|
|
<listitem><para> Intermediate results that the client does not
|
|
need do not have to be marshaled or transferred between server
|
|
and client </para></listitem>
|
|
|
|
<listitem><para> Multiple rounds of query
|
|
parsing can be avoided </para></listitem>
|
|
|
|
</itemizedlist>
|
|
<para> This can result in a considerable performance increase as
|
|
compared to an application that does not use stored functions.
|
|
</para>
|
|
|
|
<para>
|
|
Also, with <application>PL/pgSQL</application> you can use all
|
|
the data types, operators and functions of SQL.
|
|
</para>
|
|
</sect2>
|
|
|
|
<sect2 id="plpgsql-args-results">
|
|
<title>Supported Argument and Result Data Types</title>
|
|
|
|
<para>
|
|
Functions written in <application>PL/pgSQL</application> 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 <application>PL/pgSQL</application>
|
|
function as returning <type>record</>, which means that the result
|
|
is a row type whose columns are determined by specification in the
|
|
calling query, as discussed in <xref linkend="queries-tablefunctions">.
|
|
</para>
|
|
|
|
<para>
|
|
<application>PL/pgSQL</> functions can be declared to accept a variable
|
|
number of arguments by using the <literal>VARIADIC</> marker. This
|
|
works exactly the same way as for SQL functions, as discussed in
|
|
<xref linkend="xfunc-sql-variadic-functions">.
|
|
</para>
|
|
|
|
<para>
|
|
<application>PL/pgSQL</> functions can also be declared to accept
|
|
and return the polymorphic types
|
|
<type>anyelement</type>, <type>anyarray</type>, <type>anynonarray</type>,
|
|
and <type>anyenum</>. The actual
|
|
data types handled by a polymorphic function can vary from call to
|
|
call, as discussed in <xref linkend="extend-types-polymorphic">.
|
|
An example is shown in <xref linkend="plpgsql-declaration-aliases">.
|
|
</para>
|
|
|
|
<para>
|
|
<application>PL/pgSQL</> functions can also be declared to return
|
|
a <quote>set</> (or table) of any data type that can be returned as
|
|
a single instance. Such a function generates its output by executing
|
|
<command>RETURN NEXT</> for each desired element of the result
|
|
set, or by using <command>RETURN QUERY</> to output the result of
|
|
evaluating a query.
|
|
</para>
|
|
|
|
<para>
|
|
Finally, a <application>PL/pgSQL</> function can be declared to return
|
|
<type>void</> if it has no useful return value.
|
|
</para>
|
|
|
|
<para>
|
|
<application>PL/pgSQL</> 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.
|
|
The <literal>RETURNS TABLE</> notation can also be used in place
|
|
of <literal>RETURNS SETOF</>.
|
|
</para>
|
|
|
|
<para>
|
|
Specific examples appear in
|
|
<xref linkend="plpgsql-declaration-aliases"> and
|
|
<xref linkend="plpgsql-statements-returning">.
|
|
</para>
|
|
</sect2>
|
|
</sect1>
|
|
|
|
<sect1 id="plpgsql-structure">
|
|
<title>Structure of <application>PL/pgSQL</application></title>
|
|
|
|
<para>
|
|
<application>PL/pgSQL</application> is a block-structured language.
|
|
The complete text of a function definition must be a
|
|
<firstterm>block</>. A block is defined as:
|
|
|
|
<synopsis>
|
|
<optional> <<<replaceable>label</replaceable>>> </optional>
|
|
<optional> DECLARE
|
|
<replaceable>declarations</replaceable> </optional>
|
|
BEGIN
|
|
<replaceable>statements</replaceable>
|
|
END <optional> <replaceable>label</replaceable> </optional>;
|
|
</synopsis>
|
|
</para>
|
|
|
|
<para>
|
|
Each declaration and each statement within a block is terminated
|
|
by a semicolon. A block that appears within another block must
|
|
have a semicolon after <literal>END</literal>, as shown above;
|
|
however the final <literal>END</literal> that
|
|
concludes a function body does not require a semicolon.
|
|
</para>
|
|
|
|
<tip>
|
|
<para>
|
|
A common mistake is to write a semicolon immediately after
|
|
<literal>BEGIN</>. This is incorrect and will result in a syntax error.
|
|
</para>
|
|
</tip>
|
|
|
|
<para>
|
|
A <replaceable>label</replaceable> is only needed if you want to
|
|
identify the block for use
|
|
in an <literal>EXIT</> statement, or to qualify the names of the
|
|
variables declared in the block. If a label is given after
|
|
<literal>END</>, it must match the label at the block's beginning.
|
|
</para>
|
|
|
|
<para>
|
|
All key words are case-insensitive.
|
|
Identifiers are implicitly converted to lowercase
|
|
unless double-quoted, just as they are in ordinary SQL commands.
|
|
</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>
|
|
|
|
<para>
|
|
Any statement in the statement section of a block
|
|
can be a <firstterm>subblock</>. Subblocks can be used for
|
|
logical grouping or to localize variables to a small group
|
|
of statements. Variables declared in a subblock mask any
|
|
similarly-named variables of outer blocks for the duration
|
|
of the subblock; but you can access the outer variables anyway
|
|
if you qualify their names with their block's label. For example:
|
|
<programlisting>
|
|
CREATE FUNCTION somefunc() RETURNS integer AS $$
|
|
<< outerblock >>
|
|
DECLARE
|
|
quantity integer := 30;
|
|
BEGIN
|
|
RAISE NOTICE 'Quantity here is %', quantity; -- Prints 30
|
|
quantity := 50;
|
|
--
|
|
-- Create a subblock
|
|
--
|
|
DECLARE
|
|
quantity integer := 80;
|
|
BEGIN
|
|
RAISE NOTICE 'Quantity here is %', quantity; -- Prints 80
|
|
RAISE NOTICE 'Outer quantity here is %', outerblock.quantity; -- Prints 50
|
|
END;
|
|
|
|
RAISE NOTICE 'Quantity here is %', quantity; -- Prints 50
|
|
|
|
RETURN quantity;
|
|
END;
|
|
$$ LANGUAGE plpgsql;
|
|
</programlisting>
|
|
</para>
|
|
|
|
<note>
|
|
<para>
|
|
There is actually a hidden <quote>outer block</> surrounding the body
|
|
of any <application>PL/pgSQL</> function. This block provides the
|
|
declarations of the function's parameters (if any), as well as some
|
|
special variables such as <literal>FOUND</literal> (see
|
|
<xref linkend="plpgsql-statements-diagnostics">). The outer block is
|
|
labeled with the function's name, meaning that parameters and special
|
|
variables can be qualified with the function's name.
|
|
</para>
|
|
</note>
|
|
|
|
<para>
|
|
It is important not to confuse the use of
|
|
<command>BEGIN</>/<command>END</> for grouping statements in
|
|
<application>PL/pgSQL</> with the similarly-named SQL commands
|
|
for transaction
|
|
control. <application>PL/pgSQL</>'s <command>BEGIN</>/<command>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 that
|
|
transaction, since there would be no context for them to execute in.
|
|
However, a block containing an <literal>EXCEPTION</> clause effectively
|
|
forms a subtransaction that can be rolled back without affecting the
|
|
outer transaction. For more about that see <xref
|
|
linkend="plpgsql-error-trapping">.
|
|
</para>
|
|
</sect1>
|
|
|
|
<sect1 id="plpgsql-declarations">
|
|
<title>Declarations</title>
|
|
|
|
<para>
|
|
All variables used in a block must be declared in the
|
|
declarations section of the block.
|
|
(The only exceptions are that the loop variable of a <literal>FOR</> loop
|
|
iterating over a range of integer values is automatically declared as an
|
|
integer variable, and likewise the loop variable of a <literal>FOR</> loop
|
|
iterating over a cursor's result is automatically declared as a
|
|
record variable.)
|
|
</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>
|
|
|
|
<para>
|
|
Here are some examples of variable declarations:
|
|
<programlisting>
|
|
user_id integer;
|
|
quantity numeric(5);
|
|
url varchar;
|
|
myrow tablename%ROWTYPE;
|
|
myfield tablename.columnname%TYPE;
|
|
arow RECORD;
|
|
</programlisting>
|
|
</para>
|
|
|
|
<para>
|
|
The general syntax of a variable declaration is:
|
|
<synopsis>
|
|
<replaceable>name</replaceable> <optional> CONSTANT </optional> <replaceable>type</replaceable> <optional> NOT NULL </optional> <optional> { DEFAULT | := } <replaceable>expression</replaceable> </optional>;
|
|
</synopsis>
|
|
The <literal>DEFAULT</> clause, if given, specifies the initial value assigned
|
|
to the variable when the block is entered. If the <literal>DEFAULT</> clause
|
|
is not given then the variable is initialized to the
|
|
<acronym>SQL</acronym> null value.
|
|
The <literal>CONSTANT</> option prevents the variable from being assigned to,
|
|
so that its value remains constant for the duration of the block.
|
|
If <literal>NOT NULL</>
|
|
is specified, an assignment of a null value results in a run-time
|
|
error. All variables declared as <literal>NOT NULL</>
|
|
must have a nonnull default value specified.
|
|
</para>
|
|
|
|
<para>
|
|
A variable's default value is evaluated and assigned to the variable
|
|
each time the block is entered (not just once per function call).
|
|
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 the time when the function was
|
|
precompiled.
|
|
</para>
|
|
|
|
<para>
|
|
Examples:
|
|
<programlisting>
|
|
quantity integer DEFAULT 32;
|
|
url varchar := 'http://mysite.com';
|
|
user_id CONSTANT integer := 10;
|
|
</programlisting>
|
|
</para>
|
|
|
|
<sect2 id="plpgsql-declaration-aliases">
|
|
<title>Aliases for Function Parameters</title>
|
|
|
|
<para>
|
|
Parameters passed to functions are named with the identifiers
|
|
<literal>$1</literal>, <literal>$2</literal>,
|
|
etc. Optionally, aliases can be declared for
|
|
<literal>$<replaceable>n</replaceable></literal>
|
|
parameter names for increased readability. Either the alias or the
|
|
numeric identifier can then be used to refer to the parameter value.
|
|
</para>
|
|
|
|
<para>
|
|
There are two ways to create an alias. The preferred way is to give a
|
|
name to the parameter in the <command>CREATE FUNCTION</command> command,
|
|
for example:
|
|
<programlisting>
|
|
CREATE FUNCTION sales_tax(subtotal real) RETURNS real AS $$
|
|
BEGIN
|
|
RETURN subtotal * 0.06;
|
|
END;
|
|
$$ LANGUAGE plpgsql;
|
|
</programlisting>
|
|
The other way, which was the only way available before
|
|
<productname>PostgreSQL</productname> 8.0, is to explicitly
|
|
declare an alias, using the declaration syntax
|
|
|
|
<synopsis>
|
|
<replaceable>name</replaceable> ALIAS FOR $<replaceable>n</replaceable>;
|
|
</synopsis>
|
|
|
|
The same example in this style looks like:
|
|
<programlisting>
|
|
CREATE FUNCTION sales_tax(real) RETURNS real AS $$
|
|
DECLARE
|
|
subtotal ALIAS FOR $1;
|
|
BEGIN
|
|
RETURN subtotal * 0.06;
|
|
END;
|
|
$$ LANGUAGE plpgsql;
|
|
</programlisting>
|
|
</para>
|
|
|
|
<note>
|
|
<para>
|
|
These two examples are not perfectly equivalent. In the first case,
|
|
<literal>subtotal</> could be referenced as
|
|
<literal>sales_tax.subtotal</>, but in the second case it could not.
|
|
(Had we attached a label to the block, <literal>subtotal</> could
|
|
be qualified with that label, instead.)
|
|
</para>
|
|
</note>
|
|
|
|
<para>
|
|
Some more examples:
|
|
<programlisting>
|
|
CREATE FUNCTION instr(varchar, integer) RETURNS integer AS $$
|
|
DECLARE
|
|
v_string ALIAS FOR $1;
|
|
index ALIAS FOR $2;
|
|
BEGIN
|
|
-- some computations using v_string and index here
|
|
END;
|
|
$$ LANGUAGE plpgsql;
|
|
|
|
|
|
CREATE FUNCTION concat_selected_fields(in_t sometablename) RETURNS text AS $$
|
|
BEGIN
|
|
RETURN in_t.f1 || in_t.f3 || in_t.f5 || in_t.f7;
|
|
END;
|
|
$$ LANGUAGE plpgsql;
|
|
</programlisting>
|
|
</para>
|
|
|
|
<para>
|
|
When a <application>PL/pgSQL</application> function is declared
|
|
with output parameters, the output parameters are given
|
|
<literal>$<replaceable>n</replaceable></literal> names and optional
|
|
aliases in just the same way as the normal input parameters. An
|
|
output parameter is effectively a variable that starts out NULL;
|
|
it should be assigned to during the execution of the function.
|
|
The final value of the parameter is what is returned. For instance,
|
|
the sales-tax example could also be done this way:
|
|
|
|
<programlisting>
|
|
CREATE FUNCTION sales_tax(subtotal real, OUT tax real) AS $$
|
|
BEGIN
|
|
tax := subtotal * 0.06;
|
|
END;
|
|
$$ LANGUAGE plpgsql;
|
|
</programlisting>
|
|
|
|
Notice that we omitted <literal>RETURNS real</> — we could have
|
|
included it, but it would be redundant.
|
|
</para>
|
|
|
|
<para>
|
|
Output parameters are most useful when returning multiple values.
|
|
A trivial example is:
|
|
|
|
<programlisting>
|
|
CREATE FUNCTION sum_n_product(x int, y int, OUT sum int, OUT prod int) AS $$
|
|
BEGIN
|
|
sum := x + y;
|
|
prod := x * y;
|
|
END;
|
|
$$ LANGUAGE plpgsql;
|
|
</programlisting>
|
|
|
|
As discussed in <xref linkend="xfunc-output-parameters">, this
|
|
effectively creates an anonymous record type for the function's
|
|
results. If a <literal>RETURNS</> clause is given, it must say
|
|
<literal>RETURNS record</>.
|
|
</para>
|
|
|
|
<para>
|
|
Another way to declare a <application>PL/pgSQL</application> function
|
|
is with <literal>RETURNS TABLE</>, for example:
|
|
|
|
<programlisting>
|
|
CREATE FUNCTION extended_sales(p_itemno int) RETURNS TABLE(quantity int, total numeric) AS $$
|
|
BEGIN
|
|
RETURN QUERY SELECT quantity, quantity * price FROM sales WHERE itemno = p_itemno;
|
|
END;
|
|
$$ LANGUAGE plpgsql;
|
|
</programlisting>
|
|
|
|
This is exactly equivalent to declaring one or more <literal>OUT</>
|
|
parameters and specifying <literal>RETURNS SETOF
|
|
<replaceable>sometype</></literal>.
|
|
</para>
|
|
|
|
<para>
|
|
When the return type of a <application>PL/pgSQL</application>
|
|
function is declared as a polymorphic type (<type>anyelement</type>,
|
|
<type>anyarray</type>, <type>anynonarray</type>, or <type>anyenum</>),
|
|
a special parameter <literal>$0</literal>
|
|
is created. Its data type is the actual return type of the function,
|
|
as deduced from the actual input types (see <xref
|
|
linkend="extend-types-polymorphic">).
|
|
This allows the function to access its actual return type
|
|
as shown in <xref linkend="plpgsql-declaration-type">.
|
|
<literal>$0</literal> is initialized to null and can be modified by
|
|
the function, so it can be used to hold the return value if desired,
|
|
though that is not required. <literal>$0</literal> can also be
|
|
given an alias. For example, this function works on any data type
|
|
that has a <literal>+</> operator:
|
|
|
|
<programlisting>
|
|
CREATE FUNCTION add_three_values(v1 anyelement, v2 anyelement, v3 anyelement)
|
|
RETURNS anyelement AS $$
|
|
DECLARE
|
|
result ALIAS FOR $0;
|
|
BEGIN
|
|
result := v1 + v2 + v3;
|
|
RETURN result;
|
|
END;
|
|
$$ LANGUAGE plpgsql;
|
|
</programlisting>
|
|
</para>
|
|
|
|
<para>
|
|
The same effect can be had by declaring one or more output parameters as
|
|
polymorphic types. In this case the
|
|
special <literal>$0</literal> parameter is not used; the output
|
|
parameters themselves serve the same purpose. For example:
|
|
|
|
<programlisting>
|
|
CREATE FUNCTION add_three_values(v1 anyelement, v2 anyelement, v3 anyelement,
|
|
OUT sum anyelement)
|
|
AS $$
|
|
BEGIN
|
|
sum := v1 + v2 + v3;
|
|
END;
|
|
$$ LANGUAGE plpgsql;
|
|
</programlisting>
|
|
</para>
|
|
</sect2>
|
|
|
|
<sect2 id="plpgsql-declaration-type">
|
|
<title>Copying Types</title>
|
|
|
|
<synopsis>
|
|
<replaceable>variable</replaceable>%TYPE
|
|
</synopsis>
|
|
|
|
<para>
|
|
<literal>%TYPE</literal> provides the data type of a variable or
|
|
table column. You can use this to declare variables that will hold
|
|
database values. For example, let's say you have a column named
|
|
<literal>user_id</literal> in your <literal>users</literal>
|
|
table. To declare a variable with the same data type as
|
|
<literal>users.user_id</> you write:
|
|
<programlisting>
|
|
user_id users.user_id%TYPE;
|
|
</programlisting>
|
|
</para>
|
|
|
|
<para>
|
|
By using <literal>%TYPE</literal> you don't need to know the data
|
|
type of the structure you are referencing, and most importantly,
|
|
if the data type of the referenced item changes in the future (for
|
|
instance: you change the type of <literal>user_id</>
|
|
from <type>integer</type> to <type>real</type>), you might not need
|
|
to change your function definition.
|
|
</para>
|
|
|
|
<para>
|
|
<literal>%TYPE</literal> is particularly valuable in polymorphic
|
|
functions, since the data types needed for internal variables can
|
|
change from one call to the next. Appropriate variables can be
|
|
created by applying <literal>%TYPE</literal> to the function's
|
|
arguments or result placeholders.
|
|
</para>
|
|
|
|
</sect2>
|
|
|
|
<sect2 id="plpgsql-declaration-rowtypes">
|
|
<title>Row Types</title>
|
|
|
|
<synopsis>
|
|
<replaceable>name</replaceable> <replaceable>table_name</replaceable><literal>%ROWTYPE</literal>;
|
|
<replaceable>name</replaceable> <replaceable>composite_type_name</replaceable>;
|
|
</synopsis>
|
|
|
|
<para>
|
|
A variable of a composite type is called a <firstterm>row</>
|
|
variable (or <firstterm>row-type</> variable). Such a variable
|
|
can hold a whole row of a <command>SELECT</> or <command>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>
|
|
A row variable can be declared to have the same type as the rows of
|
|
an existing table or view, by using the
|
|
<replaceable>table_name</replaceable><literal>%ROWTYPE</literal>
|
|
notation; or it can be declared by giving a composite type's name.
|
|
(Since every table has an associated composite type of the same name,
|
|
it actually does not matter in <productname>PostgreSQL</> whether you
|
|
write <literal>%ROWTYPE</literal> or not. But the form with
|
|
<literal>%ROWTYPE</literal> is more portable.)
|
|
</para>
|
|
|
|
<para>
|
|
Parameters to a function can be
|
|
composite types (complete table rows). In that case, the
|
|
corresponding identifier <literal>$<replaceable>n</replaceable></> 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 columns of a table row are accessible in a
|
|
row-type variable, not the OID or other system columns (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(<replaceable>n</>)</type>.
|
|
</para>
|
|
|
|
<para>
|
|
Here is an example of using composite types. <structname>table1</>
|
|
and <structname>table2</> are existing tables having at least the
|
|
mentioned fields:
|
|
|
|
<programlisting>
|
|
CREATE FUNCTION merge_fields(t_row table1) RETURNS text AS $$
|
|
DECLARE
|
|
t2_row table2%ROWTYPE;
|
|
BEGIN
|
|
SELECT * INTO t2_row FROM table2 WHERE ... ;
|
|
RETURN t_row.f1 || t2_row.f3 || t_row.f5 || t2_row.f7;
|
|
END;
|
|
$$ LANGUAGE plpgsql;
|
|
|
|
SELECT merge_fields(t.*) FROM table1 t WHERE ... ;
|
|
</programlisting>
|
|
</para>
|
|
</sect2>
|
|
|
|
<sect2 id="plpgsql-declaration-records">
|
|
<title>Record Types</title>
|
|
|
|
<synopsis>
|
|
<replaceable>name</replaceable> RECORD;
|
|
</synopsis>
|
|
|
|
<para>
|
|
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 <command>SELECT</> or <command>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, it has no substructure, and any attempt to access a
|
|
field in it will draw a run-time error.
|
|
</para>
|
|
|
|
<para>
|
|
Note that <literal>RECORD</> is not a true data type, only a placeholder.
|
|
One should also realize that when a <application>PL/pgSQL</application>
|
|
function is declared to return type <type>record</>, this is not quite the
|
|
same concept as a record variable, even though such a function might
|
|
use a record variable to hold its result. In both cases the actual row
|
|
structure is unknown when the function is written, but for a function
|
|
returning <type>record</> the actual structure is determined when the
|
|
calling query is parsed, whereas a record variable can change its row
|
|
structure on-the-fly.
|
|
</para>
|
|
</sect2>
|
|
|
|
<sect2 id="plpgsql-declaration-renaming-vars">
|
|
<title><literal>RENAME</></title>
|
|
|
|
<synopsis>
|
|
RENAME <replaceable>oldname</replaceable> TO <replaceable>newname</replaceable>;
|
|
</synopsis>
|
|
|
|
<para>
|
|
Using the <literal>RENAME</literal> declaration you can change the
|
|
name of a variable, record or row. This is primarily useful if
|
|
<varname>NEW</varname> or <varname>OLD</varname> should be
|
|
referenced by another name inside a trigger procedure. See also
|
|
<literal>ALIAS</literal>.
|
|
</para>
|
|
|
|
<para>
|
|
Examples:
|
|
<programlisting>
|
|
RENAME id TO user_id;
|
|
RENAME this_var TO that_var;
|
|
</programlisting>
|
|
</para>
|
|
|
|
<note>
|
|
<para>
|
|
<literal>RENAME</literal> appears to be broken as of
|
|
<productname>PostgreSQL</> 7.3. Fixing this is of low priority,
|
|
since <literal>ALIAS</literal> covers most of the practical uses
|
|
of <literal>RENAME</literal>.
|
|
</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 main
|
|
<acronym>SQL</acronym> executor. For example, when you write
|
|
a <application>PL/pgSQL</application> statement like
|
|
<synopsis>
|
|
IF <replaceable>expression</replaceable> THEN ...
|
|
</synopsis>
|
|
<application>PL/pgSQL</application> will evaluate the expression by
|
|
feeding a query like
|
|
<synopsis>
|
|
SELECT <replaceable>expression</replaceable>
|
|
</synopsis>
|
|
to the main SQL engine. While forming the <command>SELECT</> command,
|
|
any occurrences of <application>PL/pgSQL</application> variable names
|
|
are replaced by parameters, as discussed in detail in
|
|
<xref linkend="plpgsql-var-subst">.
|
|
This allows the query plan for the <command>SELECT</command> to
|
|
be prepared just once and then reused for subsequent
|
|
evaluations with different values of the variables. Thus, what
|
|
really happens on first use of an expression is essentially a
|
|
<command>PREPARE</> command. For example, if we have declared
|
|
two integer variables <literal>x</> and <literal>y</>, and we write
|
|
<programlisting>
|
|
IF x < y THEN ...
|
|
</programlisting>
|
|
what happens behind the scenes is
|
|
<programlisting>
|
|
PREPARE <replaceable>statement_name</>(integer, integer) AS SELECT $1 < $2;
|
|
</programlisting>
|
|
and then this prepared statement is <command>EXECUTE</>d for each
|
|
execution of the <command>IF</> statement, with the current values
|
|
of the <application>PL/pgSQL</application> variables supplied as
|
|
parameter values.
|
|
The query plan prepared in this way is saved for the life of the database
|
|
connection, as described in
|
|
<xref linkend="plpgsql-plan-caching">. Normally these details are
|
|
not important to a <application>PL/pgSQL</application> user, but
|
|
they are useful to know when trying to diagnose a problem.
|
|
</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 command and is sent to the main database engine to execute,
|
|
as described in <xref linkend="plpgsql-statements-sql-noresult">
|
|
and <xref linkend="plpgsql-statements-sql-onerow">.
|
|
</para>
|
|
|
|
<sect2 id="plpgsql-statements-assignment">
|
|
<title>Assignment</title>
|
|
|
|
<para>
|
|
An assignment of a value to a <application>PL/pgSQL</application>
|
|
variable or row/record field is written as:
|
|
<synopsis>
|
|
<replaceable>variable</replaceable> := <replaceable>expression</replaceable>;
|
|
</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
|
|
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:
|
|
<programlisting>
|
|
tax := subtotal * 0.06;
|
|
my_record.user_id := 20;
|
|
</programlisting>
|
|
</para>
|
|
</sect2>
|
|
|
|
<sect2 id="plpgsql-statements-sql-noresult">
|
|
<title>Executing a Command With No Result</title>
|
|
|
|
<para>
|
|
For any SQL command that does not return rows, for example
|
|
<command>INSERT</> without a <literal>RETURNING</> clause, you can
|
|
execute the command within a <application>PL/pgSQL</application> function
|
|
just by writing the command.
|
|
</para>
|
|
|
|
<para>
|
|
Any <application>PL/pgSQL</application> variable name appearing
|
|
in the command text is replaced by a parameter symbol, and then the
|
|
current value of the variable is provided as the parameter value
|
|
at run time. This is exactly like the processing described earlier
|
|
for expressions; for details see <xref linkend="plpgsql-var-subst">.
|
|
As an example, if you write:
|
|
<programlisting>
|
|
DECLARE
|
|
key TEXT;
|
|
delta INTEGER;
|
|
BEGIN
|
|
...
|
|
UPDATE mytab SET val = val + delta WHERE id = key;
|
|
</programlisting>
|
|
the command text seen by the main SQL engine will look like:
|
|
<programlisting>
|
|
UPDATE mytab SET val = val + $1 WHERE id = $2;
|
|
</programlisting>
|
|
Although you don't normally have to think about this, it's helpful
|
|
to know it when you need to make sense of syntax-error messages.
|
|
</para>
|
|
|
|
<caution>
|
|
<para>
|
|
<application>PL/pgSQL</application> will substitute for any identifier
|
|
matching one of the function's declared variables; it is not bright
|
|
enough to know whether that's what you meant! Thus, it is a bad idea
|
|
to use a variable name that is the same as any table, column, or
|
|
function name that you need to reference in commands within the
|
|
function. For more discussion see <xref linkend="plpgsql-var-subst">.
|
|
</para>
|
|
</caution>
|
|
|
|
<para>
|
|
When executing a SQL command in this way,
|
|
<application>PL/pgSQL</application> plans the command just once
|
|
and re-uses the plan on subsequent executions, for the life of
|
|
the database connection. The implications of this are discussed
|
|
in detail in <xref linkend="plpgsql-plan-caching">.
|
|
</para>
|
|
|
|
<para>
|
|
Sometimes it is useful to evaluate an expression or <command>SELECT</>
|
|
query but discard the result, for example when calling a function
|
|
that has side-effects but no useful result value. To do
|
|
this in <application>PL/pgSQL</application>, use the
|
|
<command>PERFORM</command> statement:
|
|
|
|
<synopsis>
|
|
PERFORM <replaceable>query</replaceable>;
|
|
</synopsis>
|
|
|
|
This executes <replaceable>query</replaceable> and discards the
|
|
result. Write the <replaceable>query</replaceable> the same
|
|
way you would write an SQL <command>SELECT</> command, but replace the
|
|
initial keyword <command>SELECT</> with <command>PERFORM</command>.
|
|
<application>PL/pgSQL</application> variables will be
|
|
substituted into the query just as for commands that return no result,
|
|
and the plan is cached in the same way. 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 (see
|
|
<xref linkend="plpgsql-statements-diagnostics">).
|
|
</para>
|
|
|
|
<note>
|
|
<para>
|
|
One might expect that writing <command>SELECT</command> directly
|
|
would accomplish this result, but at
|
|
present the only accepted way to do it is
|
|
<command>PERFORM</command>. A SQL command that can return rows,
|
|
such as <command>SELECT</command>, will be rejected as an error
|
|
unless it has an <literal>INTO</> clause as discussed in the
|
|
next section.
|
|
</para>
|
|
</note>
|
|
|
|
<para>
|
|
An example:
|
|
<programlisting>
|
|
PERFORM create_mv('cs_session_page_requests_mv', my_query);
|
|
</programlisting>
|
|
</para>
|
|
</sect2>
|
|
|
|
<sect2 id="plpgsql-statements-sql-onerow">
|
|
<title>Executing a Query with a Single-Row Result</title>
|
|
|
|
<indexterm zone="plpgsql-statements-sql-onerow">
|
|
<primary>SELECT INTO</primary>
|
|
<secondary>in PL/pgSQL</secondary>
|
|
</indexterm>
|
|
|
|
<indexterm zone="plpgsql-statements-sql-onerow">
|
|
<primary>RETURNING INTO</primary>
|
|
<secondary>in PL/pgSQL</secondary>
|
|
</indexterm>
|
|
|
|
<para>
|
|
The result of a SQL command yielding a single row (possibly of multiple
|
|
columns) can be assigned to a record variable, row-type variable, or list
|
|
of scalar variables. This is done by writing the base SQL command and
|
|
adding an <literal>INTO</> clause. For example,
|
|
|
|
<synopsis>
|
|
SELECT <replaceable>select_expressions</replaceable> INTO <optional>STRICT</optional> <replaceable>target</replaceable> FROM ...;
|
|
INSERT ... RETURNING <replaceable>expressions</replaceable> INTO <optional>STRICT</optional> <replaceable>target</replaceable>;
|
|
UPDATE ... RETURNING <replaceable>expressions</replaceable> INTO <optional>STRICT</optional> <replaceable>target</replaceable>;
|
|
DELETE ... RETURNING <replaceable>expressions</replaceable> INTO <optional>STRICT</optional> <replaceable>target</replaceable>;
|
|
</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.
|
|
<application>PL/pgSQL</application> variables will be
|
|
substituted into the rest of the query, and the plan is cached,
|
|
just as described above for commands that do not return rows.
|
|
This works for <command>SELECT</>,
|
|
<command>INSERT</>/<command>UPDATE</>/<command>DELETE</> with
|
|
<literal>RETURNING</>, and utility commands that return row-set
|
|
results (such as <command>EXPLAIN</>).
|
|
Except for the <literal>INTO</> clause, the SQL command is the same
|
|
as it would be written outside <application>PL/pgSQL</application>.
|
|
</para>
|
|
|
|
<tip>
|
|
<para>
|
|
Note that this interpretation of <command>SELECT</> with <literal>INTO</>
|
|
is quite different from <productname>PostgreSQL</>'s regular
|
|
<command>SELECT INTO</command> command, wherein the <literal>INTO</>
|
|
target is a newly created table. If you want to create a table from a
|
|
<command>SELECT</> result inside a
|
|
<application>PL/pgSQL</application> function, use the syntax
|
|
<command>CREATE TABLE ... AS SELECT</command>.
|
|
</para>
|
|
</tip>
|
|
|
|
<para>
|
|
If a row or a variable list is used as target, the query's result columns
|
|
must exactly match the structure of the target as to number and data
|
|
types, or a run-time error
|
|
occurs. When a record variable is the target, it automatically
|
|
configures itself to the row type of the query result columns.
|
|
</para>
|
|
|
|
<para>
|
|
The <literal>INTO</> clause can appear almost anywhere in the SQL
|
|
command. Customarily it is written either just before or just after
|
|
the list of <replaceable>select_expressions</replaceable> in a
|
|
<command>SELECT</> command, or at the end of the command for other
|
|
command types. It is recommended that you follow this convention
|
|
in case the <application>PL/pgSQL</application> parser becomes
|
|
stricter in future versions.
|
|
</para>
|
|
|
|
<para>
|
|
If <literal>STRICT</literal> is not specified in the <literal>INTO</>
|
|
clause, then <replaceable>target</replaceable> will be set to the first
|
|
row returned by the query, or to nulls if the query returned no rows.
|
|
(Note that <quote>the first row</> is not
|
|
well-defined unless you've used <literal>ORDER BY</>.) Any result rows
|
|
after the first row are discarded.
|
|
You can check the special <literal>FOUND</literal> variable (see
|
|
<xref linkend="plpgsql-statements-diagnostics">) to
|
|
determine whether a row was returned:
|
|
|
|
<programlisting>
|
|
SELECT * INTO myrec FROM emp WHERE empname = myname;
|
|
IF NOT FOUND THEN
|
|
RAISE EXCEPTION 'employee % not found', myname;
|
|
END IF;
|
|
</programlisting>
|
|
|
|
If the <literal>STRICT</literal> option is specified, the query must
|
|
return exactly one row or a run-time error will be reported, either
|
|
<literal>NO_DATA_FOUND</> (no rows) or <literal>TOO_MANY_ROWS</>
|
|
(more than one row). You can use an exception block if you wish
|
|
to catch the error, for example:
|
|
|
|
<programlisting>
|
|
BEGIN
|
|
SELECT * INTO STRICT myrec FROM emp WHERE empname = myname;
|
|
EXCEPTION
|
|
WHEN NO_DATA_FOUND THEN
|
|
RAISE EXCEPTION 'employee % not found', myname;
|
|
WHEN TOO_MANY_ROWS THEN
|
|
RAISE EXCEPTION 'employee % not unique', myname;
|
|
END;
|
|
</programlisting>
|
|
Successful execution of a command with <literal>STRICT</>
|
|
always sets <literal>FOUND</literal> to true.
|
|
</para>
|
|
|
|
<para>
|
|
For <command>INSERT</>/<command>UPDATE</>/<command>DELETE</> with
|
|
<literal>RETURNING</>, <application>PL/pgSQL</application> reports
|
|
an error for more than one returned row, even when
|
|
<literal>STRICT</literal> is not specified. This is because there
|
|
is no option such as <literal>ORDER BY</> with which to determine
|
|
which affected row should be returned.
|
|
</para>
|
|
|
|
<note>
|
|
<para>
|
|
The <literal>STRICT</> option matches the behavior of
|
|
Oracle PL/SQL's <command>SELECT INTO</command> and related statements.
|
|
</para>
|
|
</note>
|
|
|
|
<para>
|
|
To handle cases where you need to process multiple result rows
|
|
from a SQL query, see <xref linkend="plpgsql-records-iterating">.
|
|
</para>
|
|
|
|
</sect2>
|
|
|
|
<sect2 id="plpgsql-statements-executing-dyn">
|
|
<title>Executing Dynamic Commands</title>
|
|
|
|
<para>
|
|
Oftentimes you will want to generate dynamic commands inside your
|
|
<application>PL/pgSQL</application> functions, that is, commands
|
|
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 commands (as discussed in
|
|
<xref linkend="plpgsql-plan-caching">) will not work in such
|
|
scenarios. To handle this sort of problem, the
|
|
<command>EXECUTE</command> statement is provided:
|
|
|
|
<synopsis>
|
|
EXECUTE <replaceable class="command">command-string</replaceable> <optional> INTO <optional>STRICT</optional> <replaceable>target</replaceable> </optional> <optional> USING <replaceable>expression</replaceable> <optional>, ...</optional> </optional>;
|
|
</synopsis>
|
|
|
|
where <replaceable>command-string</replaceable> is an expression
|
|
yielding a string (of type <type>text</type>) containing the
|
|
command to be executed. The optional <replaceable>target</replaceable>
|
|
is a record variable, a row variable, or a comma-separated list of
|
|
simple variables and record/row fields, into which the results of
|
|
the command will be stored. The optional <literal>USING</> expressions
|
|
supply values to be inserted into the command.
|
|
</para>
|
|
|
|
<para>
|
|
No substitution of <application>PL/pgSQL</> variables is done on the
|
|
computed command string. Any required variable values must be inserted
|
|
in the command string as it is constructed; or you can use parameters
|
|
as described below.
|
|
</para>
|
|
|
|
<para>
|
|
Also, there is no plan caching for commands executed via
|
|
<command>EXECUTE</command>. Instead, the
|
|
command is prepared each time the statement is run. Thus the command
|
|
string can be dynamically created within the function to perform
|
|
actions on different tables and columns.
|
|
</para>
|
|
|
|
<para>
|
|
The <literal>INTO</literal> clause specifies where the results of
|
|
a SQL command returning rows should be assigned. If a row
|
|
or variable list is provided, it must exactly match the structure
|
|
of the query's results (when a
|
|
record variable is used, it will configure itself to match the
|
|
result structure automatically). If multiple rows are returned,
|
|
only the first will be assigned to the <literal>INTO</literal>
|
|
variable. If no rows are returned, NULL is assigned to the
|
|
<literal>INTO</literal> variable(s). If no <literal>INTO</literal>
|
|
clause is specified, the query results are discarded.
|
|
</para>
|
|
|
|
<para>
|
|
If the <literal>STRICT</> option is given, an error is reported
|
|
unless the query produces exactly one row.
|
|
</para>
|
|
|
|
<para>
|
|
The command string can use parameter values, which are referenced
|
|
in the command as <literal>$1</>, <literal>$2</>, etc.
|
|
These symbols refer to values supplied in the <literal>USING</>
|
|
clause. This method is often preferable to inserting data values
|
|
into the command string as text: it avoids run-time overhead of
|
|
converting the values to text and back, and it is much less prone
|
|
to SQL-injection attacks since there is no need for quoting or escaping.
|
|
An example is:
|
|
<programlisting>
|
|
EXECUTE 'SELECT count(*) FROM mytable WHERE inserted_by = $1 AND inserted <= $2'
|
|
INTO c
|
|
USING checked_user, checked_date;
|
|
</programlisting>
|
|
|
|
Note that parameter symbols can only be used for data values
|
|
— if you want to use dynamically determined table or column
|
|
names, you must insert them into the command string textually.
|
|
For example, if the preceding query needed to be done against a
|
|
dynamically selected table, you could do this:
|
|
<programlisting>
|
|
EXECUTE 'SELECT count(*) FROM '
|
|
|| tabname::regclass
|
|
|| ' WHERE inserted_by = $1 AND inserted <= $2'
|
|
INTO c
|
|
USING checked_user, checked_date;
|
|
</programlisting>
|
|
</para>
|
|
|
|
<para>
|
|
An <command>EXECUTE</> with a simple constant command string and some
|
|
<literal>USING</> parameters, as in the first example above, is
|
|
functionally equivalent to just writing the command directly in
|
|
<application>PL/pgSQL</application> and allowing replacement of
|
|
<application>PL/pgSQL</application> variables to happen automatically.
|
|
The important difference is that <command>EXECUTE</> will re-plan
|
|
the command on each execution, generating a plan that is specific
|
|
to the current parameter values; whereas
|
|
<application>PL/pgSQL</application> normally creates a generic plan
|
|
and caches it for re-use. In situations where the best plan depends
|
|
strongly on the parameter values, <command>EXECUTE</> can be
|
|
significantly faster; while when the plan is not sensitive to parameter
|
|
values, re-planning will be a waste.
|
|
</para>
|
|
|
|
<para>
|
|
<command>SELECT INTO</command> is not currently supported within
|
|
<command>EXECUTE</command>; instead, execute a plain <command>SELECT</>
|
|
command and specify <literal>INTO</> as part of the <command>EXECUTE</>
|
|
itself.
|
|
</para>
|
|
|
|
<note>
|
|
<para>
|
|
The <application>PL/pgSQL</application>
|
|
<command>EXECUTE</command> statement is not related to the
|
|
<xref linkend="sql-execute" endterm="sql-execute-title"> SQL
|
|
statement supported by the
|
|
<productname>PostgreSQL</productname> server. The server's
|
|
<command>EXECUTE</command> statement cannot be used directly within
|
|
<application>PL/pgSQL</> functions (and is not needed).
|
|
</para>
|
|
</note>
|
|
|
|
<example id="plpgsql-quote-literal-example">
|
|
<title>Quoting values in dynamic queries</title>
|
|
|
|
<indexterm>
|
|
<primary>quote_ident</primary>
|
|
<secondary>use in PL/PgSQL</secondary>
|
|
</indexterm>
|
|
|
|
<indexterm>
|
|
<primary>quote_literal</primary>
|
|
<secondary>use in PL/PgSQL</secondary>
|
|
</indexterm>
|
|
|
|
<indexterm>
|
|
<primary>quote_nullable</primary>
|
|
<secondary>use in PL/PgSQL</secondary>
|
|
</indexterm>
|
|
|
|
<para>
|
|
When working with dynamic commands you will often have to handle escaping
|
|
of single quotes. The recommended method for quoting fixed text in your
|
|
function body is dollar quoting. (If you have legacy code that does
|
|
not use dollar quoting, please refer to the
|
|
overview in <xref linkend="plpgsql-quote-tips">, which can save you
|
|
some effort when translating said code to a more reasonable scheme.)
|
|
</para>
|
|
|
|
<para>
|
|
Dynamic values that are to be inserted into the constructed
|
|
query require careful handling since they might themselves contain
|
|
quote characters.
|
|
An example (this assumes that you are using dollar quoting for the
|
|
function as a whole, so the quote marks need not be doubled):
|
|
<programlisting>
|
|
EXECUTE 'UPDATE tbl SET '
|
|
|| quote_ident(colname)
|
|
|| ' = '
|
|
|| quote_literal(newvalue)
|
|
|| ' WHERE key = '
|
|
|| quote_literal(keyvalue);
|
|
</programlisting>
|
|
</para>
|
|
|
|
<para>
|
|
This example demonstrates the use of the
|
|
<function>quote_ident</function> and
|
|
<function>quote_literal</function> functions (see <xref
|
|
linkend="functions-string">). For safety, expressions containing column
|
|
or table identifiers should be passed through
|
|
<function>quote_ident</function> before insertion in a dynamic query.
|
|
Expressions containing values that should be literal strings in the
|
|
constructed command should be passed through <function>quote_literal</>.
|
|
These functions take the appropriate steps to return the input text
|
|
enclosed in double or single quotes respectively, with any embedded
|
|
special characters properly escaped.
|
|
</para>
|
|
|
|
<para>
|
|
Because <function>quote_literal</function> is labelled
|
|
<literal>STRICT</literal>, it will always return null when called with a
|
|
null argument. In the above example, if <literal>newvalue</> or
|
|
<literal>keyvalue</> were null, the entire dynamic query string would
|
|
become null, leading to an error from <command>EXECUTE</command>.
|
|
You can avoid this problem by using the <function>quote_nullable</>
|
|
function, which works the same as <function>quote_literal</> except that
|
|
when called with a null argument it returns the string <literal>NULL</>.
|
|
For example,
|
|
<programlisting>
|
|
EXECUTE 'UPDATE tbl SET '
|
|
|| quote_ident(colname)
|
|
|| ' = '
|
|
|| quote_nullable(newvalue)
|
|
|| ' WHERE key = '
|
|
|| quote_nullable(keyvalue);
|
|
</programlisting>
|
|
If you are dealing with values that might be null, you should usually
|
|
use <function>quote_nullable</> in place of <function>quote_literal</>.
|
|
</para>
|
|
|
|
<para>
|
|
As always, care must be taken to ensure that null values in a query do
|
|
not deliver unintended results. For example the <literal>WHERE</> clause
|
|
<programlisting>
|
|
'WHERE key = ' || quote_nullable(keyvalue)
|
|
</programlisting>
|
|
will never succeed if <literal>keyvalue</> is null, because the
|
|
result of using the equality operator <literal>=</> with a null operand
|
|
is always null. If you wish null to work like an ordinary key value,
|
|
you would need to rewrite the above as
|
|
<programlisting>
|
|
'WHERE key IS NOT DISTINCT FROM ' || quote_nullable(keyvalue)
|
|
</programlisting>
|
|
(At present, <literal>IS NOT DISTINCT FROM</> is handled much less
|
|
efficiently than <literal>=</>, so don't do this unless you must.
|
|
See <xref linkend="functions-comparison"> for
|
|
more information on nulls and <literal>IS DISTINCT</>.)
|
|
</para>
|
|
|
|
<para>
|
|
Note that dollar quoting is only useful for quoting fixed text.
|
|
It would be a very bad idea to try to write this example as:
|
|
<programlisting>
|
|
EXECUTE 'UPDATE tbl SET '
|
|
|| quote_ident(colname)
|
|
|| ' = $$'
|
|
|| newvalue
|
|
|| '$$ WHERE key = '
|
|
|| quote_literal(keyvalue);
|
|
</programlisting>
|
|
because it would break if the contents of <literal>newvalue</>
|
|
happened to contain <literal>$$</>. The same objection would
|
|
apply to any other dollar-quoting delimiter you might pick.
|
|
So, to safely quote text that is not known in advance, you
|
|
<emphasis>must</> use <function>quote_literal</>,
|
|
<function>quote_nullable</>, or <function>quote_ident</>, as appropriate.
|
|
</para>
|
|
</example>
|
|
|
|
<para>
|
|
A much larger example of a dynamic command and
|
|
<command>EXECUTE</command> can be seen in <xref
|
|
linkend="plpgsql-porting-ex2">, which builds and executes a
|
|
<command>CREATE FUNCTION</> command to define a new function.
|
|
</para>
|
|
</sect2>
|
|
|
|
<sect2 id="plpgsql-statements-diagnostics">
|
|
<title>Obtaining the Result Status</title>
|
|
|
|
<para>
|
|
There are several ways to determine the effect of a command. The
|
|
first method is to use the <command>GET DIAGNOSTICS</command>
|
|
command, which has the form:
|
|
|
|
<synopsis>
|
|
GET DIAGNOSTICS <replaceable>variable</replaceable> = <replaceable>item</replaceable> <optional> , ... </optional>;
|
|
</synopsis>
|
|
|
|
This command allows retrieval of system status indicators. Each
|
|
<replaceable>item</replaceable> is a key word 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
|
|
status items are <varname>ROW_COUNT</>, the number of rows
|
|
processed by the last <acronym>SQL</acronym> command sent down to
|
|
the <acronym>SQL</acronym> engine, and <varname>RESULT_OID</>,
|
|
the OID of the last row inserted by the most recent
|
|
<acronym>SQL</acronym> command. Note that <varname>RESULT_OID</>
|
|
is only useful after an <command>INSERT</command> command into a
|
|
table containing OIDs.
|
|
</para>
|
|
|
|
<para>
|
|
An example:
|
|
<programlisting>
|
|
GET DIAGNOSTICS integer_var = ROW_COUNT;
|
|
</programlisting>
|
|
</para>
|
|
|
|
<para>
|
|
The second method to determine the effects of a command is to check the
|
|
special variable named <literal>FOUND</literal>, which is of
|
|
type <type>boolean</type>. <literal>FOUND</literal> starts out
|
|
false within each <application>PL/pgSQL</application> function call.
|
|
It is set by each of the following types of statements:
|
|
<itemizedlist>
|
|
<listitem>
|
|
<para>
|
|
A <command>SELECT INTO</command> statement sets
|
|
<literal>FOUND</literal> true if a row is assigned, false if no
|
|
row is returned.
|
|
</para>
|
|
</listitem>
|
|
<listitem>
|
|
<para>
|
|
A <command>PERFORM</> statement sets <literal>FOUND</literal>
|
|
true if it produces (and discards) one or more rows, false if
|
|
no row is produced.
|
|
</para>
|
|
</listitem>
|
|
<listitem>
|
|
<para>
|
|
<command>UPDATE</>, <command>INSERT</>, and <command>DELETE</>
|
|
statements set <literal>FOUND</literal> true if at least one
|
|
row is affected, false if no row is affected.
|
|
</para>
|
|
</listitem>
|
|
<listitem>
|
|
<para>
|
|
A <command>FETCH</> statement sets <literal>FOUND</literal>
|
|
true if it returns a row, false if no row is returned.
|
|
</para>
|
|
</listitem>
|
|
<listitem>
|
|
<para>
|
|
A <command>MOVE</> statement sets <literal>FOUND</literal>
|
|
true if it successfully repositions the cursor, false otherwise.
|
|
</para>
|
|
</listitem>
|
|
|
|
<listitem>
|
|
<para>
|
|
A <command>FOR</> statement sets <literal>FOUND</literal> true
|
|
if it iterates one or more times, else false. This applies to
|
|
all four variants of the <command>FOR</> statement (integer
|
|
<command>FOR</> loops, record-set <command>FOR</> loops,
|
|
dynamic record-set <command>FOR</> loops, and cursor
|
|
<command>FOR</> loops).
|
|
<literal>FOUND</literal> is set this way when the
|
|
<command>FOR</> loop exits; inside the execution of the loop,
|
|
<literal>FOUND</literal> is not modified by the
|
|
<command>FOR</> statement, although it might be changed by the
|
|
execution of other statements within the loop body.
|
|
</para>
|
|
</listitem>
|
|
</itemizedlist>
|
|
|
|
<literal>FOUND</literal> is a local variable within each
|
|
<application>PL/pgSQL</application> function; any changes to it
|
|
affect only the current function.
|
|
</para>
|
|
|
|
</sect2>
|
|
|
|
<sect2 id="plpgsql-statements-null">
|
|
<title>Doing Nothing At All</title>
|
|
|
|
<para>
|
|
Sometimes a placeholder statement that does nothing is useful.
|
|
For example, it can indicate that one arm of an if/then/else
|
|
chain is deliberately empty. For this purpose, use the
|
|
<command>NULL</command> statement:
|
|
|
|
<synopsis>
|
|
NULL;
|
|
</synopsis>
|
|
</para>
|
|
|
|
<para>
|
|
For example, the following two fragments of code are equivalent:
|
|
<programlisting>
|
|
BEGIN
|
|
y := x / 0;
|
|
EXCEPTION
|
|
WHEN division_by_zero THEN
|
|
NULL; -- ignore the error
|
|
END;
|
|
</programlisting>
|
|
|
|
<programlisting>
|
|
BEGIN
|
|
y := x / 0;
|
|
EXCEPTION
|
|
WHEN division_by_zero THEN -- ignore the error
|
|
END;
|
|
</programlisting>
|
|
Which is preferable is a matter of taste.
|
|
</para>
|
|
|
|
<note>
|
|
<para>
|
|
In Oracle's PL/SQL, empty statement lists are not allowed, and so
|
|
<command>NULL</> statements are <emphasis>required</> for situations
|
|
such as this. <application>PL/pgSQL</application> allows you to
|
|
just write nothing, instead.
|
|
</para>
|
|
</note>
|
|
|
|
</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>
|
|
There are two commands available that allow you to return data
|
|
from a function: <command>RETURN</command> and <command>RETURN
|
|
NEXT</command>.
|
|
</para>
|
|
|
|
<sect3>
|
|
<title><command>RETURN</></title>
|
|
|
|
<synopsis>
|
|
RETURN <replaceable>expression</replaceable>;
|
|
</synopsis>
|
|
|
|
<para>
|
|
<command>RETURN</command> with an expression terminates the
|
|
function and returns the value of
|
|
<replaceable>expression</replaceable> to the caller. This form
|
|
is to be used for <application>PL/pgSQL</> functions that do
|
|
not return a set.
|
|
</para>
|
|
|
|
<para>
|
|
When returning a scalar type, any expression can be used. The
|
|
expression's result will be automatically cast into the
|
|
function's return type as described for assignments. To return a
|
|
composite (row) value, you must write a record or row variable
|
|
as the <replaceable>expression</replaceable>.
|
|
</para>
|
|
|
|
<para>
|
|
If you declared the function with output parameters, write just
|
|
<command>RETURN</command> with no expression. The current values
|
|
of the output parameter variables will be returned.
|
|
</para>
|
|
|
|
<para>
|
|
If you declared the function to return <type>void</type>, a
|
|
<command>RETURN</command> statement can be used to exit the function
|
|
early; but do not write an expression following
|
|
<command>RETURN</command>.
|
|
</para>
|
|
|
|
<para>
|
|
The return value of a function cannot be left undefined. If
|
|
control reaches the end of the top-level block of the function
|
|
without hitting a <command>RETURN</command> statement, a run-time
|
|
error will occur. This restriction does not apply to functions
|
|
with output parameters and functions returning <type>void</type>,
|
|
however. In those cases a <command>RETURN</command> statement is
|
|
automatically executed if the top-level block finishes.
|
|
</para>
|
|
</sect3>
|
|
|
|
<sect3>
|
|
<title><command>RETURN NEXT</> and <command>RETURN QUERY</command></title>
|
|
<indexterm>
|
|
<primary>RETURN NEXT</primary>
|
|
<secondary>in PL/PgSQL</secondary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>RETURN QUERY</primary>
|
|
<secondary>in PL/PgSQL</secondary>
|
|
</indexterm>
|
|
|
|
<synopsis>
|
|
RETURN NEXT <replaceable>expression</replaceable>;
|
|
RETURN QUERY <replaceable>query</replaceable>;
|
|
RETURN QUERY EXECUTE <replaceable class="command">command-string</replaceable> <optional> USING <replaceable>expression</replaceable> <optional>, ...</optional> </optional>;
|
|
</synopsis>
|
|
|
|
<para>
|
|
When a <application>PL/pgSQL</> function is declared to return
|
|
<literal>SETOF <replaceable>sometype</></literal>, the procedure
|
|
to follow is slightly different. In that case, the individual
|
|
items to return are specified by a sequence of <command>RETURN
|
|
NEXT</command> or <command>RETURN QUERY</command> commands, and
|
|
then a final <command>RETURN</command> command with no argument
|
|
is used to indicate that the function has finished executing.
|
|
<command>RETURN NEXT</command> can be used with both scalar and
|
|
composite data types; with a composite result type, an entire
|
|
<quote>table</quote> of results will be returned.
|
|
<command>RETURN QUERY</command> appends the results of executing
|
|
a query to the function's result set. <command>RETURN
|
|
NEXT</command> and <command>RETURN QUERY</command> can be freely
|
|
intermixed in a single set-returning function, in which case
|
|
their results will be concatenated.
|
|
</para>
|
|
|
|
<para>
|
|
<command>RETURN NEXT</command> and <command>RETURN
|
|
QUERY</command> do not actually return from the function —
|
|
they simply append zero or more rows to the function's result
|
|
set. Execution then continues with the next statement in the
|
|
<application>PL/pgSQL</> function. As successive
|
|
<command>RETURN NEXT</command> or <command>RETURN
|
|
QUERY</command> commands are executed, the result set is built
|
|
up. A final <command>RETURN</command>, which should have no
|
|
argument, causes control to exit the function (or you can just
|
|
let control reach the end of the function).
|
|
</para>
|
|
|
|
<para>
|
|
<command>RETURN QUERY</command> has a variant
|
|
<command>RETURN QUERY EXECUTE</command>, which specifies the
|
|
query to be executed dynamically. Parameter expressions can
|
|
be inserted into the computed query string via <literal>USING</>,
|
|
in just the same way as in the <command>EXECUTE</> command.
|
|
</para>
|
|
|
|
<para>
|
|
If you declared the function with output parameters, write just
|
|
<command>RETURN NEXT</command> with no expression. On each
|
|
execution, the current values of the output parameter
|
|
variable(s) will be saved for eventual return as a row of the
|
|
result. Note that you must declare the function as returning
|
|
<literal>SETOF record</literal> when there are multiple output
|
|
parameters, or <literal>SETOF <replaceable>sometype</></literal>
|
|
when there is just one output parameter of type
|
|
<replaceable>sometype</>, in order to create a set-returning
|
|
function with output parameters.
|
|
</para>
|
|
|
|
<para>
|
|
Here is an example of a function using <command>RETURN
|
|
NEXT</command>:
|
|
|
|
<programlisting>
|
|
CREATE TABLE foo (fooid INT, foosubid INT, fooname TEXT);
|
|
INSERT INTO foo VALUES (1, 2, 'three');
|
|
INSERT INTO foo VALUES (4, 5, 'six');
|
|
|
|
CREATE OR REPLACE FUNCTION getAllFoo() RETURNS SETOF foo AS
|
|
$BODY$
|
|
DECLARE
|
|
r foo%rowtype;
|
|
BEGIN
|
|
FOR r IN SELECT * FROM foo
|
|
WHERE fooid > 0
|
|
LOOP
|
|
-- can do some processing here
|
|
RETURN NEXT r; -- return current row of SELECT
|
|
END LOOP;
|
|
RETURN;
|
|
END
|
|
$BODY$
|
|
LANGUAGE 'plpgsql' ;
|
|
|
|
SELECT * FROM getallfoo();
|
|
</programlisting>
|
|
</para>
|
|
|
|
<note>
|
|
<para>
|
|
The current implementation of <command>RETURN NEXT</command>
|
|
and <command>RETURN QUERY</command> stores the entire result set
|
|
before returning from the function, as discussed above. That
|
|
means that if a <application>PL/pgSQL</> function produces a
|
|
very large result set, performance might be poor: data will be
|
|
written to disk to avoid memory exhaustion, but the function
|
|
itself will not return until the entire result set has been
|
|
generated. A future version of <application>PL/pgSQL</> might
|
|
allow users to define set-returning functions
|
|
that do not have this limitation. Currently, the point at
|
|
which data begins being written to disk is controlled by the
|
|
<xref linkend="guc-work-mem">
|
|
configuration variable. Administrators who have sufficient
|
|
memory to store larger result sets in memory should consider
|
|
increasing this parameter.
|
|
</para>
|
|
</note>
|
|
</sect3>
|
|
</sect2>
|
|
|
|
<sect2 id="plpgsql-conditionals">
|
|
<title>Conditionals</title>
|
|
|
|
<para>
|
|
<command>IF</> and <command>CASE</> statements let you execute
|
|
alternative commands based on certain conditions.
|
|
<application>PL/pgSQL</> has three forms of <command>IF</>:
|
|
<itemizedlist>
|
|
<listitem>
|
|
<para><literal>IF ... THEN</></>
|
|
</listitem>
|
|
<listitem>
|
|
<para><literal>IF ... THEN ... ELSE</></>
|
|
</listitem>
|
|
<listitem>
|
|
<para><literal>IF ... THEN ... ELSIF ... THEN ... ELSE</></>
|
|
</listitem>
|
|
</itemizedlist>
|
|
|
|
and two forms of <command>CASE</>:
|
|
<itemizedlist>
|
|
<listitem>
|
|
<para><literal>CASE ... WHEN ... THEN ... ELSE ... END CASE</></>
|
|
</listitem>
|
|
<listitem>
|
|
<para><literal>CASE WHEN ... THEN ... ELSE ... END CASE</></>
|
|
</listitem>
|
|
</itemizedlist>
|
|
</para>
|
|
|
|
<sect3>
|
|
<title><literal>IF-THEN</></title>
|
|
|
|
<synopsis>
|
|
IF <replaceable>boolean-expression</replaceable> THEN
|
|
<replaceable>statements</replaceable>
|
|
END IF;
|
|
</synopsis>
|
|
|
|
<para>
|
|
<literal>IF-THEN</literal> statements are the simplest form of
|
|
<literal>IF</literal>. The statements between
|
|
<literal>THEN</literal> and <literal>END IF</literal> will be
|
|
executed if the condition is true. Otherwise, they are
|
|
skipped.
|
|
</para>
|
|
|
|
<para>
|
|
Example:
|
|
<programlisting>
|
|
IF v_user_id <> 0 THEN
|
|
UPDATE users SET email = v_email WHERE user_id = v_user_id;
|
|
END IF;
|
|
</programlisting>
|
|
</para>
|
|
</sect3>
|
|
|
|
<sect3>
|
|
<title><literal>IF-THEN-ELSE</></title>
|
|
|
|
<synopsis>
|
|
IF <replaceable>boolean-expression</replaceable> THEN
|
|
<replaceable>statements</replaceable>
|
|
ELSE
|
|
<replaceable>statements</replaceable>
|
|
END IF;
|
|
</synopsis>
|
|
|
|
<para>
|
|
<literal>IF-THEN-ELSE</literal> statements add to
|
|
<literal>IF-THEN</literal> by letting you specify an
|
|
alternative set of statements that should be executed if the
|
|
condition is not true. (Note this includes the case where the
|
|
condition evaluates to NULL.)
|
|
</para>
|
|
|
|
<para>
|
|
Examples:
|
|
<programlisting>
|
|
IF parentid IS NULL OR parentid = ''
|
|
THEN
|
|
RETURN fullname;
|
|
ELSE
|
|
RETURN hp_true_filename(parentid) || '/' || fullname;
|
|
END IF;
|
|
</programlisting>
|
|
|
|
<programlisting>
|
|
IF v_count > 0 THEN
|
|
INSERT INTO users_count (count) VALUES (v_count);
|
|
RETURN 't';
|
|
ELSE
|
|
RETURN 'f';
|
|
END IF;
|
|
</programlisting>
|
|
</para>
|
|
</sect3>
|
|
|
|
<sect3>
|
|
<title><literal>IF-THEN-ELSIF</></title>
|
|
|
|
<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>
|
|
|
|
<para>
|
|
Sometimes there are more than just two alternatives.
|
|
<literal>IF-THEN-ELSIF</> provides a convenient
|
|
method of checking several alternatives in turn.
|
|
The <literal>IF</> conditions are tested successively
|
|
until the first one that is true is found. Then the
|
|
associated statement(s) are executed, after which control
|
|
passes to the next statement after <literal>END IF</>.
|
|
(Any subsequent <literal>IF</> conditions are <emphasis>not</>
|
|
tested.) If none of the <literal>IF</> conditions is true,
|
|
then the <literal>ELSE</> block (if any) is executed.
|
|
</para>
|
|
|
|
<para>
|
|
Here is an example:
|
|
|
|
<programlisting>
|
|
IF number = 0 THEN
|
|
result := 'zero';
|
|
ELSIF number > 0 THEN
|
|
result := 'positive';
|
|
ELSIF number < 0 THEN
|
|
result := 'negative';
|
|
ELSE
|
|
-- hmm, the only other possibility is that number is null
|
|
result := 'NULL';
|
|
END IF;
|
|
</programlisting>
|
|
</para>
|
|
|
|
<para>
|
|
The key word <literal>ELSIF</> can also be spelled
|
|
<literal>ELSEIF</>.
|
|
</para>
|
|
|
|
<para>
|
|
An alternative way of accomplishing the same task is to nest
|
|
<literal>IF-THEN-ELSE</literal> statements, as in the
|
|
following example:
|
|
|
|
<programlisting>
|
|
IF demo_row.sex = 'm' THEN
|
|
pretty_sex := 'man';
|
|
ELSE
|
|
IF demo_row.sex = 'f' THEN
|
|
pretty_sex := 'woman';
|
|
END IF;
|
|
END IF;
|
|
</programlisting>
|
|
</para>
|
|
|
|
<para>
|
|
However, this method requires writing a matching <literal>END IF</>
|
|
for each <literal>IF</>, so it is much more cumbersome than
|
|
using <literal>ELSIF</> when there are many alternatives.
|
|
</para>
|
|
</sect3>
|
|
|
|
<sect3>
|
|
<title>Simple <literal>CASE</></title>
|
|
|
|
<synopsis>
|
|
CASE <replaceable>search-expression</replaceable>
|
|
WHEN <replaceable>expression</replaceable> <optional>, <replaceable>expression</replaceable> <optional> ... </optional></optional> THEN
|
|
<replaceable>statements</replaceable>
|
|
<optional> WHEN <replaceable>expression</replaceable> <optional>, <replaceable>expression</replaceable> <optional> ... </optional></optional> THEN
|
|
<replaceable>statements</replaceable>
|
|
... </optional>
|
|
<optional> ELSE
|
|
<replaceable>statements</replaceable> </optional>
|
|
END CASE;
|
|
</synopsis>
|
|
|
|
<para>
|
|
The simple form of <command>CASE</> provides conditional execution
|
|
based on equality of operands. The <replaceable>search-expression</>
|
|
is evaluated (once) and successively compared to each
|
|
<replaceable>expression</> in the <literal>WHEN</> clauses.
|
|
If a match is found, then the corresponding
|
|
<replaceable>statements</replaceable> are executed, and then control
|
|
passes to the next statement after <literal>END CASE</>. (Subsequent
|
|
<literal>WHEN</> expressions are not evaluated.) If no match is
|
|
found, the <literal>ELSE</> <replaceable>statements</replaceable> are
|
|
executed; but if <literal>ELSE</> is not present, then a
|
|
<literal>CASE_NOT_FOUND</literal> exception is raised.
|
|
</para>
|
|
|
|
<para>
|
|
Here is a simple example:
|
|
|
|
<programlisting>
|
|
CASE x
|
|
WHEN 1, 2 THEN
|
|
msg := 'one or two';
|
|
ELSE
|
|
msg := 'other value than one or two';
|
|
END CASE;
|
|
</programlisting>
|
|
</para>
|
|
</sect3>
|
|
|
|
<sect3>
|
|
<title>Searched <literal>CASE</></title>
|
|
|
|
<synopsis>
|
|
CASE
|
|
WHEN <replaceable>boolean-expression</replaceable> THEN
|
|
<replaceable>statements</replaceable>
|
|
<optional> WHEN <replaceable>boolean-expression</replaceable> THEN
|
|
<replaceable>statements</replaceable>
|
|
... </optional>
|
|
<optional> ELSE
|
|
<replaceable>statements</replaceable> </optional>
|
|
END CASE;
|
|
</synopsis>
|
|
|
|
<para>
|
|
The searched form of <command>CASE</> provides conditional execution
|
|
based on truth of boolean expressions. Each <literal>WHEN</> clause's
|
|
<replaceable>boolean-expression</replaceable> is evaluated in turn,
|
|
until one is found that yields <literal>true</>. Then the
|
|
corresponding <replaceable>statements</replaceable> are executed, and
|
|
then control passes to the next statement after <literal>END CASE</>.
|
|
(Subsequent <literal>WHEN</> expressions are not evaluated.)
|
|
If no true result is found, the <literal>ELSE</>
|
|
<replaceable>statements</replaceable> are executed;
|
|
but if <literal>ELSE</> is not present, then a
|
|
<literal>CASE_NOT_FOUND</literal> exception is raised.
|
|
</para>
|
|
|
|
<para>
|
|
Here is an example:
|
|
|
|
<programlisting>
|
|
CASE
|
|
WHEN x BETWEEN 0 AND 10 THEN
|
|
msg := 'value is between zero and ten';
|
|
WHEN x BETWEEN 11 AND 20 THEN
|
|
msg := 'value is between eleven and twenty';
|
|
END CASE;
|
|
</programlisting>
|
|
</para>
|
|
|
|
<para>
|
|
This form of <command>CASE</> is entirely equivalent to
|
|
<literal>IF-THEN-ELSIF</>, except for the rule that reaching
|
|
an omitted <literal>ELSE</> clause results in an error rather
|
|
than doing nothing.
|
|
</para>
|
|
|
|
</sect3>
|
|
</sect2>
|
|
|
|
<sect2 id="plpgsql-control-structures-loops">
|
|
<title>Simple Loops</title>
|
|
|
|
<indexterm zone="plpgsql-control-structures-loops">
|
|
<primary>loop</primary>
|
|
<secondary>in PL/pgSQL</secondary>
|
|
</indexterm>
|
|
|
|
<para>
|
|
With the <literal>LOOP</>, <literal>EXIT</>,
|
|
<literal>CONTINUE</>, <literal>WHILE</>, and <literal>FOR</>
|
|
statements, you can arrange for your <application>PL/pgSQL</>
|
|
function to repeat a series of commands.
|
|
</para>
|
|
|
|
<sect3>
|
|
<title><literal>LOOP</></title>
|
|
|
|
<synopsis>
|
|
<optional> <<<replaceable>label</replaceable>>> </optional>
|
|
LOOP
|
|
<replaceable>statements</replaceable>
|
|
END LOOP <optional> <replaceable>label</replaceable> </optional>;
|
|
</synopsis>
|
|
|
|
<para>
|
|
<literal>LOOP</> defines an unconditional loop that is repeated
|
|
indefinitely until terminated by an <literal>EXIT</> or
|
|
<command>RETURN</command> statement. The optional
|
|
<replaceable>label</replaceable> can be used by <literal>EXIT</>
|
|
and <literal>CONTINUE</literal> statements in nested loops to
|
|
specify which loop the statement should be applied to.
|
|
</para>
|
|
</sect3>
|
|
|
|
<sect3>
|
|
<title><literal>EXIT</></title>
|
|
|
|
<indexterm>
|
|
<primary>EXIT</primary>
|
|
<secondary>in PL/pgSQL</secondary>
|
|
</indexterm>
|
|
|
|
<synopsis>
|
|
EXIT <optional> <replaceable>label</replaceable> </optional> <optional> WHEN <replaceable>boolean-expression</replaceable> </optional>;
|
|
</synopsis>
|
|
|
|
<para>
|
|
If no <replaceable>label</replaceable> is given, the innermost
|
|
loop is terminated and the statement following <literal>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 <literal>END</>.
|
|
</para>
|
|
|
|
<para>
|
|
If <literal>WHEN</> is specified, the loop exit occurs only if
|
|
<replaceable>boolean-expression</> is true. Otherwise, control passes
|
|
to the statement after <literal>EXIT</>.
|
|
</para>
|
|
|
|
<para>
|
|
<literal>EXIT</> can be used with all types of loops; it is
|
|
not limited to use with unconditional loops. When used with a
|
|
<literal>BEGIN</literal> block, <literal>EXIT</literal> passes
|
|
control to the next statement after the end of the block.
|
|
</para>
|
|
|
|
<para>
|
|
Examples:
|
|
<programlisting>
|
|
LOOP
|
|
-- some computations
|
|
IF count > 0 THEN
|
|
EXIT; -- exit loop
|
|
END IF;
|
|
END LOOP;
|
|
|
|
LOOP
|
|
-- some computations
|
|
EXIT WHEN count > 0; -- same result as previous example
|
|
END LOOP;
|
|
|
|
BEGIN
|
|
-- some computations
|
|
IF stocks > 100000 THEN
|
|
EXIT; -- causes exit from the BEGIN block
|
|
END IF;
|
|
END;
|
|
</programlisting>
|
|
</para>
|
|
</sect3>
|
|
|
|
<sect3>
|
|
<title><literal>CONTINUE</></title>
|
|
|
|
<indexterm>
|
|
<primary>CONTINUE</primary>
|
|
<secondary>in PL/pgSQL</secondary>
|
|
</indexterm>
|
|
|
|
<synopsis>
|
|
CONTINUE <optional> <replaceable>label</replaceable> </optional> <optional> WHEN <replaceable>boolean-expression</replaceable> </optional>;
|
|
</synopsis>
|
|
|
|
<para>
|
|
If no <replaceable>label</> is given, the next iteration of
|
|
the innermost loop is begun. That is, all statements remaining
|
|
in the loop body are skipped, and control returns
|
|
to the loop control expression (if any) to determine whether
|
|
another loop iteration is needed.
|
|
If <replaceable>label</> is present, it
|
|
specifies the label of the loop whose execution will be
|
|
continued.
|
|
</para>
|
|
|
|
<para>
|
|
If <literal>WHEN</> is specified, the next iteration of the
|
|
loop is begun only if <replaceable>boolean-expression</> is
|
|
true. Otherwise, control passes to the statement after
|
|
<literal>CONTINUE</>.
|
|
</para>
|
|
|
|
<para>
|
|
<literal>CONTINUE</> can be used with all types of loops; it
|
|
is not limited to use with unconditional loops.
|
|
</para>
|
|
|
|
<para>
|
|
Examples:
|
|
<programlisting>
|
|
LOOP
|
|
-- some computations
|
|
EXIT WHEN count > 100;
|
|
CONTINUE WHEN count < 50;
|
|
-- some computations for count IN [50 .. 100]
|
|
END LOOP;
|
|
</programlisting>
|
|
</para>
|
|
</sect3>
|
|
|
|
|
|
<sect3>
|
|
<title><literal>WHILE</></title>
|
|
|
|
<indexterm>
|
|
<primary>WHILE</primary>
|
|
<secondary>in PL/pgSQL</secondary>
|
|
</indexterm>
|
|
|
|
<synopsis>
|
|
<optional> <<<replaceable>label</replaceable>>> </optional>
|
|
WHILE <replaceable>boolean-expression</replaceable> LOOP
|
|
<replaceable>statements</replaceable>
|
|
END LOOP <optional> <replaceable>label</replaceable> </optional>;
|
|
</synopsis>
|
|
|
|
<para>
|
|
The <literal>WHILE</> statement repeats a
|
|
sequence of statements so long as the
|
|
<replaceable>boolean-expression</replaceable>
|
|
evaluates to true. The expression is checked just before
|
|
each entry to the loop body.
|
|
</para>
|
|
|
|
<para>
|
|
For example:
|
|
<programlisting>
|
|
WHILE amount_owed > 0 AND gift_certificate_balance > 0 LOOP
|
|
-- some computations here
|
|
END LOOP;
|
|
|
|
WHILE NOT done LOOP
|
|
-- some computations here
|
|
END LOOP;
|
|
</programlisting>
|
|
</para>
|
|
</sect3>
|
|
|
|
<sect3 id="plpgsql-integer-for">
|
|
<title><literal>FOR</> (integer variant)</title>
|
|
|
|
<synopsis>
|
|
<optional> <<<replaceable>label</replaceable>>> </optional>
|
|
FOR <replaceable>name</replaceable> IN <optional> REVERSE </optional> <replaceable>expression</replaceable> .. <replaceable>expression</replaceable> <optional> BY <replaceable>expression</replaceable> </optional> LOOP
|
|
<replaceable>statements</replaceable>
|
|
END LOOP <optional> <replaceable>label</replaceable> </optional>;
|
|
</synopsis>
|
|
|
|
<para>
|
|
This form of <literal>FOR</> creates a loop that iterates over a range
|
|
of integer values. The variable
|
|
<replaceable>name</replaceable> is automatically defined as type
|
|
<type>integer</> and exists only inside the loop (any existing
|
|
definition of the variable name is ignored within the loop).
|
|
The two expressions giving
|
|
the lower and upper bound of the range are evaluated once when entering
|
|
the loop. If the <literal>BY</> clause isn't specified the iteration
|
|
step is 1, otherwise it's the value specified in the <literal>BY</>
|
|
clause, which again is evaluated once on loop entry.
|
|
If <literal>REVERSE</> is specified then the step value is
|
|
subtracted, rather than added, after each iteration.
|
|
</para>
|
|
|
|
<para>
|
|
Some examples of integer <literal>FOR</> loops:
|
|
<programlisting>
|
|
FOR i IN 1..10 LOOP
|
|
-- i will take on the values 1,2,3,4,5,6,7,8,9,10 within the loop
|
|
END LOOP;
|
|
|
|
FOR i IN REVERSE 10..1 LOOP
|
|
-- i will take on the values 10,9,8,7,6,5,4,3,2,1 within the loop
|
|
END LOOP;
|
|
|
|
FOR i IN REVERSE 10..1 BY 2 LOOP
|
|
-- i will take on the values 10,8,6,4,2 within the loop
|
|
END LOOP;
|
|
</programlisting>
|
|
</para>
|
|
|
|
<para>
|
|
If the lower bound is greater than the upper bound (or less than,
|
|
in the <literal>REVERSE</> case), the loop body is not
|
|
executed at all. No error is raised.
|
|
</para>
|
|
|
|
<para>
|
|
If a <replaceable>label</replaceable> is attached to the
|
|
<literal>FOR</> loop then the integer loop variable can be
|
|
referenced with a qualified name, using that
|
|
<replaceable>label</replaceable>.
|
|
</para>
|
|
</sect3>
|
|
</sect2>
|
|
|
|
<sect2 id="plpgsql-records-iterating">
|
|
<title>Looping Through Query Results</title>
|
|
|
|
<para>
|
|
Using a different type of <literal>FOR</> loop, you can iterate through
|
|
the results of a query and manipulate that data
|
|
accordingly. The syntax is:
|
|
<synopsis>
|
|
<optional> <<<replaceable>label</replaceable>>> </optional>
|
|
FOR <replaceable>target</replaceable> IN <replaceable>query</replaceable> LOOP
|
|
<replaceable>statements</replaceable>
|
|
END LOOP <optional> <replaceable>label</replaceable> </optional>;
|
|
</synopsis>
|
|
The <replaceable>target</replaceable> is a record variable, row variable,
|
|
or comma-separated list of scalar variables.
|
|
The <replaceable>target</replaceable> is successively assigned each row
|
|
resulting from the <replaceable>query</replaceable> and the loop body is
|
|
executed for each row. Here is an example:
|
|
<programlisting>
|
|
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.');
|
|
RETURN 1;
|
|
END;
|
|
$$ LANGUAGE plpgsql;
|
|
</programlisting>
|
|
|
|
If the loop is terminated by an <literal>EXIT</> statement, the last
|
|
assigned row value is still accessible after the loop.
|
|
</para>
|
|
|
|
<para>
|
|
The <replaceable>query</replaceable> used in this type of <literal>FOR</>
|
|
statement can be any SQL command that returns rows to the caller:
|
|
<command>SELECT</> is the most common case,
|
|
but you can also use <command>INSERT</>, <command>UPDATE</>, or
|
|
<command>DELETE</> with a <literal>RETURNING</> clause. Some utility
|
|
commands such as <command>EXPLAIN</> will work too.
|
|
</para>
|
|
|
|
<para>
|
|
<application>PL/pgSQL</> variables are substituted into the query text,
|
|
and the query plan is cached for possible re-use, as discussed in
|
|
detail in <xref linkend="plpgsql-var-subst"> and
|
|
<xref linkend="plpgsql-plan-caching">.
|
|
</para>
|
|
|
|
<para>
|
|
The <literal>FOR-IN-EXECUTE</> statement is another way to iterate over
|
|
rows:
|
|
<synopsis>
|
|
<optional> <<<replaceable>label</replaceable>>> </optional>
|
|
FOR <replaceable>target</replaceable> IN EXECUTE <replaceable>text_expression</replaceable> <optional> USING <replaceable>expression</replaceable> <optional>, ...</optional> </optional> LOOP
|
|
<replaceable>statements</replaceable>
|
|
END LOOP <optional> <replaceable>label</replaceable> </optional>;
|
|
</synopsis>
|
|
This is like the previous form, except that the source query
|
|
is specified as a string expression, which is evaluated and replanned
|
|
on each entry to the <literal>FOR</> loop. This allows the programmer to
|
|
choose the speed of a preplanned query or the flexibility of a dynamic
|
|
query, just as with a plain <command>EXECUTE</command> statement.
|
|
As with <command>EXECUTE</command>, parameter values can be inserted
|
|
into the dynamic command via <literal>USING</>.
|
|
</para>
|
|
|
|
<para>
|
|
Another way to specify the query whose results should be iterated
|
|
through is to declare it as a cursor. This is described in
|
|
<xref linkend="plpgsql-cursor-for-loop">.
|
|
</para>
|
|
</sect2>
|
|
|
|
<sect2 id="plpgsql-error-trapping">
|
|
<title>Trapping Errors</title>
|
|
|
|
<indexterm>
|
|
<primary>exceptions</primary>
|
|
<secondary>in PL/PgSQL</secondary>
|
|
</indexterm>
|
|
|
|
<para>
|
|
By default, any error occurring in a <application>PL/pgSQL</>
|
|
function aborts execution of the function, and indeed of the
|
|
surrounding transaction as well. You can trap errors and recover
|
|
from them by using a <command>BEGIN</> block with an
|
|
<literal>EXCEPTION</> clause. The syntax is an extension of the
|
|
normal syntax for a <command>BEGIN</> block:
|
|
|
|
<synopsis>
|
|
<optional> <<<replaceable>label</replaceable>>> </optional>
|
|
<optional> DECLARE
|
|
<replaceable>declarations</replaceable> </optional>
|
|
BEGIN
|
|
<replaceable>statements</replaceable>
|
|
EXCEPTION
|
|
WHEN <replaceable>condition</replaceable> <optional> OR <replaceable>condition</replaceable> ... </optional> THEN
|
|
<replaceable>handler_statements</replaceable>
|
|
<optional> WHEN <replaceable>condition</replaceable> <optional> OR <replaceable>condition</replaceable> ... </optional> THEN
|
|
<replaceable>handler_statements</replaceable>
|
|
... </optional>
|
|
END;
|
|
</synopsis>
|
|
</para>
|
|
|
|
<para>
|
|
If no error occurs, this form of block simply executes all the
|
|
<replaceable>statements</replaceable>, and then control passes
|
|
to the next statement after <literal>END</>. But if an error
|
|
occurs within the <replaceable>statements</replaceable>, further
|
|
processing of the <replaceable>statements</replaceable> is
|
|
abandoned, and control passes to the <literal>EXCEPTION</> list.
|
|
The list is searched for the first <replaceable>condition</replaceable>
|
|
matching the error that occurred. If a match is found, the
|
|
corresponding <replaceable>handler_statements</replaceable> are
|
|
executed, and then control passes to the next statement after
|
|
<literal>END</>. If no match is found, the error propagates out
|
|
as though the <literal>EXCEPTION</> clause were not there at all:
|
|
the error can be caught by an enclosing block with
|
|
<literal>EXCEPTION</>, or if there is none it aborts processing
|
|
of the function.
|
|
</para>
|
|
|
|
<para>
|
|
The <replaceable>condition</replaceable> names can be any of
|
|
those shown in <xref linkend="errcodes-appendix">. A category
|
|
name matches any error within its category. The special
|
|
condition name <literal>OTHERS</> matches every error type except
|
|
<literal>QUERY_CANCELED</>. (It is possible, but often unwise,
|
|
to trap <literal>QUERY_CANCELED</> by name.) Condition names are
|
|
not case-sensitive. Also, an error condition can be specified
|
|
by <literal>SQLSTATE</> code; for example these are equivalent:
|
|
<programlisting>
|
|
WHEN division_by_zero THEN ...
|
|
WHEN SQLSTATE '22012' THEN ...
|
|
</programlisting>
|
|
</para>
|
|
|
|
<para>
|
|
If a new error occurs within the selected
|
|
<replaceable>handler_statements</replaceable>, it cannot be caught
|
|
by this <literal>EXCEPTION</> clause, but is propagated out.
|
|
A surrounding <literal>EXCEPTION</> clause could catch it.
|
|
</para>
|
|
|
|
<para>
|
|
When an error is caught by an <literal>EXCEPTION</> clause,
|
|
the local variables of the <application>PL/pgSQL</> function
|
|
remain as they were when the error occurred, but all changes
|
|
to persistent database state within the block are rolled back.
|
|
As an example, consider this fragment:
|
|
|
|
<programlisting>
|
|
INSERT INTO mytab(firstname, lastname) VALUES('Tom', 'Jones');
|
|
BEGIN
|
|
UPDATE mytab SET firstname = 'Joe' WHERE lastname = 'Jones';
|
|
x := x + 1;
|
|
y := x / 0;
|
|
EXCEPTION
|
|
WHEN division_by_zero THEN
|
|
RAISE NOTICE 'caught division_by_zero';
|
|
RETURN x;
|
|
END;
|
|
</programlisting>
|
|
|
|
When control reaches the assignment to <literal>y</>, it will
|
|
fail with a <literal>division_by_zero</> error. This will be caught by
|
|
the <literal>EXCEPTION</> clause. The value returned in the
|
|
<command>RETURN</> statement will be the incremented value of
|
|
<literal>x</>, but the effects of the <command>UPDATE</> command will
|
|
have been rolled back. The <command>INSERT</> command preceding the
|
|
block is not rolled back, however, so the end result is that the database
|
|
contains <literal>Tom Jones</> not <literal>Joe Jones</>.
|
|
</para>
|
|
|
|
<tip>
|
|
<para>
|
|
A block containing an <literal>EXCEPTION</> clause is significantly
|
|
more expensive to enter and exit than a block without one. Therefore,
|
|
don't use <literal>EXCEPTION</> without need.
|
|
</para>
|
|
</tip>
|
|
|
|
<para>
|
|
Within an exception handler, the <varname>SQLSTATE</varname>
|
|
variable contains the error code that corresponds to the
|
|
exception that was raised (refer to <xref
|
|
linkend="errcodes-table"> for a list of possible error
|
|
codes). The <varname>SQLERRM</varname> variable contains the
|
|
error message associated with the exception. These variables are
|
|
undefined outside exception handlers.
|
|
</para>
|
|
|
|
<example id="plpgsql-upsert-example">
|
|
<title>Exceptions with <command>UPDATE</>/<command>INSERT</></title>
|
|
<para>
|
|
|
|
This example uses exception handling to perform either
|
|
<command>UPDATE</> or <command>INSERT</>, as appropriate:
|
|
|
|
<programlisting>
|
|
CREATE TABLE db (a INT PRIMARY KEY, b TEXT);
|
|
|
|
CREATE FUNCTION merge_db(key INT, data TEXT) RETURNS VOID AS
|
|
$$
|
|
BEGIN
|
|
LOOP
|
|
-- first try to update the key
|
|
UPDATE db SET b = data WHERE a = key;
|
|
IF found THEN
|
|
RETURN;
|
|
END IF;
|
|
-- not there, so try to insert the key
|
|
-- if someone else inserts the same key concurrently,
|
|
-- we could get a unique-key failure
|
|
BEGIN
|
|
INSERT INTO db(a,b) VALUES (key, data);
|
|
RETURN;
|
|
EXCEPTION WHEN unique_violation THEN
|
|
-- do nothing, and loop to try the UPDATE again
|
|
END;
|
|
END LOOP;
|
|
END;
|
|
$$
|
|
LANGUAGE plpgsql;
|
|
|
|
SELECT merge_db(1, 'david');
|
|
SELECT merge_db(1, 'dennis');
|
|
</programlisting>
|
|
|
|
</para>
|
|
</example>
|
|
</sect2>
|
|
</sect1>
|
|
|
|
<sect1 id="plpgsql-cursors">
|
|
<title>Cursors</title>
|
|
|
|
<indexterm zone="plpgsql-cursors">
|
|
<primary>cursor</primary>
|
|
<secondary>in PL/pgSQL</secondary>
|
|
</indexterm>
|
|
|
|
<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 do not normally need
|
|
to worry about that, since <literal>FOR</> loops automatically use a cursor
|
|
internally to avoid memory problems.) A more interesting usage is to
|
|
return a reference to a cursor that a function has created, allowing the
|
|
caller to read the rows. This provides an efficient way to return
|
|
large 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
|
|
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> <optional> <optional> NO </optional> SCROLL </optional> CURSOR <optional> ( <replaceable>arguments</replaceable> ) </optional> FOR <replaceable>query</replaceable>;
|
|
</synopsis>
|
|
(<literal>FOR</> can be replaced by <literal>IS</> for
|
|
<productname>Oracle</productname> compatibility.)
|
|
If <literal>SCROLL</> is specified, the cursor will be capable of
|
|
scrolling backward; if <literal>NO SCROLL</> is specified, backward
|
|
fetches will be rejected; if neither specification appears, it is
|
|
query-dependent whether backward fetches will be allowed.
|
|
<replaceable>arguments</replaceable>, if specified, is a
|
|
comma-separated list of pairs <literal><replaceable>name</replaceable>
|
|
<replaceable>datatype</replaceable></literal> 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 integer) IS SELECT * FROM tenk1 WHERE unique1 = key;
|
|
</programlisting>
|
|
All three of these variables have the data type <type>refcursor</>,
|
|
but the first can 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
|
|
three forms of the <command>OPEN</> statement, two of which use unbound
|
|
cursor variables while the third uses a bound cursor variable.
|
|
</para>
|
|
|
|
<note>
|
|
<para>
|
|
Bound cursors can also be used without explicitly opening them,
|
|
via the <command>FOR</> statement described in
|
|
<xref linkend="plpgsql-cursor-for-loop">.
|
|
</para>
|
|
</note>
|
|
|
|
<sect3>
|
|
<title><command>OPEN FOR</command> <replaceable>query</replaceable></title>
|
|
|
|
<synopsis>
|
|
OPEN <replaceable>unbound_cursor</replaceable> <optional> <optional> NO </optional> SCROLL </optional> FOR <replaceable>query</replaceable>;
|
|
</synopsis>
|
|
|
|
<para>
|
|
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 must be a
|
|
<command>SELECT</command>, or something else that returns rows
|
|
(such as <command>EXPLAIN</>). The query
|
|
is treated in the same way as other SQL commands in
|
|
<application>PL/pgSQL</>: <application>PL/pgSQL</>
|
|
variable names are substituted, and the query plan is cached for
|
|
possible reuse. When a <application>PL/pgSQL</>
|
|
variable is substituted into the cursor query, the value that is
|
|
substituted is the one it has at the time of the <command>OPEN</>;
|
|
subsequent changes to the variable will not affect the cursor's
|
|
behavior.
|
|
The <literal>SCROLL</> and <literal>NO SCROLL</>
|
|
options have the same meanings as for a bound cursor.
|
|
</para>
|
|
|
|
<para>
|
|
An example:
|
|
<programlisting>
|
|
OPEN curs1 FOR SELECT * FROM foo WHERE key = mykey;
|
|
</programlisting>
|
|
</para>
|
|
</sect3>
|
|
|
|
<sect3>
|
|
<title><command>OPEN FOR EXECUTE</command></title>
|
|
|
|
<synopsis>
|
|
OPEN <replaceable>unbound_cursor</replaceable> <optional> <optional> NO </optional> SCROLL </optional> FOR EXECUTE <replaceable class="command">query_string</replaceable>;
|
|
</synopsis>
|
|
|
|
<para>
|
|
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 <command>EXECUTE</command>
|
|
command. As usual, this gives flexibility so the query plan can vary
|
|
from one run to the next (see <xref linkend="plpgsql-plan-caching">),
|
|
and it also means that variable substitution is not done on the
|
|
command string.
|
|
The <literal>SCROLL</> and
|
|
<literal>NO SCROLL</> options have the same meanings as for a bound
|
|
cursor.
|
|
</para>
|
|
|
|
<para>
|
|
An example:
|
|
<programlisting>
|
|
OPEN curs1 FOR EXECUTE 'SELECT * FROM ' || quote_ident($1);
|
|
</programlisting>
|
|
</para>
|
|
</sect3>
|
|
|
|
<sect3>
|
|
<title>Opening a Bound Cursor</title>
|
|
|
|
<synopsis>
|
|
OPEN <replaceable>bound_cursor</replaceable> <optional> ( <replaceable>argument_values</replaceable> ) </optional>;
|
|
</synopsis>
|
|
|
|
<para>
|
|
This form of <command>OPEN</command> 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 <command>EXECUTE</command> in this case.
|
|
Notice that <literal>SCROLL</> and
|
|
<literal>NO SCROLL</> cannot be specified, as the cursor's scrolling
|
|
behavior was already determined.
|
|
</para>
|
|
|
|
<para>
|
|
Note that because variable substitution is done on the bound
|
|
cursor's query, there are two ways to pass values into the cursor:
|
|
either with an explicit argument to <command>OPEN</>, or
|
|
implicitly by referencing a <application>PL/pgSQL</> variable
|
|
in the query. However, only variables declared before the bound
|
|
cursor was declared will be substituted into it. In either case
|
|
the value to be passed is determined at the time of the
|
|
<command>OPEN</>.
|
|
</para>
|
|
|
|
<para>
|
|
Examples:
|
|
<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 so-called 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 usable to reference an open cursor
|
|
only until the end of the transaction.
|
|
</para>
|
|
|
|
<sect3>
|
|
<title><literal>FETCH</></title>
|
|
|
|
<synopsis>
|
|
FETCH <optional> <replaceable>direction</replaceable> { FROM | IN } </optional> <replaceable>cursor</replaceable> INTO <replaceable>target</replaceable>;
|
|
</synopsis>
|
|
|
|
<para>
|
|
<command>FETCH</command> retrieves the next row from the
|
|
cursor into a target, which might be a row variable, a record
|
|
variable, or a comma-separated list of simple variables, just like
|
|
<command>SELECT INTO</command>. If there is no next row, the
|
|
target is set to NULL(s). As with <command>SELECT
|
|
INTO</command>, the special variable <literal>FOUND</literal> can
|
|
be checked to see whether a row was obtained or not.
|
|
</para>
|
|
|
|
<para>
|
|
The <replaceable>direction</replaceable> clause can be any of the
|
|
variants allowed in the SQL <xref linkend="sql-fetch"
|
|
endterm="sql-fetch-title"> command except the ones that can fetch
|
|
more than one row; namely, it can be
|
|
<literal>NEXT</>,
|
|
<literal>PRIOR</>,
|
|
<literal>FIRST</>,
|
|
<literal>LAST</>,
|
|
<literal>ABSOLUTE</> <replaceable>count</replaceable>,
|
|
<literal>RELATIVE</> <replaceable>count</replaceable>,
|
|
<literal>FORWARD</>, or
|
|
<literal>BACKWARD</>.
|
|
Omitting <replaceable>direction</replaceable> is the same
|
|
as specifying <literal>NEXT</>.
|
|
<replaceable>direction</replaceable> values that require moving
|
|
backward are likely to fail unless the cursor was declared or opened
|
|
with the <literal>SCROLL</> option.
|
|
</para>
|
|
|
|
<para>
|
|
<replaceable>cursor</replaceable> must be the name of a <type>refcursor</>
|
|
variable that references an open cursor portal.
|
|
</para>
|
|
|
|
<para>
|
|
Examples:
|
|
<programlisting>
|
|
FETCH curs1 INTO rowvar;
|
|
FETCH curs2 INTO foo, bar, baz;
|
|
FETCH LAST FROM curs3 INTO x, y;
|
|
FETCH RELATIVE -2 FROM curs4 INTO x;
|
|
</programlisting>
|
|
</para>
|
|
</sect3>
|
|
|
|
<sect3>
|
|
<title><literal>MOVE</></title>
|
|
|
|
<synopsis>
|
|
MOVE <optional> <replaceable>direction</replaceable> { FROM | IN } </optional> <replaceable>cursor</replaceable>;
|
|
</synopsis>
|
|
|
|
<para>
|
|
<command>MOVE</command> repositions a cursor without retrieving
|
|
any data. <command>MOVE</command> works exactly like the
|
|
<command>FETCH</command> command, except it only repositions the
|
|
cursor and does not return the row moved to. As with <command>SELECT
|
|
INTO</command>, the special variable <literal>FOUND</literal> can
|
|
be checked to see whether there was a next row to move to.
|
|
</para>
|
|
|
|
<para>
|
|
The options for the <replaceable>direction</replaceable> clause are
|
|
the same as for <command>FETCH</>, namely
|
|
<literal>NEXT</>,
|
|
<literal>PRIOR</>,
|
|
<literal>FIRST</>,
|
|
<literal>LAST</>,
|
|
<literal>ABSOLUTE</> <replaceable>count</replaceable>,
|
|
<literal>RELATIVE</> <replaceable>count</replaceable>,
|
|
<literal>FORWARD</>, or
|
|
<literal>BACKWARD</>.
|
|
Omitting <replaceable>direction</replaceable> is the same
|
|
as specifying <literal>NEXT</>.
|
|
<replaceable>direction</replaceable> values that require moving
|
|
backward are likely to fail unless the cursor was declared or opened
|
|
with the <literal>SCROLL</> option.
|
|
</para>
|
|
|
|
<para>
|
|
Examples:
|
|
<programlisting>
|
|
MOVE curs1;
|
|
MOVE LAST FROM curs3;
|
|
MOVE RELATIVE -2 FROM curs4;
|
|
</programlisting>
|
|
</para>
|
|
</sect3>
|
|
|
|
<sect3>
|
|
<title><literal>UPDATE/DELETE WHERE CURRENT OF</></title>
|
|
|
|
<synopsis>
|
|
UPDATE <replaceable>table</replaceable> SET ... WHERE CURRENT OF <replaceable>cursor</replaceable>;
|
|
DELETE FROM <replaceable>table</replaceable> WHERE CURRENT OF <replaceable>cursor</replaceable>;
|
|
</synopsis>
|
|
|
|
<para>
|
|
When a cursor is positioned on a table row, that row can be updated
|
|
or deleted using the cursor to identify the row. Note that this
|
|
only works for simple (non-join, non-grouping) cursor queries.
|
|
For additional information see the
|
|
<xref linkend="sql-declare" endterm="sql-declare-title">
|
|
reference page.
|
|
</para>
|
|
|
|
<para>
|
|
An example:
|
|
<programlisting>
|
|
UPDATE foo SET dataval = myval WHERE CURRENT OF curs1;
|
|
</programlisting>
|
|
</para>
|
|
</sect3>
|
|
|
|
<sect3>
|
|
<title><literal>CLOSE</></title>
|
|
|
|
<synopsis>
|
|
CLOSE <replaceable>cursor</replaceable>;
|
|
</synopsis>
|
|
|
|
<para>
|
|
<command>CLOSE</command> 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.
|
|
</para>
|
|
|
|
<para>
|
|
An example:
|
|
<programlisting>
|
|
CLOSE curs1;
|
|
</programlisting>
|
|
</para>
|
|
</sect3>
|
|
|
|
<sect3>
|
|
<title>Returning Cursors</title>
|
|
|
|
<para>
|
|
<application>PL/pgSQL</> functions can return cursors to the
|
|
caller. This is useful to return multiple rows or columns,
|
|
especially with very large result sets. To do this, the function
|
|
opens the cursor and returns the cursor name to the caller (or simply
|
|
opens the cursor using a portal name specified by or otherwise known
|
|
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 portal name used for a cursor can be specified by the
|
|
programmer or automatically generated. To specify a portal name,
|
|
simply assign a string to the <type>refcursor</> variable before
|
|
opening it. The string value of the <type>refcursor</> variable
|
|
will be used by <command>OPEN</> as the name of the underlying portal.
|
|
However, if the <type>refcursor</> variable is null,
|
|
<command>OPEN</> automatically generates a name that does not
|
|
conflict with any existing portal, and assigns it to the
|
|
<type>refcursor</> variable.
|
|
</para>
|
|
|
|
<note>
|
|
<para>
|
|
A bound cursor variable is initialized to the string value
|
|
representing its name, so that the portal name is the same as
|
|
the cursor variable name, unless the programmer overrides it
|
|
by assignment before opening the cursor. But an unbound cursor
|
|
variable defaults to the null value initially, so it will receive
|
|
an automatically-generated unique name, unless overridden.
|
|
</para>
|
|
</note>
|
|
|
|
<para>
|
|
The following example shows one way 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
|
|
--------------------
|
|
<unnamed cursor 1>
|
|
(1 row)
|
|
|
|
FETCH ALL IN "<unnamed cursor 1>";
|
|
COMMIT;
|
|
</programlisting>
|
|
</para>
|
|
|
|
<para>
|
|
The following example shows one way to return multiple cursors
|
|
from a single function:
|
|
|
|
<programlisting>
|
|
CREATE FUNCTION myfunc(refcursor, refcursor) RETURNS SETOF refcursor AS $$
|
|
BEGIN
|
|
OPEN $1 FOR SELECT * FROM table_1;
|
|
RETURN NEXT $1;
|
|
OPEN $2 FOR SELECT * FROM table_2;
|
|
RETURN NEXT $2;
|
|
END;
|
|
$$ LANGUAGE plpgsql;
|
|
|
|
-- need to be in a transaction to use cursors.
|
|
BEGIN;
|
|
|
|
SELECT * FROM myfunc('a', 'b');
|
|
|
|
FETCH ALL FROM a;
|
|
FETCH ALL FROM b;
|
|
COMMIT;
|
|
</programlisting>
|
|
</para>
|
|
</sect3>
|
|
</sect2>
|
|
|
|
<sect2 id="plpgsql-cursor-for-loop">
|
|
<title>Looping Through a Cursor's Result</title>
|
|
|
|
<para>
|
|
There is a variant of the <command>FOR</> statement that allows
|
|
iterating through the rows returned by a cursor. The syntax is:
|
|
|
|
<synopsis>
|
|
<optional> <<<replaceable>label</replaceable>>> </optional>
|
|
FOR <replaceable>recordvar</replaceable> IN <replaceable>bound_cursor</replaceable> <optional> ( <replaceable>argument_values</replaceable> ) </optional> LOOP
|
|
<replaceable>statements</replaceable>
|
|
END LOOP <optional> <replaceable>label</replaceable> </optional>;
|
|
</synopsis>
|
|
|
|
The cursor variable must have been bound to some query when it was
|
|
declared, and it <emphasis>cannot</> be open already. The
|
|
<command>FOR</> statement automatically opens the cursor, and it closes
|
|
the cursor again when the loop exits. 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, in just
|
|
the same way as during an <command>OPEN</>.
|
|
The variable <replaceable>recordvar</replaceable> is automatically
|
|
defined as type <type>record</> and exists only inside the loop (any
|
|
existing definition of the variable name is ignored within the loop).
|
|
Each row returned by the cursor is successively assigned to this
|
|
record variable and the loop body is executed.
|
|
</para>
|
|
</sect2>
|
|
|
|
</sect1>
|
|
|
|
<sect1 id="plpgsql-errors-and-messages">
|
|
<title>Errors and Messages</title>
|
|
|
|
<indexterm>
|
|
<primary>RAISE</primary>
|
|
</indexterm>
|
|
|
|
<indexterm>
|
|
<primary>reporting errors</primary>
|
|
<secondary>in PL/PgSQL</secondary>
|
|
</indexterm>
|
|
|
|
<para>
|
|
Use the <command>RAISE</command> statement to report messages and
|
|
raise errors.
|
|
|
|
<synopsis>
|
|
RAISE <optional> <replaceable class="parameter">level</replaceable> </optional> '<replaceable class="parameter">format</replaceable>' <optional>, <replaceable class="parameter">expression</replaceable> <optional>, ...</optional></optional> <optional> USING <replaceable class="parameter">option</replaceable> = <replaceable class="parameter">expression</replaceable> <optional>, ... </optional> </optional>;
|
|
RAISE <optional> <replaceable class="parameter">level</replaceable> </optional> <replaceable class="parameter">condition_name</> <optional> USING <replaceable class="parameter">option</replaceable> = <replaceable class="parameter">expression</replaceable> <optional>, ... </optional> </optional>;
|
|
RAISE <optional> <replaceable class="parameter">level</replaceable> </optional> SQLSTATE '<replaceable class="parameter">sqlstate</>' <optional> USING <replaceable class="parameter">option</replaceable> = <replaceable class="parameter">expression</replaceable> <optional>, ... </optional> </optional>;
|
|
RAISE <optional> <replaceable class="parameter">level</replaceable> </optional> USING <replaceable class="parameter">option</replaceable> = <replaceable class="parameter">expression</replaceable> <optional>, ... </optional>;
|
|
RAISE ;
|
|
</synopsis>
|
|
|
|
The <replaceable class="parameter">level</replaceable> option specifies
|
|
the error severity. Allowed levels are <literal>DEBUG</literal>,
|
|
<literal>LOG</literal>, <literal>INFO</literal>,
|
|
<literal>NOTICE</literal>, <literal>WARNING</literal>,
|
|
and <literal>EXCEPTION</literal>, with <literal>EXCEPTION</literal>
|
|
being the default.
|
|
<literal>EXCEPTION</literal> raises an error (which normally aborts the
|
|
current transaction); the other levels only generate messages of different
|
|
priority levels.
|
|
Whether messages of a particular priority are reported to the client,
|
|
written to the server log, or both is controlled by the
|
|
<xref linkend="guc-log-min-messages"> and
|
|
<xref linkend="guc-client-min-messages"> configuration
|
|
variables. See <xref linkend="runtime-config"> for more
|
|
information.
|
|
</para>
|
|
|
|
<para>
|
|
After <replaceable class="parameter">level</replaceable> if any,
|
|
you can write a <replaceable class="parameter">format</replaceable>
|
|
(which must be a simple string literal, not an expression). The
|
|
format string specifies the error message text to be reported.
|
|
The format string can be followed
|
|
by optional argument expressions to be inserted into the message.
|
|
Inside the format string, <literal>%</literal> is replaced by the
|
|
string representation of the next optional argument's value. Write
|
|
<literal>%%</literal> to emit a literal <literal>%</literal>.
|
|
</para>
|
|
|
|
<para>
|
|
In this example, the value of <literal>v_job_id</> will replace the
|
|
<literal>%</literal> in the string:
|
|
<programlisting>
|
|
RAISE NOTICE 'Calling cs_create_job(%)', v_job_id;
|
|
</programlisting>
|
|
</para>
|
|
|
|
<para>
|
|
You can attach additional information to the error report by writing
|
|
<literal>USING</> followed by <replaceable
|
|
class="parameter">option</replaceable> = <replaceable
|
|
class="parameter">expression</replaceable> items. The allowed
|
|
<replaceable class="parameter">option</replaceable> keywords are
|
|
<literal>MESSAGE</>, <literal>DETAIL</>, <literal>HINT</>, and
|
|
<literal>ERRCODE</>, while each <replaceable
|
|
class="parameter">expression</replaceable> can be any string-valued
|
|
expression.
|
|
<literal>MESSAGE</> sets the error message text (this option can't
|
|
be used in the form of <command>RAISE</> that includes a format
|
|
string before <literal>USING</>).
|
|
<literal>DETAIL</> supplies an error detail message, while
|
|
<literal>HINT</> supplies a hint message.
|
|
<literal>ERRCODE</> specifies the error code (SQLSTATE) to report,
|
|
either by condition name as shown in <xref linkend="errcodes-appendix">,
|
|
or directly as a five-character SQLSTATE code.
|
|
</para>
|
|
|
|
<para>
|
|
This example will abort the transaction with the given error message
|
|
and hint:
|
|
<programlisting>
|
|
RAISE EXCEPTION 'Nonexistent ID --> %', user_id USING HINT = 'Please check your user id';
|
|
</programlisting>
|
|
</para>
|
|
|
|
<para>
|
|
These two examples show equivalent ways of setting the SQLSTATE:
|
|
<programlisting>
|
|
RAISE 'Duplicate user ID: %', user_id USING ERRCODE = 'unique_violation';
|
|
RAISE 'Duplicate user ID: %', user_id USING ERRCODE = '23505';
|
|
</programlisting>
|
|
</para>
|
|
|
|
<para>
|
|
There is a second <command>RAISE</> syntax in which the main argument
|
|
is the condition name or SQLSTATE to be reported, for example:
|
|
<programlisting>
|
|
RAISE division_by_zero;
|
|
RAISE SQLSTATE '22012';
|
|
</programlisting>
|
|
In this syntax, <literal>USING</> can be used to supply a custom
|
|
error message, detail, or hint. Another way to do the earlier
|
|
example is
|
|
<programlisting>
|
|
RAISE unique_violation USING MESSAGE = 'Duplicate user ID: ' || user_id;
|
|
</programlisting>
|
|
</para>
|
|
|
|
<para>
|
|
Still another variant is to write <literal>RAISE USING</> or <literal>RAISE
|
|
<replaceable class="parameter">level</replaceable> USING</> and put
|
|
everything else into the <literal>USING</> list.
|
|
</para>
|
|
|
|
<para>
|
|
The last variant of <command>RAISE</> has no parameters at all.
|
|
This form can only be used inside a <literal>BEGIN</> block's
|
|
<literal>EXCEPTION</> clause;
|
|
it causes the error currently being handled to be re-thrown to the
|
|
next enclosing block.
|
|
</para>
|
|
|
|
<para>
|
|
If no condition name nor SQLSTATE is specified in a
|
|
<command>RAISE EXCEPTION</command> command, the default is to use
|
|
<literal>RAISE_EXCEPTION</> (<literal>P0001</>). If no message
|
|
text is specified, the default is to use the condition name or
|
|
SQLSTATE as message text.
|
|
</para>
|
|
|
|
<note>
|
|
<para>
|
|
When specifying an error code by SQLSTATE code, you are not
|
|
limited to the predefined error codes, but can select any
|
|
error code consisting of five digits and/or upper-case ASCII
|
|
letters, other than <literal>00000</>. It is recommended that
|
|
you avoid throwing error codes that end in three zeroes, because
|
|
these are category codes and can only be trapped by trapping
|
|
the whole category.
|
|
</para>
|
|
</note>
|
|
|
|
</sect1>
|
|
|
|
<sect1 id="plpgsql-trigger">
|
|
<title>Trigger Procedures</title>
|
|
|
|
<indexterm zone="plpgsql-trigger">
|
|
<primary>trigger</primary>
|
|
<secondary>in PL/pgSQL</secondary>
|
|
</indexterm>
|
|
|
|
<para>
|
|
<application>PL/pgSQL</application> can be used to define trigger
|
|
procedures. A trigger procedure is created with the
|
|
<command>CREATE FUNCTION</> command, declaring it 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.
|
|
</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 <command>INSERT</>/<command>UPDATE</> operations in row-level
|
|
triggers. This variable is <symbol>NULL</symbol> in statement-level triggers
|
|
and for <command>DELETE</command> operations.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><varname>OLD</varname></term>
|
|
<listitem>
|
|
<para>
|
|
Data type <type>RECORD</type>; variable holding the old
|
|
database row for <command>UPDATE</>/<command>DELETE</> operations in row-level
|
|
triggers. This variable is <symbol>NULL</symbol> in statement-level triggers
|
|
and for <command>INSERT</command> operations.
|
|
</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>,
|
|
<literal>DELETE</literal>, or <literal>TRUNCATE</>
|
|
telling for which operation the trigger was 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. This is now deprecated, and could disappear in a future
|
|
release. Use <literal>TG_TABLE_NAME</> instead.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><varname>TG_TABLE_NAME</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_TABLE_SCHEMA</varname></term>
|
|
<listitem>
|
|
<para>
|
|
Data type <type>name</type>; the name of the schema 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. Invalid
|
|
indices (less than 0 or greater than or equal to <varname>tg_nargs</>) result in a null value.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
</variablelist>
|
|
</para>
|
|
|
|
<para>
|
|
A trigger function must return either <symbol>NULL</symbol> or a
|
|
record/row value having exactly the structure of the table the
|
|
trigger was fired for.
|
|
</para>
|
|
|
|
<para>
|
|
Row-level triggers fired <literal>BEFORE</> can return null to signal the
|
|
trigger manager to skip the rest of the operation for this row
|
|
(i.e., subsequent triggers are not fired, and the
|
|
<command>INSERT</>/<command>UPDATE</>/<command>DELETE</> does not occur
|
|
for this row). If a nonnull
|
|
value is returned then the operation proceeds with that row value.
|
|
Returning a row value different from the original value
|
|
of <varname>NEW</> alters the row that will be inserted or updated
|
|
(but has no direct effect in the <command>DELETE</> case).
|
|
To alter the row to be stored, it is possible to replace single values
|
|
directly in <varname>NEW</> and return the modified <varname>NEW</>,
|
|
or to build a complete new record/row to return.
|
|
</para>
|
|
|
|
<para>
|
|
The return value of a <literal>BEFORE</> or <literal>AFTER</>
|
|
statement-level trigger or an <literal>AFTER</> row-level trigger is
|
|
always ignored; it might as well be null. However, any of these types of
|
|
triggers might still abort the entire operation by raising an error.
|
|
</para>
|
|
|
|
<para>
|
|
<xref linkend="plpgsql-trigger-example"> shows an example of a
|
|
trigger procedure in <application>PL/pgSQL</application>.
|
|
</para>
|
|
|
|
<example id="plpgsql-trigger-example">
|
|
<title>A <application>PL/pgSQL</application> Trigger Procedure</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 checks that an employee's name is given and that the
|
|
salary is a positive value.
|
|
</para>
|
|
|
|
<programlisting>
|
|
CREATE TABLE emp (
|
|
empname text,
|
|
salary integer,
|
|
last_date timestamp,
|
|
last_user text
|
|
);
|
|
|
|
CREATE FUNCTION emp_stamp() RETURNS trigger AS $emp_stamp$
|
|
BEGIN
|
|
-- Check that empname and salary are given
|
|
IF NEW.empname IS NULL THEN
|
|
RAISE EXCEPTION 'empname cannot be null';
|
|
END IF;
|
|
IF NEW.salary IS NULL THEN
|
|
RAISE EXCEPTION '% cannot have null salary', NEW.empname;
|
|
END IF;
|
|
|
|
-- Who works for us when she must pay for it?
|
|
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 := current_timestamp;
|
|
NEW.last_user := current_user;
|
|
RETURN NEW;
|
|
END;
|
|
$emp_stamp$ LANGUAGE plpgsql;
|
|
|
|
CREATE TRIGGER emp_stamp BEFORE INSERT OR UPDATE ON emp
|
|
FOR EACH ROW EXECUTE PROCEDURE emp_stamp();
|
|
</programlisting>
|
|
</example>
|
|
|
|
<para>
|
|
Another way to log changes to a table involves creating a new table that
|
|
holds a row for each insert, update, or delete that occurs. This approach
|
|
can be thought of as auditing changes to a table.
|
|
<xref linkend="plpgsql-trigger-audit-example"> shows an example of an
|
|
audit trigger procedure in <application>PL/pgSQL</application>.
|
|
</para>
|
|
|
|
<example id="plpgsql-trigger-audit-example">
|
|
<title>A <application>PL/pgSQL</application> Trigger Procedure For Auditing</title>
|
|
|
|
<para>
|
|
This example trigger ensures that any insert, update or delete of a row
|
|
in the <literal>emp</literal> table is recorded (i.e., audited) in the <literal>emp_audit</literal> table.
|
|
The current time and user name are stamped into the row, together with
|
|
the type of operation performed on it.
|
|
</para>
|
|
|
|
<programlisting>
|
|
CREATE TABLE emp (
|
|
empname text NOT NULL,
|
|
salary integer
|
|
);
|
|
|
|
CREATE TABLE emp_audit(
|
|
operation char(1) NOT NULL,
|
|
stamp timestamp NOT NULL,
|
|
userid text NOT NULL,
|
|
empname text NOT NULL,
|
|
salary integer
|
|
);
|
|
|
|
CREATE OR REPLACE FUNCTION process_emp_audit() RETURNS TRIGGER AS $emp_audit$
|
|
BEGIN
|
|
--
|
|
-- Create a row in emp_audit to reflect the operation performed on emp,
|
|
-- make use of the special variable TG_OP to work out the operation.
|
|
--
|
|
IF (TG_OP = 'DELETE') THEN
|
|
INSERT INTO emp_audit SELECT 'D', now(), user, OLD.*;
|
|
RETURN OLD;
|
|
ELSIF (TG_OP = 'UPDATE') THEN
|
|
INSERT INTO emp_audit SELECT 'U', now(), user, NEW.*;
|
|
RETURN NEW;
|
|
ELSIF (TG_OP = 'INSERT') THEN
|
|
INSERT INTO emp_audit SELECT 'I', now(), user, NEW.*;
|
|
RETURN NEW;
|
|
END IF;
|
|
RETURN NULL; -- result is ignored since this is an AFTER trigger
|
|
END;
|
|
$emp_audit$ LANGUAGE plpgsql;
|
|
|
|
CREATE TRIGGER emp_audit
|
|
AFTER INSERT OR UPDATE OR DELETE ON emp
|
|
FOR EACH ROW EXECUTE PROCEDURE process_emp_audit();
|
|
</programlisting>
|
|
</example>
|
|
|
|
<para>
|
|
One use of triggers is to maintain a summary table
|
|
of another table. The resulting summary can be used in place of the
|
|
original table for certain queries — often with vastly reduced run
|
|
times.
|
|
This technique is commonly used in Data Warehousing, where the tables
|
|
of measured or observed data (called fact tables) might be extremely large.
|
|
<xref linkend="plpgsql-trigger-summary-example"> shows an example of a
|
|
trigger procedure in <application>PL/pgSQL</application> that maintains
|
|
a summary table for a fact table in a data warehouse.
|
|
</para>
|
|
|
|
|
|
<example id="plpgsql-trigger-summary-example">
|
|
<title>A <application>PL/pgSQL</application> Trigger Procedure For Maintaining A Summary Table</title>
|
|
|
|
<para>
|
|
The schema detailed here is partly based on the <emphasis>Grocery Store
|
|
</emphasis> example from <emphasis>The Data Warehouse Toolkit</emphasis>
|
|
by Ralph Kimball.
|
|
</para>
|
|
|
|
<programlisting>
|
|
--
|
|
-- Main tables - time dimension and sales fact.
|
|
--
|
|
CREATE TABLE time_dimension (
|
|
time_key integer NOT NULL,
|
|
day_of_week integer NOT NULL,
|
|
day_of_month integer NOT NULL,
|
|
month integer NOT NULL,
|
|
quarter integer NOT NULL,
|
|
year integer NOT NULL
|
|
);
|
|
CREATE UNIQUE INDEX time_dimension_key ON time_dimension(time_key);
|
|
|
|
CREATE TABLE sales_fact (
|
|
time_key integer NOT NULL,
|
|
product_key integer NOT NULL,
|
|
store_key integer NOT NULL,
|
|
amount_sold numeric(12,2) NOT NULL,
|
|
units_sold integer NOT NULL,
|
|
amount_cost numeric(12,2) NOT NULL
|
|
);
|
|
CREATE INDEX sales_fact_time ON sales_fact(time_key);
|
|
|
|
--
|
|
-- Summary table - sales by time.
|
|
--
|
|
CREATE TABLE sales_summary_bytime (
|
|
time_key integer NOT NULL,
|
|
amount_sold numeric(15,2) NOT NULL,
|
|
units_sold numeric(12) NOT NULL,
|
|
amount_cost numeric(15,2) NOT NULL
|
|
);
|
|
CREATE UNIQUE INDEX sales_summary_bytime_key ON sales_summary_bytime(time_key);
|
|
|
|
--
|
|
-- Function and trigger to amend summarized column(s) on UPDATE, INSERT, DELETE.
|
|
--
|
|
CREATE OR REPLACE FUNCTION maint_sales_summary_bytime() RETURNS TRIGGER AS $maint_sales_summary_bytime$
|
|
DECLARE
|
|
delta_time_key integer;
|
|
delta_amount_sold numeric(15,2);
|
|
delta_units_sold numeric(12);
|
|
delta_amount_cost numeric(15,2);
|
|
BEGIN
|
|
|
|
-- Work out the increment/decrement amount(s).
|
|
IF (TG_OP = 'DELETE') THEN
|
|
|
|
delta_time_key = OLD.time_key;
|
|
delta_amount_sold = -1 * OLD.amount_sold;
|
|
delta_units_sold = -1 * OLD.units_sold;
|
|
delta_amount_cost = -1 * OLD.amount_cost;
|
|
|
|
ELSIF (TG_OP = 'UPDATE') THEN
|
|
|
|
-- forbid updates that change the time_key -
|
|
-- (probably not too onerous, as DELETE + INSERT is how most
|
|
-- changes will be made).
|
|
IF ( OLD.time_key != NEW.time_key) THEN
|
|
RAISE EXCEPTION 'Update of time_key : % -> % not allowed', OLD.time_key, NEW.time_key;
|
|
END IF;
|
|
|
|
delta_time_key = OLD.time_key;
|
|
delta_amount_sold = NEW.amount_sold - OLD.amount_sold;
|
|
delta_units_sold = NEW.units_sold - OLD.units_sold;
|
|
delta_amount_cost = NEW.amount_cost - OLD.amount_cost;
|
|
|
|
ELSIF (TG_OP = 'INSERT') THEN
|
|
|
|
delta_time_key = NEW.time_key;
|
|
delta_amount_sold = NEW.amount_sold;
|
|
delta_units_sold = NEW.units_sold;
|
|
delta_amount_cost = NEW.amount_cost;
|
|
|
|
END IF;
|
|
|
|
|
|
-- Insert or update the summary row with the new values.
|
|
<<insert_update>>
|
|
LOOP
|
|
UPDATE sales_summary_bytime
|
|
SET amount_sold = amount_sold + delta_amount_sold,
|
|
units_sold = units_sold + delta_units_sold,
|
|
amount_cost = amount_cost + delta_amount_cost
|
|
WHERE time_key = delta_time_key;
|
|
|
|
EXIT insert_update WHEN found;
|
|
|
|
BEGIN
|
|
INSERT INTO sales_summary_bytime (
|
|
time_key,
|
|
amount_sold,
|
|
units_sold,
|
|
amount_cost)
|
|
VALUES (
|
|
delta_time_key,
|
|
delta_amount_sold,
|
|
delta_units_sold,
|
|
delta_amount_cost
|
|
);
|
|
|
|
EXIT insert_update;
|
|
|
|
EXCEPTION
|
|
WHEN UNIQUE_VIOLATION THEN
|
|
-- do nothing
|
|
END;
|
|
END LOOP insert_update;
|
|
|
|
RETURN NULL;
|
|
|
|
END;
|
|
$maint_sales_summary_bytime$ LANGUAGE plpgsql;
|
|
|
|
CREATE TRIGGER maint_sales_summary_bytime
|
|
AFTER INSERT OR UPDATE OR DELETE ON sales_fact
|
|
FOR EACH ROW EXECUTE PROCEDURE maint_sales_summary_bytime();
|
|
|
|
INSERT INTO sales_fact VALUES(1,1,1,10,3,15);
|
|
INSERT INTO sales_fact VALUES(1,2,1,20,5,35);
|
|
INSERT INTO sales_fact VALUES(2,2,1,40,15,135);
|
|
INSERT INTO sales_fact VALUES(2,3,1,10,1,13);
|
|
SELECT * FROM sales_summary_bytime;
|
|
DELETE FROM sales_fact WHERE product_key = 1;
|
|
SELECT * FROM sales_summary_bytime;
|
|
UPDATE sales_fact SET units_sold = units_sold * 2;
|
|
SELECT * FROM sales_summary_bytime;
|
|
</programlisting>
|
|
</example>
|
|
|
|
</sect1>
|
|
|
|
<sect1 id="plpgsql-implementation">
|
|
<title><application>PL/pgSQL</> Under the Hood</title>
|
|
|
|
<para>
|
|
This section discusses some implementation details that are
|
|
frequently important for <application>PL/pgSQL</> users to know.
|
|
</para>
|
|
|
|
<sect2 id="plpgsql-var-subst">
|
|
<title>Variable Substitution</title>
|
|
|
|
<para>
|
|
When <application>PL/pgSQL</> prepares a SQL statement or expression
|
|
for execution, any <application>PL/pgSQL</application> variable name
|
|
appearing in the statement or expression is replaced by a parameter symbol,
|
|
<literal>$<replaceable>n</replaceable></literal>. The current value
|
|
of the variable is then provided as the value for the parameter whenever
|
|
the statement or expression is executed. As an example, consider the
|
|
function
|
|
<programlisting>
|
|
CREATE FUNCTION logfunc(logtxt text) RETURNS void AS $$
|
|
DECLARE
|
|
curtime timestamp := now();
|
|
BEGIN
|
|
INSERT INTO logtable VALUES (logtxt, curtime);
|
|
END;
|
|
$$ LANGUAGE plpgsql;
|
|
</programlisting>
|
|
The <command>INSERT</> statement will effectively be processed as
|
|
<programlisting>
|
|
PREPARE <replaceable>statement_name</>(text, timestamp) AS
|
|
INSERT INTO logtable VALUES ($1, $2);
|
|
</programlisting>
|
|
followed on each execution by <command>EXECUTE</> with the current
|
|
actual values of the two variables. (Note: here we are speaking of
|
|
the main SQL engine's
|
|
<xref linkend="sql-execute" endterm="sql-execute-title"> command,
|
|
not <application>PL/pgSQL</application>'s <command>EXECUTE</>.)
|
|
</para>
|
|
|
|
<para>
|
|
<emphasis>The substitution mechanism will replace any token that matches a
|
|
known variable's name.</> This poses various traps for the unwary.
|
|
For example, it is a bad idea
|
|
to use a variable name that is the same as any table or column name
|
|
that you need to reference in queries within the function, because
|
|
what you think is a table or column name will still get replaced.
|
|
In the above example, suppose that <structname>logtable</> has
|
|
column names <structfield>logtxt</> and <structfield>logtime</>,
|
|
and we try to write the <command>INSERT</> as
|
|
<programlisting>
|
|
INSERT INTO logtable (logtxt, logtime) VALUES (logtxt, curtime);
|
|
</programlisting>
|
|
This will be fed to the main SQL parser as
|
|
<programlisting>
|
|
INSERT INTO logtable ($1, logtime) VALUES ($1, $2);
|
|
</programlisting>
|
|
resulting in a syntax error like this:
|
|
<screen>
|
|
ERROR: syntax error at or near "$1"
|
|
LINE 1: INSERT INTO logtable ( $1 , logtime) VALUES ( $1 , $2 )
|
|
^
|
|
QUERY: INSERT INTO logtable ( $1 , logtime) VALUES ( $1 , $2 )
|
|
CONTEXT: SQL statement in PL/PgSQL function "logfunc2" near line 5
|
|
</screen>
|
|
</para>
|
|
|
|
<para>
|
|
This example is fairly easy to diagnose, since it leads to an
|
|
obvious syntax error. Much nastier are cases where the substitution
|
|
is syntactically permissible, since the only symptom may be misbehavior
|
|
of the function. In one case, a user wrote something like this:
|
|
<programlisting>
|
|
DECLARE
|
|
val text;
|
|
search_key integer;
|
|
BEGIN
|
|
...
|
|
FOR val IN SELECT val FROM table WHERE key = search_key LOOP ...
|
|
</programlisting>
|
|
and wondered why all his table entries seemed to be NULL. Of course
|
|
what happened here was that the query became
|
|
<programlisting>
|
|
SELECT $1 FROM table WHERE key = $2
|
|
</programlisting>
|
|
and thus it was just an expensive way of assigning <literal>val</>'s
|
|
current value back to itself for each row.
|
|
</para>
|
|
|
|
<para>
|
|
A commonly used coding rule for avoiding such traps is to use a
|
|
different naming convention for <application>PL/pgSQL</application>
|
|
variables than you use for table and column names. For example,
|
|
if all your variables are named
|
|
<literal>v_<replaceable>something</></literal> while none of your
|
|
table or column names start with <literal>v_</>, you're pretty safe.
|
|
</para>
|
|
|
|
<para>
|
|
Another workaround is to use qualified (dotted) names for SQL entities.
|
|
For instance we could safely have written the above example as
|
|
<programlisting>
|
|
FOR val IN SELECT table.val FROM table WHERE key = search_key LOOP ...
|
|
</programlisting>
|
|
because <application>PL/pgSQL</application> will not substitute a
|
|
variable for a trailing component of a qualified name.
|
|
However this solution does not work in every case — you can't
|
|
qualify a name in an <command>INSERT</>'s column name list, for instance.
|
|
Another point is that record and row variable names will be matched to
|
|
the first components of qualified names, so a qualified SQL name is
|
|
still vulnerable in some cases.
|
|
In such cases choosing a non-conflicting variable name is the only way.
|
|
</para>
|
|
|
|
<para>
|
|
Another technique you can use is to attach a label to the block in
|
|
which your variables are declared, and then qualify the variable names
|
|
in your SQL commands (see <xref linkend="plpgsql-structure">).
|
|
For example,
|
|
<programlisting>
|
|
<<pl>>
|
|
DECLARE
|
|
val text;
|
|
BEGIN
|
|
...
|
|
UPDATE table SET col = pl.val WHERE ...
|
|
</programlisting>
|
|
This is not in itself a solution to the problem of conflicts,
|
|
since an unqualified name in a SQL command is still at risk of being
|
|
interpreted the <quote>wrong</> way. But it is useful for clarifying
|
|
the intent of potentially-ambiguous code.
|
|
</para>
|
|
|
|
<para>
|
|
Variable substitution does not happen in the command string given
|
|
to <command>EXECUTE</> or one of its variants. If you need to
|
|
insert a varying value into such a command, do so as part of
|
|
constructing the string value, as illustrated in
|
|
<xref linkend="plpgsql-statements-executing-dyn">.
|
|
</para>
|
|
|
|
<para>
|
|
Variable substitution currently works only in <command>SELECT</>,
|
|
<command>INSERT</>, <command>UPDATE</>, and <command>DELETE</> commands,
|
|
because the main SQL engine allows parameter symbols only in these
|
|
commands. To use a non-constant name or value in other statement
|
|
types (generically called utility statements), you must construct
|
|
the utility statement as a string and <command>EXECUTE</> it.
|
|
</para>
|
|
|
|
</sect2>
|
|
|
|
<sect2 id="plpgsql-plan-caching">
|
|
<title>Plan Caching</title>
|
|
|
|
<para>
|
|
The <application>PL/pgSQL</> interpreter 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
|
|
<application>PL/pgSQL</> statement structure, but individual
|
|
<acronym>SQL</acronym> expressions and <acronym>SQL</acronym> commands
|
|
used in the function are not translated immediately.
|
|
</para>
|
|
|
|
<para>
|
|
As each expression and <acronym>SQL</acronym> command is first
|
|
executed 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).<indexterm><primary>preparing a query</><secondary>in
|
|
PL/pgSQL</></> 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
|
|
<application>PL/pgSQL</> function. A disadvantage is that errors
|
|
in a specific expression or command cannot be detected until that
|
|
part of the function is reached in execution. (Trivial syntax
|
|
errors will be detected during the initial parsing pass, but
|
|
anything deeper will not be detected until execution.)
|
|
</para>
|
|
|
|
<para>
|
|
Once <application>PL/pgSQL</> 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:
|
|
|
|
<programlisting>
|
|
CREATE FUNCTION populate() RETURNS integer AS $$
|
|
DECLARE
|
|
-- declarations
|
|
BEGIN
|
|
PERFORM my_function();
|
|
END;
|
|
$$ LANGUAGE plpgsql;
|
|
</programlisting>
|
|
|
|
If you execute the above function, it will reference the OID for
|
|
<function>my_function()</function> in the execution plan produced for
|
|
the <command>PERFORM</command> statement. Later, if you
|
|
drop and recreate <function>my_function()</function>, then
|
|
<function>populate()</function> will not be able to find
|
|
<function>my_function()</function> anymore. You would then have to
|
|
start a new database session so that <function>populate()</function>
|
|
will be compiled afresh, before it will work again. You can avoid
|
|
this problem by using <command>CREATE OR REPLACE FUNCTION</command>
|
|
when updating the definition of
|
|
<function>my_function</function>, since when a function is
|
|
<quote>replaced</quote>, its OID is not changed.
|
|
</para>
|
|
|
|
<note>
|
|
<para>
|
|
In <productname>PostgreSQL</productname> 8.3 and later, saved plans
|
|
will be replaced whenever any schema changes have occurred to any
|
|
tables they reference. This eliminates one of the major disadvantages
|
|
of saved plans. However, there is no such mechanism for function
|
|
references, and thus the above example involving a reference to a
|
|
deleted function is still valid.
|
|
</para>
|
|
</note>
|
|
|
|
<para>
|
|
Because <application>PL/pgSQL</application> saves execution plans
|
|
in this way, SQL commands that appear directly in a
|
|
<application>PL/pgSQL</application> 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 <application>PL/pgSQL</application> <command>EXECUTE</command>
|
|
statement — at the price of constructing a new execution plan on
|
|
every execution.
|
|
</para>
|
|
|
|
<para>
|
|
Another important point is that the prepared plans are parameterized
|
|
to allow the values of <application>PL/pgSQL</application> variables
|
|
to change from one use to the next, as discussed in detail above.
|
|
Sometimes this means that a plan is less efficient than it would be
|
|
if generated for a specific variable value. As an example, consider
|
|
<programlisting>
|
|
SELECT * INTO myrec FROM dictionary WHERE word LIKE search_term;
|
|
</programlisting>
|
|
where <literal>search_term</> is a <application>PL/pgSQL</application>
|
|
variable. The cached plan for this query will never use an index on
|
|
<structfield>word</>, since the planner cannot assume that the
|
|
<literal>LIKE</> pattern will be left-anchored at run time. To use
|
|
an index the query must be planned with a specific constant
|
|
<literal>LIKE</> pattern provided. This is another situation where
|
|
<command>EXECUTE</command> can be used to force a new plan to be
|
|
generated for each execution.
|
|
</para>
|
|
|
|
<para>
|
|
The mutable nature of record variables presents another 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 from one call of the function to the next, since each
|
|
expression will be planned using the data type that is present
|
|
when the expression is first reached. <command>EXECUTE</command> can be
|
|
used to get around this problem when necessary.
|
|
</para>
|
|
|
|
<para>
|
|
If the same function is used as a trigger for more than one table,
|
|
<application>PL/pgSQL</application> prepares and caches plans
|
|
independently for each such table — that is, there is a cache
|
|
for each trigger function and table combination, not just for each
|
|
function. This alleviates some of the problems with varying
|
|
data types; for instance, a trigger function will be able to work
|
|
successfully with a column named <literal>key</> even if it happens
|
|
to have different types in different tables.
|
|
</para>
|
|
|
|
<para>
|
|
Likewise, functions having polymorphic argument types have a separate
|
|
plan cache for each combination of actual argument types they have been
|
|
invoked for, so that data type differences do not cause unexpected
|
|
failures.
|
|
</para>
|
|
|
|
<para>
|
|
Plan caching can sometimes have surprising effects on the interpretation
|
|
of time-sensitive values. For example there
|
|
is a difference between what these two functions do:
|
|
|
|
<programlisting>
|
|
CREATE FUNCTION logfunc1(logtxt text) RETURNS void AS $$
|
|
BEGIN
|
|
INSERT INTO logtable VALUES (logtxt, 'now');
|
|
END;
|
|
$$ LANGUAGE plpgsql;
|
|
</programlisting>
|
|
|
|
and:
|
|
|
|
<programlisting>
|
|
CREATE FUNCTION logfunc2(logtxt text) RETURNS void AS $$
|
|
DECLARE
|
|
curtime timestamp;
|
|
BEGIN
|
|
curtime := 'now';
|
|
INSERT INTO logtable VALUES (logtxt, curtime);
|
|
END;
|
|
$$ LANGUAGE plpgsql;
|
|
</programlisting>
|
|
</para>
|
|
|
|
<para>
|
|
In the case of <function>logfunc1</function>, the
|
|
<productname>PostgreSQL</productname> main parser knows when
|
|
preparing the plan for the <command>INSERT</command> that the
|
|
string <literal>'now'</literal> should be interpreted as
|
|
<type>timestamp</type>, because the target column of
|
|
<classname>logtable</classname> is of that type. Thus,
|
|
<literal>'now'</literal> will be converted to a constant when the
|
|
<command>INSERT</command> is planned, and then used in all
|
|
invocations of <function>logfunc1</function> during the lifetime
|
|
of the session. Needless to say, this isn't what the programmer
|
|
wanted.
|
|
</para>
|
|
|
|
<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>
|
|
functions for the conversion. So, the computed time stamp is updated
|
|
on each execution as the programmer expects.
|
|
</para>
|
|
|
|
</sect2>
|
|
|
|
</sect1>
|
|
|
|
<sect1 id="plpgsql-development-tips">
|
|
<title>Tips for Developing in <application>PL/pgSQL</application></title>
|
|
|
|
<para>
|
|
One good way to develop in
|
|
<application>PL/pgSQL</> is to use the text editor of your
|
|
choice to create your functions, and in another window, use
|
|
<application>psql</application> to load and test those functions.
|
|
If you are doing it this way, it
|
|
is a good idea to write the function using <command>CREATE OR
|
|
REPLACE FUNCTION</>. That way you can just reload the file to update
|
|
the function definition. For example:
|
|
<programlisting>
|
|
CREATE OR REPLACE FUNCTION testfunc(integer) RETURNS integer AS $$
|
|
....
|
|
$$ LANGUAGE plpgsql;
|
|
</programlisting>
|
|
</para>
|
|
|
|
<para>
|
|
While running <application>psql</application>, you can load or reload such
|
|
a function definition file with:
|
|
<programlisting>
|
|
\i filename.sql
|
|
</programlisting>
|
|
and then immediately issue SQL commands to test the function.
|
|
</para>
|
|
|
|
<para>
|
|
Another good way to develop in <application>PL/pgSQL</> is with a
|
|
GUI database access tool that facilitates development in a
|
|
procedural language. One example of such as a tool is
|
|
<application>pgAdmin</>, although others exist. These tools often
|
|
provide convenient features such as escaping single quotes and
|
|
making it easier to recreate and debug functions.
|
|
</para>
|
|
|
|
<sect2 id="plpgsql-quote-tips">
|
|
<title>Handling of Quotation Marks</title>
|
|
|
|
<para>
|
|
The code of a <application>PL/pgSQL</> function is specified in
|
|
<command>CREATE FUNCTION</command> as a string literal. If you
|
|
write the string literal in the ordinary way with surrounding
|
|
single quotes, then any single quotes inside the function body
|
|
must be doubled; likewise any backslashes must be doubled (assuming
|
|
escape string syntax is used).
|
|
Doubling quotes is at best tedious, and in more complicated cases
|
|
the code can become downright incomprehensible, because you can
|
|
easily find yourself needing half a dozen or more adjacent quote marks.
|
|
It's recommended that you instead write the function body as a
|
|
<quote>dollar-quoted</> string literal (see <xref
|
|
linkend="sql-syntax-dollar-quoting">). In the dollar-quoting
|
|
approach, you never double any quote marks, but instead take care to
|
|
choose a different dollar-quoting delimiter for each level of
|
|
nesting you need. For example, you might write the <command>CREATE
|
|
FUNCTION</command> command as:
|
|
<programlisting>
|
|
CREATE OR REPLACE FUNCTION testfunc(integer) RETURNS integer AS $PROC$
|
|
....
|
|
$PROC$ LANGUAGE plpgsql;
|
|
</programlisting>
|
|
Within this, you might use quote marks for simple literal strings in
|
|
SQL commands and <literal>$$</> to delimit fragments of SQL commands
|
|
that you are assembling as strings. If you need to quote text that
|
|
includes <literal>$$</>, you could use <literal>$Q$</>, and so on.
|
|
</para>
|
|
|
|
<para>
|
|
The following chart shows what you have to do when writing quote
|
|
marks without dollar quoting. It might be useful when translating
|
|
pre-dollar quoting code into something more comprehensible.
|
|
</para>
|
|
|
|
<variablelist>
|
|
<varlistentry>
|
|
<term>1 quotation mark</term>
|
|
<listitem>
|
|
<para>
|
|
To begin and end the function body, for example:
|
|
<programlisting>
|
|
CREATE FUNCTION foo() RETURNS integer AS '
|
|
....
|
|
' LANGUAGE plpgsql;
|
|
</programlisting>
|
|
Anywhere within a single-quoted function body, quote marks
|
|
<emphasis>must</> appear in pairs.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term>2 quotation marks</term>
|
|
<listitem>
|
|
<para>
|
|
For string literals inside the function body, for example:
|
|
<programlisting>
|
|
a_output := ''Blah'';
|
|
SELECT * FROM users WHERE f_name=''foobar'';
|
|
</programlisting>
|
|
In the dollar-quoting approach, you'd just write:
|
|
<programlisting>
|
|
a_output := 'Blah';
|
|
SELECT * FROM users WHERE f_name='foobar';
|
|
</programlisting>
|
|
which is exactly what the <application>PL/pgSQL</> parser would see
|
|
in either case.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term>4 quotation marks</term>
|
|
<listitem>
|
|
<para>
|
|
When you need a single quotation mark in a string constant inside the
|
|
function body, for example:
|
|
<programlisting>
|
|
a_output := a_output || '' AND name LIKE ''''foobar'''' AND xyz''
|
|
</programlisting>
|
|
The value actually appended to <literal>a_output</literal> would be:
|
|
<literal> AND name LIKE 'foobar' AND xyz</literal>.
|
|
</para>
|
|
<para>
|
|
In the dollar-quoting approach, you'd write:
|
|
<programlisting>
|
|
a_output := a_output || $$ AND name LIKE 'foobar' AND xyz$$
|
|
</programlisting>
|
|
being careful that any dollar-quote delimiters around this are not
|
|
just <literal>$$</>.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term>6 quotation marks</term>
|
|
<listitem>
|
|
<para>
|
|
When a single quotation mark in a string inside the function body is
|
|
adjacent to the end of that string constant, for example:
|
|
<programlisting>
|
|
a_output := a_output || '' AND name LIKE ''''foobar''''''
|
|
</programlisting>
|
|
The value appended to <literal>a_output</literal> would then be:
|
|
<literal> AND name LIKE 'foobar'</literal>.
|
|
</para>
|
|
<para>
|
|
In the dollar-quoting approach, this becomes:
|
|
<programlisting>
|
|
a_output := a_output || $$ AND name LIKE 'foobar'$$
|
|
</programlisting>
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term>10 quotation marks</term>
|
|
<listitem>
|
|
<para>
|
|
When you want two single quotation marks in a string constant (which
|
|
accounts for 8 quotation marks) and this is adjacent to the end of that
|
|
string constant (2 more). You will probably only need that if
|
|
you are writing a function that generates other functions, as in
|
|
<xref linkend="plpgsql-porting-ex2">.
|
|
For example:
|
|
<programlisting>
|
|
a_output := a_output || '' if v_'' ||
|
|
referrer_keys.kind || '' like ''''''''''
|
|
|| referrer_keys.key_string || ''''''''''
|
|
then return '''''' || referrer_keys.referrer_type
|
|
|| ''''''; end if;'';
|
|
</programlisting>
|
|
The value of <literal>a_output</literal> would then be:
|
|
<programlisting>
|
|
if v_... like ''...'' then return ''...''; end if;
|
|
</programlisting>
|
|
</para>
|
|
<para>
|
|
In the dollar-quoting approach, this becomes:
|
|
<programlisting>
|
|
a_output := a_output || $$ if v_$$ || referrer_keys.kind || $$ like '$$
|
|
|| referrer_keys.key_string || $$'
|
|
then return '$$ || referrer_keys.referrer_type
|
|
|| $$'; end if;$$;
|
|
</programlisting>
|
|
where we assume we only need to put single quote marks into
|
|
<literal>a_output</literal>, because it will be re-quoted before use.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
</variablelist>
|
|
|
|
</sect2>
|
|
</sect1>
|
|
|
|
<!-- **** Porting from Oracle PL/SQL **** -->
|
|
|
|
<sect1 id="plpgsql-porting">
|
|
<title>Porting from <productname>Oracle</productname> PL/SQL</title>
|
|
|
|
<indexterm zone="plpgsql-porting">
|
|
<primary>Oracle</primary>
|
|
<secondary>porting from PL/SQL to PL/pgSQL</secondary>
|
|
</indexterm>
|
|
|
|
<indexterm zone="plpgsql-porting">
|
|
<primary>PL/SQL (Oracle)</primary>
|
|
<secondary>porting to PL/pgSQL</secondary>
|
|
</indexterm>
|
|
|
|
<para>
|
|
This section explains differences between
|
|
<productname>PostgreSQL</>'s <application>PL/pgSQL</application>
|
|
language and Oracle's <application>PL/SQL</application> language,
|
|
to help developers who port applications from
|
|
<trademark class=registered>Oracle</> to <productname>PostgreSQL</>.
|
|
</para>
|
|
|
|
<para>
|
|
<application>PL/pgSQL</application> is similar to PL/SQL in many
|
|
aspects. It is a block-structured, imperative language, and all
|
|
variables have to be declared. Assignments, loops, conditionals
|
|
are similar. The main differences you should keep in mind when
|
|
porting from <application>PL/SQL</> to
|
|
<application>PL/pgSQL</application> are:
|
|
|
|
<itemizedlist>
|
|
<listitem>
|
|
<para>
|
|
There are no default values for parameters in <productname>PostgreSQL</>.
|
|
</para>
|
|
</listitem>
|
|
|
|
<listitem>
|
|
<para>
|
|
You can overload function names in <productname>PostgreSQL</>. This is
|
|
often used to work around the lack of default parameters.
|
|
</para>
|
|
</listitem>
|
|
|
|
<listitem>
|
|
<para>
|
|
If a name used in a SQL command could be either a column name of a
|
|
table or a reference to a variable of the function,
|
|
<application>PL/SQL</> treats it as a column name, while
|
|
<application>PL/pgSQL</> treats it as a variable name. It's best
|
|
to avoid such ambiguities in the first place, but if necessary you
|
|
can fix them by properly qualifying the ambiguous name.
|
|
(See <xref linkend="plpgsql-var-subst">.)
|
|
</para>
|
|
</listitem>
|
|
|
|
<listitem>
|
|
<para>
|
|
In <productname>PostgreSQL</> the function body must be written as
|
|
a string literal. Therefore you need to use dollar quoting or escape
|
|
single quotes in the function body. (See <xref
|
|
linkend="plpgsql-quote-tips">.)
|
|
</para>
|
|
</listitem>
|
|
|
|
<listitem>
|
|
<para>
|
|
Instead of packages, use schemas to organize your functions
|
|
into groups.
|
|
</para>
|
|
</listitem>
|
|
|
|
<listitem>
|
|
<para>
|
|
Since there are no packages, there are no package-level variables
|
|
either. This is somewhat annoying. You can keep per-session state
|
|
in temporary tables instead.
|
|
</para>
|
|
</listitem>
|
|
|
|
<listitem>
|
|
<para>
|
|
Integer <command>FOR</> loops with <literal>REVERSE</> work
|
|
differently: <application>PL/SQL</> counts down from the second
|
|
number to the first, while <application>PL/pgSQL</> counts down
|
|
from the first number to the second, requiring the loop bounds
|
|
to be swapped when porting. This incompatibility is unfortunate
|
|
but is unlikely to be changed. (See <xref
|
|
linkend="plpgsql-integer-for">.)
|
|
</para>
|
|
</listitem>
|
|
|
|
<listitem>
|
|
<para>
|
|
<command>FOR</> loops over queries (other than cursors) also work
|
|
differently: the target variable(s) must have been declared,
|
|
whereas <application>PL/SQL</> always declares them implicitly.
|
|
An advantage of this is that the variable values are still accessible
|
|
after the loop exits.
|
|
</para>
|
|
</listitem>
|
|
|
|
<listitem>
|
|
<para>
|
|
There are various notational differences for the use of cursor
|
|
variables.
|
|
</para>
|
|
</listitem>
|
|
|
|
</itemizedlist>
|
|
</para>
|
|
|
|
<sect2>
|
|
<title>Porting Examples</title>
|
|
|
|
<para>
|
|
<xref linkend="pgsql-porting-ex1"> shows how to port a simple
|
|
function from <application>PL/SQL</> to <application>PL/pgSQL</>.
|
|
</para>
|
|
|
|
<example id="pgsql-porting-ex1">
|
|
<title>Porting a Simple Function from <application>PL/SQL</> to <application>PL/pgSQL</></title>
|
|
|
|
<para>
|
|
Here is an <productname>Oracle</productname> <application>PL/SQL</> function:
|
|
<programlisting>
|
|
CREATE OR REPLACE FUNCTION cs_fmt_browser_version(v_name varchar,
|
|
v_version 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 compared to
|
|
<application>PL/pgSQL</>:
|
|
|
|
<itemizedlist>
|
|
<listitem>
|
|
<para>
|
|
The <literal>RETURN</literal> key word in the function
|
|
prototype (not the function body) becomes
|
|
<literal>RETURNS</literal> in
|
|
<productname>PostgreSQL</productname>.
|
|
Also, <literal>IS</> becomes <literal>AS</>, and you need to
|
|
add a <literal>LANGUAGE</> clause because <application>PL/pgSQL</>
|
|
is not the only possible function language.
|
|
</para>
|
|
</listitem>
|
|
|
|
<listitem>
|
|
<para>
|
|
In <productname>PostgreSQL</>, the function body is considered
|
|
to be a string literal, so you need to use quote marks or dollar
|
|
quotes around it. This substitutes for the terminating <literal>/</>
|
|
in the Oracle approach.
|
|
</para>
|
|
</listitem>
|
|
|
|
<listitem>
|
|
<para>
|
|
The <literal>show errors</literal> command does not exist in
|
|
<productname>PostgreSQL</>, and is not needed since errors are
|
|
reported automatically.
|
|
</para>
|
|
</listitem>
|
|
</itemizedlist>
|
|
</para>
|
|
|
|
<para>
|
|
This is how this function would look when ported to
|
|
<productname>PostgreSQL</>:
|
|
|
|
<programlisting>
|
|
CREATE OR REPLACE FUNCTION cs_fmt_browser_version(v_name varchar,
|
|
v_version varchar)
|
|
RETURNS varchar AS $$
|
|
BEGIN
|
|
IF v_version IS NULL THEN
|
|
RETURN v_name;
|
|
END IF;
|
|
RETURN v_name || '/' || v_version;
|
|
END;
|
|
$$ LANGUAGE plpgsql;
|
|
</programlisting>
|
|
</para>
|
|
</example>
|
|
|
|
<para>
|
|
<xref linkend="plpgsql-porting-ex2"> shows how to port a
|
|
function that creates another function and how to handle the
|
|
ensuing quoting problems.
|
|
</para>
|
|
|
|
<example id="plpgsql-porting-ex2">
|
|
<title>Porting a Function that Creates Another Function from <application>PL/SQL</> to <application>PL/pgSQL</></title>
|
|
|
|
<para>
|
|
The following procedure grabs rows from a
|
|
<command>SELECT</command> statement and builds a large function
|
|
with the results in <literal>IF</literal> statements, for the
|
|
sake of efficiency.
|
|
</para>
|
|
|
|
<para>
|
|
This is the Oracle version:
|
|
<programlisting>
|
|
CREATE OR REPLACE PROCEDURE cs_update_referrer_type_proc IS
|
|
CURSOR referrer_keys IS
|
|
SELECT * FROM cs_referrer_keys
|
|
ORDER BY try_order;
|
|
func_cmd VARCHAR(4000);
|
|
BEGIN
|
|
func_cmd := '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
|
|
func_cmd := func_cmd ||
|
|
' IF v_' || referrer_key.kind
|
|
|| ' LIKE ''' || referrer_key.key_string
|
|
|| ''' THEN RETURN ''' || referrer_key.referrer_type
|
|
|| '''; END IF;';
|
|
END LOOP;
|
|
|
|
func_cmd := func_cmd || ' RETURN NULL; END;';
|
|
|
|
EXECUTE IMMEDIATE func_cmd;
|
|
END;
|
|
/
|
|
show errors;
|
|
</programlisting>
|
|
</para>
|
|
|
|
<para>
|
|
Here is how this function would end up in <productname>PostgreSQL</>:
|
|
<programlisting>
|
|
CREATE OR REPLACE FUNCTION cs_update_referrer_type_proc() RETURNS void AS $func$
|
|
DECLARE
|
|
CURSOR referrer_keys IS
|
|
SELECT * FROM cs_referrer_keys
|
|
ORDER BY try_order;
|
|
func_body text;
|
|
func_cmd text;
|
|
BEGIN
|
|
func_body := 'BEGIN';
|
|
|
|
FOR referrer_key IN referrer_keys LOOP
|
|
func_body := func_body ||
|
|
' IF v_' || referrer_key.kind
|
|
|| ' LIKE ' || quote_literal(referrer_key.key_string)
|
|
|| ' THEN RETURN ' || quote_literal(referrer_key.referrer_type)
|
|
|| '; END IF;' ;
|
|
END LOOP;
|
|
|
|
func_body := func_body || ' RETURN NULL; END;';
|
|
|
|
func_cmd :=
|
|
'CREATE OR REPLACE FUNCTION cs_find_referrer_type(v_host varchar,
|
|
v_domain varchar,
|
|
v_url varchar)
|
|
RETURNS varchar AS '
|
|
|| quote_literal(func_body)
|
|
|| ' LANGUAGE plpgsql;' ;
|
|
|
|
EXECUTE func_cmd;
|
|
END;
|
|
$func$ LANGUAGE plpgsql;
|
|
</programlisting>
|
|
Notice how the body of the function is built separately and passed
|
|
through <literal>quote_literal</> to double any quote marks in it. This
|
|
technique is needed because we cannot safely use dollar quoting for
|
|
defining the new function: we do not know for sure what strings will
|
|
be interpolated from the <structfield>referrer_key.key_string</> field.
|
|
(We are assuming here that <structfield>referrer_key.kind</> can be
|
|
trusted to always be <literal>host</>, <literal>domain</>, or
|
|
<literal>url</>, but <structfield>referrer_key.key_string</> might be
|
|
anything, in particular it might contain dollar signs.) This function
|
|
is actually an improvement on the Oracle original, because it will
|
|
not generate broken code when <structfield>referrer_key.key_string</> or
|
|
<structfield>referrer_key.referrer_type</> contain quote marks.
|
|
</para>
|
|
</example>
|
|
|
|
<para>
|
|
<xref linkend="plpgsql-porting-ex3"> shows how to port a function
|
|
with <literal>OUT</> parameters and string manipulation.
|
|
<productname>PostgreSQL</> does not have a built-in
|
|
<function>instr</function> function, but you can create one
|
|
using a combination of other
|
|
functions.<indexterm><primary>instr</></indexterm> In <xref
|
|
linkend="plpgsql-porting-appendix"> there is a
|
|
<application>PL/pgSQL</application> implementation of
|
|
<function>instr</function> that you can use to make your porting
|
|
easier.
|
|
</para>
|
|
|
|
<example id="plpgsql-porting-ex3">
|
|
<title>Porting a Procedure With String Manipulation and
|
|
<literal>OUT</> Parameters from <application>PL/SQL</> to
|
|
<application>PL/pgSQL</></title>
|
|
|
|
<para>
|
|
The following <productname>Oracle</productname> PL/SQL procedure is used
|
|
to parse a URL and return several elements (host, path, and query).
|
|
</para>
|
|
|
|
<para>
|
|
This is the Oracle version:
|
|
<programlisting>
|
|
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
|
|
a_pos1 INTEGER;
|
|
a_pos2 INTEGER;
|
|
BEGIN
|
|
v_host := NULL;
|
|
v_path := NULL;
|
|
v_query := NULL;
|
|
a_pos1 := instr(v_url, '//');
|
|
|
|
IF a_pos1 = 0 THEN
|
|
RETURN;
|
|
END IF;
|
|
a_pos2 := instr(v_url, '/', a_pos1 + 2);
|
|
IF a_pos2 = 0 THEN
|
|
v_host := substr(v_url, a_pos1 + 2);
|
|
v_path := '/';
|
|
RETURN;
|
|
END IF;
|
|
|
|
v_host := substr(v_url, a_pos1 + 2, a_pos2 - a_pos1 - 2);
|
|
a_pos1 := instr(v_url, '?', a_pos2 + 1);
|
|
|
|
IF a_pos1 = 0 THEN
|
|
v_path := substr(v_url, a_pos2);
|
|
RETURN;
|
|
END IF;
|
|
|
|
v_path := substr(v_url, a_pos2, a_pos1 - a_pos2);
|
|
v_query := substr(v_url, a_pos1 + 1);
|
|
END;
|
|
/
|
|
show errors;
|
|
</programlisting>
|
|
</para>
|
|
|
|
<para>
|
|
Here is a possible translation into <application>PL/pgSQL</>:
|
|
<programlisting>
|
|
CREATE OR REPLACE FUNCTION 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
|
|
AS $$
|
|
DECLARE
|
|
a_pos1 INTEGER;
|
|
a_pos2 INTEGER;
|
|
BEGIN
|
|
v_host := NULL;
|
|
v_path := NULL;
|
|
v_query := NULL;
|
|
a_pos1 := instr(v_url, '//');
|
|
|
|
IF a_pos1 = 0 THEN
|
|
RETURN;
|
|
END IF;
|
|
a_pos2 := instr(v_url, '/', a_pos1 + 2);
|
|
IF a_pos2 = 0 THEN
|
|
v_host := substr(v_url, a_pos1 + 2);
|
|
v_path := '/';
|
|
RETURN;
|
|
END IF;
|
|
|
|
v_host := substr(v_url, a_pos1 + 2, a_pos2 - a_pos1 - 2);
|
|
a_pos1 := instr(v_url, '?', a_pos2 + 1);
|
|
|
|
IF a_pos1 = 0 THEN
|
|
v_path := substr(v_url, a_pos2);
|
|
RETURN;
|
|
END IF;
|
|
|
|
v_path := substr(v_url, a_pos2, a_pos1 - a_pos2);
|
|
v_query := substr(v_url, a_pos1 + 1);
|
|
END;
|
|
$$ LANGUAGE plpgsql;
|
|
</programlisting>
|
|
|
|
This function could be used like this:
|
|
<programlisting>
|
|
SELECT * FROM cs_parse_url('http://foobar.com/query.cgi?baz');
|
|
</programlisting>
|
|
</para>
|
|
</example>
|
|
|
|
<para>
|
|
<xref linkend="plpgsql-porting-ex4"> shows how to port a procedure
|
|
that uses numerous features that are specific to Oracle.
|
|
</para>
|
|
|
|
<example id="plpgsql-porting-ex4">
|
|
<title>Porting a Procedure from <application>PL/SQL</> to <application>PL/pgSQL</></title>
|
|
|
|
<para>
|
|
The Oracle version:
|
|
|
|
<programlisting>
|
|
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">
|
|
|
|
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<co id="co.plpgsql-porting-commit">
|
|
raise_application_error(-20000, '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);
|
|
|
|
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
|
|
END;
|
|
COMMIT;
|
|
END;
|
|
/
|
|
show errors
|
|
</programlisting>
|
|
</para>
|
|
|
|
<para>
|
|
Procedures like this can easily be converted into <productname>PostgreSQL</>
|
|
functions returning <type>void</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 <command>LOCK TABLE</command> 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 cannot issue <command>COMMIT</> in a
|
|
<application>PL/pgSQL</application> function. The function is
|
|
running within some outer transaction and so <command>COMMIT</>
|
|
would imply terminating the function's execution. However, in
|
|
this particular case it is not necessary anyway, because the lock
|
|
obtained by the <command>LOCK TABLE</command> will be released when
|
|
we raise an error.
|
|
</para>
|
|
</callout>
|
|
</calloutlist>
|
|
</para>
|
|
|
|
<para>
|
|
This is how we could port this procedure to <application>PL/pgSQL</>:
|
|
|
|
<programlisting>
|
|
CREATE OR REPLACE FUNCTION cs_create_job(v_job_id integer) RETURNS void AS $$
|
|
DECLARE
|
|
a_running_job_count integer;
|
|
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
|
|
RAISE EXCEPTION 'Unable to create a new job: a job is currently running';<co id="co.plpgsql-porting-raise">
|
|
END IF;
|
|
|
|
DELETE FROM cs_active_job;
|
|
INSERT INTO cs_active_job(job_id) VALUES (v_job_id);
|
|
|
|
BEGIN
|
|
INSERT INTO cs_jobs (job_id, start_stamp) VALUES (v_job_id, now());
|
|
EXCEPTION
|
|
WHEN unique_violation THEN <co id="co.plpgsql-porting-exception">
|
|
-- don't worry if it already exists
|
|
END;
|
|
END;
|
|
$$ LANGUAGE plpgsql;
|
|
</programlisting>
|
|
|
|
<calloutlist>
|
|
<callout arearefs="co.plpgsql-porting-raise">
|
|
<para>
|
|
The syntax of <literal>RAISE</> is considerably different from
|
|
Oracle's statement, although the basic case <literal>RAISE</>
|
|
<replaceable class="parameter">exception_name</replaceable> works
|
|
similarly.
|
|
</para>
|
|
</callout>
|
|
<callout arearefs="co.plpgsql-porting-exception">
|
|
<para>
|
|
The exception names supported by <application>PL/pgSQL</> are
|
|
different from Oracle's. The set of built-in exception names
|
|
is much larger (see <xref linkend="errcodes-appendix">). There
|
|
is not currently a way to declare user-defined exception names.
|
|
</para>
|
|
</callout>
|
|
</calloutlist>
|
|
|
|
The main functional difference between this procedure and the
|
|
Oracle equivalent is that the exclusive lock on the <literal>cs_jobs</>
|
|
table will be held until the calling transaction completes. Also, if
|
|
the caller later aborts (for example due to an error), the effects of
|
|
this procedure will be rolled back.
|
|
</para>
|
|
</example>
|
|
</sect2>
|
|
|
|
<sect2 id="plpgsql-porting-other">
|
|
<title>Other Things to Watch For</title>
|
|
|
|
<para>
|
|
This section explains a few other things to watch for when porting
|
|
Oracle <application>PL/SQL</> functions to
|
|
<productname>PostgreSQL</productname>.
|
|
</para>
|
|
|
|
<sect3 id="plpgsql-porting-exceptions">
|
|
<title>Implicit Rollback after Exceptions</title>
|
|
|
|
<para>
|
|
In <application>PL/pgSQL</>, when an exception is caught by an
|
|
<literal>EXCEPTION</> clause, all database changes since the block's
|
|
<literal>BEGIN</> are automatically rolled back. That is, the behavior
|
|
is equivalent to what you'd get in Oracle with:
|
|
|
|
<programlisting>
|
|
BEGIN
|
|
SAVEPOINT s1;
|
|
... code here ...
|
|
EXCEPTION
|
|
WHEN ... THEN
|
|
ROLLBACK TO s1;
|
|
... code here ...
|
|
WHEN ... THEN
|
|
ROLLBACK TO s1;
|
|
... code here ...
|
|
END;
|
|
</programlisting>
|
|
|
|
If you are translating an Oracle procedure that uses
|
|
<command>SAVEPOINT</> and <command>ROLLBACK TO</> in this style,
|
|
your task is easy: just omit the <command>SAVEPOINT</> and
|
|
<command>ROLLBACK TO</>. If you have a procedure that uses
|
|
<command>SAVEPOINT</> and <command>ROLLBACK TO</> in a different way
|
|
then some actual thought will be required.
|
|
</para>
|
|
</sect3>
|
|
|
|
<sect3>
|
|
<title><command>EXECUTE</command></title>
|
|
|
|
<para>
|
|
The <application>PL/pgSQL</> version of
|
|
<command>EXECUTE</command> works similarly to the
|
|
<application>PL/SQL</> version, but you have to remember to use
|
|
<function>quote_literal</function> and
|
|
<function>quote_ident</function> as described in <xref
|
|
linkend="plpgsql-statements-executing-dyn">. Constructs of the
|
|
type <literal>EXECUTE 'SELECT * FROM $1';</literal> will not work
|
|
reliably 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: <quote>volatility</> (whether
|
|
the function always returns the same result when given the same
|
|
arguments) and <quote>strictness</quote> (whether the function
|
|
returns null if any argument is null). Consult the <xref
|
|
linkend="sql-createfunction" endterm="sql-createfunction-title">
|
|
reference page for details.
|
|
</para>
|
|
|
|
<para>
|
|
When making use of these optimization attributes, your
|
|
<command>CREATE FUNCTION</command> statement might look something
|
|
like this:
|
|
|
|
<programlisting>
|
|
CREATE FUNCTION foo(...) RETURNS integer AS $$
|
|
...
|
|
$$ LANGUAGE plpgsql STRICT IMMUTABLE;
|
|
</programlisting>
|
|
</para>
|
|
</sect3>
|
|
</sect2>
|
|
|
|
<sect2 id="plpgsql-porting-appendix">
|
|
<title>Appendix</title>
|
|
|
|
<para>
|
|
This section contains the code for a set of Oracle-compatible
|
|
<function>instr</function> functions that you can use to simplify
|
|
your porting efforts.
|
|
</para>
|
|
|
|
<programlisting>
|
|
--
|
|
-- instr functions that mimic Oracle's counterpart
|
|
-- Syntax: instr(string1, string2, [n], [m]) where [] denotes optional parameters.
|
|
--
|
|
-- 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).
|
|
--
|
|
|
|
CREATE FUNCTION instr(varchar, varchar) RETURNS integer AS $$
|
|
DECLARE
|
|
pos integer;
|
|
BEGIN
|
|
pos:= instr($1, $2, 1);
|
|
RETURN pos;
|
|
END;
|
|
$$ LANGUAGE plpgsql STRICT IMMUTABLE;
|
|
|
|
|
|
CREATE FUNCTION instr(string varchar, string_to_search varchar, beg_index integer)
|
|
RETURNS integer AS $$
|
|
DECLARE
|
|
pos integer NOT NULL DEFAULT 0;
|
|
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;
|
|
$$ LANGUAGE plpgsql STRICT IMMUTABLE;
|
|
|
|
|
|
CREATE FUNCTION instr(string varchar, string_to_search varchar,
|
|
beg_index integer, occur_index integer)
|
|
RETURNS integer AS $$
|
|
DECLARE
|
|
pos integer NOT NULL DEFAULT 0;
|
|
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 STRICT IMMUTABLE;
|
|
</programlisting>
|
|
</sect2>
|
|
|
|
</sect1>
|
|
|
|
</chapter>
|