From: | Merlin Moncure <mmoncure(at)gmail(dot)com> |
---|---|
To: | Sven Haag <sven-haag(at)gmx(dot)de> |
Cc: | pgsql-general(at)postgresql(dot)org |
Subject: | Re: Recursive function that receives a list of IDs and returns all child IDs |
Date: | 2011-03-23 21:46:25 |
Message-ID: | AANLkTikHcb7_DQqbQnsnN182FP2WJ90yJxc4yaYQt2+_@mail.gmail.com |
Views: | Raw Message | Whole Thread | Download mbox | Resend email |
Thread: | |
Lists: | pgsql-general |
On Wed, Mar 23, 2011 at 10:29 AM, Sven Haag <sven-haag(at)gmx(dot)de> wrote:
> hello pgsql fans out there,
>
> i've already created a function that returns a list of IDs of all sub-samples based on a given sample ID. this works fine. now i like to extend this function so that it can receive a list of sample IDs. e.g.:
>
> fn_get_subsamples(IN sample_numbers SETOF integer)
>
>
> here is the existing function:
>
> CREATE OR REPLACE FUNCTION fn_get_subsamples(IN sample_number integer)
> RETURNS SETOF integer AS
> $BODY$
> WITH RECURSIVE recursetree(sample_number) AS (
> SELECT sample_number
> FROM sample
> WHERE parent_sample = $1
>
> UNION ALL
>
> SELECT t.sample_number
> FROM sample t
> JOIN recursetree rt ON rt.sample_number = t.parent_sample
> )
>
> SELECT sample_number
> FROM recursetree;
> $BODY$
> LANGUAGE sql VOLATILE
CREATE OR REPLACE FUNCTION fn_get_subsamples(IN sample_numbers integer[])
RETURNS SETOF integer AS
$BODY$
WITH RECURSIVE recursetree(sample_number) AS (
SELECT sample_number
FROM sample
WHERE parent_sample in (select unnest($1))
UNION ALL
SELECT t.sample_number
FROM sample t
JOIN recursetree rt ON rt.sample_number = t.parent_sample
)
SELECT sample_number
FROM recursetree;
$BODY$
LANGUAGE sql VOLATILE
merlin
From | Date | Subject | |
---|---|---|---|
Next Message | Tom Lane | 2011-03-23 22:00:57 | Re: constraint partition issue |
Previous Message | damien clochard | 2011-03-23 21:13:42 | PG Session #2 : Call For Papers |