- publishing free software manuals
PostgreSQL Reference Manual - Volume 2 - Programming Guide
by The PostgreSQL Global Development Group
Paperback (6"x9"), 408 pages
ISBN 0954612035
RRP £19.95 ($34.95)

Sales of this book support the PostgreSQL project! Get a printed copy>>>

9.1 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). 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.

Note: The PL/pgSQL EXECUTE statement is not related to the Volume 1: EXECUTE SQL statement supported by the PostgreSQL server. The server's EXECUTE statement cannot be used within PL/pgSQL functions (and is not needed).

ISBN 0954612035PostgreSQL Reference Manual - Volume 2 - Programming GuideSee the print edition