2 41.6. Control Structures #
4 41.6.1. Returning from a Function
5 41.6.2. Returning from a Procedure
6 41.6.3. Calling a Procedure
9 41.6.6. Looping through Query Results
10 41.6.7. Looping through Arrays
11 41.6.8. Trapping Errors
12 41.6.9. Obtaining Execution Location Information
14 Control structures are probably the most useful (and important) part of
15 PL/pgSQL. With PL/pgSQL's control structures, you can manipulate
16 PostgreSQL data in a very flexible and powerful way.
18 41.6.1. Returning from a Function #
20 There are two commands available that allow you to return data from a
21 function: RETURN and RETURN NEXT.
27 RETURN with an expression terminates the function and returns the value
28 of expression to the caller. This form is used for PL/pgSQL functions
29 that do not return a set.
31 In a function that returns a scalar type, the expression's result will
32 automatically be cast into the function's return type as described for
33 assignments. But to return a composite (row) value, you must write an
34 expression delivering exactly the requested column set. This may
35 require use of explicit casting.
37 If you declared the function with output parameters, write just RETURN
38 with no expression. The current values of the output parameter
39 variables will be returned.
41 If you declared the function to return void, a RETURN statement can be
42 used to exit the function early; but do not write an expression
45 The return value of a function cannot be left undefined. If control
46 reaches the end of the top-level block of the function without hitting
47 a RETURN statement, a run-time error will occur. This restriction does
48 not apply to functions with output parameters and functions returning
49 void, however. In those cases a RETURN statement is automatically
50 executed if the top-level block finishes.
53 -- functions returning a scalar type
57 -- functions returning a composite type
58 RETURN composite_type_var;
59 RETURN (1, 2, 'three'::text); -- must cast columns to correct types
61 41.6.1.2. RETURN NEXT and RETURN QUERY #
63 RETURN NEXT expression;
65 RETURN QUERY EXECUTE command-string [ USING expression [, ... ] ];
67 When a PL/pgSQL function is declared to return SETOF sometype, the
68 procedure to follow is slightly different. In that case, the individual
69 items to return are specified by a sequence of RETURN NEXT or RETURN
70 QUERY commands, and then a final RETURN command with no argument is
71 used to indicate that the function has finished executing. RETURN NEXT
72 can be used with both scalar and composite data types; with a composite
73 result type, an entire “table” of results will be returned. RETURN
74 QUERY appends the results of executing a query to the function's result
75 set. RETURN NEXT and RETURN QUERY can be freely intermixed in a single
76 set-returning function, in which case their results will be
79 RETURN NEXT and RETURN QUERY do not actually return from the function —
80 they simply append zero or more rows to the function's result set.
81 Execution then continues with the next statement in the PL/pgSQL
82 function. As successive RETURN NEXT or RETURN QUERY commands are
83 executed, the result set is built up. A final RETURN, which should have
84 no argument, causes control to exit the function (or you can just let
85 control reach the end of the function).
87 RETURN QUERY has a variant RETURN QUERY EXECUTE, which specifies the
88 query to be executed dynamically. Parameter expressions can be inserted
89 into the computed query string via USING, in just the same way as in
92 If you declared the function with output parameters, write just RETURN
93 NEXT with no expression. On each execution, the current values of the
94 output parameter variable(s) will be saved for eventual return as a row
95 of the result. Note that you must declare the function as returning
96 SETOF record when there are multiple output parameters, or SETOF
97 sometype when there is just one output parameter of type sometype, in
98 order to create a set-returning function with output parameters.
100 Here is an example of a function using RETURN NEXT:
101 CREATE TABLE foo (fooid INT, foosubid INT, fooname TEXT);
102 INSERT INTO foo VALUES (1, 2, 'three');
103 INSERT INTO foo VALUES (4, 5, 'six');
105 CREATE OR REPLACE FUNCTION get_all_foo() RETURNS SETOF foo AS
111 SELECT * FROM foo WHERE fooid > 0
113 -- can do some processing here
114 RETURN NEXT r; -- return current row of SELECT
121 SELECT * FROM get_all_foo();
123 Here is an example of a function using RETURN QUERY:
124 CREATE FUNCTION get_available_flightid(date) RETURNS SETOF integer AS
127 RETURN QUERY SELECT flightid
129 WHERE flightdate >= $1
130 AND flightdate < ($1 + 1);
132 -- Since execution is not finished, we can check whether rows were returned
133 -- and raise exception if not.
135 RAISE EXCEPTION 'No flight at %.', $1;
143 -- Returns available flights or raises exception if there are no
144 -- available flights.
145 SELECT * FROM get_available_flightid(CURRENT_DATE);
149 The current implementation of RETURN NEXT and RETURN QUERY stores the
150 entire result set before returning from the function, as discussed
151 above. That means that if a PL/pgSQL function produces a very large
152 result set, performance might be poor: data will be written to disk to
153 avoid memory exhaustion, but the function itself will not return until
154 the entire result set has been generated. A future version of PL/pgSQL
155 might allow users to define set-returning functions that do not have
156 this limitation. Currently, the point at which data begins being
157 written to disk is controlled by the work_mem configuration variable.
158 Administrators who have sufficient memory to store larger result sets
159 in memory should consider increasing this parameter.
161 41.6.2. Returning from a Procedure #
163 A procedure does not have a return value. A procedure can therefore end
164 without a RETURN statement. If you wish to use a RETURN statement to
165 exit the code early, write just RETURN with no expression.
167 If the procedure has output parameters, the final values of the output
168 parameter variables will be returned to the caller.
170 41.6.3. Calling a Procedure #
172 A PL/pgSQL function, procedure, or DO block can call a procedure using
173 CALL. Output parameters are handled differently from the way that CALL
174 works in plain SQL. Each OUT or INOUT parameter of the procedure must
175 correspond to a variable in the CALL statement, and whatever the
176 procedure returns is assigned back to that variable after it returns.
178 CREATE PROCEDURE triple(INOUT x int)
187 DECLARE myvar int := 5;
190 RAISE NOTICE 'myvar = %', myvar; -- prints 15
194 The variable corresponding to an output parameter can be a simple
195 variable or a field of a composite-type variable. Currently, it cannot
196 be an element of an array.
198 41.6.4. Conditionals #
200 IF and CASE statements let you execute alternative commands based on
201 certain conditions. PL/pgSQL has three forms of IF:
202 * IF ... THEN ... END IF
203 * IF ... THEN ... ELSE ... END IF
204 * IF ... THEN ... ELSIF ... THEN ... ELSE ... END IF
206 and two forms of CASE:
207 * CASE ... WHEN ... THEN ... ELSE ... END CASE
208 * CASE WHEN ... THEN ... ELSE ... END CASE
212 IF boolean-expression THEN
216 IF-THEN statements are the simplest form of IF. The statements between
217 THEN and END IF will be executed if the condition is true. Otherwise,
221 IF v_user_id <> 0 THEN
222 UPDATE users SET email = v_email WHERE user_id = v_user_id;
225 41.6.4.2. IF-THEN-ELSE #
227 IF boolean-expression THEN
233 IF-THEN-ELSE statements add to IF-THEN by letting you specify an
234 alternative set of statements that should be executed if the condition
235 is not true. (Note this includes the case where the condition evaluates
239 IF parentid IS NULL OR parentid = ''
243 RETURN hp_true_filename(parentid) || '/' || fullname;
247 INSERT INTO users_count (count) VALUES (v_count);
253 41.6.4.3. IF-THEN-ELSIF #
255 IF boolean-expression THEN
257 [ ELSIF boolean-expression THEN
259 [ ELSIF boolean-expression THEN
268 Sometimes there are more than just two alternatives. IF-THEN-ELSIF
269 provides a convenient method of checking several alternatives in turn.
270 The IF conditions are tested successively until the first one that is
271 true is found. Then the associated statement(s) are executed, after
272 which control passes to the next statement after END IF. (Any
273 subsequent IF conditions are not tested.) If none of the IF conditions
274 is true, then the ELSE block (if any) is executed.
279 ELSIF number > 0 THEN
280 result := 'positive';
281 ELSIF number < 0 THEN
282 result := 'negative';
284 -- hmm, the only other possibility is that number is null
288 The key word ELSIF can also be spelled ELSEIF.
290 An alternative way of accomplishing the same task is to nest
291 IF-THEN-ELSE statements, as in the following example:
292 IF demo_row.sex = 'm' THEN
295 IF demo_row.sex = 'f' THEN
296 pretty_sex := 'woman';
300 However, this method requires writing a matching END IF for each IF, so
301 it is much more cumbersome than using ELSIF when there are many
304 41.6.4.4. Simple CASE #
306 CASE search-expression
307 WHEN expression [, expression [ ... ]] THEN
309 [ WHEN expression [, expression [ ... ]] THEN
316 The simple form of CASE provides conditional execution based on
317 equality of operands. The search-expression is evaluated (once) and
318 successively compared to each expression in the WHEN clauses. If a
319 match is found, then the corresponding statements are executed, and
320 then control passes to the next statement after END CASE. (Subsequent
321 WHEN expressions are not evaluated.) If no match is found, the ELSE
322 statements are executed; but if ELSE is not present, then a
323 CASE_NOT_FOUND exception is raised.
325 Here is a simple example:
330 msg := 'other value than one or two';
333 41.6.4.5. Searched CASE #
336 WHEN boolean-expression THEN
338 [ WHEN boolean-expression THEN
345 The searched form of CASE provides conditional execution based on truth
346 of Boolean expressions. Each WHEN clause's boolean-expression is
347 evaluated in turn, until one is found that yields true. Then the
348 corresponding statements are executed, and then control passes to the
349 next statement after END CASE. (Subsequent WHEN expressions are not
350 evaluated.) If no true result is found, the ELSE statements are
351 executed; but if ELSE is not present, then a CASE_NOT_FOUND exception
356 WHEN x BETWEEN 0 AND 10 THEN
357 msg := 'value is between zero and ten';
358 WHEN x BETWEEN 11 AND 20 THEN
359 msg := 'value is between eleven and twenty';
362 This form of CASE is entirely equivalent to IF-THEN-ELSIF, except for
363 the rule that reaching an omitted ELSE clause results in an error
364 rather than doing nothing.
366 41.6.5. Simple Loops #
368 With the LOOP, EXIT, CONTINUE, WHILE, FOR, and FOREACH statements, you
369 can arrange for your PL/pgSQL function to repeat a series of commands.
378 LOOP defines an unconditional loop that is repeated indefinitely until
379 terminated by an EXIT or RETURN statement. The optional label can be
380 used by EXIT and CONTINUE statements within nested loops to specify
381 which loop those statements refer to.
385 EXIT [ label ] [ WHEN boolean-expression ];
387 If no label is given, the innermost loop is terminated and the
388 statement following END LOOP is executed next. If label is given, it
389 must be the label of the current or some outer level of nested loop or
390 block. Then the named loop or block is terminated and control continues
391 with the statement after the loop's/block's corresponding END.
393 If WHEN is specified, the loop exit occurs only if boolean-expression
394 is true. Otherwise, control passes to the statement after EXIT.
396 EXIT can be used with all types of loops; it is not limited to use with
399 When used with a BEGIN block, EXIT passes control to the next statement
400 after the end of the block. Note that a label must be used for this
401 purpose; an unlabeled EXIT is never considered to match a BEGIN block.
402 (This is a change from pre-8.4 releases of PostgreSQL, which would
403 allow an unlabeled EXIT to match a BEGIN block.)
415 EXIT WHEN count > 0; -- same result as previous example
421 IF stocks > 100000 THEN
422 EXIT ablock; -- causes exit from the BEGIN block
424 -- computations here will be skipped when stocks > 100000
429 CONTINUE [ label ] [ WHEN boolean-expression ];
431 If no label is given, the next iteration of the innermost loop is
432 begun. That is, all statements remaining in the loop body are skipped,
433 and control returns to the loop control expression (if any) to
434 determine whether another loop iteration is needed. If label is
435 present, it specifies the label of the loop whose execution will be
438 If WHEN is specified, the next iteration of the loop is begun only if
439 boolean-expression is true. Otherwise, control passes to the statement
442 CONTINUE can be used with all types of loops; it is not limited to use
443 with unconditional loops.
448 EXIT WHEN count > 100;
449 CONTINUE WHEN count < 50;
450 -- some computations for count IN [50 .. 100]
456 WHILE boolean-expression LOOP
460 The WHILE statement repeats a sequence of statements so long as the
461 boolean-expression evaluates to true. The expression is checked just
462 before each entry to the loop body.
465 WHILE amount_owed > 0 AND gift_certificate_balance > 0 LOOP
466 -- some computations here
470 -- some computations here
473 41.6.5.5. FOR (Integer Variant) #
476 FOR name IN [ REVERSE ] expression .. expression [ BY expression ] LOOP
480 This form of FOR creates a loop that iterates over a range of integer
481 values. The variable name is automatically defined as type integer and
482 exists only inside the loop (any existing definition of the variable
483 name is ignored within the loop). The two expressions giving the lower
484 and upper bound of the range are evaluated once when entering the loop.
485 If the BY clause isn't specified the iteration step is 1, otherwise
486 it's the value specified in the BY clause, which again is evaluated
487 once on loop entry. If REVERSE is specified then the step value is
488 subtracted, rather than added, after each iteration.
490 Some examples of integer FOR loops:
492 -- i will take on the values 1,2,3,4,5,6,7,8,9,10 within the loop
495 FOR i IN REVERSE 10..1 LOOP
496 -- i will take on the values 10,9,8,7,6,5,4,3,2,1 within the loop
499 FOR i IN REVERSE 10..1 BY 2 LOOP
500 -- i will take on the values 10,8,6,4,2 within the loop
503 If the lower bound is greater than the upper bound (or less than, in
504 the REVERSE case), the loop body is not executed at all. No error is
507 If a label is attached to the FOR loop then the integer loop variable
508 can be referenced with a qualified name, using that label.
510 41.6.6. Looping through Query Results #
512 Using a different type of FOR loop, you can iterate through the results
513 of a query and manipulate that data accordingly. The syntax is:
515 FOR target IN query LOOP
519 The target is a record variable, row variable, or comma-separated list
520 of scalar variables. The target is successively assigned each row
521 resulting from the query and the loop body is executed for each row.
523 CREATE FUNCTION refresh_mviews() RETURNS integer AS $$
527 RAISE NOTICE 'Refreshing all materialized views...';
530 SELECT n.nspname AS mv_schema,
531 c.relname AS mv_name,
532 pg_catalog.pg_get_userbyid(c.relowner) AS owner
533 FROM pg_catalog.pg_class c
534 LEFT JOIN pg_catalog.pg_namespace n ON (n.oid = c.relnamespace)
535 WHERE c.relkind = 'm'
539 -- Now "mviews" has one record with information about the materialized v
542 RAISE NOTICE 'Refreshing materialized view %.% (owner: %)...',
543 quote_ident(mviews.mv_schema),
544 quote_ident(mviews.mv_name),
545 quote_ident(mviews.owner);
546 EXECUTE format('REFRESH MATERIALIZED VIEW %I.%I', mviews.mv_schema, mvie
550 RAISE NOTICE 'Done refreshing materialized views.';
555 If the loop is terminated by an EXIT statement, the last assigned row
556 value is still accessible after the loop.
558 The query used in this type of FOR statement can be any SQL command
559 that returns rows to the caller: SELECT is the most common case, but
560 you can also use INSERT, UPDATE, DELETE, or MERGE with a RETURNING
561 clause. Some utility commands such as EXPLAIN will work too.
563 PL/pgSQL variables are replaced by query parameters, and the query plan
564 is cached for possible re-use, as discussed in detail in
565 Section 41.11.1 and Section 41.11.2.
567 The FOR-IN-EXECUTE statement is another way to iterate over rows:
569 FOR target IN EXECUTE text_expression [ USING expression [, ... ] ] LOOP
573 This is like the previous form, except that the source query is
574 specified as a string expression, which is evaluated and replanned on
575 each entry to the FOR loop. This allows the programmer to choose the
576 speed of a preplanned query or the flexibility of a dynamic query, just
577 as with a plain EXECUTE statement. As with EXECUTE, parameter values
578 can be inserted into the dynamic command via USING.
580 Another way to specify the query whose results should be iterated
581 through is to declare it as a cursor. This is described in
584 41.6.7. Looping through Arrays #
586 The FOREACH loop is much like a FOR loop, but instead of iterating
587 through the rows returned by an SQL query, it iterates through the
588 elements of an array value. (In general, FOREACH is meant for looping
589 through components of a composite-valued expression; variants for
590 looping through composites besides arrays may be added in future.) The
591 FOREACH statement to loop over an array is:
593 FOREACH target [ SLICE number ] IN ARRAY expression LOOP
597 Without SLICE, or if SLICE 0 is specified, the loop iterates through
598 individual elements of the array produced by evaluating the expression.
599 The target variable is assigned each element value in sequence, and the
600 loop body is executed for each element. Here is an example of looping
601 through the elements of an integer array:
602 CREATE FUNCTION sum(int[]) RETURNS int8 AS $$
607 FOREACH x IN ARRAY $1
615 The elements are visited in storage order, regardless of the number of
616 array dimensions. Although the target is usually just a single
617 variable, it can be a list of variables when looping through an array
618 of composite values (records). In that case, for each array element,
619 the variables are assigned from successive columns of the composite
622 With a positive SLICE value, FOREACH iterates through slices of the
623 array rather than single elements. The SLICE value must be an integer
624 constant not larger than the number of dimensions of the array. The
625 target variable must be an array, and it receives successive slices of
626 the array value, where each slice is of the number of dimensions
627 specified by SLICE. Here is an example of iterating through
628 one-dimensional slices:
629 CREATE FUNCTION scan_rows(int[]) RETURNS void AS $$
633 FOREACH x SLICE 1 IN ARRAY $1
635 RAISE NOTICE 'row = %', x;
640 SELECT scan_rows(ARRAY[[1,2,3],[4,5,6],[7,8,9],[10,11,12]]);
642 NOTICE: row = {1,2,3}
643 NOTICE: row = {4,5,6}
644 NOTICE: row = {7,8,9}
645 NOTICE: row = {10,11,12}
647 41.6.8. Trapping Errors #
649 By default, any error occurring in a PL/pgSQL function aborts execution
650 of the function and the surrounding transaction. You can trap errors
651 and recover from them by using a BEGIN block with an EXCEPTION clause.
652 The syntax is an extension of the normal syntax for a BEGIN block:
659 WHEN condition [ OR condition ... ] THEN
661 [ WHEN condition [ OR condition ... ] THEN
666 If no error occurs, this form of block simply executes all the
667 statements, and then control passes to the next statement after END.
668 But if an error occurs within the statements, further processing of the
669 statements is abandoned, and control passes to the EXCEPTION list. The
670 list is searched for the first condition matching the error that
671 occurred. If a match is found, the corresponding handler_statements are
672 executed, and then control passes to the next statement after END. If
673 no match is found, the error propagates out as though the EXCEPTION
674 clause were not there at all: the error can be caught by an enclosing
675 block with EXCEPTION, or if there is none it aborts processing of the
678 The condition names can be any of those shown in Appendix A. A category
679 name matches any error within its category. The special condition name
680 OTHERS matches every error type except QUERY_CANCELED and
681 ASSERT_FAILURE. (It is possible, but often unwise, to trap those two
682 error types by name.) Condition names are not case-sensitive. Also, an
683 error condition can be specified by SQLSTATE code; for example these
685 WHEN division_by_zero THEN ...
686 WHEN SQLSTATE '22012' THEN ...
688 If a new error occurs within the selected handler_statements, it cannot
689 be caught by this EXCEPTION clause, but is propagated out. A
690 surrounding EXCEPTION clause could catch it.
692 When an error is caught by an EXCEPTION clause, the local variables of
693 the PL/pgSQL function remain as they were when the error occurred, but
694 all changes to persistent database state within the block are rolled
695 back. As an example, consider this fragment:
696 INSERT INTO mytab(firstname, lastname) VALUES('Tom', 'Jones');
698 UPDATE mytab SET firstname = 'Joe' WHERE lastname = 'Jones';
702 WHEN division_by_zero THEN
703 RAISE NOTICE 'caught division_by_zero';
707 When control reaches the assignment to y, it will fail with a
708 division_by_zero error. This will be caught by the EXCEPTION clause.
709 The value returned in the RETURN statement will be the incremented
710 value of x, but the effects of the UPDATE command will have been rolled
711 back. The INSERT command preceding the block is not rolled back,
712 however, so the end result is that the database contains Tom Jones not
717 A block containing an EXCEPTION clause is significantly more expensive
718 to enter and exit than a block without one. Therefore, don't use
719 EXCEPTION without need.
721 Example 41.2. Exceptions with UPDATE/INSERT
723 This example uses exception handling to perform either UPDATE or
724 INSERT, as appropriate. It is recommended that applications use INSERT
725 with ON CONFLICT DO UPDATE rather than actually using this pattern.
726 This example serves primarily to illustrate use of PL/pgSQL control
728 CREATE TABLE db (a INT PRIMARY KEY, b TEXT);
730 CREATE FUNCTION merge_db(key INT, data TEXT) RETURNS VOID AS
734 -- first try to update the key
735 UPDATE db SET b = data WHERE a = key;
739 -- not there, so try to insert the key
740 -- if someone else inserts the same key concurrently,
741 -- we could get a unique-key failure
743 INSERT INTO db(a,b) VALUES (key, data);
745 EXCEPTION WHEN unique_violation THEN
746 -- Do nothing, and loop to try the UPDATE again.
753 SELECT merge_db(1, 'david');
754 SELECT merge_db(1, 'dennis');
756 This coding assumes the unique_violation error is caused by the INSERT,
757 and not by, say, an INSERT in a trigger function on the table. It might
758 also misbehave if there is more than one unique index on the table,
759 since it will retry the operation regardless of which index caused the
760 error. More safety could be had by using the features discussed next to
761 check that the trapped error was the one expected.
763 41.6.8.1. Obtaining Information about an Error #
765 Exception handlers frequently need to identify the specific error that
766 occurred. There are two ways to get information about the current
767 exception in PL/pgSQL: special variables and the GET STACKED
770 Within an exception handler, the special variable SQLSTATE contains the
771 error code that corresponds to the exception that was raised (refer to
772 Table A.1 for a list of possible error codes). The special variable
773 SQLERRM contains the error message associated with the exception. These
774 variables are undefined outside exception handlers.
776 Within an exception handler, one may also retrieve information about
777 the current exception by using the GET STACKED DIAGNOSTICS command,
779 GET STACKED DIAGNOSTICS variable { = | := } item [ , ... ];
781 Each item is a key word identifying a status value to be assigned to
782 the specified variable (which should be of the right data type to
783 receive it). The currently available status items are shown in
786 Table 41.2. Error Diagnostics Items
787 Name Type Description
788 RETURNED_SQLSTATE text the SQLSTATE error code of the exception
789 COLUMN_NAME text the name of the column related to exception
790 CONSTRAINT_NAME text the name of the constraint related to exception
791 PG_DATATYPE_NAME text the name of the data type related to exception
792 MESSAGE_TEXT text the text of the exception's primary message
793 TABLE_NAME text the name of the table related to exception
794 SCHEMA_NAME text the name of the schema related to exception
795 PG_EXCEPTION_DETAIL text the text of the exception's detail message, if
797 PG_EXCEPTION_HINT text the text of the exception's hint message, if any
798 PG_EXCEPTION_CONTEXT text line(s) of text describing the call stack at
799 the time of the exception (see Section 41.6.9)
801 If the exception did not set a value for an item, an empty string will
810 -- some processing which might cause an exception
812 EXCEPTION WHEN OTHERS THEN
813 GET STACKED DIAGNOSTICS text_var1 = MESSAGE_TEXT,
814 text_var2 = PG_EXCEPTION_DETAIL,
815 text_var3 = PG_EXCEPTION_HINT;
818 41.6.9. Obtaining Execution Location Information #
820 The GET DIAGNOSTICS command, previously described in Section 41.5.5,
821 retrieves information about current execution state (whereas the GET
822 STACKED DIAGNOSTICS command discussed above reports information about
823 the execution state as of a previous error). Its PG_CONTEXT status item
824 is useful for identifying the current execution location. PG_CONTEXT
825 returns a text string with line(s) of text describing the call stack.
826 The first line refers to the current function and currently executing
827 GET DIAGNOSTICS command. The second and any subsequent lines refer to
828 calling functions further up the call stack. For example:
829 CREATE OR REPLACE FUNCTION outer_func() RETURNS integer AS $$
835 CREATE OR REPLACE FUNCTION inner_func() RETURNS integer AS $$
839 GET DIAGNOSTICS stack = PG_CONTEXT;
840 RAISE NOTICE E'--- Call Stack ---\n%', stack;
847 NOTICE: --- Call Stack ---
848 PL/pgSQL function inner_func() line 5 at GET DIAGNOSTICS
849 PL/pgSQL function outer_func() line 3 at RETURN
850 CONTEXT: PL/pgSQL function outer_func() line 3 at RETURN
856 GET STACKED DIAGNOSTICS ... PG_EXCEPTION_CONTEXT returns the same sort
857 of stack trace, but describing the location at which an error was
858 detected, rather than the current location.