Sophie

Sophie

distrib > Mandriva > 2006.0 > x86_64 > by-pkgid > b8f4049de69feba5041d49ed4382e582 > files > 280

postgresql-docs-8.0.11-0.1.20060mdk.x86_64.rpm

<!DOCTYPE HTML PUBLIC "-//W3C//DTD HTML 4.01 Transitional//EN" "http://www.w3.org/TR/html4/loose.dtd">
<HTML
><HEAD
><TITLE
>Control Structures</TITLE
><META
NAME="GENERATOR"
CONTENT="Modular DocBook HTML Stylesheet Version 1.79"><LINK
REV="MADE"
HREF="mailto:pgsql-docs@postgresql.org"><LINK
REL="HOME"
TITLE="PostgreSQL 8.0.11 Documentation"
HREF="index.html"><LINK
REL="UP"
TITLE="PL/pgSQL - SQL Procedural Language"
HREF="plpgsql.html"><LINK
REL="PREVIOUS"
TITLE="Basic Statements"
HREF="plpgsql-statements.html"><LINK
REL="NEXT"
TITLE="Cursors"
HREF="plpgsql-cursors.html"><LINK
REL="STYLESHEET"
TYPE="text/css"
HREF="stylesheet.css"><META
HTTP-EQUIV="Content-Type"
CONTENT="text/html; charset=ISO-8859-1"><META
NAME="creation"
CONTENT="2007-02-02T03:57:22"></HEAD
><BODY
CLASS="SECT1"
><DIV
CLASS="NAVHEADER"
><TABLE
SUMMARY="Header navigation table"
WIDTH="100%"
BORDER="0"
CELLPADDING="0"
CELLSPACING="0"
><TR
><TH
COLSPAN="5"
ALIGN="center"
VALIGN="bottom"
>PostgreSQL 8.0.11 Documentation</TH
></TR
><TR
><TD
WIDTH="10%"
ALIGN="left"
VALIGN="top"
><A
HREF="plpgsql-statements.html"
ACCESSKEY="P"
>Prev</A
></TD
><TD
WIDTH="10%"
ALIGN="left"
VALIGN="top"
><A
HREF="plpgsql.html"
>Fast Backward</A
></TD
><TD
WIDTH="60%"
ALIGN="center"
VALIGN="bottom"
>Chapter 35. <SPAN
CLASS="APPLICATION"
>PL/pgSQL</SPAN
> - <ACRONYM
CLASS="ACRONYM"
>SQL</ACRONYM
> Procedural Language</TD
><TD
WIDTH="10%"
ALIGN="right"
VALIGN="top"
><A
HREF="plpgsql.html"
>Fast Forward</A
></TD
><TD
WIDTH="10%"
ALIGN="right"
VALIGN="top"
><A
HREF="plpgsql-cursors.html"
ACCESSKEY="N"
>Next</A
></TD
></TR
></TABLE
><HR
ALIGN="LEFT"
WIDTH="100%"></DIV
><DIV
CLASS="SECT1"
><H1
CLASS="SECT1"
><A
NAME="PLPGSQL-CONTROL-STRUCTURES"
>35.7. Control Structures</A
></H1
><P
>    Control structures are probably the most useful (and
    important) part of <SPAN
CLASS="APPLICATION"
>PL/pgSQL</SPAN
>. With
    <SPAN
CLASS="APPLICATION"
>PL/pgSQL</SPAN
>'s control structures,
    you can manipulate <SPAN
CLASS="PRODUCTNAME"
>PostgreSQL</SPAN
> data in a very
    flexible and powerful way. 
   </P
><DIV
CLASS="SECT2"
><H2
CLASS="SECT2"
><A
NAME="PLPGSQL-STATEMENTS-RETURNING"
>35.7.1. Returning From a Function</A
></H2
><P
>     There are two commands available that allow you to return data
     from a function: <TT
CLASS="COMMAND"
>RETURN</TT
> and <TT
CLASS="COMMAND"
>RETURN
     NEXT</TT
>.
    </P
><DIV
CLASS="SECT3"
><H3
CLASS="SECT3"
><A
NAME="AEN32947"
>35.7.1.1. <TT
CLASS="COMMAND"
>RETURN</TT
></A
></H3
><PRE
CLASS="SYNOPSIS"
>RETURN <TT
CLASS="REPLACEABLE"
><I
>expression</I
></TT
>;</PRE
><P
>      <TT
CLASS="COMMAND"
>RETURN</TT
> with an expression terminates the
      function and returns the value of
      <TT
