Commit 3d4fda8d authored by Thomas G. Lockhart's avatar Thomas G. Lockhart

New updates from Roberto Mello sent privately today due to email troubles.

parent 937ec006
<!--
$Header: /cvsroot/pgsql/doc/src/sgml/Attic/plsql.sgml,v 2.22 2001/03/09 19:09:00 petere Exp $
$Header: /cvsroot/pgsql/doc/src/sgml/Attic/plsql.sgml,v 2.23 2001/03/17 01:53:22 thomas Exp $
-->
<chapter id="plpgsql">
<title>PL/pgSQL - <acronym>SQL</acronym> Procedural Language</title>
<chapter id="plpgsql">
<title>PL/pgSQL - <acronym>SQL<acronym> Procedural Language</title>
<para>
PL/pgSQL is a loadable procedural language for the
<productname>Postgres</productname> database system.
</para>
<para>
This package was originally written by Jan Wieck.
</para>
<para>
PL/pgSQL is a loadable procedural language for the
<productname>Postgres</productname> database system.
</para>
<para>
This package was originally written by Jan Wieck. This
documentation was re-organized and in part written
by Roberto Mello (rmello@fslc.usu.edu).
</para>
<sect1 id="plpgsql-overview">
<title>Overview</title>
......@@ -64,14 +66,34 @@ $Header: /cvsroot/pgsql/doc/src/sgml/Attic/plsql.sgml,v 2.22 2001/03/09 19:09:00
<para>
For all expressions and <acronym>SQL</acronym> statements used in
the function, the PL/pgSQL bytecode interpreter creates a
prepared execution plan using the <acronym>SPI</acronym> manager's <function>SPI_prepare()</function> and
<function>SPI_saveplan()</function> functions. This is done the first time the individual
prepared execution plan using the <acronym>SPI</acronym> manager's
<function>SPI_prepare()</function> and
<function>SPI_saveplan()</function> functions. This is done the
first time the individual
statement is processed in the PL/pgSQL function. Thus, a function with
conditional code that contains many statements for which execution
plans would be required, will only prepare and save those plans
that are really used during the lifetime of the database
connection.
</para>
<para>
This means that you have to be careful about your user-defined
functions. For example:
<programlisting>
CREATE FUNCTION populate() RETURNS INTEGER AS '
DECLARE
-- Declarations
BEGIN
PERFORM my_function();
END;
' language 'plpgsql';
</programlisting>
If you CREATE the above function, it will reference the ID for
my_function() in its bytecode. Later, if you DROP and re-CREATE
my_function(), populate() will not be able to find my_function()
anymore. You'll have to re-CREATE populate().
</para>
<para>
Because PL/pgSQL saves execution plans in this way, queries that appear
directly in a PL/pgSQL function must refer to the same tables and fields
......@@ -88,6 +110,130 @@ $Header: /cvsroot/pgsql/doc/src/sgml/Attic/plsql.sgml,v 2.22 2001/03/09 19:09:00
create complex conditional computation functions and later use
them to define operators or use them in functional indices.
</para>
<sect2 id="plpgsql-advantages">
<title>Advantages of Using PL/pgSQL</title>
<itemizedlist>
<listitem>
<para>
<xref linkend="plpgsql-advantages-performance">Better performance</xref>
</para>
</listitem>
<listitem>
<para>
<xref linkend="plpgsql-advantages-sqlsupport">SQL Support</xref>
</para>
</listitem>
<listitem>
<para>
<xref linkend="plpgsql-advantages-portability">Portability</xref>
</para>
</listitem>
</itemizedlist>
<sect3 id="plpgsql-advantages-performance">
<title>Better Performance</title>
<para>
<acronym>SQL</acronym> is the language 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 process it,
receive the results, do some computation, then send
other queries to the server. All this incurs inter
process communication and may also incur network
overhead if your client is on a different machine than
the database server.
</para>
<para>
With PL/pgSQL you can group a block of computation and a
series of queries <emphasis>inside</emphasis> the
database server, thus having the power of a procedural
language and the ease of use of SQL, but saving lots of
time because you don't have the whole client/server
communication overhead. Your application will enjoy a
considerable performance increase by using PL/pgSQL.
</para>
</sect3>
<sect3 id="plpgsql-advantages-sqlsupport">
<title>SQL Support</title>
<para>
PL/pgSQL adds the power of a procedural language to the
flexibility and ease of <acronym>SQL</acronym>. With
PL/pgSQL you can use all the datatypes, columns, operators
and functions of SQL.
</para>
</sect3>
<sect3 id="plpgsql-advantages-portability">
<title>Portability</title>
<para>
Because PL/pgSQL functions run inside PostgreSQL, these
functions will run on any platform where PostgreSQL
runs. Thus you can reuse code and have less development costs.
</para>
</sect3>
</sect2>
<sect2 id="plpgsql-overview-developing-in-plpgsql">
<title>Developing in PL/pgSQL</title>
<para>
Developing in PL/pgSQL is pretty straight forward, especially
if you have developed in other database procedural languages,
such as Oracle's PL/SQL. Two good ways of developing in
PL/pgSQL are:
<itemizedlist>
<listitem>
<para>
Using a text editor and reloading the file with <command>psql</command>
</para>
</listitem>
<listitem>
<para>
Using PostgreSQL's GUI Tool: pgaccess
</para>
</listitem>
</itemizedlist>
</para>
<para>
One good way to develop in PL/pgSQL is to simply use the text
editor of your choice to create your functions, and in another
console, use <command>psql</command> (PostgreSQL's interactive monitor) to load
those functions. If you are doing it this way (and if you are
a PL/pgSQL novice or in debugging stage), it is a good idea to
always <command>DROP</command> your function before creating it. That way
when you reload the file, it'll drop your functions and then
re-create them. For example:
</para>
<para>
<programlisting>
drop function testfunc(integer);
create function testfunc(integer) return integer as '
....
end;
' language 'plpgsql';
</programlisting>
When you load the file for the first time,
<productname>PostgreSQL</> will raise a warning saying this
function doesn't exist and go on to create it. To load an SQL
file (filename.sql) into a database named "dbname", use the command:
</para>
<para>
<programlisting>
psql -f filename.sql dbname
</programlisting>
Another good way to develop in PL/pgSQL is using
<productname>PostgreSQL</>'s GUI tool: pgaccess. It does some
nice things for you, like escaping single-quotes, and making
it easy to recreate and debug functions.
</para>
</sect2>
</sect1>
<!-- **** PL/pgSQL Description **** -->
......@@ -101,30 +247,50 @@ $Header: /cvsroot/pgsql/doc/src/sgml/Attic/plsql.sgml,v 2.22 2001/03/09 19:09:00
<title>Structure of PL/pgSQL</title>
<para>
The PL/pgSQL language is case insensitive. All keywords and
identifiers can be used in mixed upper- and lower-case.
</para>
<para>
PL/pgSQL is a block oriented language. A block is defined as
PL/pgSQL is a <emphasis>block structured</emphasis>, case
insensitive language. All keywords and identifiers can be
used in mixed upper- and lower-case. A block is defined as:
</para>
<synopsis>
<synopsis>
<optional>&lt;&lt;label&gt;&gt;</optional>
<optional>DECLARE
<replaceable>declarations</replaceable></optional>
BEGIN
<replaceable>statements</replaceable>
END;
</synopsis>
</para>
</synopsis>
<para>
There can be any number of sub-blocks in the statement section
of a block. Sub-blocks can be used to hide variables from outside a
block of statements. The variables
declared in the declarations section preceding a block are
initialized to their default values every time the block is entered,
not only once per function call.
block of statements.
</para>
<para>
The variables declared in the declarations section preceding a
block are initialized to their default values every time the
block is entered, not only once per function call. For example:
</para>
<programlisting>
CREATE FUNCTION somefunc() RETURNS INTEGER AS '
DECLARE
quantity INTEGER := 30;
BEGIN
RAISE NOTICE ''Quantity here is %'',quantity; -- Quantity here is 30
quantity := 50;
--
-- Create a sub-block
--
DECLARE
quantity INTEGER := 80;
BEGIN
RAISE NOTICE ''Quantity here is %'',quantity; -- Quantity here is 80
END;
RAISE NOTICE ''Quantity here is %'',quantity; -- Quantity here is 50
END;
' language 'plpgsql';
</programlisting>
<para>
It is important not to confuse the use of BEGIN/END for
......@@ -150,178 +316,209 @@ END;
</para>
</sect2>
<!-- **** PL/pgSQL declarations **** -->
<!-- **** PL/pgSQL Variables and Constants **** -->
<sect2>
<title>Declarations</title>
<title>Variables and Constants</title>
<para>
All variables, rows and records used in a block or its
sub-blocks must be declared in the declarations section of a block,
except for the loop variable of a FOR-loop iterating over a range
of integer values. Parameters given to a PL/pgSQL function are
automatically declared with the usual identifiers <literal>$1</literal>, <literal>$2</literal>, etc.
The declarations have the following syntax:
sub-blocks must be declared in the declarations section of a block.
The exception being the loop variable of a FOR loop iterating over a range
of integer values.
</para>
<para>
PL/pgSQL variables can have any SQL datatype, such as
<type>INTEGER</type>, <type>VARCHAR</type> and
<type>CHAR</type>. All variables have as default value the
<acronym>SQL</acronym> NULL value.
</para>
<variablelist>
<para>
Here are some examples of variable declarations:
</para>
<programlisting>
user_id INTEGER;
quantity NUMBER(5);
url VARCHAR;
</programlisting>
<sect3 id="plpgsql-description-default-vars">
<title>Constants and Variables With Default Values</title>
<para>
The declarations have the following syntax:
</para>
<synopsis>
<replaceable>name</replaceable> <optional> CONSTANT </optional> <replaceable>type</replaceable> <optional> NOT NULL </optional> <optional> { DEFAULT | := } <replaceable>value</replaceable> </optional>;
</synopsis>
<para>
The value of variables declared as CONSTANT cannot be changed. If NOT NULL
is specified, an assignment of a NULL value results in a runtime
error. Since the default value of all variables is the
<acronym>SQL</acronym> NULL value, all variables declared as NOT NULL
must also have a default value specified.
</para>
<para>
The default value is evaluated every time the function is called. So
assigning '<literal>now</literal>' to a variable of type
<type>timestamp</type> causes the variable to have the
time of the actual function call, not when the function was
precompiled into its bytecode.
</para>
<para>
Examples:
</para>
<programlisting>
quantity INTEGER := 32;
url varchar := ''http://mysite.com'';
user_id CONSTANT INTEGER := 10;
</programlisting>
</sect3>
<sect3 id="plpgsql-description-passed-vars">
<title>Variables Passed to Functions</title>
<para>
Variables passed to functions are named with the identifiers
<literal>$1</literal>, <literal>$2</literal>,
etc. (maximum is 16). Some examples:
</para>
<programlisting>
CREATE FUNCTION sales_tax(REAL) RETURNS REAL AS '
DECLARE
subtotal ALIAS FOR $1;
BEGIN
return subtotal * 0.06;
END;
' language 'plpgsql';
<varlistentry>
<term>
<replaceable>name</replaceable> <optional> CONSTANT </optional>
<replaceable>type</replaceable> <optional> NOT NULL </optional> <optional> DEFAULT | :=
<replaceable>value</replaceable> </optional>;
</term>
<listitem>
<para>
Declares a variable of the specified base type. If the variable
is declared as CONSTANT, the value cannot be changed. If NOT NULL
is specified, an assignment of a NULL value results in a runtime
error. Since the default value of all variables is the
<acronym>SQL</acronym> NULL value, all variables declared as NOT NULL
must also have a default value specified.
</para>
<para>
The default value is evaluated every time the block is entered. So
assigning <literal>'now'</literal> to a variable of type
<type>timestamp</type> causes the variable to have the
time of the actual function call, not when the function was
precompiled into its bytecode.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term>
<replaceable>name</replaceable> <replaceable>table</replaceable>%ROWTYPE;
</term>
<listitem>
<para>
Declares a row with the structure of the given table. <replaceable>table</replaceable> must be
an existing table or view name of the database. The fields of the row
are accessed in the dot notation. Parameters to a function can
be composite types (complete table rows). In that case, the
corresponding identifier $n will be a rowtype, but it
must be aliased using the ALIAS command described below. Only the user
attributes of a table row are accessible in the row, no Oid or other
system attributes (because the row could be from a view and view rows
don't have useful system attributes).
</para>
<para>
The fields of the rowtype inherit the table's field sizes
or precision for <type>char()</type> etc. data types.
</para>
</listitem>
</varlistentry>
CREATE FUNCTION instr(VARCHAR,INTEGER) RETURNS INTEGER AS '
DECLARE
v_string ALIAS FOR $1;
index ALIAS FOR $2;
BEGIN
-- Some computations here
END;
' language 'plpgsql';
</programlisting>
</sect3>
<sect3 id="plpgsql-description-attributes">
<title>Attributes</title>
<para>
Using the <type>%TYPE</type> and <type>%ROWTYPE</type>
attributes, you can declare variables with the same
datatype or structure of another database item (e.g: a
table field).
</para>
<variablelist>
<varlistentry>
<term>
%TYPE
</term>
<listitem>
<para>
<type>%TYPE</type> provides the datatype of a
variable or database column. You can use this to
declare variables that will hold database
values. For example, let's say you have a column
named <type>user_id</type> in your
<type>users</type> table. To declare a variable with
the same datatype as users you do:
</para>
<programlisting>
user_id users.user_id%TYPE;
</programlisting>
<para>
By using <type>%TYPE</type> you don't need to know
the datatype of the structure you are referencing,
and most important, if the datatype of the
referenced item changes in the future (e.g: you
change your table definition of user_id to become a
REAL), you won't need to change your function
definition.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term>
<replaceable>name</replaceable> <replaceable>table</replaceable>%ROWTYPE;
</term>
<listitem>
<para>
Declares a row with the structure of the given table. <replaceable>table</replaceable> must be
an existing table or view name of the database. The fields of the row
are accessed in the dot notation. Parameters to a function can
be composite types (complete table rows). In that case, the
corresponding identifier $n will be a rowtype, but it
must be aliased using the ALIAS command described above.
</para>
<para>
Only the user
attributes of a table row are accessible in the row, no OID or other
system attributes (because the row could be from a view).
The fields of the rowtype inherit the table's field sizes
or precision for <type>char()</type> etc. data types.
</para>
<programlisting>
DECLARE
users_rec users%ROWTYPE;
user_id users%TYPE;
BEGIN
user_id := users_rec.user_id;
...
<varlistentry>
<term>
<replaceable>name</replaceable> RECORD;
</term>
<listitem>
<para>
Records are similar to rowtypes, but they have no predefined structure.
They are used in selections and FOR loops to hold one actual
database row from a SELECT operation. One and the same record can be
used in different selections. Accessing a record or an attempt to assign
a value to a record field when there is no actual row in it results
in a runtime error.
</para>
<para>
The NEW and OLD rows in a trigger are given to the procedure as
records. This is necessary because in <productname>Postgres</productname>
one and the same trigger procedure can handle trigger events for
different tables.
</para>
</listitem>
</varlistentry>
create function cs_refresh_one_mv(integer) returns integer as '
DECLARE
key ALIAS FOR $1;
table_data cs_materialized_views%ROWTYPE;
BEGIN
SELECT INTO table_data * FROM cs_materialized_views
WHERE sort_key=key;
IF NOT FOUND THEN
RAISE EXCEPTION ''View '' || key || '' not found'';
RETURN 0;
END IF;
<varlistentry>
<term>
<replaceable>name</replaceable> ALIAS FOR $n;
</term>
<listitem>
<para>
For better readability of the code it is possible to define an alias
for a positional parameter to a function.
</para>
<para>
This aliasing is required for composite types given as arguments to
a function. The dot notation $1.salary as in <acronym>SQL</acronym> functions is not
allowed in PL/pgSQL.
</para>
</listitem>
</varlistentry>
-- The mv_name column of cs_materialized_views stores view
-- names.
TRUNCATE TABLE table_data.mv_name;
INSERT INTO table_data.mv_name || '' '' || table_data.mv_query;
<varlistentry>
<term>
return 1;
end;
' language 'plpgsql';
</programlisting>
</listitem>
</varlistentry>
</variablelist>
</sect3>
<sect3 id="plpgsql-description-remaning-vars">
<title>
RENAME
</title>
<para>
Using RENAME you can change the name of a variable, record
or row. This is useful if NEW or OLD should be referenced
by another name inside a trigger procedure.
</para>
<para>
Syntax and examples:
</para>
<programlisting>
RENAME <replaceable>oldname</replaceable> TO <replaceable>newname</replaceable>;
</term>
<listitem>
<para>
Change the name of a variable, record or row. This is useful
if NEW or OLD should be referenced by another name inside a
trigger procedure.
</para>
</listitem>
</varlistentry>
</variablelist>
</sect2>
<!-- **** PL/pgSQL data types **** -->
<sect2>
<title>Data Types</title>
<para>
The type of a variable can be any of the existing base types of
the database. <replaceable>type</replaceable> in the declarations
section above is defined as:
</para>
<para>
<itemizedlist>
<listitem>
<para>
<productname>Postgres</productname>-basetype
</para>
</listitem>
<listitem>
<para>
<replaceable>variable</replaceable>%TYPE
</para>
</listitem>
<listitem>
<para>
<replaceable>table.field</replaceable>%TYPE
</para>
</listitem>
</itemizedlist>
</para>
<para>
<replaceable>variable</replaceable> is the name of a variable,
previously declared in the
same function, that is visible at this point.
</para>
<para>
<replaceable>table</replaceable> is the name of an existing table
or view where <replaceable>field</replaceable> is the name of
an attribute.
</para>
<para>
Using the <replaceable>table.field</replaceable>%TYPE
causes PL/pgSQL to look up the attributes definitions at the
first call to the function during the lifetime of a backend.
Suppose we have a table with a <type>char(20)</type> attribute and some PL/pgSQL functions
that deal with its content in local variables. Now someone
decides that <type>char(20)</type> is not enough, dumps the table, drops it,
recreates it now with the attribute in question defined as
<type>char(40)</type> and restores the data. Hah - he forgot about the
functions. The computations inside them will truncate the values
to 20 characters. But if they are defined using the
<replaceable>table.field</replaceable>%TYPE
declarations, they will automagically handle the size change or
if the new table schema defines the attribute as <type>text</type> type.
</para>
RENAME id TO user_id;
RENAME this_var TO that_var;
</programlisting>
</sect3>
</sect2>
<!-- **** PL/pgSQL expressions **** -->
......@@ -332,14 +529,15 @@ RENAME <replaceable>oldname</replaceable> TO <replaceable>newname</replaceable>;
<para>
All expressions used in PL/pgSQL statements are processed using
the backend's executor. Expressions that appear to contain
constants may in fact require runtime evaluation (e.g., <literal>'now'</literal> for the
constants may in fact require run-time evaluation
(e.g. <literal>'now'</literal> for the
<type>timestamp</type> type) so
it is impossible for the PL/pgSQL parser
to identify real constant values other than the NULL keyword. All
expressions are evaluated internally by executing a query
<synopsis>
<synopsis>
SELECT <replaceable>expression</replaceable>
</synopsis>
</synopsis>
using the <acronym>SPI</acronym> manager. In the expression, occurrences of variable
identifiers are substituted by parameters and the actual values from
the variables are passed to the executor in the parameter array. All
......@@ -351,9 +549,9 @@ SELECT <replaceable>expression</replaceable>
The type checking done by the <productname>Postgres</productname>
main parser has some side
effects to the interpretation of constant values. In detail there
is a difference between what the two functions
is a difference between what these two functions do:
<programlisting>
<programlisting>
CREATE FUNCTION logfunc1 (text) RETURNS timestamp AS '
DECLARE
logtxt ALIAS FOR $1;
......@@ -362,11 +560,11 @@ CREATE FUNCTION logfunc1 (text) RETURNS timestamp AS '
RETURN ''now'';
END;
' LANGUAGE 'plpgsql';
</programlisting>
</programlisting>
and
<programlisting>
<programlisting>
CREATE FUNCTION logfunc2 (text) RETURNS timestamp AS '
DECLARE
logtxt ALIAS FOR $1;
......@@ -377,26 +575,28 @@ CREATE FUNCTION logfunc2 (text) RETURNS timestamp AS '
RETURN curtime;
END;
' LANGUAGE 'plpgsql';
</programlisting>
do. In the case of <function>logfunc1()</function>, the
<productname>Postgres</productname> main parser knows when
preparing the plan for the INSERT, that the string
<literal>'now'</literal> should be interpreted as
<type>timestamp</type> because the target field of logtable is of
that type. Thus, it will make a constant from it at this time and
this constant value is then used in all invocations of
</programlisting>
In the case of <function>logfunc1()</function>, the
<productname>Postgres</productname> main parser knows when
preparing the plan for the INSERT, that the string
<literal>'now'</literal> should be interpreted as
<type>timestamp</type> because the target field of logtable
is of that type. Thus, it will make a constant from it at this
time and this constant value is then used in all invocations of
<function>logfunc1()</function> during the lifetime of the
backend. Needless to say that this isn't what the programmer
wanted.
backend. Needless to say that this isn't what the
programmer wanted.
</para>
<para>
In the case of <function>logfunc2()</function>, the <productname>Postgres</productname>
main parser does not know
what type <literal>'now'</literal> should become and therefore it returns a data type of
<type>text</type> containing the string <literal>'now'</literal>. During the assignment
In the case of <function>logfunc2()</function>, the
<productname>Postgres</productname> main parser does not know
what type <literal>'now'</literal> should become and therefore
it returns a data type of <type>text</type> containing the string
<literal>'now'</literal>. During the assignment
to the local variable curtime, the PL/pgSQL interpreter casts this
string to the timestamp type by calling the <function>text_out()</function> and <function>timestamp_in()</function>
string to the timestamp type by calling the
<function>text_out()</function> and <function>timestamp_in()</function>
functions for the conversion.
</para>
<para>
......@@ -418,100 +618,93 @@ CREATE FUNCTION logfunc2 (text) RETURNS timestamp AS '
<!-- **** PL/pgSQL statements **** -->
<sect2 id="plpgsql-statements">
<title>Statements</title>
<sect2>
<title>Statements</title>
<para>
Anything not understood by the PL/pgSQL parser as specified below
will be put into a query and sent down to the database engine
to execute. The resulting query should not return any data.
</para>
<sect3 id="plpgsql-statements-assignment">
<title>Assignment</title>
<para>
Anything not understood by the PL/pgSQL parser as specified below
will be put into a query and sent down to the database engine
to execute. The resulting query should not return any data.
</para>
<variablelist>
<varlistentry>
<term>Assignment</term>
<listitem>
<para>
An assignment of a value to a variable or row/record field is
written as
<synopsis>
An assignment of a value to a variable or row/record field is
written as:
<synopsis>
<replaceable>identifier</replaceable> := <replaceable>expression</replaceable>;
</synopsis>
If the expressions result data type doesn't match the variables
data type, or the variable has a size/precision that is known
(as for <type>char(20)</type>), the result value will be implicitly cast by
the PL/pgSQL bytecode interpreter using the result types output- and
the variables type input-functions. Note that this could potentially
result in runtime errors generated by the types input functions.
</para>
<para>
An assignment of a complete selection into a record or row can
be done by
<synopsis>
SELECT INTO <replaceable>target</replaceable> <replaceable>expressions</replaceable> FROM ...;
</synopsis>
<replaceable>target</replaceable> can be a record, a row variable or a
comma separated list of variables and record-/row-fields. Note that
this is quite different from Postgres' normal interpretation of
SELECT INTO, which is that the INTO target is a newly created table.
(If you want to create a table from a SELECT result inside a PL/pgSQL
function, use the equivalent syntax CREATE TABLE AS SELECT.)
</para>
<para>
if a row or a variable list is used as target, the selected values
must exactly match the structure of the target(s) or a runtime error
occurs. The FROM keyword can be followed by any valid qualification,
grouping, sorting etc. that can be given for a SELECT statement.
</para>
<para>
There is a special variable named FOUND of type <type>boolean</type> that can be used
immediately after a SELECT INTO to check if an assignment had success.
</synopsis>
If the expressions result data type doesn't match the variables
data type, or the variable has a size/precision that is known
(as for <type>char(20)</type>), the result value will be implicitly casted by
the PL/pgSQL bytecode interpreter using the result types output- and
the variables type input-functions. Note that this could potentially
result in runtime errors generated by the types input functions.
</para>
<programlisting>
SELECT INTO myrec * FROM EMP WHERE empname = myname;
IF NOT FOUND THEN
RAISE EXCEPTION ''employee % not found'', myname;
END IF;
</programlisting>
<programlisting>
user_id := 20;
tax := subtotal * 0.06;
</programlisting>
</sect3>
If the selection returns multiple rows, only the first is moved
into the target fields. All others are silently discarded.
</para>
</listitem>
</varlistentry>
<sect3 id="plpgsql-statements-calling-other-funcs">
<title>Calling another function</title>
<varlistentry>
<term>Calling another function</term>
<listitem>
<para>
All functions defined in a <productname>Postgres</productname>
database return a value. Thus, the normal way to call a function
is to execute a SELECT query or doing an assignment (resulting
in a PL/pgSQL internal SELECT). But there are cases where someone
is not interested in the function's result.
<synopsis>
<para>
All functions defined in a <productname>Postgres</productname>
database return a value. Thus, the normal way to call a function
is to execute a SELECT query or doing an assignment (resulting
in a PL/pgSQL internal SELECT).
</para>
<para>
But there are cases where someone is not interested in the
function's result. In these cases, use the PERFORM
statement.
</para>
<synopsis>
PERFORM <replaceable>query</replaceable>
</synopsis>
executes a <literal>SELECT <replaceable>query</replaceable></literal> over the
<acronym>SPI</acronym> manager and discards the result. Identifiers like local
variables are still substituted into parameters.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term>Executing dynamic queries</term>
<listitem>
<para>
<synopsis>
</synopsis>
<para>
executes a <literal>SELECT <replaceable>query</replaceable></literal> over the
<acronym>SPI manager</acronym> and discards the result. Identifiers like local
variables are still substituted into parameters.
</para>
<programlisting>
PERFORM create_mv(''cs_session_page_requests_mv'',''
select session_id, page_id, count(*) as n_hits,
sum(dwell_time) as dwell_time, count(dwell_time) as dwell_count
from cs_fact_table
group by session_id, page_id '');
</programlisting>
</sect3>
<sect3 id="plpgsql-statements-executing-dyn-queries">
<title>Executing dynamic queries</title>
<para>
Often times you will want to generate dynamic queries inside
your PL/pgSQL functions. Or you have functions that will
generate other functions. PL/pgSQL provides the EXECUTE
statement for these occasions.
</para>
<para>
<synopsis>
EXECUTE <replaceable class="command">query-string</replaceable>
</synopsis>
where <replaceable>query-string</replaceable> is a string of
type <type>text</type> containing the <replaceable>query</replaceable> to be
executed.
</synopsis>
where <replaceable>query-string</replaceable> is a string of
type <type>text</type> containing the <replaceable>query</replaceable> to be
executed.
</para>
<para>
When working with dynamic queries you will have to face
escaping of single quotes in PL/pgSQL. Please refer to the
table available at the "Porting from Oracle PL/SQL" chapter
for a detailed explanation that will save you some effort.
</para>
<para>
Unlike all other queries in PL/pgSQL, a
<replaceable>query</replaceable> run by an EXECUTE statement
......@@ -522,325 +715,566 @@ EXECUTE <replaceable class="command">query-string</replaceable>
within the procedure to perform actions on variable tables and
fields.
</para>
<para>
The results from SELECT queries are discarded by EXECUTE, and
SELECT INTO is not currently supported within EXECUTE. So, the
only way to extract a result from a dynamically-created SELECT
is to use the FOR ... EXECUTE form described later.
The results from SELECT queries are discarded by EXECUTE, and
SELECT INTO is not currently supported within EXECUTE. So, the
only way to extract a result from a dynamically-created SELECT
is to use the FOR ... EXECUTE form described later.
</para>
<para>
An example:
<programlisting>
<synopsis>
EXECUTE ''UPDATE tbl SET ''
|| quote_ident(fieldname)
|| '' = ''
|| quote_literal(newvalue)
|| '' WHERE ...'';
</programlisting>
This example shows use of the functions
<function>quote_ident</function>(<type>TEXT</type>) and
<function>quote_literal</function>(<type>TEXT</type>).
Variables containing field and table identifiers should be
passed to function <function>quote_ident()</function>.
Variables containing literal elements of the dynamic query
string should be passed to
<function>quote_literal()</function>. Both take the
appropriate steps to return the input text enclosed in single
or double quotes and with any embedded special characters
properly escaped.
</synopsis>
</para>
<para>
This example shows use of the functions
<function>quote_ident</function>(<type>TEXT</type>) and
<function>quote_literal</function>(<type>TEXT</type>).
Variables containing field and table identifiers should be
passed to function <function>quote_ident()</function>.
Variables containing literal elements of the dynamic query
string should be passed to
<function>quote_literal()</function>. Both take the
appropriate steps to return the input text enclosed in single
or double quotes and with any embedded special characters.
</para>
</listitem>
</varlistentry>
<para>
Here is a much larger example of a dynamic query and EXECUTE:
<programlisting>
CREATE FUNCTION cs_update_referrer_type_proc() RETURNS INTEGER AS '
DECLARE
referrer_keys RECORD; -- Declare a generic record to be used in a FOR
a_output varchar(4000);
BEGIN
a_output := ''CREATE FUNCTION cs_find_referrer_type(varchar,varchar,varchar)
RETURNS varchar AS ''''
DECLARE
v_host ALIAS FOR $1;
v_domain ALIAS FOR $2;
v_url ALIAS FOR $3; '';
<varlistentry>
<term>Obtaining other results status</term>
<listitem>
<para>
<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 keyword identifying a state
value to be assigned to the specified variable (which should be of
the right datatype to receive it). The currently available status
items are <varname>ROW_COUNT</>, the number of rows processed by
the last <acronym>SQL</acronym> query sent down to the <acronym>SQL</acronym> engine; and
<varname>RESULT_OID</>, the Oid of the last row inserted by the
most recent <acronym>SQL</acronym> query. Note that <varname>RESULT_OID</> is only
useful after an INSERT query.
</para>
</listitem>
</varlistentry>
--
-- Notice how we scan through the results of a query in a FOR loop
-- using the FOR &lt;record&gt; construct.
--
<varlistentry>
<term>Returning from the function</term>
<listitem>
<para>
<synopsis>
RETURN <replaceable>expression</replaceable>
</synopsis>
The function terminates and the value of <replaceable>expression</replaceable>
will be returned to the upper executor. The return value of a function
cannot be undefined. If control reaches the end of the top-level block
of the function without hitting a RETURN statement, a runtime error
will occur.
</para>
<para>
The expressions result will be automatically casted into the
function's return type as described for assignments.
</para>
</listitem>
</varlistentry>
FOR referrer_keys IN select * from cs_referrer_keys order by try_order LOOP
a_output := a_output || '' if v_'' || referrer_keys.kind || '' like ''''''''''
|| referrer_keys.key_string || '''''''''' then return ''''''
|| referrer_keys.referrer_type || ''''''; end if;'';
END LOOP;
a_output := a_output || '' return null; end; '''' language ''''plpgsql'''';'';
-- This works because we are not substituting any variables
-- Otherwise it would fail. Look at PERFORM for another way to run functions
EXECUTE a_output;
end;
' language 'plpgsql';
</programlisting>
</para>
</sect3>
<varlistentry>
<term>Aborting and messages</term>
<listitem>
<sect3 id="plpgsql-statements-diagnostics">
<title>Obtaining other results status</title>
<para>
As indicated in the above examples there is a RAISE statement that
can throw messages into the <productname>Postgres</productname>
elog mechanism.
<synopsis>
RAISE <replaceable class="parameter">level</replaceable> '<replaceable class="parameter">format</replaceable>' <optional>, <replaceable class="parameter">identifier</replaceable> <optional>...</optional></optional>;
</synopsis>
Inside the format, <literal>%</literal> is used as a placeholder for the
subsequent comma-separated identifiers. Possible levels are
DEBUG (silently suppressed in production running databases), NOTICE
(written into the database log and forwarded to the client application)
and EXCEPTION (written into the database log and aborting the transaction).
<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 keyword identifying a state
value to be assigned to the specified variable (which should be of
the right datatype to receive it). The currently available status
items are <varname>ROW_COUNT</>, the number of rows processed by
the last <acronym>SQL</acronym> query sent down to the <acronym>SQL</acronym> engine; and
<varname>RESULT_OID</>, the Oid of the last row inserted by the
most recent <acronym>SQL</acronym> query. Note that <varname>RESULT_OID</> is only
useful after an INSERT query.
</para>
</listitem>
</varlistentry>
</sect3>
<sect3 id="plpgsql-statements-returning">
<title>Returning from a function</title>
<varlistentry>
<term>Conditionals</term>
<listitem>
<para>
<synopsis>
IF <replaceable>expression</replaceable> THEN
<replaceable>statements</replaceable>
<optional>ELSE
<replaceable>statements</replaceable></optional>
END IF;
</synopsis>
The <replaceable>expression</replaceable> must return a value that
is of type <type>boolean</type> or can be casted to a <type>boolean</type>.
<para>
<synopsis>
RETURN <replaceable>expression</replaceable>
</synopsis>
The function terminates and the value of <replaceable>expression</replaceable>
will be returned to the upper executor. The return value of a function
cannot be undefined. If control reaches the end of the top-level block
of the function without hitting a RETURN statement, a runtime error
will occur.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term>
Loops
</term>
<listitem>
<para>
There are multiple types of loops.
<synopsis>
<optional>&lt;&lt;label&gt;&gt;</optional>
LOOP
<replaceable>statements</replaceable>
END LOOP;
</synopsis>
An unconditional loop that must be terminated explicitly
by an EXIT statement. The optional label can be used by
EXIT statements of nested loops to specify which level of
nesting should be terminated.
<synopsis>
<optional>&lt;&lt;label&gt;&gt;</optional>
WHILE <replaceable>expression</replaceable> LOOP
<replaceable>statements</replaceable>
END LOOP;
</synopsis>
A conditional loop that is executed as long as the evaluation
of <replaceable>expression</replaceable> is true.
<synopsis>
<optional>&lt;&lt;label&gt;&gt;</optional>
FOR <replaceable>name</replaceable> IN <optional> REVERSE </optional> <replaceable>expression</replaceable> .. <replaceable>expression</replaceable> LOOP
<replaceable>statements</replaceable>
END LOOP;
</synopsis>
A loop that iterates over a range of integer values. The variable
<replaceable>name</replaceable> is automatically created as type
integer and exists only inside the loop. The two expressions giving
the lower and upper bound of the range are evaluated only when entering
the loop. The iteration step is always 1.
<synopsis>
<optional>&lt;&lt;label&gt;&gt;</optional>
FOR <replaceable>record | row</replaceable> IN <replaceable>select_clause</replaceable> LOOP
<replaceable>statements</replaceable>
END LOOP;
</synopsis>
The record or row is assigned all the rows resulting from the select
clause and the loop body is executed for each row. If the loop is
terminated with an EXIT statement, the last assigned row is still
accessible after the loop.
<synopsis>
<optional>&lt;&lt;label&gt;&gt;</optional>
FOR <replaceable>record | row</replaceable> IN EXECUTE <replaceable>text_expression</replaceable> LOOP
<replaceable>statements</replaceable>
END LOOP;
</synopsis>
This is like the previous form, except that the source SELECT
statement is specified as a string expression, which is evaluated
and re-planned on each entry to the FOR loop. This allows the
programmer to choose the speed of a pre-planned query or the
flexibility of a dynamic query, just as with a plain EXECUTE
statement.
<synopsis>
EXIT <optional> <replaceable>label</replaceable> </optional> <optional> WHEN <replaceable>expression</replaceable> </optional>;
</synopsis>
If no <replaceable>label</replaceable> given,
the innermost loop is terminated and the
statement following END LOOP is executed next.
If <replaceable>label</replaceable> is given, it
must be the label of the current or an upper level of nested loop
blocks. Then the named loop or block is terminated and control
continues with the statement after the loops/blocks corresponding
END.
The expressions result will be automatically casted into the
function's return type as described for assignments.
</para>
</listitem>
</varlistentry>
</variablelist>
</sect3>
</sect2>
</sect2>
<!-- **** PL/pgSQL Control Structures **** -->
<!-- **** PL/pgSQL trigger procedures **** -->
<sect2 id="plpgsql-description-control-structures">
<sect2>
<title>Trigger Procedures</title>
<title>Control Structures</title>
<para>
Control structures are probably the most useful (and
important) part of PL/SQL. With PL/pgSQL's control structures,
you can manipulate <productname>PostgreSQL</> data in a very
flexible and powerful way.
</para>
<sect3 id="plpgsql-description-control-structures-conditionals">
<title>Conditional Control: IF statements</title>
<para>
PL/pgSQL can be used to define trigger procedures. They are created
with the usual CREATE FUNCTION command as a function with no
arguments and a return type of OPAQUE.
</para>
<para>
There are some <productname>Postgres</productname> specific details
in functions used as trigger procedures.
</para>
<para>
First they have some special variables created automatically in the
top-level blocks declaration section. They are
<function>IF</function> statements let you take action
according to certain conditions. PL/pgSQL has three forms of
IF: IF-THEN, IF-THEN-ELSE, IF-THEN-ELSE IF. NOTE: All
PL/pgSQL IF statements need a corresponding <function>END
IF</function> statement. In ELSE-IF statements you need two:
one for the first IF and one for the second (ELSE IF).
</para>
<variablelist>
<varlistentry>
<term><varname>NEW</varname></term>
<term>
IF-THEN
</term>
<listitem>
<para>
Data type RECORD; variable holding the new database row on INSERT/UPDATE
operations on ROW level triggers.
IF-THEN statements is the simplest form of an IF. The
statements between THEN and END IF will be executed if
the condition is true. Otherwise, the statements
following END IF will be executed.
<programlisting>
IF v_user_id &lt;&gt; 0 THEN
UPDATE users SET email = v_email WHERE user_id = v_user_id;
END IF;
</programlisting>
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><varname>OLD</varname></term>
<term>
IF-THEN-ELSE
</term>
<listitem>
<para>
Data type RECORD; variable holding the old database row on UPDATE/DELETE
operations on ROW level triggers.
</para>
</listitem>
</varlistentry>
IF-THEN-ELSE statements adds to IF-THEN by letting you
specify the statements that should be executed if the
condition evaluates to FALSE.
<programlisting>
IF parentid IS NULL or parentid = ''''
THEN
return fullname;
ELSE
return hp_true_filename(parentid) || ''/'' || fullname;
END IF;
<varlistentry>
<term><varname>TG_NAME</varname></term>
<listitem>
IF v_count > 0 THEN
INSERT INTO users_count(count) VALUES(v_count);
return ''t'';
ELSE
return ''f'';
END IF;
</programlisting>
</para>
<para>
Data type <type>name</type>; variable that contains the name of the trigger actually
fired.
IF statements can be nested and 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>
</listitem>
</varlistentry>
<varlistentry>
<term><varname>TG_WHEN</varname></term>
<term>
IF-THEN-ELSE IF
</term>
<listitem>
<para>
Data type <type>text</type>; a string of either <literal>'BEFORE'</literal> or <literal>'AFTER'</literal> depending on the
triggers definition.
When you use the "ELSE IF" statement, you are actually
nesting an IF statement inside the ELSE
statement. Thus you need one END IF statement for each
nested IF and one for the parent IF-ELSE.
</para>
<para>
For 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>
</listitem>
</varlistentry>
</variablelist>
</sect3>
<sect3 id="plpgsql-description-control-structures-loops">
<title>Iterative Control: LOOP, WHILE, FOR and EXIT</title>
<para>
With the LOOP, WHILE, FOR and EXIT statements, you can
control the flow of execution of your PL/pgSQL program
iteratively.
</para>
<variablelist>
<varlistentry>
<term><varname>TG_LEVEL</varname></term>
<term>
LOOP
</term>
<listitem>
<para>
Data type <type>text</type>; a string of either <literal>'ROW'</literal> or <literal>'STATEMENT'</literal> depending on the
triggers definition.
<synopsis>
<optional>&lt;&lt;label&gt;&gt;</optional>
LOOP
<replaceable>statements</replaceable>
END LOOP;
</synopsis>
An unconditional loop that must be terminated explicitly
by an EXIT statement. The optional label can be used by
EXIT statements of nested loops to specify which level of
nesting should be terminated.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><varname>TG_OP</varname></term>
<term>
EXIT
</term>
<listitem>
<para>
Data type <type>text</type>; a string of <literal>'INSERT'</literal>, <literal>'UPDATE'</literal>, or <literal>'DELETE'</literal> telling
for which operation the trigger is actually fired.
<synopsis>
EXIT <optional> <replaceable>label</replaceable> </optional> <optional> WHEN <replaceable>expression</replaceable> </optional>;
</synopsis>
If no <replaceable>label</replaceable> is given,
the innermost loop is terminated and the
statement following END LOOP is executed next.
If <replaceable>label</replaceable> is given, it
must be the label of the current or an upper level of nested loop
blocks. Then the named loop or block is terminated and control
continues with the statement after the loops/blocks corresponding
END.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><varname>TG_RELID</varname></term>
<listitem>
<para>
Data type oid; the object ID of the table that caused the
trigger invocation.
Examples:
<programlisting>
LOOP
-- some computations
IF count > 0 THEN
EXIT; -- exit loop
END IF;
END LOOP;
LOOP
-- some computations
EXIT WHEN count > 0;
END LOOP;
BEGIN
-- some computations
IF stocks > 100000 THEN
EXIT; -- illegal. Can't use EXIT outside of a LOOP
END IF;
END;
</programlisting>
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><varname>TG_RELNAME</varname></term>
<term>
WHILE
</term>
<listitem>
<para>
Data type name; the name of the table that caused the trigger
invocation.
With the WHILE statement, you can loop through a
sequence of statements as long as the evaluation of
the condition expression is true.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><varname>TG_NARGS</varname></term>
<listitem>
<para>
Data type integer; the number of arguments given to the trigger
procedure in the CREATE TRIGGER statement.
<synopsis>
<optional>&lt;&lt;label&gt;&gt;</optional>
WHILE <replaceable>expression</replaceable> LOOP
<replaceable>statements</replaceable>
END LOOP;
</synopsis>
<para>
For example:
</para>
<programlisting>
WHILE amount_owed > 0 AND gift_certificate_balance > 0 LOOP
-- some computations here
END LOOP;
WHILE NOT boolean_expression LOOP
-- some computations here
END LOOP;
</programlisting>
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><varname>TG_ARGV[]</varname></term>
<term>
FOR
</term>
<listitem>
<para>
Data type array of <type>text</type>; the arguments from the CREATE TRIGGER statement.
The index counts from 0 and can be given as an expression. Invalid
indices (&lt; 0 or &gt;= tg_nargs) result in a NULL value.
<synopsis>
<optional>&lt;&lt;label&gt;&gt;</optional>
FOR <replaceable>name</replaceable> IN <optional> REVERSE </optional> <replaceable>expression</replaceable> .. <replaceable>expression</replaceable> LOOP
<replaceable>statements</replaceable>
END LOOP;
</synopsis>
A loop that iterates over a range of integer values. The variable
<replaceable>name</replaceable> is automatically created as type
integer and exists only inside the loop. The two expressions giving
the lower and upper bound of the range are evaluated only when entering
the loop. The iteration step is always 1.
</para>
<para>
Some examples of FOR loops (see <xref linkend="plpgsql-description-records"></xref> for
iterating over records in FOR loops):
<programlisting>
FOR i IN 1..10 LOOP
-- some expressions here
RAISE NOTICE 'i is %',i;
END LOOP;
FOR i IN REVERSE 1..10 LOOP
-- some expressions here
END LOOP;
</programlisting>
</para>
</listitem>
</varlistentry>
</variablelist>
</sect3>
</sect2>
<!-- **** PL/pgSQL records **** -->
<sect2 id="plpgsql-description-records">
<title>Working with RECORDs</title>
<para>
Records are similar to rowtypes, but they have no predefined structure.
They are used in selections and FOR loops to hold one actual
database row from a SELECT operation.
</para>
<sect3 id="plpgsql-description-records-declaration">
<title>Declaration</title>
<para>
Second they must return either NULL or a record/row containing
exactly the structure of the table the trigger was fired for.
Triggers fired AFTER might always return a NULL value with no
effect. Triggers fired BEFORE signal the trigger manager
to skip the operation for this actual row when returning NULL.
Otherwise, the returned record/row replaces the inserted/updated
row in the operation. It is possible to replace single values directly
in NEW and return that or to build a complete new record/row to
return.
One variables of type RECORD can be used for different
selections. Accessing a record or an attempt to assign
a value to a record field when there is no actual row in it results
in a runtime error. They can be declared like this:
</para>
</sect2>
<para>
<synopsis>
<replaceable>name</replaceable> RECORD;
</synopsis>
</para>
</sect3>
<sect3 id="plpgsql-description-records-assignment">
<title>Assignments</title>
<para>
An assignment of a complete selection into a record or row can
be done by:
<synopsis>
SELECT INTO <replaceable>target</replaceable> <replaceable>expressions</replaceable> FROM ...;
</synopsis>
<replaceable>target</replaceable> can be a record, a row variable or a
comma separated list of variables and record-/row-fields. Note that
this is quite different from Postgres' normal interpretation of
SELECT INTO, which is that the INTO target is a newly created table.
(If you want to create a table from a SELECT result inside a PL/pgSQL
function, use the equivalent syntax <command>CREATE TABLE AS SELECT</command>.)
</para>
<para>
If a row or a variable list is used as target, the selected values
must exactly match the structure of the target(s) or a runtime error
occurs. The FROM keyword can be followed by any valid qualification,
grouping, sorting etc. that can be given for a SELECT statement.
</para>
<para>
Once a record or row has been assigned to a RECORD variable,
you can use the "." (dot) notation to access fields in that
record:
</para>
<para>
<programlisting>
DECLARE
users_rec RECORD;
full_name varchar;
BEGIN
SELECT INTO users_rec * FROM users WHERE user_id=3;
full_name := users_rec.first_name || '' '' || users_rec.last_name;
</programlisting>
</para>
<para>
There is a special variable named FOUND of type <type>boolean</type> that can be used
immediately after a SELECT INTO to check if an assignment had success.
<programlisting>
SELECT INTO myrec * FROM EMP WHERE empname = myname;
IF NOT FOUND THEN
RAISE EXCEPTION ''employee % not found'', myname;
END IF;
</programlisting>
You can also use the IS NULL (or ISNULL) conditionals to
test for NULLity of a RECORD/ROW. If the selection returns
multiple rows, only the first is moved into the target
fields. All others are silently discarded.
</para>
<para>
<programlisting>
DECLARE
users_rec RECORD;
full_name varchar;
BEGIN
SELECT INTO users_rec * FROM users WHERE user_id=3;
IF users_rec.homepage IS NULL THEN
-- user entered no homepage, return "http://"
return ''http://'';
END IF;
END;
</programlisting>
</para>
</sect3>
<sect3 id="plpgsql-description-records-iterating">
<title>Iterating Through Records</title>
<para>
Using a special type of FOR loop, you can iterate through
the results of a query and manipulate that data
accordingly. The syntax is as follow:
</para>
<para>
<synopsis>
<optional>&lt;&lt;label&gt;&gt;</optional>
FOR <replaceable>record | row</replaceable> IN <replaceable>select_clause</replaceable> LOOP
<replaceable>statements</replaceable>
END LOOP;
</synopsis>
The record or row is assigned all the rows
resulting from the select clause and the loop body executed
for each. Here is an example:
</para>
<para>
<programlisting>
create function cs_refresh_mviews () returns integer as '
DECLARE
mviews RECORD;
-- Instead, if you did:
-- mviews cs_materialized_views%ROWTYPE;
-- this record would ONLY be usable for the cs_materialized_views table
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 '' || mview.mv_name || ''...'');
TRUNCATE TABLE mview.mv_name;
INSERT INTO mview.mv_name || '' '' || mview.mv_query;
END LOOP;
PERFORM cs_log(''Done refreshing materialized views.'');
return 1;
end;
' language 'plpgsql';
</programlisting>
If the loop is terminated with an EXIT statement,
the last assigned row is still accessible after the loop.
</para>
<para>
The FOR-IN EXECUTE statement is another way to iterate over
records:
</para>
<para>
<synopsis>
<optional>&lt;&lt;label&gt;&gt;</optional>
FOR <replaceable>record | row</replaceable> IN EXECUTE <replaceable>text_expression</replaceable> LOOP
<replaceable>statements</replaceable>
END LOOP;
</synopsis>
This is like the previous form, except that the source SELECT
statement is specified as a string expression, which is evaluated
and re-planned on each entry to the FOR loop. This allows the
programmer to choose the speed of a pre-planned query or the
flexibility of a dynamic query, just as with a plain EXECUTE
statement.
</para>
</sect3>
</sect2>
<sect2 id="plpgsql-description-aborting-and-messages">
<title>Aborting and Messages</title>
<para>
Use the RAISE statement to throw messages into the
<productname>Postgres</productname> elog mechanism.
<synopsis>
RAISE <replaceable class="parameter">level</replaceable> '<replaceable class="parameter">format</replaceable>' <optional>, <replaceable class="parameter">identifier</replaceable> <optional>...</optional></optional>;
</synopsis>
Inside the format, <literal>%</literal> is used as a placeholder for the
subsequent comma-separated identifiers. Possible levels are
DEBUG (silently suppressed in production running databases), NOTICE
(written into the database log and forwarded to the client application)
and EXCEPTION (written into the database log and aborting the transaction).
</para>
<para>
<programlisting>
RAISE NOTICE ''Id number '' || key || '' not found!'';
RAISE NOTICE ''Calling cs_create_job(%)'',v_job_id;
</programlisting>
In this last example, v_job_id will replace the % in the
string.
</para>
<para>
<programlisting>
RAISE EXCEPTION ''Inexistent ID --> %'',user_id;
</programlisting>
This will abort the transaction and write to the database log.
</para>
</sect2>
<!-- **** PL/pgSQL exceptions **** -->
......@@ -873,90 +1307,161 @@ EXIT <optional> <replaceable>label</replaceable> </optional> <optional> WHEN <re
statement) this happened.
</para>
</sect2>
</sect1>
</sect1>
<!-- **** PL/pgSQL Examples **** -->
<sect1 id="plpgsql-examples">
<title>Examples</title>
<!-- **** PL/pgSQL trigger procedures **** -->
<sect1 id="plpgsql-trigger">
<title>Trigger Procedures</title>
<sect2 id="plpgsql-trigger-description">
<title>Description</title>
<para>
Here are only a few functions to demonstrate how easy it is to write PL/pgSQL
functions. For more complex examples the programmer
might look at the regression test for PL/pgSQL.
PL/pgSQL can be used to define trigger procedures. They are created
with the usual <command>CREATE FUNCTION</command> command as a function with no
arguments and a return type of <type>OPAQUE</type>.
</para>
<para>
One painful detail in writing functions in PL/pgSQL is the handling
of single quotes. The function's source text in the <command>CREATE FUNCTION</command> command must
be a literal string. Single quotes inside of literal strings must be
either doubled or quoted with a backslash. We are still looking for
an elegant alternative. In the meantime, doubling the single quotes
as in the examples below should be used. Any solution for this
in future versions of <productname>Postgres</productname> will be
forward compatible.
There are some <productname>Postgres</productname> specific details
in functions used as trigger procedures.
</para>
<para>
First they have some special variables created automatically in the
top-level blocks declaration section. They are
</para>
<variablelist>
<varlistentry>
<term><varname>NEW</varname></term>
<listitem>
<para>
Data type <type>RECORD</type>; variable holding the new database row on INSERT/UPDATE
operations on ROW level triggers.
</para>
</listitem>
</varlistentry>
<example>
<title>A Simple PL/pgSQL Functions</title>
<varlistentry>
<term><varname>OLD</varname></term>
<listitem>
<para>
Data type <type>RECORD</type>; variable holding the old database row on UPDATE/DELETE
operations on ROW level triggers.
</para>
</listitem>
</varlistentry>
<para>
The following two PL/pgSQL functions are identical to their
counterparts from the C language function discussion.
<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>
<programlisting>
CREATE FUNCTION add_one (integer) RETURNS integer AS '
BEGIN
RETURN $1 + 1;
END;
' LANGUAGE 'plpgsql';
</programlisting>
<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 triggers definition.
</para>
</listitem>
</varlistentry>
<programlisting>
CREATE FUNCTION concat_text (text, text) RETURNS text AS '
BEGIN
RETURN $1 || $2;
END;
' LANGUAGE 'plpgsql';
</programlisting>
</para>
<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
triggers definition.
</para>
</listitem>
</varlistentry>
</example>
<varlistentry>
<term><varname>TG_OP</varname></term>
<listitem>
<para>
Data type <type>text</type>; a string of
<literal>INSERT</literal>, <literal>UPDATE</literal>
or <literal>DELETE</literal> telling
for which operation the trigger is actually fired.
</para>
</listitem>
</varlistentry>
<example>
<title>A PL/pgSQL Function on a Composite Type</title>
<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>
<para>
Again, this is the PL/pgSQL equivalent to the example from
the C functions.
<varlistentry>
<term><varname>TG_RELNAME</varname></term>
<listitem>
<para>
Data type <type>name</type>; the name of the table that caused the trigger
invocation.
</para>
</listitem>
</varlistentry>
<programlisting>
CREATE FUNCTION c_overpaid (EMP, integer) RETURNS boolean AS '
DECLARE
emprec ALIAS FOR $1;
sallim ALIAS FOR $2;
BEGIN
IF emprec.salary ISNULL THEN
RETURN ''f'';
END IF;
RETURN emprec.salary > sallim;
END;
' LANGUAGE 'plpgsql';
</programlisting>
</para>
<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>
</example>
<varlistentry>
<term><varname>TG_ARGV[]</varname></term>
<listitem>
<para>
Data type array of <type>text</type>; the arguments from
the <command>CREATE TRIGGER</command> statement.
The index counts from 0 and can be given as an expression. Invalid
indices (&lt; 0 or &gt;= tg_nargs) result in a NULL value.
</para>
</listitem>
</varlistentry>
</variablelist>
<para>
Second they must return either NULL or a record/row containing
exactly the structure of the table the trigger was fired for.
Triggers fired AFTER might always return a NULL value with no
effect. Triggers fired BEFORE signal the trigger manager
to skip the operation for this actual row when returning NULL.
Otherwise, the returned record/row replaces the inserted/updated
row in the operation. It is possible to replace single values directly
in NEW and return that or to build a complete new record/row to
return.
</para>
</sect2>
<example>
<title>A PL/pgSQL Trigger Procedure</title>
<title>A PL/pgSQL Trigger Procedure Example</title>
<para>
This trigger ensures that any time a row is inserted or updated
This trigger ensures, that any time a row is inserted or updated
in the table, the current user name and time are stamped into the
row. And it ensures that an employees name is given and that the
salary is a positive value.
<programlisting>
<programlisting>
CREATE TABLE emp (
empname text,
salary integer,
......@@ -987,11 +1492,107 @@ CREATE FUNCTION emp_stamp () RETURNS OPAQUE AS '
CREATE TRIGGER emp_stamp BEFORE INSERT OR UPDATE ON emp
FOR EACH ROW EXECUTE PROCEDURE emp_stamp();
</programlisting>
</programlisting>
</para>
</example>
</sect1>
<!-- **** PL/pgSQL Examples **** -->
<sect1 id="plpgsql-examples">
<title>Examples</title>
<para>
Here are only a few functions to demonstrate how easy it is to
write PL/pgSQL
functions. For more complex examples the programmer
might look at the regression test for PL/pgSQL.
</para>
<para>
One painful detail in writing functions in PL/pgSQL is the handling
of single quotes. The function's source text on <command>CREATE FUNCTION</command> must
be a literal string. Single quotes inside of literal strings must be
either doubled or quoted with a backslash. We are still looking for
an elegant alternative. In the meantime, doubling the single quotes
as in the examples below should be used. Any solution for this
in future versions of <productname>Postgres</productname> will be
forward compatible.
</para>
<para>
For a detailed explanation and examples of how to escape single
quotes in different situations, please see <xref linkend="plpgsql-quote"></xref> in
<xref linkend="plpgsql-porting">Porting From Oracle PL/SQL</xref>.
</para>
<example>
<title>A Simple PL/pgSQL Function to Increment an Integer</title>
<para>
The following two PL/pgSQL functions are identical to their
counterparts from the C language function discussion. This
function receives an <type>integer</type> and increments it by
one, returning the incremented value.
</para>
<programlisting>
CREATE FUNCTION add_one (integer) RETURNS integer AS '
BEGIN
RETURN $1 + 1;
END;
' LANGUAGE 'plpgsql';
</programlisting>
</example>
<example>
<title>A Simple PL/pgSQL Function to Concatenate Text</title>
<para>
This function receives two <type>text</type> parameters and
returns the result of concatenating them.
</para>
<programlisting>
CREATE FUNCTION concat_text (text, text) RETURNS text AS '
BEGIN
RETURN $1 || $2;
END;
' LANGUAGE 'plpgsql';
</programlisting>
</example>
<example>
<title>A PL/pgSQL Function on Composite Type</title>
<para>
In this example, we take EMP (a table) and an <type>integer</type> as
arguments to our function, which returns a <type>boolean</type>. If the
"salary" field of the EMP table is <literal>NULL</literal>, we return
"f". Otherwise we compare with that field with the <type>integer</type>
passed to the function and return the <type>boolean</type> result of the
comparison (t or f). This is the PL/pgSQL equivalent to the
example from the C functions.
</para>
<para>
<programlisting>
CREATE FUNCTION c_overpaid (EMP, integer) RETURNS boolean AS '
DECLARE
emprec ALIAS FOR $1;
sallim ALIAS FOR $2;
BEGIN
IF emprec.salary ISNULL THEN
RETURN ''f'';
END IF;
RETURN emprec.salary > sallim;
END;
' LANGUAGE 'plpgsql';
</programlisting>
</para>
</example>
</sect1>
<!-- **** Porting from Oracle PL/SQL **** -->
<sect1 id="plpgsql-porting">
<sect1info>
......@@ -1080,7 +1681,7 @@ CREATE TRIGGER emp_stamp BEFORE INSERT OR UPDATE ON emp
<listitem>
<para>
In PostgreSQL you <emphasis>need</emphasis> to escape single
quotes. See <xref linkend="plpgsql-quote">.
quotes. See <xref linkend="plpgsql-quote"></xref>.
</para>
</listitem>
</itemizedlist>
......@@ -1093,15 +1694,16 @@ CREATE TRIGGER emp_stamp BEFORE INSERT OR UPDATE ON emp
In PostgreSQL you need to escape single quotes inside your
function definition. This can lead to quite amusing code at
times, especially if you are creating a function that generates
other function(s), as in <xref
linkend="plpgsql-porting-nastyquote">. One thing to keep in mind
other function(s), as in
<xref linkend="plpgsql-porting-nastyquote">this example</xref>.
One thing to keep in mind
when escaping lots of single quotes is that, except for the
beginning/ending quotes, all the others will come in even
quantity.
</para>
<para>
<xref linkend="plpgsql-quoting-table"> gives the scoop. (You'll
<xref linkend="plpgsql-quoting-table"></xref> gives the scoop. (You'll
love this little chart.)
</para>
......@@ -1174,7 +1776,7 @@ a_output := a_output || '' AND name
(which accounts for 8 quotes) <emphasis>and</emphasis>
terminate that string (2 more). You will probably only need
that if you were using a function to generate other functions
(like in <xref linkend="plpgsql-porting-nastyquote">).
(like in <xref linkend="plpgsql-porting-nastyquote"></xref>).
</entry>
<entry><programlisting>
a_output := a_output || '' if v_'' ||
......@@ -1263,7 +1865,7 @@ SHOW ERRORS;
On PostgreSQL functions are created using single quotes as
delimiters, so you have to escape single quotes inside your
functions (which can be quite annoying at times; see <xref
linkend="plpgsql-quote">).
linkend="plpgsql-quote">this example</xref>).
</para>
</listitem>
......@@ -1383,8 +1985,8 @@ end;
<para>
The following Oracle PL/SQL procedure is used to parse a URL and
return several elements (host, path and query). It is an
procedure because in functions only one value can be returned
(see <xref linkend="plpgsql-porting-procedures">). In
procedure because in PL/pgSQL functions only one value can be returned
(see <xref linkend="plpgsql-porting-procedures"></xref>). In
PostgreSQL, one way to work around this is to split the procedure
in three different functions: one to return the host, another for
the path and another for the query.
......@@ -1473,7 +2075,7 @@ show errors;
I got tired of doing this and created my own
<function>instr</function> functions that behave exactly like
Oracle's (it makes life easier). See the <xref
linkend="plpgsql-porting-appendix"> for the code.
linkend="plpgsql-porting-appendix"></xref> for the code.
</para>
</note>
</sect2>
......@@ -1496,15 +2098,15 @@ show errors;
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">
pragma autonomous_transaction;<co id="co.plpgsql-porting-pragma"></co>
begin
lock table cs_jobs in exclusive mode;<co id="co.plpgsql-porting-locktable">
lock table cs_jobs in exclusive mode;<co id="co.plpgsql-porting-locktable"></co>
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">
commit; -- free lock<co id="co.plpgsql-porting-commit"></co>
raise_application_error(-20000, 'Unable to create a new job: a job is currently running.');
end if;
......@@ -1513,7 +2115,7 @@ begin
begin
insert into cs_jobs(job_id, start_stamp) values(v_job_id, sysdate);
exception when dup_val_on_index then null; -- don't worry if it already exists<co id="co.plpgsql-porting-exception">
exception when dup_val_on_index then null; -- don't worry if it already exists<co id="co.plpgsql-porting-exception"></co>
end;
commit;
end;
......@@ -1588,7 +2190,7 @@ begin
insert into cs_jobs(job_id, start_stamp) values(v_job_id, sysdate());
return 1;
ELSE
raise NOTICE ''Job already running.'';<co id="co.plpgsql-porting-raise">
raise NOTICE ''Job already running.'';<co id="co.plpgsql-porting-raise"></co>
END IF;
return 0;
......@@ -1699,7 +2301,7 @@ END;
nicely, but you have to remember to use
<function>quote_literal(TEXT)</function> and
<function>quote_string(TEXT)</function> as described in <xref
linkend="plpgsql-statements">. Constructs of the type
linkend="plpgsql-statements"></xref>. Constructs of the type
<literal>EXECUTE ''SELECT * from $1'';</literal> will not work
unless you use these functions.
</para>
......@@ -1713,14 +2315,14 @@ END;
execution: <literal>iscachable</literal> (function always returns
the same result when given the same arguments) and
<literal>isstrict</literal> (function returns NULL if any
argument is NULL). Consult the <literal>CREATE
FUNCTION</literal> reference for details.
argument is NULL). Consult the <command>CREATE
FUNCTION</command> reference for details.
</para>
<para>
To make use of these optimization attributes, you have to use the
<literal>WITH</literal> modifier in your <literal>CREATE
FUNCTION</literal> statement. Something like:
<literal>WITH</literal> modifier in your <command>CREATE
FUNCTION</command> statement. Something like:
<programlisting>
CREATE FUNCTION foo(...) RETURNS integer AS '
......
Markdown is supported
0% or
You are about to add 0 people to the discussion. Proceed with caution.
Finish editing this message first!
Please register or to comment