PL/pgSQL - SQL Procedural Language
PL/pgSQL
PL/pgSQL is a loadable procedural
language for the PostgreSQL database
system. The design goals of PL/pgSQL> were to create
a loadable procedural language that
can be used to create functions and trigger procedures,
adds control structures to the SQL language,
can perform complex computations,
inherits all user-defined types, functions, and operators,
can be defined to be trusted by the server,
is easy to use.
Except for input/output conversion and calculation functions
for user-defined types, anything that can be defined in C language
functions can also be done with PL/pgSQL.
For example, it is possible to
create complex conditional computation functions and later use
them to define operators or use them in index expressions.
Overview
The PL/pgSQL> call handler parses the function's source text and
produces an internal binary instruction tree the first time the
function is called (within each session). The instruction tree
fully translates the
PL/pgSQL> statement structure, but individual
SQL expressions and SQL commands
used in the function are not translated immediately.
As each expression and SQL command is first
used in the function, the PL/pgSQL> interpreter
creates a prepared execution plan (using the
SPI manager's SPI_prepare
and SPI_saveplan
functions).preparing a query>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
PL/pgSQL> function. A disadvantage is that errors
in a specific expression or command may not be detected until that
part of the function is reached in execution.
Once 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:
CREATE FUNCTION populate() RETURNS integer AS $$
DECLARE
-- declarations
BEGIN
PERFORM my_function();
END;
$$ LANGUAGE plpgsql;
If you execute the above function, it will reference the OID for
my_function() in the execution plan produced for
the PERFORM statement. Later, if you
drop and recreate my_function(), then
populate() will not be able to find
my_function() anymore. You would then have to
recreate populate(), or at least start a new
database session so that it will be compiled afresh. Another way
to avoid this problem is to use CREATE OR REPLACE
FUNCTION when updating the definition of
my_function (when a function is
replaced
, its OID is not changed).
Because PL/pgSQL saves execution plans
in this way, SQL commands that appear directly in a
PL/pgSQL 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 PL/pgSQL EXECUTE
statement — at the price of constructing a new execution plan on
every execution.
The PL/pgSQL
EXECUTE statement is not related to the
SQL
statement supported by the
PostgreSQL server. The server's
EXECUTE statement cannot be used within
PL/pgSQL> functions (and is not needed).
Advantages of Using PL/pgSQL
SQL is the language PostgreSQL>
and most other relational databases use as query language. It's
portable and easy to learn. But every SQL
statement must be executed individually by the database server.
That means that your client application must send each query to
the database server, wait for it to be processed, receive the
results, do some computation, then send other queries to the
server. All this incurs interprocess communication and may also
incur network overhead if your client is on a different machine
than the database server.
With PL/pgSQL you can group a block of computation and a
series of queries inside the
database server, thus having the power of a procedural
language and the ease of use of SQL, but saving lots of
time because you don't have the whole client/server
communication overhead. This can make for a
considerable performance increase.
Also, with PL/pgSQL you can use all
the data types, operators and functions of SQL.
Supported Argument and Result Data Types
Functions written in PL/pgSQL 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 PL/pgSQL
function as returning record>, which means that the result
is a row type whose columns are determined by specification in the
calling query, as discussed in .
PL/pgSQL> functions may also be declared to accept
and return the polymorphic types
anyelement and anyarray. The actual
data types handled by a polymorphic function can vary from call to
call, as discussed in .
An example is shown in .
PL/pgSQL> functions can also be declared to return
a set>, or table, of any data type they can return a single
instance of. Such a function generates its output by executing
RETURN NEXT> for each desired element of the result set.
Finally, a PL/pgSQL> function may be declared to return
void> if it has no useful return value.
PL/pgSQL> does not currently have full support for
domain types: it treats a domain the same as the underlying scalar
type. This means that constraints associated with the domain will
not be enforced. This is not an issue for function arguments, but
it is a hazard if you declare a PL/pgSQL> function
as returning a domain type.
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.
Specific examples appear in
and
.
Tips for Developing in PL/pgSQL
One good way to develop in
PL/pgSQL> is to use the text editor of your
choice to create your functions, and in another window, use
psql to load and test those functions.
If you are doing it this way, it
is a good idea to write the function using CREATE OR
REPLACE FUNCTION>. That way you can just reload the file to update
the function definition. For example:
CREATE OR REPLACE FUNCTION testfunc(integer) RETURNS integer AS $$
....
$$ LANGUAGE plpgsql;
While running psql, you can load or reload such
a function definition file with
\i filename.sql
and then immediately issue SQL commands to test the function.
Another good way to develop in PL/pgSQL> is with a
GUI database access tool that facilitates development in a
procedural language. One example of such as a tool is
PgAccess>, although others exist. These tools often
provide convenient features such as escaping single quotes and
making it easier to recreate and debug functions.
Handling of Quotation Marks
The code of a PL/pgSQL> function is specified in
CREATE FUNCTION 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.
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
dollar-quoted> string literal (see ). 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 CREATE
FUNCTION command as
CREATE OR REPLACE FUNCTION testfunc(integer) RETURNS integer AS $PROC$
....
$PROC$ LANGUAGE plpgsql;
Within this, you might use quote marks for simple literal strings in
SQL commands and $$> to delimit fragments of SQL commands
that you are assembling as strings. If you need to quote text that
includes $$>, you could use $Q$>, and so on.
The following chart shows what you have to do when writing quote
marks without dollar quoting. It may be useful when translating
pre-dollar quoting code into something more comprehensible.
1 quotation mark
To begin and end the function body, for example:
CREATE FUNCTION foo() RETURNS integer AS '
....
' LANGUAGE plpgsql;
Anywhere within a single-quoted function body, quote marks
must> appear in pairs.
2 quotation marks
For string literals inside the function body, for example:
a_output := ''Blah'';
SELECT * FROM users WHERE f_name=''foobar'';
In the dollar-quoting approach, you'd just write
a_output := 'Blah';
SELECT * FROM users WHERE f_name='foobar';
which is exactly what the PL/pgSQL> parser would see
in either case.
4 quotation marks
When you need a single quotation mark in a string constant inside the
function body, for example:
a_output := a_output || '' AND name LIKE ''''foobar'''' AND xyz''
The value actually appended to a_output would be:
AND name LIKE 'foobar' AND xyz.
In the dollar-quoting approach, you'd write
a_output := a_output || $$ AND name LIKE 'foobar' AND xyz$$
being careful that any dollar-quote delimiters around this are not
just $$>.
6 quotation marks
When a single quotation mark in a string inside the function body is
adjacent to the end of that string constant, for example:
a_output := a_output || '' AND name LIKE ''''foobar''''''
The value appended to a_output would then be:
AND name LIKE 'foobar'.
In the dollar-quoting approach, this becomes
a_output := a_output || $$ AND name LIKE 'foobar'$$
10 quotation marks
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
.
For example:
a_output := a_output || '' if v_'' ||
referrer_keys.kind || '' like ''''''''''
|| referrer_keys.key_string || ''''''''''
then return '''''' || referrer_keys.referrer_type
|| ''''''; end if;'';
The value of a_output would then be:
if v_... like ''...'' then return ''...''; end if;
In the dollar-quoting approach, this becomes
a_output := a_output || $$ if v_$$ || referrer_keys.kind || $$ like '$$
|| referrer_keys.key_string || $$'
then return '$$ || referrer_keys.referrer_type
|| $$'; end if;$$;
where we assume we only need to put single quote marks into
a_output, because it will be re-quoted before use.
A variant approach is to escape quotation marks in the function body
with a backslash rather than by doubling them. With this method
you'll find yourself writing things like \'\'> instead
of ''''>. Some find this easier to keep track of, some
do not.
Structure of PL/pgSQL
PL/pgSQL is a block-structured language.
The complete text of a function definition must be a
block>. A block is defined as:
<<label>>
DECLARE
declarations
BEGIN
statements
END label ;
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 END, as shown above;
however the final END that
concludes a function body does not require a semicolon.
All key words and identifiers can be written in mixed upper and
lower case. Identifiers are implicitly converted to lowercase
unless double-quoted.
There are two types of comments in PL/pgSQL>. A double
dash (--) starts a comment that extends to the end of
the line. A /* starts a block comment that extends to
the next occurrence of */. 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 /*
and */.
Any statement in the statement section of a block
can be a subblock>. Subblocks can be used for
logical grouping or to localize variables to a small group
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. For example:
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 subblock
--
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
RETURN quantity;
END;
$$ LANGUAGE plpgsql;
It is important not to confuse the use of
BEGIN>/END> for grouping statements in
PL/pgSQL> with the database commands for transaction
control. PL/pgSQL>'s BEGIN>/END>
are only for grouping; they do not start or end a transaction.
Functions and trigger procedures are always executed within a transaction
established by an outer query — they cannot start or commit that
transaction, since there would be no context for them to execute in.
However, a block containing an EXCEPTION> clause effectively
forms a subtransaction that can be rolled back without affecting the
outer transaction. For more about that see .
Declarations
All variables used in a block must be declared in the
declarations section of the block.
(The only exception is that the loop variable of a FOR> loop
iterating over a range of integer values is automatically declared as an
integer variable.)
PL/pgSQL> variables can have any SQL data type, such as
integer, varchar, and
char.
Here are some examples of variable declarations:
user_id integer;
quantity numeric(5);
url varchar;
myrow tablename%ROWTYPE;
myfield tablename.columnname%TYPE;
arow RECORD;
The general syntax of a variable declaration is:
name CONSTANT type NOT NULL { DEFAULT | := } expression ;
The DEFAULT> clause, if given, specifies the initial value assigned
to the variable when the block is entered. If the DEFAULT> clause
is not given then the variable is initialized to the
SQL null value.
The CONSTANT> option prevents the variable from being assigned to,
so that its value remains constant for the duration of the block.
If NOT NULL>
is specified, an assignment of a null value results in a run-time
error. All variables declared as NOT NULL>
must have a nonnull default value specified.
The default value is evaluated every time the block is entered. So,
for example, assigning now() to a variable of type
timestamp causes the variable to have the
time of the current function call, not the time when the function was
precompiled.
Examples:
quantity integer DEFAULT 32;
url varchar := 'http://mysite.com';
user_id CONSTANT integer := 10;
Aliases for Function Parameters
Parameters passed to functions are named with the identifiers
$1, $2,
etc. Optionally, aliases can be declared for
$n
parameter names for increased readability. Either the alias or the
numeric identifier can then be used to refer to the parameter value.
There are two ways to create an alias. The preferred way is to give a
name to the parameter in the CREATE FUNCTION command,
for example:
CREATE FUNCTION sales_tax(subtotal real) RETURNS real AS $$
BEGIN
RETURN subtotal * 0.06;
END;
$$ LANGUAGE plpgsql;
The other way, which was the only way available before
PostgreSQL 8.0, is to explicitly
declare an alias, using the declaration syntax
name ALIAS FOR $n;
The same example in this style looks like
CREATE FUNCTION sales_tax(real) RETURNS real AS $$
DECLARE
subtotal ALIAS FOR $1;
BEGIN
RETURN subtotal * 0.06;
END;
$$ LANGUAGE plpgsql;
Some more examples:
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;
When a PL/pgSQL function is declared
with output parameters, the output parameters are given
$n 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:
CREATE FUNCTION sales_tax(subtotal real, OUT tax real) AS $$
BEGIN
tax := subtotal * 0.06;
END;
$$ LANGUAGE plpgsql;
Notice that we omitted RETURNS real> — we could have
included it, but it would be redundant.
Output parameters are most useful when returning multiple values.
A trivial example is:
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;
As discussed in , this
effectively creates an anonymous record type for the function's
results. If a RETURNS> clause is given, it must say
RETURNS record>.
When the return type of a PL/pgSQL
function is declared as a polymorphic type (anyelement
or anyarray), a special parameter $0
is created. Its data type is the actual return type of the function,
as deduced from the actual input types (see ).
This allows the function to access its actual return type
as shown in .
$0 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. $0 can also be
given an alias. For example, this function works on any data type
that has a +> operator:
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;
The same effect can be had by declaring one or more output parameters as
anyelement or anyarray. In this case the
special $0 parameter is not used; the output
parameters themselves serve the same purpose. For example:
CREATE FUNCTION add_three_values(v1 anyelement, v2 anyelement, v3 anyelement,
OUT sum anyelement)
AS $$
BEGIN
sum := v1 + v2 + v3;
END;
$$ LANGUAGE plpgsql;
Copying Types
variable%TYPE
%TYPE 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
user_id in your users
table. To declare a variable with the same data type as
users.user_id> you write:
user_id users.user_id%TYPE;
By using %TYPE 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 user_id>
from integer to real), you may not need
to change your function definition.
%TYPE is particularly valuable in polymorphic
functions, since the data types needed for internal variables may
change from one call to the next. Appropriate variables can be
created by applying %TYPE to the function's
arguments or result placeholders.
Row Types
name table_name%ROWTYPE;
name composite_type_name;
A variable of a composite type is called a row>
variable (or row-type> variable). Such a variable
can hold a whole row of a SELECT> or FOR>
query result, so long as that query's column set matches the
declared type of the variable.
The individual fields of the row value
are accessed using the usual dot notation, for example
rowvar.field.
A row variable can be declared to have the same type as the rows of
an existing table or view, by using the
table_name%ROWTYPE
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 PostgreSQL> whether you
write %ROWTYPE or not. But the form with
%ROWTYPE is more portable.)
Parameters to a function can be
composite types (complete table rows). In that case, the
corresponding identifier $n> will be a row variable, and fields can
be selected from it, for example $1.user_id.
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
char(n>).
Here is an example of using composite types. table1>
and table2> are existing tables having at least the
mentioned fields:
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 ... ;
Record Types
name RECORD;
Record variables are similar to row-type variables, but they have no
predefined structure. They take on the actual row structure of the
row they are assigned during a SELECT> or FOR> command. The substructure
of a record variable can change each time it is assigned to.
A consequence of this is that until a record variable is first assigned
to, it has no substructure, and any attempt to access a
field in it will draw a run-time error.
Note that RECORD> is not a true data type, only a placeholder.
One should also realize that when a PL/pgSQL
function is declared to return type record>, this is not quite the
same concept as a record variable, even though such a function may well
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 record> the actual structure is determined when the
calling query is parsed, whereas a record variable can change its row
structure on-the-fly.
RENAME>
RENAME oldname TO newname;
Using the RENAME declaration you can change the
name of a variable, record or row. This is primarily useful if
NEW or OLD should be
referenced by another name inside a trigger procedure. See also
ALIAS.
Examples:
RENAME id TO user_id;
RENAME this_var TO that_var;
RENAME appears to be broken as of
PostgreSQL> 7.3. Fixing this is of low priority,
since ALIAS covers most of the practical uses
of RENAME.
Expressions
All expressions used in PL/pgSQL
statements are processed using the server's regular
SQL executor. In effect, a query like
SELECT expression
is executed using the SPI manager. Before evaluation,
occurrences of PL/pgSQL variable
identifiers are replaced by parameters, and the actual values from
the variables are passed to the executor in the parameter array.
This allows the query plan for the SELECT to
be prepared just once and then reused for subsequent
evaluations.
The evaluation done by the PostgreSQL
main parser has some side
effects on the interpretation of constant values. In detail there
is a difference between what these two functions do:
CREATE FUNCTION logfunc1(logtxt text) RETURNS timestamp AS $$
BEGIN
INSERT INTO logtable VALUES (logtxt, 'now');
RETURN 'now';
END;
$$ LANGUAGE plpgsql;
and
CREATE FUNCTION logfunc2(logtxt text) RETURNS timestamp AS $$
DECLARE
curtime timestamp;
BEGIN
curtime := 'now';
INSERT INTO logtable VALUES (logtxt, curtime);
RETURN curtime;
END;
$$ LANGUAGE plpgsql;
In the case of logfunc1, the
PostgreSQL main parser knows when
preparing the plan for the INSERT that the
string 'now' should be interpreted as
timestamp because the target column of
logtable is of that type. Thus,
'now' will be converted to a constant when the
INSERT is planned, and then used in all
invocations of logfunc1 during the lifetime
of the session. Needless to say, this isn't what the programmer
wanted.
In the case of logfunc2, the
PostgreSQL main parser does not know
what type 'now' should become and therefore
it returns a data value of type text containing the string
now. During the ensuing assignment
to the local variable curtime, the
PL/pgSQL interpreter casts this
string to the timestamp type by calling the
text_out and timestamp_in
functions for the conversion. So, the computed time stamp is updated
on each execution as the programmer expects.
The mutable nature of record variables presents a problem in this
connection. When fields of a record variable are used in
expressions or statements, the data types of the fields must not
change between calls of one and the same expression, since the
expression will be planned using the data type that is present
when the expression is first reached. Keep this in mind when
writing trigger procedures that handle events for more than one
table. (EXECUTE can be used to get around
this problem when necessary.)
Basic Statements
In this section and the following ones, we describe all the statement
types that are explicitly understood by
PL/pgSQL.
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
(after substitution of any PL/pgSQL variables
used in the statement). Thus,
for example, the SQL commands INSERT>, UPDATE>, and
DELETE> may be considered to be statements of
PL/pgSQL, but they are not specifically
listed here.
Assignment
An assignment of a value to a variable or row/record field is
written as:
identifier := expression;
As explained above, the expression in such a statement is evaluated
by means of an SQL SELECT> command sent to the main
database engine. The expression must yield a single value.
If the expression's result data type doesn't match the variable's
data type, or the variable has a specific size/precision
(like char(20)), the result value will be implicitly
converted by the PL/pgSQL 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.
Examples:
user_id := 20;
tax := subtotal * 0.06;
SELECT INTO
SELECT INTO
in PL/pgSQL
The result of a SELECT command yielding multiple columns (but
only one row) can be assigned to a record variable, row-type
variable, or list of scalar variables. This is done by:
SELECT INTO target select_expressions FROM ...;
where target can be a record variable, a row
variable, or a comma-separated list of simple variables and
record/row fields. The select_expressions
and the remainder of the command are the same as in regular SQL.
Note that this is quite different from
PostgreSQL>'s normal interpretation of
SELECT INTO, where 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 syntax
CREATE TABLE ... AS SELECT.
If a row or a variable list is used as target, the selected values
must exactly match the structure of the target, 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.
Except for the INTO> clause, the SELECT>
statement is the same as a normal SQL SELECT> command
and can use its full power.
The INTO> clause can appear almost anywhere in the
SELECT statement. Customarily it is written
either just after SELECT> as shown above, or
just before FROM> — that is, either just before
or just after the list of select_expressions.
If the query returns zero rows, null values are assigned to the
target(s). If the query returns multiple rows, the first
row is assigned to the target(s) and the rest are discarded.
(Note that the first row> is not well-defined unless you've
used ORDER BY>.)
You can check the special FOUND variable (see
) after a
SELECT INTO statement to determine whether the
assignment was successful, that is, at least one row was was returned by
the query. For example:
SELECT INTO myrec * FROM emp WHERE empname = myname;
IF NOT FOUND THEN
RAISE EXCEPTION 'employee % not found', myname;
END IF;
To test for whether a record/row result is null, you can use the
IS NULL conditional. There is, however, no
way to tell whether any additional rows might have been
discarded. Here is an example that handles the case where no
rows have been returned:
DECLARE
users_rec RECORD;
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;
Executing an Expression or Query With No Result
Sometimes one wishes to evaluate an expression or query but
discard the result (typically because one is calling a function
that has useful side-effects but no useful result value). To do
this in PL/pgSQL, use the
PERFORM statement:
PERFORM query;
This executes query and discards the
result. Write the query the same
way as you would in an SQL SELECT> command, but replace the
initial keyword SELECT> with PERFORM.
PL/pgSQL variables will be
substituted into the query as usual. Also, the special variable
FOUND is set to true if the query produced at
least one row or false if it produced no rows.
One might expect that SELECT with no
INTO> clause would accomplish this result, but at
present the only accepted way to do it is
PERFORM.
An example:
PERFORM create_mv('cs_session_page_requests_mv', my_query);
Doing Nothing At All
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
NULL statement:
NULL;
For example, the following two fragments of code are equivalent:
BEGIN
y := x / 0;
EXCEPTION
WHEN division_by_zero THEN
NULL; -- ignore the error
END;
BEGIN
y := x / 0;
EXCEPTION
WHEN division_by_zero THEN -- ignore the error
END;
Which is preferable is a matter of taste.
In Oracle's PL/SQL, empty statement lists are not allowed, and so
NULL> statements are required> for situations
such as this. PL/pgSQL allows you to
just write nothing, instead.
Executing Dynamic Commands
Oftentimes you will want to generate dynamic commands inside your
PL/pgSQL functions, that is, commands
that will involve different tables or different data types each
time they are executed. PL/pgSQL's
normal attempts to cache plans for commands will not work in such
scenarios. To handle this sort of problem, the
EXECUTE statement is provided:
EXECUTE command-string [ INTO target ];
where command-string is an expression
yielding a string (of type text) containing the
command to be executed and target is a
record variable, row variable, or a comma-separated list of
simple variables and record/row fields.
Note in particular that no substitution of PL/pgSQL>
variables is done on the command string. The values of variables must
be inserted in the command string as it is constructed.
Unlike all other commands in PL/pgSQL>, a command
run by an EXECUTE statement is not prepared
and saved just once during the life of the session. Instead, the
command is prepared each time the statement is run. The command
string can be dynamically created within the function to perform
actions on different tables and columns.
The INTO clause specifies where the results of
a SELECT command should be assigned. If a row
or variable list is provided, it must exactly match the structure
of the results produced by the SELECT (when a
record variable is used, it will configure itself to match the
result's structure automatically). If multiple rows are returned,
only the first will be assigned to the INTO
variable. If no rows are returned, NULL is assigned to the
INTO variable. If no INTO
clause is specified, the results of a SELECT
command are discarded.
SELECT INTO is not currently supported within
EXECUTE.
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 , which can save you
some effort when translating said code to a more reasonable scheme.)
Dynamic values that are to be inserted into the constructed
query require special 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):
EXECUTE 'UPDATE tbl SET '
|| quote_ident(colname)
|| ' = '
|| quote_literal(newvalue)
|| ' WHERE key = '
|| quote_literal(keyvalue);
quote_ident
use in PL/PgSQL
quote_literal
use in PL/PgSQL
This example demonstrates the use of the
quote_ident and
quote_literal functions. For safety,
expressions containing column and table identifiers should be
passed to quote_ident. Expressions containing
values that should be literal strings in the constructed command
should be passed to quote_literal. Both
take the appropriate steps to return the input text enclosed in
double or single quotes respectively, with any embedded special
characters properly escaped.
Note that dollar quoting is only useful for quoting fixed text.
It would be a very bad idea to try to do the above example as
EXECUTE 'UPDATE tbl SET '
|| quote_ident(colname)
|| ' = $$'
|| newvalue
|| '$$ WHERE key = '
|| quote_literal(keyvalue);
because it would break if the contents of newvalue>
happened to contain $$>. 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
must> use quote_literal.
A much larger example of a dynamic command and
EXECUTE can be seen in , which builds and executes a
CREATE FUNCTION> command to define a new function.
Obtaining the Result Status
There are several ways to determine the effect of a command. The
first method is to use the GET DIAGNOSTICS
command, which has the form:
GET DIAGNOSTICS variable = item , ... ;
This command allows retrieval of system status indicators. Each
item 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 ROW_COUNT>, the number of rows
processed by the last SQL command sent down to
the SQL engine, and RESULT_OID>,
the OID of the last row inserted by the most recent
SQL command. Note that RESULT_OID>
is only useful after an INSERT command into a
table containing OIDs.
An example:
GET DIAGNOSTICS integer_var = ROW_COUNT;
The second method to determine the effects of a command is to check the
special variable named FOUND, which is of
type boolean. FOUND starts out
false within each PL/pgSQL function call.
It is set by each of the following types of statements:
A SELECT INTO statement sets
FOUND true if it returns a row, false if no
row is returned.
A PERFORM> statement sets FOUND
true if it produces (and discards) a row, false if no row is
produced.
UPDATE>, INSERT>, and DELETE>
statements set FOUND true if at least one
row is affected, false if no row is affected.
A FETCH> statement sets FOUND
true if it returns a row, false if no row is returned.
A FOR> statement sets FOUND true
if it iterates one or more times, else false. This applies to
all three variants of the FOR> statement (integer
FOR> loops, record-set FOR> loops, and
dynamic record-set FOR>
loops). FOUND is set this way when the
FOR> loop exits; inside the execution of the loop,
FOUND is not modified by the
FOR> statement, although it may be changed by the
execution of other statements within the loop body.
FOUND is a local variable within each
PL/pgSQL function; any changes to it
affect only the current function.
Control Structures
Control structures are probably the most useful (and
important) part of PL/pgSQL>. With
PL/pgSQL>'s control structures,
you can manipulate PostgreSQL> data in a very
flexible and powerful way.
Returning From a Function
There are two commands available that allow you to return data
from a function: RETURN and RETURN
NEXT.
RETURN>
RETURN expression;
RETURN with an expression terminates the
function and returns the value of
expression to the caller. This form
is to be used for PL/pgSQL> functions that do
not return a set.
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 expression.
If you declared the function with output parameters, write just
RETURN with no expression. The current values
of the output parameter variables will be returned.
If you declared the function to return void, a
RETURN statement can be used to exit the function
early; but do not write an expression following
RETURN.
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 RETURN statement, a run-time
error will occur. This restriction does not apply to functions
with output parameters and functions returning void,
however. In those cases a RETURN statement is
automatically executed if the top-level block finishes.
RETURN NEXT>
RETURN NEXT expression;
When a PL/pgSQL> function is declared to return
SETOF sometype>, the procedure
to follow is slightly different. In that case, the individual
items to return are specified in RETURN NEXT
commands, and then a final RETURN command
with no argument is used to indicate that the function has
finished executing. RETURN NEXT can be used
with both scalar and composite data types; with a composite result
type, an entire table
of results will be returned.
RETURN NEXT does not actually return from the
function — it simply saves away the value of the expression.
Execution then continues with the next statement in
the PL/pgSQL> function. As successive
RETURN NEXT commands are executed, the result
set is built up. A final RETURN, which should
have no argument, causes control to exit the function (or you can
just let control reach the end of the function).
If you declared the function with output parameters, write just
RETURN NEXT with no expression. The current values
of the output parameter variable(s) will be saved for eventual return.
Note that you must declare the function as returning
SETOF record when there are
multiple output parameters, or
SETOF sometype> when there is
just one output parameter of type sometype>, in
order to create a set-returning function with output parameters.
Functions that use RETURN NEXT should be
called in the following fashion:
SELECT * FROM some_func();
That is, the function must be used as a table source in a
FROM clause.
The current implementation of RETURN NEXT
for PL/pgSQL> stores the entire result set
before returning from the function, as discussed above. That
means that if a PL/pgSQL> function produces a
very large result set, performance may 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 PL/pgSQL> may
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
configuration variable. Administrators who have sufficient
memory to store larger result sets in memory should consider
increasing this parameter.
Conditionals
IF> statements let you execute commands based on
certain conditions. PL/pgSQL> has five forms of
IF>:
IF ... THEN>>
IF ... THEN ... ELSE>>
IF ... THEN ... ELSE IF>>
IF ... THEN ... ELSIF ... THEN ... ELSE>>
IF ... THEN ... ELSEIF ... THEN ... ELSE>>
IF-THEN>
IF boolean-expression THEN
statements
END IF;
IF-THEN statements are the simplest form of
IF. The statements between
THEN and END IF will be
executed if the condition is true. Otherwise, they are
skipped.
Example:
IF v_user_id <> 0 THEN
UPDATE users SET email = v_email WHERE user_id = v_user_id;
END IF;
IF-THEN-ELSE>
IF boolean-expression THEN
statements
ELSE
statements
END IF;
IF-THEN-ELSE statements add to
IF-THEN by letting you specify an
alternative set of statements that should be executed if the
condition evaluates to false.
Examples:
IF parentid IS NULL OR parentid = ''
THEN
RETURN fullname;
ELSE
RETURN hp_true_filename(parentid) || '/' || fullname;
END IF;
IF v_count > 0 THEN
INSERT INTO users_count (count) VALUES (v_count);
RETURN 't';
ELSE
RETURN 'f';
END IF;
IF-THEN-ELSE IF>
IF statements can be nested, as in the
following example:
IF demo_row.sex = 'm' THEN
pretty_sex := 'man';
ELSE
IF demo_row.sex = 'f' THEN
pretty_sex := 'woman';
END IF;
END IF;
When you use this form, you are actually nesting an
IF statement inside the
ELSE part of an outer IF
statement. Thus you need one END IF
statement for each nested IF and one for the parent
IF-ELSE. This is workable but grows
tedious when there are many alternatives to be checked.
Hence the next form.
IF-THEN-ELSIF-ELSE>
IF boolean-expression THEN
statements
ELSIF boolean-expression THEN
statements
ELSIF boolean-expression THEN
statements
...
ELSE
statements
END IF;
IF-THEN-ELSIF-ELSE> provides a more convenient
method of checking many alternatives in one statement.
Formally it is equivalent to nested
IF-THEN-ELSE-IF-THEN> commands, but only one
END IF> is needed.
Here is an example:
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;
IF-THEN-ELSEIF-ELSE>
ELSEIF> is an alias for ELSIF>.
Simple Loops
loop
in PL/pgSQL
With the LOOP>, EXIT>,
CONTINUE>, WHILE>, and FOR>
statements, you can arrange for your PL/pgSQL>
function to repeat a series of commands.
LOOP>
<<label>>
LOOP
statements
END LOOP label ;
LOOP> defines an unconditional loop that is repeated
indefinitely until terminated by an EXIT> or
RETURN statement. The optional
label can be used by EXIT>
and CONTINUE statements in nested loops to
specify which loop the statement should be applied to.
EXIT>
EXIT
in PL/pgSQL
EXIT label WHEN expression ;
If no label is given, the innermost
loop is terminated and the statement following END
LOOP> is executed next. If label
is given, it must be the label of the current or some outer
level of nested loop or block. Then the named loop or block is
terminated and control continues with the statement after the
loop's/block's corresponding END>.
If WHEN> is specified, the loop exit occurs only if
expression> is true. Otherwise, control passes
to the statement after EXIT>.
EXIT> can be used with all types of loops; it is
not limited to use with unconditional loops. When used with a
BEGIN block, EXIT passes
control to the next statement after the end of the block.
Examples:
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;
CONTINUE>
CONTINUE
in PL/pgSQL
CONTINUE label WHEN expression ;
If no label> is given, the next iteration of
the innermost loop is begun. That is, control is passed back
to the loop control expression (if any), and the body of the
loop is re-evaluated. If label> is present, it
specifies the label of the loop whose execution will be
continued.
If WHEN> is specified, the next iteration of the
loop is begun only if expression> is
true. Otherwise, control passes to the statement after
CONTINUE>.
CONTINUE> can be used with all types of loops; it
is not limited to use with unconditional loops.
Examples:
LOOP
-- some computations
EXIT WHEN count > 100;
CONTINUE WHEN count < 50;
-- some computations for count IN [50 .. 100]
END LOOP;
WHILE>
WHILE
in PL/pgSQL
<<label>>
WHILE expression LOOP
statements
END LOOP label ;
The WHILE> statement repeats a
sequence of statements so long as the condition expression
evaluates to true. The condition is checked just before
each entry to the loop body.
For example:
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;
FOR> (integer variant)
<<label>>
FOR name IN REVERSE expression .. expression LOOP
statements
END LOOP labal ;
This form of FOR> creates a loop that iterates over a range of integer
values. The variable
name is automatically defined as type
integer> and exists only inside the loop. The two expressions giving
the lower and upper bound of the range are evaluated once when entering
the loop. The iteration step is normally 1, but is -1 when REVERSE> is
specified.
Some examples of integer FOR> loops:
FOR i IN 1..10 LOOP
-- some computations here
RAISE NOTICE 'i is %', i;
END LOOP;
FOR i IN REVERSE 10..1 LOOP
-- some computations here
END LOOP;
If the lower bound is greater than the upper bound (or less than,
in the REVERSE> case), the loop body is not
executed at all. No error is raised.
Looping Through Query Results
Using a different type of FOR> loop, you can iterate through
the results of a query and manipulate that data
accordingly. The syntax is:
<<label>>
FOR record_or_row IN query LOOP
statements
END LOOP label ;
The record or row variable is successively assigned each row
resulting from the query (which must be a
SELECT command) and the loop body is executed for each
row. Here is an example:
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;
If the loop is terminated by an EXIT> statement, the last
assigned row value is still accessible after the loop.
The FOR-IN-EXECUTE> statement is another way to iterate over
rows:
<<label>>
FOR record_or_row IN EXECUTE text_expression LOOP
statements
END LOOP label ;
This is like the previous form, except that the source
SELECT statement is specified as a string
expression, which is evaluated and replanned on each entry to
the 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 EXECUTE statement.
The PL/pgSQL> parser presently distinguishes the
two kinds of FOR> loops (integer or query result) by checking
whether ..> appears outside any parentheses between
IN> and LOOP>. If ..> is not seen then
the loop is presumed to be a loop over rows. Mistyping the ..>
is thus likely to lead to a complaint along the lines of
loop variable of loop over rows must be a record or row variable>,
rather than the simple syntax error one might expect to get.
Trapping Errors
exceptions
in PL/PgSQL
By default, any error occurring in a 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 BEGIN> block with an
EXCEPTION> clause. The syntax is an extension of the
normal syntax for a BEGIN> block:
<<label>>
DECLARE
declarations
BEGIN
statements
EXCEPTION
WHEN condition OR condition ... THEN
handler_statements
WHEN condition OR condition ... THEN
handler_statements
...
END;
If no error occurs, this form of block simply executes all the
statements, and then control passes
to the next statement after END>. But if an error
occurs within the statements, further
processing of the statements is
abandoned, and control passes to the EXCEPTION> list.
The list is searched for the first condition
matching the error that occurred. If a match is found, the
corresponding handler_statements are
executed, and then control passes to the next statement after
END>. If no match is found, the error propagates out
as though the EXCEPTION> clause were not there at all:
the error can be caught by an enclosing block with
EXCEPTION>, or if there is none it aborts processing
of the function.
The condition names can be any of
those shown in . A category
name matches any error within its category. The special
condition name OTHERS> matches every error type except
QUERY_CANCELED>. (It is possible, but often unwise,
to trap QUERY_CANCELED> by name.) Condition names are
not case-sensitive.
If a new error occurs within the selected
handler_statements, it cannot be caught
by this EXCEPTION> clause, but is propagated out.
A surrounding EXCEPTION> clause could catch it.
When an error is caught by an EXCEPTION> clause,
the local variables of the 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:
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;
When control reaches the assignment to y>, it will
fail with a division_by_zero> error. This will be caught by
the EXCEPTION> clause. The value returned in the
RETURN> statement will be the incremented value of
x>, but the effects of the UPDATE> command will
have been rolled back. The INSERT> command preceding the
block is not rolled back, however, so the end result is that the database
contains Tom Jones> not Joe Jones>.
A block containing an EXCEPTION> clause is significantly
more expensive to enter and exit than a block without one. Therefore,
don't use EXCEPTION> without need.
Within an exception handler, the SQLSTATE
variable contains the error code that corresponds to the
exception that was raised (refer to for a list of possible error
codes). The SQLERRM variable contains the
error message associated with the exception. These variables are
undefined outside exception handlers.
Exceptions with UPDATE>/INSERT>
This example uses exception handling to perform either
UPDATE> or INSERT>, as appropriate.
CREATE TABLE db (a INT PRIMARY KEY, b TEXT);
CREATE FUNCTION merge_db(key INT, data TEXT) RETURNS VOID AS
$$
BEGIN
LOOP
UPDATE db SET b = data WHERE a = key;
IF found THEN
RETURN;
END IF;
BEGIN
INSERT INTO db(a,b) VALUES (key, data);
RETURN;
EXCEPTION WHEN unique_violation THEN
-- do nothing
END;
END LOOP;
END;
$$
LANGUAGE plpgsql;
SELECT merge_db(1, 'david');
SELECT merge_db(1, 'dennis');
Cursors
cursor
in PL/pgSQL
Rather than executing a whole query at once, it is possible to set
up a 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, PL/pgSQL> users do not normally need
to worry about that, since FOR> loops automatically use a cursor
internally to avoid memory problems.) A more interesting usage is to
return a reference to a cursor that a function has created, allowing the
caller to read the rows. This provides an efficient way to return
large row sets from functions.
Declaring Cursor Variables
All access to cursors in PL/pgSQL> goes through
cursor variables, which are always of the special data type
refcursor>. One way to create a cursor variable
is just to declare it as a variable of type refcursor>.
Another way is to use the cursor declaration syntax,
which in general is:
name CURSOR ( arguments ) FOR query;
(FOR> may be replaced by IS> for
Oracle compatibility.)
arguments, if specified, is a
comma-separated list of pairs name
datatype 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.
Some examples:
DECLARE
curs1 refcursor;
curs2 CURSOR FOR SELECT * FROM tenk1;
curs3 CURSOR (key integer) IS SELECT * FROM tenk1 WHERE unique1 = key;
All three of these variables have the data type refcursor>,
but the first may be used with any query, while the second has
a fully specified query already bound> to it, and the last
has a parameterized query bound to it. (key> will be
replaced by an integer parameter value when the cursor is opened.)
The variable curs1>
is said to be unbound> since it is not bound to
any particular query.
Opening Cursors
Before a cursor can be used to retrieve rows, it must be
opened>. (This is the equivalent action to the SQL
command DECLARE CURSOR>.) PL/pgSQL> has
three forms of the OPEN> statement, two of which use unbound
cursor variables while the third uses a bound cursor variable.
OPEN FOR query
OPEN unbound_cursor FOR query;
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
refcursor> variable). The query must be a
SELECT, or something else that returns rows
(such as EXPLAIN>). The query
is treated in the same way as other SQL commands in
PL/pgSQL>: PL/pgSQL>
variable names are substituted, and the query plan is cached for
possible reuse.
An example:
OPEN curs1 FOR SELECT * FROM foo WHERE key = mykey;
OPEN FOR EXECUTE
OPEN unbound_cursor FOR EXECUTE query_string;
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
refcursor> variable). The query is specified as a string
expression, in the same way as in the EXECUTE
command. As usual, this gives flexibility so the query can vary
from one run to the next.
An example:
OPEN curs1 FOR EXECUTE 'SELECT * FROM ' || quote_ident($1);
Opening a Bound Cursor
OPEN bound_cursor ( argument_values ) ;
This form of OPEN is used to open a cursor
variable whose query was bound to it when it was declared. The
cursor cannot be open already. A list of actual argument value
expressions must appear if and only if the cursor was declared to
take arguments. These values will be substituted in the query.
The query plan for a bound cursor is always considered cacheable;
there is no equivalent of EXECUTE in this case.
Examples:
OPEN curs2;
OPEN curs3(42);
Using Cursors
Once a cursor has been opened, it can be manipulated with the
statements described here.
These manipulations need not occur in the same function that
opened the cursor to begin with. You can return a refcursor>
value out of a function and let the caller operate on the cursor.
(Internally, a 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 refcursor> variables,
and so on, without disturbing the portal.)
All portals are implicitly closed at transaction end. Therefore
a refcursor> value is usable to reference an open cursor
only until the end of the transaction.
FETCH>
FETCH cursor INTO target;
FETCH retrieves the next row from the
cursor into a target, which may be a row variable, a record
variable, or a comma-separated list of simple variables, just like
SELECT INTO. As with SELECT
INTO, the special variable FOUND may
be checked to see whether a row was obtained or not.
An example:
FETCH curs1 INTO rowvar;
FETCH curs2 INTO foo, bar, baz;
CLOSE>
CLOSE cursor;
CLOSE closes the portal underlying an open
cursor. This can be used to release resources earlier than end of
transaction, or to free up the cursor variable to be opened again.
An example:
CLOSE curs1;
Returning Cursors
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.
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 refcursor> variable before
opening it. The string value of the refcursor> variable
will be used by OPEN> as the name of the underlying portal.
However, if the refcursor> variable is null,
OPEN> automatically generates a name that does not
conflict with any existing portal, and assigns it to the
refcursor> variable.
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.
The following example shows one way a cursor name can be supplied by
the caller:
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;
The following example uses automatic cursor name generation:
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;
The following example shows one way to return multiple cursors
from a single function:
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;
Errors and Messages
RAISE
reporting errors
in PL/PgSQL
Use the RAISE statement to report messages and
raise errors.
RAISE level 'format' , expression , ...;
Possible levels are DEBUG,
LOG, INFO,
NOTICE, WARNING,
and EXCEPTION.
EXCEPTION 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
and
configuration
variables. See for more
information.
Inside the format string, % is replaced by the
next optional argument's string representation. Write
%% to emit a literal %.
Arguments can be simple variables or expressions,
and the format must be a simple string literal.
In this example, the value of v_job_id> will replace the
% in the string:
RAISE NOTICE 'Calling cs_create_job(%)', v_job_id;
This example will abort the transaction with the given error message:
RAISE EXCEPTION 'Nonexistent ID --> %', user_id;
RAISE EXCEPTION presently always generates
the same SQLSTATE code, P0001>, no matter what message
it is invoked with. It is possible to trap this exception with
EXCEPTION ... WHEN RAISE_EXCEPTION THEN ...> but there
is no way to tell one RAISE> from another.
Trigger Procedures
trigger
in PL/pgSQL
PL/pgSQL can be used to define trigger
procedures. A trigger procedure is created with the
CREATE FUNCTION> command, declaring it as a function with
no arguments and a return type of trigger. Note that
the function must be declared with no arguments even if it expects
to receive arguments specified in CREATE TRIGGER> —
trigger arguments are passed via TG_ARGV>, as described
below.
When a PL/pgSQL function is called as a
trigger, several special variables are created automatically in the
top-level block. They are:
NEW
Data type RECORD; variable holding the new
database row for INSERT>/UPDATE> operations in row-level
triggers. This variable is NULL in statement-level triggers.
OLD
Data type RECORD; variable holding the old
database row for UPDATE>/DELETE> operations in row-level
triggers. This variable is NULL in statement-level triggers.
TG_NAME
Data type name; variable that contains the name of the trigger actually
fired.
TG_WHEN
Data type text; a string of either
BEFORE or AFTER
depending on the trigger's definition.
TG_LEVEL
Data type text; a string of either
ROW or STATEMENT
depending on the trigger's definition.
TG_OP
Data type text; a string of
INSERT, UPDATE, or
DELETE telling for which operation the
trigger was fired.
TG_RELID
Data type oid; the object ID of the table that caused the
trigger invocation.
TG_RELNAME
Data type name; the name of the table that caused the trigger
invocation.
TG_NARGS
Data type integer; the number of arguments given to the trigger
procedure in the CREATE TRIGGER statement.
TG_ARGV[]
Data type array of text; the arguments from
the CREATE TRIGGER statement.
The index counts from 0. Invalid
indices (less than 0 or greater than or equal to tg_nargs>) result in a null value.
A trigger function must return either NULL or a
record/row value having exactly the structure of the table the
trigger was fired for.
Row-level triggers fired BEFORE> may 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
INSERT>/UPDATE>/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 NEW> alters the row that will be inserted or updated
(but has no direct effect in the DELETE> case).
To alter the row to be stored, it is possible to replace single values
directly in NEW> and return the modified NEW>,
or to build a complete new record/row to return.
The return value of a BEFORE> or AFTER>
statement-level trigger or an AFTER> row-level trigger is
always ignored; it may as well be null. However, any of these types of
triggers can still abort the entire operation by raising an error.
shows an example of a
trigger procedure in PL/pgSQL.
A PL/pgSQL Trigger Procedure
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.
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();
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.
shows an example of an
audit trigger procedure in PL/pgSQL.
A PL/pgSQL Trigger Procedure For Auditing
This example trigger ensures that any insert, update or delete of a row
in the emp table is recorded (i.e., audited) in the emp_audit table.
The current time and user name are stamped into the row, together with
the type of operation performed on it.
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();
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) can be extremely large.
shows an example of a
trigger procedure in PL/pgSQL that maintains
a summary table for a fact table in a data warehouse.
A PL/pgSQL Trigger Procedure For Maintaining A Summary Table
The schema detailed here is partly based on the Grocery Store
example from The Data Warehouse Toolkit
by Ralph Kimball.
--
-- 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;
-- Update the summary row with the new values.
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;
-- There might have been no row with this time_key (e.g new data!).
IF (NOT FOUND) THEN
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
);
EXCEPTION
--
-- Catch race condition when two transactions are adding data
-- for a new time_key.
--
WHEN UNIQUE_VIOLATION THEN
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;
END;
END IF;
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();
Porting from Oracle PL/SQL
Oracle
porting from PL/SQL to PL/pgSQL
PL/SQL (Oracle)
porting to PL/pgSQL
This section explains differences between
PostgreSQL>'s PL/pgSQL
language and Oracle's PL/SQL language,
to help developers who port applications from
Oracle> to PostgreSQL>.
PL/pgSQL 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 PL/SQL> to
PL/pgSQL are:
There are no default values for parameters in PostgreSQL>.
You can overload function names in PostgreSQL>. This is
often used to work around the lack of default parameters.
No need for cursors in PL/pgSQL>, just put the
query in the FOR statement. (See .)
In PostgreSQL> the function body has to be written as
a string literal. Therefore you need to use dollar quoting or escape
single quotes in the function body. See .
Instead of packages, use schemas to organize your functions
into groups.
Since there are no packages, there are no package-level variables
either. This is somewhat annoying. You may be able to keep per-session
state in temporary tables, instead.
Porting Examples
shows how to port a simple
function from PL/SQL> to PL/pgSQL>.
Porting a Simple Function from PL/SQL> to PL/pgSQL>
Here is an Oracle PL/SQL> function:
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;
Let's go through this function and see the differences compared to
PL/pgSQL>:
The RETURN key word in the function
prototype (not the function body) becomes
RETURNS in
PostgreSQL.
Also, IS> becomes AS>, and you need to
add a LANGUAGE> clause because PL/pgSQL>
is not the only possible function language.
In 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 />
in the Oracle approach.
The show errors command does not exist in
PostgreSQL>, and is not needed since errors are
reported automatically.
This is how this function would look when ported to
PostgreSQL>:
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;
shows how to port a
function that creates another function and how to handle the
ensuing quoting problems.
Porting a Function that Creates Another Function from PL/SQL> to PL/pgSQL>
The following procedure grabs rows from a
SELECT statement and builds a large function
with the results in IF statements, for the
sake of efficiency. Notice particularly the differences in the
cursor and the FOR loop.
This is the Oracle version:
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;
Here is how this function would end up in PostgreSQL>:
CREATE OR REPLACE FUNCTION cs_update_referrer_type_proc() RETURNS void AS $func$
DECLARE
referrer_key RECORD; -- declare a generic record to be used in a FOR
func_body text;
func_cmd text;
BEGIN
func_body := 'BEGIN';
-- Notice how we scan through the results of a query in a FOR loop
-- using the FOR <record> construct.
FOR referrer_key IN SELECT * FROM cs_referrer_keys ORDER BY try_order 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;
Notice how the body of the function is built separately and passed
through 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 referrer_key.key_string> field.
(We are assuming here that referrer_key.kind> can be
trusted to always be host>, domain>, or
url>, but 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 referrer_key.key_string> or
referrer_key.referrer_type> contain quote marks.
shows how to port a function
with OUT> parameters and string manipulation.
PostgreSQL> does not have a built-in
instr function, but you can create one
using a combination of other
functions.instr> In there is a
PL/pgSQL implementation of
instr that you can use to make your porting
easier.
Porting a Procedure With String Manipulation and
OUT> Parameters from PL/SQL> to
PL/pgSQL>
The following Oracle PL/SQL procedure is used
to parse a URL and return several elements (host, path, and query).
This is the Oracle version:
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;
Here is a possible translation into PL/pgSQL>:
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;
This function could be used like this:
SELECT * FROM cs_parse_url('http://foobar.com/query.cgi?baz');
shows how to port a procedure
that uses numerous features that are specific to Oracle.
Porting a Procedure from PL/SQL> to PL/pgSQL>
The Oracle version:
CREATE OR REPLACE PROCEDURE cs_create_job(v_job_id IN INTEGER) IS
a_running_job_count INTEGER;
PRAGMA AUTONOMOUS_TRANSACTION;
BEGIN
LOCK TABLE cs_jobs IN EXCLUSIVE MODE;
SELECT count(*) INTO a_running_job_count FROM cs_jobs WHERE end_stamp IS NULL;
IF a_running_job_count > 0 THEN
COMMIT; -- free lock
raise_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
Procedures like this can easily be converted into PostgreSQL>
functions returning void. This procedure in
particular is interesting because it can teach us some things:
There is no PRAGMA statement in PostgreSQL>.
If you do a LOCK TABLE in PL/pgSQL>,
the lock will not be released until the calling transaction is
finished.
You cannot issue COMMIT> in a
PL/pgSQL function. The function is
running within some outer transaction and so COMMIT>
would imply terminating the function's execution. However, in
this particular case it is not necessary anyway, because the lock
obtained by the LOCK TABLE will be released when
we raise an error.
This is how we could port this procedure to PL/pgSQL>:
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';
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
-- don't worry if it already exists
END;
END;
$$ LANGUAGE plpgsql;
The syntax of RAISE> is considerably different from
Oracle's similar statement.
The exception names supported by PL/pgSQL> are
different from Oracle's. The set of built-in exception names
is much larger (see ). There
is not currently a way to declare user-defined exception names.
The main functional difference between this procedure and the
Oracle equivalent is that the exclusive lock on the 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.
Other Things to Watch For
This section explains a few other things to watch for when porting
Oracle PL/SQL> functions to
PostgreSQL.
Implicit Rollback after Exceptions
In PL/pgSQL>, when an exception is caught by an
EXCEPTION> clause, all database changes since the block's
BEGIN> are automatically rolled back. That is, the behavior
is equivalent to what you'd get in Oracle with
BEGIN
SAVEPOINT s1;
... code here ...
EXCEPTION
WHEN ... THEN
ROLLBACK TO s1;
... code here ...
WHEN ... THEN
ROLLBACK TO s1;
... code here ...
END;
If you are translating an Oracle procedure that uses
SAVEPOINT> and ROLLBACK TO> in this style,
your task is easy: just omit the SAVEPOINT> and
ROLLBACK TO>. If you have a procedure that uses
SAVEPOINT> and ROLLBACK TO> in a different way
then some actual thought will be required.
EXECUTE
The PL/pgSQL> version of
EXECUTE works similarly to the
PL/SQL> version, but you have to remember to use
quote_literal and
quote_ident as described in . Constructs of the
type EXECUTE 'SELECT * FROM $1'; will not work
unless you use these functions.
Optimizing PL/pgSQL Functions
PostgreSQL> gives you two function creation
modifiers to optimize execution: volatility> (whether the
function always returns the same result when given the same
arguments) and strictness
(whether the
function returns null if any argument is null). Consult the
reference page for details.
When making use of these optimization attributes, your
CREATE FUNCTION statement might look something
like this:
CREATE FUNCTION foo(...) RETURNS integer AS $$
...
$$ LANGUAGE plpgsql STRICT IMMUTABLE;
Appendix
This section contains the code for a set of Oracle-compatible
instr functions that you can use to simplify
your porting efforts.
--
-- 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;