CLASS="REPLACEABLE"
><I
>expression</I
></TT
> to the caller.  This form
      is to be used for <SPAN
CLASS="APPLICATION"
>PL/pgSQL</SPAN
> functions that do
      not return a set.
     </P
><P
>      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 <TT
CLASS="REPLACEABLE"
><I
>expression</I
></TT
>.
     </P
><P
>      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 <TT
CLASS="COMMAND"
>RETURN</TT
> statement, a run-time
      error will occur.
     </P
><P
>      If you have declared the function to
      return <TT
CLASS="TYPE"
>void</TT
>, a <TT
CLASS="COMMAND"
>RETURN</TT
> statement
      must still be provided; but in this case the expression following
      <TT
CLASS="COMMAND"
>RETURN</TT
> is optional and will be ignored if present.
     </P
></DIV
><DIV
CLASS="SECT3"
><H3
CLASS="SECT3"
><A
NAME="AEN32964"
>35.7.1.2. <TT
CLASS="COMMAND"
>RETURN NEXT</TT
></A
></H3
><PRE
CLASS="SYNOPSIS"
>RETURN NEXT <TT
CLASS="REPLACEABLE"
><I
>expression</I
></TT
>;</PRE
><P
>      When a <SPAN
CLASS="APPLICATION"
>PL/pgSQL</SPAN
> function is declared to return
      <TT
CLASS="LITERAL"
>SETOF <TT
CLASS="REPLACEABLE"
><I
>sometype</I
></TT
></TT
>, the procedure
      to follow is slightly different.  In that case, the individual
      items to return are specified in <TT
CLASS="COMMAND"
>RETURN NEXT</TT
>
      commands, and then a final <TT
CLASS="COMMAND"
>RETURN</TT
> command
      with no argument is used to indicate that the function has
      finished executing.  <TT
CLASS="COMMAND"
>RETURN NEXT</TT
> can be used
      with both scalar and composite data types; in the latter case, an
      entire <SPAN
CLASS="QUOTE"
>"table"</SPAN
> of results will be returned.
     </P
><P
>      Functions that use <TT
CLASS="COMMAND"
>RETURN NEXT</TT
> should be
      called in the following fashion:

</P><PRE
CLASS="PROGRAMLISTING"
>SELECT * FROM some_func();</PRE
><P>

      That is, the function must be used as a table source in a
      <TT
CLASS="LITERAL"
>FROM</TT
> clause.
     </P
><P
>      <TT
CLASS="COMMAND"
>RETURN NEXT</TT
> 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 <SPAN
CLASS="APPLICATION"
>PL/pgSQL</SPAN
> function.  As successive
      <TT
CLASS="COMMAND"
>RETURN NEXT</TT
> commands are executed, the result
      set is built up.  A final <TT
CLASS="COMMAND"
>RETURN</TT
>, which should
      have no argument, causes control to exit the function.
     </P
><DIV
CLASS="NOTE"
><BLOCKQUOTE
CLASS="NOTE"
><P
><B
>Note: </B
>       The current implementation of <TT
CLASS="COMMAND"
>RETURN NEXT</TT
>
       for <SPAN
CLASS="APPLICATION"
>PL/pgSQL</SPAN
> stores the entire result set
       before returning from the function, as discussed above.  That
       means that if a <SPAN
CLASS="APPLICATION"
>PL/pgSQL</SPAN
> 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 <SPAN
CLASS="APPLICATION"
>PL/pgSQL</SPAN
> 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
       <TT
CLASS="VARNAME"
>work_mem</TT
> configuration variable.  Administrators
       who have sufficient memory to store larger result sets in
       memory should consider increasing this parameter.
      </P
></BLOCKQUOTE
></DIV
></DIV
></DIV
><DIV
CLASS="SECT2"
><H2
CLASS="SECT2"
><A
NAME="PLPGSQL-CONDITIONALS"
>35.7.2. Conditionals</A
></H2
><P
>     <TT
CLASS="LITERAL"
>IF</TT
> statements let you execute commands based on
     certain conditions.  <SPAN
CLASS="APPLICATION"
>PL/pgSQL</SPAN
> has five forms of
     <TT
CLASS="LITERAL"
>IF</TT
>:
    <P
