Thread: How to access multicolumn function results?
Hi I've got functions that return a TABLE. If I call it with constant parameters like: SELECT * FROM some_fct( 42 ); I get a table with column names as the result as intended. When I rather call it with the parameter coming from another table I get a set of records where I don't know how to access specific columns: SELECT some_fct( some_id ) FROM some_other_table; Now I get e.g. the result ( id1, value11, value12, value13 ), ( id1, value14, value15, value16 ), ( id2, value24, value25, value26 ), ... How can I split this up to look like a normal table or view with the column names that are defined in the RETURNS TABLE ( ... ) expression of the function.
Andreas <maps.on@gmx.net> writes: > SELECT some_fct( some_id ) FROM some_other_table; > How can I split this up to look like a normal table or view with the > column names that are defined in the RETURNS TABLE ( ... ) expression of > the function. The easy way is SELECT (some_fct(some_id)).* FROM some_other_table; If you're not too concerned about efficiency, you're done. However this isn't very efficient, because the way the parser deals with expanding the "*" is to make N copies of the function call, as you can see with EXPLAIN VERBOSE --- you'll see something similar to Output: (some_fct(some_id)).fld1, (some_fct(some_id)).fld2, ... If the function is expensive enough that that's a problem, the basic way to fix it is SELECT (ss.x).* FROM (SELECT some_fct(some_id) AS x FROM some_other_table) ss; With a RETURNS TABLE function, this should be good enough. With simpler functions you might have to insert OFFSET 0 into the sub-select to keep the planner from "flattening" it into the upper query and producing the same multiple-evaluation situation. regards, tom lane