From: | Tom Lane <tgl(at)sss(dot)pgh(dot)pa(dot)us> |
---|---|
To: | Andreas <maps(dot)on(at)gmx(dot)net> |
Cc: | pgsql-sql(at)postgresql(dot)org |
Subject: | Re: How to access multicolumn function results? |
Date: | 2013-01-24 01:42:47 |
Message-ID: | 17722.1358991767@sss.pgh.pa.us |
Views: | Raw Message | Whole Thread | Download mbox | Resend email |
Thread: | |
Lists: | pgsql-sql |
Andreas <maps(dot)on(at)gmx(dot)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
From | Date | Subject | |
---|---|---|---|
Next Message | Kong Man | 2013-01-29 02:32:51 | Writeable CTE Not Working? |
Previous Message | Andreas | 2013-01-24 00:58:25 | How to access multicolumn function results? |