></P
></P><UL
><LI
><P
><TT
CLASS="LITERAL"
>IF ... THEN</TT
></P
></LI
><LI
><P
><TT
CLASS="LITERAL"
>IF ... THEN ... ELSE</TT
></P
></LI
><LI
><P
><TT
CLASS="LITERAL"
>IF ... THEN ... ELSE IF</TT
></P
></LI
><LI
><P
><TT
CLASS="LITERAL"
>IF ... THEN ... ELSIF ... THEN ... ELSE</TT
></P
></LI
><LI
><P
><TT
CLASS="LITERAL"
>IF ... THEN ... ELSEIF ... THEN ... ELSE</TT
></P
></LI
></UL
><P>
    </P
><DIV
CLASS="SECT3"
><H3
CLASS="SECT3"
><A
NAME="AEN33015"
>35.7.2.1. <TT
CLASS="LITERAL"
>IF-THEN</TT
></A
></H3
><PRE
CLASS="SYNOPSIS"
>IF <TT
CLASS="REPLACEABLE"
><I
>boolean-expression</I
></TT
> THEN
    <TT
CLASS="REPLACEABLE"
><I
>statements</I
></TT
>
END IF;</PRE
><P
>        <TT
CLASS="LITERAL"
>IF-THEN</TT
> statements are the simplest form of
        <TT
CLASS="LITERAL"
>IF</TT
>. The statements between
        <TT
CLASS="LITERAL"
>THEN</TT
> and <TT
CLASS="LITERAL"
>END IF</TT
> will be
        executed if the condition is true. Otherwise, they are
        skipped.
       </P
><P
>        Example:
</P><PRE
CLASS="PROGRAMLISTING"
>IF v_user_id &lt;&gt; 0 THEN
    UPDATE users SET email = v_email WHERE user_id = v_user_id;
END IF;</PRE
><P>
       </P
></DIV
><DIV
CLASS="SECT3"
><H3
CLASS="SECT3"
><A
NAME="AEN33028"
>35.7.2.2. <TT
CLASS="LITERAL"
>IF-THEN-ELSE</TT
></A
></H3
><PRE
CLASS="SYNOPSIS"
>IF <TT
CLASS="REPLACEABLE"
><I
>boolean-expression</I
></TT
> THEN
    <TT
CLASS="REPLACEABLE"
><I
>statements</I
></TT
>
ELSE
    <TT
CLASS="REPLACEABLE"
><I
>statements</I
></TT
>
END IF;</PRE
><P
>        <TT
CLASS="LITERAL"
>IF-THEN-ELSE</TT
> statements add to
        <TT
CLASS="LITERAL"
>IF-THEN</TT
> by letting you specify an
        alternative set of statements that should be executed if the
        condition evaluates to false.
       </P
><P
>        Examples:
</P><PRE
CLASS="PROGRAMLISTING"
>IF parentid IS NULL OR parentid = ''
THEN
    RETURN fullname;
ELSE
    RETURN hp_true_filename(parentid) || '/' || fullname;
END IF;</PRE
><P>

</P><PRE
CLASS="PROGRAMLISTING"
>IF v_count &gt; 0 THEN 
    INSERT INTO users_count (count) VALUES (v_count);
    RETURN 't';
ELSE
    RETURN 'f';
END IF;</PRE
><P>
     </P
></DIV
><DIV
CLASS="SECT3"
><H3
CLASS="SECT3"
><A
NAME="AEN33041"
>35.7.2.3. <TT
CLASS="LITERAL"
>IF-THEN-ELSE IF</TT
></A
></H3
><P
>        <TT
CLASS="LITERAL"
>IF</TT
> statements can be nested, as in the
        following example:

</P><PRE
CLASS="PROGRAMLISTING"
>IF demo_row.sex = 'm' THEN
    pretty_sex := 'man';
ELSE
    IF demo_row.sex = 'f' THEN
        pretty_sex := 'woman';
    END IF;
END IF;</PRE
><P>
       </P
><P
>        When you use this form, you are actually nesting an
        <TT
CLASS="LITERAL"
>IF</TT
> statement inside the
        <TT
CLASS="LITERAL"
>ELSE</TT
> part of an outer <TT
CLASS="LITERAL"
>IF</TT
>
        statement. Thus you need one <TT
CLASS="LITERAL"
>END IF</TT
>
        statement for each nested <TT
CLASS="LITERAL"
>IF</TT
> and one for the parent
        <TT
CLASS="LITERAL"
>IF-ELSE</TT
>.  This is workable but grows
        tedious when there are many alternatives to be checked.
        Hence the next form.
       </P
