|
|
PostgreSQL 8.2.9 Documentation | ||||
---|---|---|---|---|
Prev | Fast Backward | Chapter 37. PL/pgSQL - SQL Procedural Language | Fast Forward | Next |
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.
There are two commands available that allow you to return data from a function: RETURN and RETURN NEXT.
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 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.
Note: 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 work_mem configuration variable. Administrators who have sufficient memory to store larger result sets in memory should consider increasing this parameter.
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 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 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 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 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;
ELSEIF is an alias for ELSIF.
With the LOOP, EXIT, CONTINUE, WHILE, and FOR statements, you can arrange for your PL/pgSQL function to repeat a series of commands.
[ <<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 [ 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 [ 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;
[ <<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;
[ <<label>> ] FOR name IN [ REVERSE ] expression .. expression [ BY expression ] LOOP statements END LOOP [ label ];
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 (any existing definition of the variable name is ignored within the loop). The two expressions giving the lower and upper bound of the range are evaluated once when entering the loop. If the BY clause isn't specified the iteration step is 1 otherwise it's the value specified in the BY clause. If REVERSE is specified then the step value is considered negative.
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; FOR i IN REVERSE 10..1 BY 2 LOOP -- some computations here RAISE NOTICE 'i is %', i; 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.
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 target IN query LOOP statements END LOOP [ label ];
The target is a record variable, row variable, or comma-separated list of scalar variables. The target is successively assigned each row resulting from the query 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 query used in this type of FOR statement can be any SQL command that returns rows to the caller: SELECT is the most common case, but you can also use INSERT, UPDATE, or DELETE with a RETURNING clause. Some utility commands such as EXPLAIN will work too.
The FOR-IN-EXECUTE statement is another way to iterate over rows:
[ <<label>> ] FOR target IN EXECUTE text_expression LOOP statements END LOOP [ label ];
This is like the previous form, except that the source query is specified as a string expression, which is evaluated and replanned on each entry to the 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.
Note: 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 or list of scalar variables", rather than the simple syntax error one might expect to get.
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 Appendix A. 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.
Tip: 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 Table A-1 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.
Example 37-1. 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');