From: Tom Lane Date: Sat, 1 Sep 2012 04:40:15 +0000 (-0400) Subject: More documentation updates for LATERAL. X-Git-Tag: REL9_3_BETA1~966 X-Git-Url: https://granicus.if.org/sourcecode?a=commitdiff_plain;h=06310178ef54720bc4ed7bc85c887e6ebed24d83;p=postgresql More documentation updates for LATERAL. Extend xfunc.sgml's discussion of set-returning functions to show an example of using LATERAL, and recommend that over putting SRFs in the targetlist. In passing, reword func.sgml's section on set-returning functions so that it doesn't claim that the functions listed therein are all the built-in set-returning functions. That hasn't been true for a long time, and trying to make it so doesn't seem like it would be an improvement. (Perhaps we should rename that section?) Both per suggestions from Merlin Moncure. --- diff --git a/doc/src/sgml/func.sgml b/doc/src/sgml/func.sgml index 5caf10711a..f8f63d89f9 100644 --- a/doc/src/sgml/func.sgml +++ b/doc/src/sgml/func.sgml @@ -12548,9 +12548,10 @@ AND This section describes functions that possibly return more than one row. - Currently the only functions in this class are series generating functions, - as detailed in and - . + The most widely used functions in this class are series generating + functions, as detailed in and + . Other, more specialized + set-returning functions are described elsewhere in this manual. diff --git a/doc/src/sgml/xfunc.sgml b/doc/src/sgml/xfunc.sgml index 7b2d2b0ad3..85539feb0d 100644 --- a/doc/src/sgml/xfunc.sgml +++ b/doc/src/sgml/xfunc.sgml @@ -93,8 +93,8 @@ - Alternatively, an SQL function can be declared to return a set, - by specifying the function's return type as SETOF + Alternatively, an SQL function can be declared to return a set (that is, + multiple rows) by specifying the function's return type as SETOF sometype, or equivalently by declaring it as RETURNS TABLE(columns). In this case all rows of the last query's result are returned. Further details appear @@ -927,19 +927,15 @@ SELECT * FROM sum_n_product_with_tab(10); - Currently, functions returning sets can also be called in the select list - of a query. For each row that the query - generates by itself, the function returning set is invoked, and an output - row is generated for each element of the function's result set. Note, - however, that this capability is deprecated and might be removed in future - releases. The following is an example function returning a set from the - select list: + It is frequently useful to construct a query's result by invoking a + set-returning function multiple times, with the parameters for each + invocation coming from successive rows of a table or subquery. The + preferred way to do this is to use the LATERAL key word, + which is described in . + Here is an example using a set-returning function to enumerate + elements of a tree structure: -CREATE FUNCTION listchildren(text) RETURNS SETOF text AS $$ - SELECT name FROM nodes WHERE parent = $1 -$$ LANGUAGE SQL; - SELECT * FROM nodes; name | parent -----------+-------- @@ -951,6 +947,44 @@ SELECT * FROM nodes; SubChild2 | Child1 (6 rows) +CREATE FUNCTION listchildren(text) RETURNS SETOF text AS $$ + SELECT name FROM nodes WHERE parent = $1 +$$ LANGUAGE SQL STABLE; + +SELECT * FROM listchildren('Top'); + listchildren +-------------- + Child1 + Child2 + Child3 +(3 rows) + +SELECT name, child FROM nodes, LATERAL listchildren(name) AS child; + name | child +--------+----------- + Top | Child1 + Top | Child2 + Top | Child3 + Child1 | SubChild1 + Child1 | SubChild2 +(5 rows) + + + This example does not do anything that we couldn't have done with a + simple join, but in more complex calculations the option to put + some of the work into a function can be quite convenient. + + + + Currently, functions returning sets can also be called in the select list + of a query. For each row that the query + generates by itself, the function returning set is invoked, and an output + row is generated for each element of the function's result set. Note, + however, that this capability is deprecated and might be removed in future + releases. The previous example could also be done with queries like + these: + + SELECT listchildren('Top'); listchildren -------------- @@ -973,7 +1007,9 @@ SELECT name, listchildren(name) FROM nodes; In the last SELECT, notice that no output row appears for Child2, Child3, etc. This happens because listchildren returns an empty set - for those arguments, so no result rows are generated. + for those arguments, so no result rows are generated. This is the same + behavior as we got from an inner join to the function result when using + the LATERAL syntax. @@ -987,6 +1023,19 @@ SELECT name, listchildren(name) FROM nodes; still happen (and are all completed before returning from the function). + + + + The key problem with using set-returning functions in the select list, + rather than the FROM clause, is that putting more than one + set-returning function in the same select list does not behave very + sensibly. (What you actually get if you do so is a number of output + rows equal to the least common multiple of the numbers of rows produced + by each set-returning function.) The LATERAL syntax + produces less surprising results when calling multiple set-returning + functions, and should usually be used instead. + +