></DIV
><DIV
CLASS="SECT3"
><H3
CLASS="SECT3"
><A
NAME="AEN33054"
>35.7.2.4. <TT
CLASS="LITERAL"
>IF-THEN-ELSIF-ELSE</TT
></A
></H3
><PRE
CLASS="SYNOPSIS"
>IF <TT
CLASS="REPLACEABLE"
><I
>boolean-expression</I
></TT
> THEN
    <TT
CLASS="REPLACEABLE"
><I
>statements</I
></TT
>
[<SPAN
CLASS="OPTIONAL"
> ELSIF <TT
CLASS="REPLACEABLE"
><I
>boolean-expression</I
></TT
> THEN
    <TT
CLASS="REPLACEABLE"
><I
>statements</I
></TT
>
[<SPAN
CLASS="OPTIONAL"
> ELSIF <TT
CLASS="REPLACEABLE"
><I
>boolean-expression</I
></TT
> THEN
    <TT
CLASS="REPLACEABLE"
><I
>statements</I
></TT
>
    ...</SPAN
>]</SPAN
>]
[<SPAN
CLASS="OPTIONAL"
> ELSE
    <TT
CLASS="REPLACEABLE"
><I
>statements</I
></TT
> </SPAN
>]
END IF;</PRE
><P
>        <TT
CLASS="LITERAL"
>IF-THEN-ELSIF-ELSE</TT
> provides a more convenient
        method of checking many alternatives in one statement.
        Formally it is equivalent to nested
        <TT
CLASS="LITERAL"
>IF-THEN-ELSE-IF-THEN</TT
> commands, but only one
        <TT
CLASS="LITERAL"
>END IF</TT
> is needed.
       </P
><P
>        Here is an example:

</P><PRE
CLASS="PROGRAMLISTING"
>IF number = 0 THEN
    result := 'zero';
ELSIF number &gt; 0 THEN 
    result := 'positive';
ELSIF number &lt; 0 THEN
    result := 'negative';
ELSE
    -- hmm, the only other possibility is that number is null
    result := 'NULL';
END IF;</PRE
><P>
       </P
></DIV
><DIV
CLASS="SECT3"
><H3
CLASS="SECT3"
><A
NAME="AEN33074"
>35.7.2.5. <TT
CLASS="LITERAL"
>IF-THEN-ELSEIF-ELSE</TT
></A
></H3
><P
>       <TT
CLASS="LITERAL"
>ELSEIF</TT
> is an alias for <TT
CLASS="LITERAL"
>ELSIF</TT
>.
      </P
></DIV
></DIV
><DIV
CLASS="SECT2"
><H2
CLASS="SECT2"
><A
NAME="PLPGSQL-CONTROL-STRUCTURES-LOOPS"
>35.7.3. Simple Loops</A
></H2
><A
NAME="AEN33082"
></A
><P
>     With the <TT
CLASS="LITERAL"
>LOOP</TT
>, <TT
CLASS="LITERAL"
>EXIT</TT
>, <TT
CLASS="LITERAL"
>WHILE</TT
>,
     and <TT
CLASS="LITERAL"
>FOR</TT
> statements, you can arrange for your
     <SPAN
CLASS="APPLICATION"
>PL/pgSQL</SPAN
> function to repeat a series
     of commands.
    </P
><DIV
CLASS="SECT3"
><H3
CLASS="SECT3"
><A
NAME="AEN33091"
>35.7.3.1. <TT
CLASS="LITERAL"
>LOOP</TT
></A
></H3
><PRE
CLASS="SYNOPSIS"
>[<SPAN
CLASS="OPTIONAL"
>&lt;&lt;<TT
CLASS="REPLACEABLE"
><I
>label</I
></TT
>&gt;&gt;</SPAN
>]
LOOP
    <TT
CLASS="REPLACEABLE"
><I
>statements</I
></TT
>
END LOOP;</PRE
><P
>      <TT
CLASS="LITERAL"
>LOOP</TT
> defines an unconditional loop that is repeated indefinitely
      until terminated by an <TT
CLASS="LITERAL"
>EXIT</TT
> or <TT
CLASS="COMMAND"
>RETURN</TT
>
      statement.  The optional label can be used by <TT
CLASS="LITERAL"
>EXIT</TT
> statements in
      nested loops to specify which level of nesting should be
      terminated.
     </P
