Thread: Turning a subselect into an array

Turning a subselect into an array

From
"Jim C. Nasby"
Date:
I'm sure this has been answered before, but the search seems to be down
again.

How can I convert the results of a subselect into an array? IE:

CREATE TABLE a(a int, b int, c int[]);
INSERT INTO table_a
    SELECT a, b, (SELECT c FROM table_c WHERE table_c.parent = table_b.id)
        FROM table_b
;
--
Jim C. Nasby, Database Consultant               decibel@decibel.org
Give your computer some brain candy! www.distributed.net Team #1828

Windows: "Where do you want to go today?"
Linux: "Where do you want to go tomorrow?"
FreeBSD: "Are you guys coming, or what?"

Re: Turning a subselect into an array

From
Michael Fuhr
Date:
On Thu, Oct 28, 2004 at 05:37:29PM -0500, Jim C. Nasby wrote:
> I'm sure this has been answered before, but the search seems to be down
> again.
>
> How can I convert the results of a subselect into an array? IE:
>
> CREATE TABLE a(a int, b int, c int[]);
> INSERT INTO table_a
>     SELECT a, b, (SELECT c FROM table_c WHERE table_c.parent = table_b.id)
>         FROM table_b

See the "Array Constructors" section in the PostgreSQL documentation:

http://www.postgresql.org/docs/7.4/static/sql-expressions.html#SQL-SYNTAX-ARRAY-CONSTRUCTORS

INSERT INTO table_a
  SELECT a, b, ARRAY(SELECT c FROM table_c WHERE table_c.parent = table_b.id)
  FROM table_b

--
Michael Fuhr
http://www.fuhr.org/~mfuhr/

Re: Turning a subselect into an array

From
"Jim C. Nasby"
Date:
Ok, next stupid question that I can't find in the docs... How would I
join a table to an array? IE: if I have an array of primary keys for
some table and I want to get the name field from that table and turn it
back into an array, how would I do that?

On Thu, Oct 28, 2004 at 05:21:52PM -0600, Michael Fuhr wrote:
> On Thu, Oct 28, 2004 at 05:37:29PM -0500, Jim C. Nasby wrote:
> > I'm sure this has been answered before, but the search seems to be down
> > again.
> >
> > How can I convert the results of a subselect into an array? IE:
> >
> > CREATE TABLE a(a int, b int, c int[]);
> > INSERT INTO table_a
> >     SELECT a, b, (SELECT c FROM table_c WHERE table_c.parent = table_b.id)
> >         FROM table_b
>
> See the "Array Constructors" section in the PostgreSQL documentation:
>
> http://www.postgresql.org/docs/7.4/static/sql-expressions.html#SQL-SYNTAX-ARRAY-CONSTRUCTORS
>
> INSERT INTO table_a
>   SELECT a, b, ARRAY(SELECT c FROM table_c WHERE table_c.parent = table_b.id)
>   FROM table_b
>
> --
> Michael Fuhr
> http://www.fuhr.org/~mfuhr/
>
> ---------------------------(end of broadcast)---------------------------
> TIP 7: don't forget to increase your free space map settings
>

--
Jim C. Nasby, Database Consultant               decibel@decibel.org
Give your computer some brain candy! www.distributed.net Team #1828

Windows: "Where do you want to go today?"
Linux: "Where do you want to go tomorrow?"
FreeBSD: "Are you guys coming, or what?"

Re: Turning a subselect into an array

From
Michael Fuhr
Date:
On Fri, Oct 29, 2004 at 05:13:02PM -0500, Jim C. Nasby wrote:
> Ok, next stupid question that I can't find in the docs... How would I
> join a table to an array? IE: if I have an array of primary keys for
> some table and I want to get the name field from that table and turn it
> back into an array, how would I do that?

See the "Subquery Expressions" and "Row and Array Comparisons"
sections in the PostgreSQL documentation:

http://www.postgresql.org/docs/7.4/static/functions-subquery.html
http://www.postgresql.org/docs/7.4/static/functions-comparisons.html

If I understand you correctly, this should work:

SELECT ARRAY(SELECT name FROM foo WHERE id = ANY(ARRAY[1,2,3]));

A test I just ran showed "id = ANY(ARRAY[1,2,3])" doing a sequential
scan whereas "id IN (1,2,3)" did an index scan, so you might want to
use the latter if possible.

--
Michael Fuhr
http://www.fuhr.org/~mfuhr/

Re: Turning a subselect into an array

From
"Jim C. Nasby"
Date:
Thanks again for the help. I did manage to find that after a bunch of
searching in the mailing list. There should really be a portion of the
docs dedicated to array handling.

On Fri, Oct 29, 2004 at 10:40:57PM -0600, Michael Fuhr wrote:
> On Fri, Oct 29, 2004 at 05:13:02PM -0500, Jim C. Nasby wrote:
> > Ok, next stupid question that I can't find in the docs... How would I
> > join a table to an array? IE: if I have an array of primary keys for
> > some table and I want to get the name field from that table and turn it
> > back into an array, how would I do that?
>
> See the "Subquery Expressions" and "Row and Array Comparisons"
> sections in the PostgreSQL documentation:
>
> http://www.postgresql.org/docs/7.4/static/functions-subquery.html
> http://www.postgresql.org/docs/7.4/static/functions-comparisons.html
>
> If I understand you correctly, this should work:
>
> SELECT ARRAY(SELECT name FROM foo WHERE id = ANY(ARRAY[1,2,3]));
>
> A test I just ran showed "id = ANY(ARRAY[1,2,3])" doing a sequential
> scan whereas "id IN (1,2,3)" did an index scan, so you might want to
> use the latter if possible.
>
> --
> Michael Fuhr
> http://www.fuhr.org/~mfuhr/
>
> ---------------------------(end of broadcast)---------------------------
> TIP 2: you can get off all lists at once with the unregister command
>     (send "unregister YourEmailAddressHere" to majordomo@postgresql.org)
>

--
Jim C. Nasby, Database Consultant               decibel@decibel.org
Give your computer some brain candy! www.distributed.net Team #1828

Windows: "Where do you want to go today?"
Linux: "Where do you want to go tomorrow?"
FreeBSD: "Are you guys coming, or what?"