></DIV
><DIV
CLASS="SECT3"
><H3
CLASS="SECT3"
><A
NAME="AEN33103"
>35.7.3.2. <TT
CLASS="LITERAL"
>EXIT</TT
></A
></H3
><PRE
CLASS="SYNOPSIS"
>EXIT [<SPAN
CLASS="OPTIONAL"
> <TT
CLASS="REPLACEABLE"
><I
>label</I
></TT
> </SPAN
>] [<SPAN
CLASS="OPTIONAL"
> WHEN <TT
CLASS="REPLACEABLE"
><I
>expression</I
></TT
> </SPAN
>];</PRE
><P
>        If no <TT
CLASS="REPLACEABLE"
><I
>label</I
></TT
> is given,
        the innermost loop is terminated and the
        statement following <TT
CLASS="LITERAL"
>END LOOP</TT
> is executed next.
        If <TT
CLASS="REPLACEABLE"
><I
>label</I
></TT
> 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
        <TT
CLASS="LITERAL"
>END</TT
>.
       </P
><P
>        If <TT
CLASS="LITERAL"
>WHEN</TT
> is present, loop exit occurs only if the specified
        condition is true, otherwise control passes to the statement after
        <TT
CLASS="LITERAL"
>EXIT</TT
>.
       </P
><P
>        <TT
CLASS="LITERAL"
>EXIT</TT
> can be used to cause early exit from all types of
        loops; it is not limited to use with unconditional loops.
       </P
><P
>        Examples:
</P><PRE
CLASS="PROGRAMLISTING"
>LOOP
    -- some computations
    IF count &gt; 0 THEN
        EXIT;  -- exit loop
    END IF;
END LOOP;

LOOP
    -- some computations
    EXIT WHEN count &gt; 0;  -- same result as previous example
END LOOP;

BEGIN
    -- some computations
    IF stocks &gt; 100000 THEN
        EXIT;  -- causes exit from the BEGIN block
    END IF;
END;</PRE
><P>
       </P
></DIV
><DIV
CLASS="SECT3"
><H3
CLASS="SECT3"
><A
NAME="AEN33123"
>35.7.3.3. <TT
CLASS="LITERAL"
>WHILE</TT
></A
></H3
><PRE
CLASS="SYNOPSIS"
>[<SPAN
CLASS="OPTIONAL"
>&lt;&lt;<TT
CLASS="REPLACEABLE"
><I
>label</I
></TT
>&gt;&gt;</SPAN
>]
WHILE <TT
CLASS="REPLACEABLE"
><I
>expression</I
></TT
> LOOP
    <TT
CLASS="REPLACEABLE"
><I
>statements</I
></TT
>
END LOOP;</PRE
><P
>        The <TT
CLASS="LITERAL"
>WHILE</TT
> 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.
       </P
><P
>        For example:
</P><PRE
CLASS="PROGRAMLISTING"
>WHILE amount_owed &gt; 0 AND gift_certificate_balance &gt; 0 LOOP
    -- some computations here
END LOOP;

WHILE NOT boolean_expression LOOP
    -- some computations here
END LOOP;</PRE
><P>
       </P
></DIV
><DIV
CLASS="SECT3"
><H3
CLASS="SECT3"
><A
NAME="AEN33135"
>35.7.3.4. <TT
CLASS="LITERAL"
>FOR</TT
> (integer variant)</A
></H3
><PRE
CLASS="SYNOPSIS"
>[<SPAN
CLASS="OPTIONAL"
>&lt;&lt;<TT
CLASS="REPLACEABLE"
><I
>label</I
></TT
>&gt;&gt;</SPAN
>]
FOR <TT
CLASS="REPLACEABLE"
><I
>name</I
></TT
> IN [<SPAN
CLASS="OPTIONAL"
> REVERSE </SPAN
>] <TT
CLASS="REPLACEABLE"
><I
>expression</I
></TT
> .. <TT
CLASS="REPLACEABLE"
><I
>expression</I
></TT
> LOOP
    <TT
CLASS="REPLACEABLE"
><I
>statements</I
></TT
>
END LOOP;</PRE
><P
>        This form of <TT
CLASS="LITERAL"
>FOR</TT
> creates a loop that iterates over a range of integer
        values. The variable 
        <TT
CLASS="REPLACEABLE"
><I
>name</I
></TT
> is automatically defined as type
        <TT
CLASS="TYPE"
>integer</TT
> 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 <TT
CLASS="LITERAL"
>REVERSE</TT
> is
        specified.
       </P
><P
>        Some examples of integer <TT
CLASS="LITERAL"
>FOR</TT
> loops:
</P><PRE
CLASS="PROGRAMLISTING"
>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;</PRE
><P>
       </P
><P
>        If the lower bound is greater than the upper bound (or less than,
        in the <TT
CLASS="LITERAL"
>REVERSE</TT
> case), the loop body is not
        executed at all.  No error is raised.
       </P
></DIV
></DIV
><DIV
CLASS="SECT2"
><H2
CLASS="SECT2"
><A
NAME="PLPGSQL-RECORDS-ITERATING"
>35.7.4. Looping Through Query Results</A
></H2
><P
>     Using a different type of <TT
CLASS="LITERAL"
>FOR</TT
> loop, you can iterate through
     the results of a query and manipulate that data
     accordingly. The syntax is:
</P><PRE
CLASS="SYNOPSIS"
>[<SPAN
CLASS="OPTIONAL"
>&lt;&lt;<TT
CLASS="REPLACEABLE"
><I
>label</I
></TT
>&gt;&gt;</SPAN
>]
FOR <TT
CLASS="REPLACEABLE"
><I
>record_or_row</I
></TT
> IN <TT
CLASS="REPLACEABLE"
><I
>query</I
></TT
> LOOP
    <TT
CLASS="REPLACEABLE"
><I
>statements</I
></TT
>
END LOOP;</PRE
><P>
     The record or row variable is successively assigned each row
     resulting from the <TT
CLASS="REPLACEABLE"
><I
>query</I
></TT
> (which must be a
     <TT
CLASS="COMMAND"
>SELECT</TT
> command) and the loop body is executed for each
     row. Here is an example:
</P><PRE
CLASS="PROGRAMLISTING"
>CREATE FUNCTION cs_refresh_mviews() RETURNS integer AS $$
DECLARE
    mviews RECORD;
BEGIN
    PERFORM cs_log('Refreshing materialized views...');

    FOR mviews IN SELECT * FROM cs_materialized_views ORDER BY sort_key LOOP

        -- Now "mviews" has one record from cs_materialized_views

        PERFORM cs_log('Refreshing materialized view ' || quote_ident(mviews.mv_name) || ' ...');
        EXECUTE 'TRUNCATE TABLE ' || quote_ident(mviews.mv_name);
        EXECUTE 'INSERT INTO ' || quote_ident(mviews.mv_name) || ' ' || mviews.mv_query;
    END LOOP;

    PERFORM cs_log('Done refreshing materialized views.');
    RETURN 1;
END;
$$ LANGUAGE plpgsql;</PRE
><P>

     If the loop is terminated by an <TT
CLASS="LITERAL"
>EXIT</TT
> statement, the last
     assigned row value is still accessible after the loop.
    </P
><P
>     The <TT
CLASS="LITERAL"
>FOR-IN-EXECUTE</TT
> statement is another way to iterate over
     rows:
</P><PRE
CLASS="SYNOPSIS"
>[<SPAN
CLASS="OPTIONAL"
>&lt;&lt;<TT
CLASS="REPLACEABLE"
><I
>label</I
></TT
>&gt;&gt;</SPAN
>]
FOR <TT
CLASS="REPLACEABLE"
><I
>record_or_row</I
></TT
> IN EXECUTE <TT
CLASS="REPLACEABLE"
><I
>text_expression</I
></TT
> LOOP 
    <TT
CLASS="REPLACEABLE"
><I
>statements</I
></TT
>
END LOOP;</PRE
><P>
     This is like the previous form, except that the source
     <TT
CLASS="COMMAND"
>SELECT</TT
> statement is specified as a string
     expression, which is evaluated and replanned on each entry to
     the <TT
CLASS="LITERAL"
>FOR</TT
> 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 <TT
CLASS="COMMAND"
>EXECUTE</TT
> statement.
    </P
><DIV
CLASS="NOTE"
><BLOCKQUOTE
CLASS="NOTE"
><P
><B
>Note: </B
>     The <SPAN
CLASS="APPLICATION"
>PL/pgSQL</SPAN
> parser presently distinguishes the
     two kinds of <TT
CLASS="LITERAL"
>FOR</TT
> loops (integer or query result) by checking
     whether <TT
CLASS="LITERAL"
>..</TT
> appears outside any parentheses between
     <TT
CLASS="LITERAL"
>IN</TT
> and <TT
CLASS="LITERAL"
>LOOP</TT
>.  If <TT
CLASS="LITERAL"
>..</TT
> is not seen then
     the loop is presumed to be a loop over rows.  Mistyping the <TT
CLASS="LITERAL"
>..</TT
>
     is thus likely to lead to a complaint along the lines of
     <SPAN
CLASS="QUOTE"
>"loop variable of loop over rows must be a record or row variable"</SPAN
>,
     rather than the simple syntax error one might expect to get.
    </P
></BLOCKQUOTE
></DIV
></DIV
><DIV
CLASS="SECT2"
><H2
CLASS="SECT2"
><A
NAME="PLPGSQL-ERROR-TRAPPING"
>35.7.5. Trapping Errors</A
></H2
><P
>     By default, any error occurring in a <SPAN
CLASS="APPLICATION"
>PL/pgSQL</SPAN
>
     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 <TT
CLASS="COMMAND"
>BEGIN</TT
> block with an
     <TT
CLASS="LITERAL"
>EXCEPTION</TT
> clause.  The syntax is an extension of the
     normal syntax for a <TT
CLASS="COMMAND"
>BEGIN</TT
> block:

</P><PRE
CLASS="SYNOPSIS"
>[<SPAN
CLASS="OPTIONAL"
> &lt;&lt;<TT
CLASS="REPLACEABLE"
><I
>label</I
></TT
>&gt;&gt; </SPAN
>]
[<SPAN
CLASS="OPTIONAL"
> DECLARE
    <TT
CLASS="REPLACEABLE"
><I
>declarations</I
></TT
> </SPAN
>]
BEGIN
    <TT
CLASS="REPLACEABLE"
><I
>statements</I
></TT
>
EXCEPTION
    WHEN <TT
CLASS="REPLACEABLE"
><I
>condition</I
></TT
> [<SPAN
CLASS="OPTIONAL"
> OR <TT
CLASS="REPLACEABLE"
><I
>condition</I
></TT
> ... </SPAN
>] THEN
        <TT
CLASS="REPLACEABLE"
><I
>handler_statements</I
></TT
>
    [<SPAN
CLASS="OPTIONAL"
> WHEN <TT
CLASS="REPLACEABLE"
><I
>condition</I
></TT
> [<SPAN
CLASS="OPTIONAL"
> OR <TT
CLASS="REPLACEABLE"
><I
>condition</I
></TT
> ... </SPAN
>] THEN
          <TT
CLASS="REPLACEABLE"
><I
>handler_statements</I
></TT
>
      ... </SPAN
>]
END;</PRE
><P>
    </P
><P
>     If no error occurs, this form of block simply executes all the
     <TT
CLASS="REPLACEABLE"
><I
>statements</I
></TT
>, and then control passes
     to the next statement after <TT
CLASS="LITERAL"
>END</TT
>.  But if an error
     occurs within the <TT
CLASS="REPLACEABLE"
><I
>statements</I
></TT
>, further
     processing of the <TT
CLASS="REPLACEABLE"
><I
>statements</I
></TT
> is
     abandoned, and control passes to the <TT
CLASS="LITERAL"
>EXCEPTION</TT
> list.
     The list is searched for the first <TT
CLASS="REPLACEABLE"
><I
>condition</I
></TT
>
     matching the error that occurred.  If a match is found, the
     corresponding <TT
CLASS="REPLACEABLE"
><I
>handler_statements</I
></TT
> are
     executed, and then control passes to the next statement after
     <TT
CLASS="LITERAL"
>END</TT
>.  If no match is found, the error propagates out
     as though the <TT
CLASS="LITERAL"
>EXCEPTION</TT
> clause were not there at all:
     the error can be caught by an enclosing block with
     <TT
CLASS="LITERAL"
>EXCEPTION</TT
>, or if there is none it aborts processing
     of the function.
    </P
><P
>     The <TT
CLASS="REPLACEABLE"
><I
>condition</I
></TT
> names can be any of those
     shown in <A
HREF="errcodes-appendix.html"
>Appendix A</A
>.  A category name matches
     any error within its category.
     The special condition name <TT
CLASS="LITERAL"
>OTHERS</TT
>
     matches every error type except <TT
CLASS="LITERAL"
>QUERY_CANCELED</TT
>.
     (It is possible, but often unwise, to trap
     <TT
CLASS="LITERAL"
>QUERY_CANCELED</TT
> by name.)
     Condition names are not case-sensitive.
    </P
><P
>     If a new error occurs within the selected
     <TT
CLASS="REPLACEABLE"
><I
>handler_statements</I
></TT
>, it cannot be caught
     by this <TT
CLASS="LITERAL"
>EXCEPTION</TT
> clause, but is propagated out.
     A surrounding <TT
CLASS="LITERAL"
>EXCEPTION</TT
> clause could catch it.
    </P
><P
>     When an error is caught by an <TT
CLASS="LITERAL"
>EXCEPTION</TT
> clause,
     the local variables of the <SPAN
CLASS="APPLICATION"
>PL/pgSQL</SPAN
> 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:

</P><PRE
CLASS="PROGRAMLISTING"
>    INSERT INTO mytab(firstname, lastname) VALUES('Tom', 'Jones');
    BEGIN
        UPDATE mytab SET firstname = 'Joe' WHERE lastname = 'Jones';
        x := x + 1;
        y := x / 0;
    EXCEPTION
        WHEN division_by_zero THEN
            RAISE NOTICE 'caught division_by_zero';
            RETURN x;
    END;</PRE
><P>

     When control reaches the assignment to <TT
CLASS="LITERAL"
>y</TT
>, it will
     fail with a <TT
CLASS="LITERAL"
>division_by_zero</TT
> error.  This will be caught by
     the <TT
CLASS="LITERAL"
>EXCEPTION</TT
> clause.  The value returned in the
     <TT
CLASS="COMMAND"
>RETURN</TT
> statement will be the incremented value of
     <TT
CLASS="LITERAL"
>x</TT
>, but the effects of the <TT
CLASS="COMMAND"
>UPDATE</TT
> command will
     have been rolled back.  The <TT
CLASS="COMMAND"
>INSERT</TT
> command preceding the
     block is not rolled back, however, so the end result is that the database
     contains <TT
CLASS="LITERAL"
>Tom Jones</TT
> not <TT
CLASS="LITERAL"
>Joe Jones</TT
>.
    </P
><DIV
CLASS="TIP"
><BLOCKQUOTE
CLASS="TIP"
><P
><B
>Tip: </B
>      A block containing an <TT
CLASS="LITERAL"
>EXCEPTION</TT
> clause is significantly
      more expensive to enter and exit than a block without one.  Therefore,
      don't use <TT
CLASS="LITERAL"
>EXCEPTION</TT
> without need.
     </P
></BLOCKQUOTE
></DIV
><DIV
CLASS="EXAMPLE"
><A
NAME="PLPGSQL-UPSERT-EXAMPLE"
></A
><P
><B
>Example 35-1. Exceptions with <TT
CLASS="COMMAND"
>UPDATE</TT
>/<TT
CLASS="COMMAND"
>INSERT</TT
></B
></P
><P
>&#13;
    This example uses exception handling to perform either
    <TT
CLASS="COMMAND"
>UPDATE</TT
> or <TT
CLASS="COMMAND"
>INSERT</TT
>, as appropriate.

</P><PRE
CLASS="PROGRAMLISTING"
>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');</PRE
><P>

    </P
></DIV
></DIV
></DIV
><DIV
CLASS="NAVFOOTER"
><HR
ALIGN="LEFT"
WIDTH="100%"><TABLE
SUMMARY="Footer navigation table"
WIDTH="100%"
BORDER="0"
CELLPADDING="0"
CELLSPACING="0"
><TR
><TD
WIDTH="33%"
ALIGN="left"
VALIGN="top"
><A
HREF="plpgsql-statements.html"
ACCESSKEY="P"
>Prev</A
></TD
><TD
WIDTH="34%"
ALIGN="center"
VALIGN="top"
><A
HREF="index.html"
ACCESSKEY="H"
>Home</A
></TD
><TD
WIDTH="33%"
ALIGN="right"
VALIGN="top"
><A
HREF="plpgsql-cursors.html"
ACCESSKEY="N"
>Next</A
></TD
></TR
><TR
><TD
WIDTH="33%"
ALIGN="left"
VALIGN="top"
>Basic Statements</TD
><TD
WIDTH="34%"
ALIGN="center"
VALIGN="top"
><A
HREF="plpgsql.html"
ACCESSKEY="U"
>Up</A
></TD
><TD
WIDTH="33%"
ALIGN="right"
VALIGN="top"
>Cursors</TD
></TR
></TABLE
></DIV
></BODY
></HTML
>