Thread: how can I select into an array?
I would like to select strings from a table and return them as an array
For example,
select new_array(name) from my_tbl
would return
String[] { name1, name2, name3, etc }
Is this possible with built-in SQL/psql functions?
If not, how hard would it be to write a function that does this? (given that I have coding experience but none writing pgsql functions)
Andy Kriger | Software Mechanic | Greater Than One, Inc.
28 West 27th Street | 7th Floor | New York, NY 10001
P: 212.252.7197 | F: 212.252.7364 | E: akriger@greaterthanone.com
hello, try: CREATE OR REPLACE FUNCTION aggregate_array(ANYARRAY,ANYELEMENT) RETURNS ANYARRAY AS ' SELECT CASE WHEN $1 IS NULL THEN ARRAY[$2] WHEN $2 IS NULL THEN $1 ELSE array_append($1,$2) END; ' LANGUAGE 'SQL'; CREATE AGGREGATE aggarray (BASETYPE = ANYELEMENT, SFUNC = aggregate_array, STYPE = ANYARRAY); or CREATE AGGREGATE aggarray (basetype = anyelement, sfunc = array_append, stype = anyarray, initcond = '{}' ); testdb011=> SELECT count(*), aggarray(prijmeni) FROM lide GROUP BY prijmeni ~ '.*á'; regards Pavel Stehule On Fri, 6 Feb 2004, Andy Kriger wrote: > I would like to select strings from a table and return them as an array > For example, > select new_array(name) from my_tbl > would return > String[] { name1, name2, name3, etc } > > Is this possible with built-in SQL/psql functions? > If not, how hard would it be to write a function that does this? (given that > I have coding experience but none writing pgsql functions) > > Andy Kriger | Software Mechanic | Greater Than One, Inc. > 28 West 27th Street | 7th Floor | New York, NY 10001 > P: 212.252.7197 | F: 212.252.7364 | E: akriger@greaterthanone.com > >
Thank you for your response - I should have mention I'm using Postgres 7.2.x ANYARRAY does not appear to exist in that version Is there a workaround? -----Original Message----- From: Pavel Stehule [mailto:stehule@kix.fsv.cvut.cz] Sent: Friday, February 06, 2004 10:49 AM To: Andy Kriger Cc: Pgsql-General Subject: Re: [GENERAL] how can I select into an array? hello, try: CREATE OR REPLACE FUNCTION aggregate_array(ANYARRAY,ANYELEMENT) RETURNS ANYARRAY AS ' SELECT CASE WHEN $1 IS NULL THEN ARRAY[$2] WHEN $2 IS NULL THEN $1 ELSE array_append($1,$2) END; ' LANGUAGE 'SQL'; CREATE AGGREGATE aggarray (BASETYPE = ANYELEMENT, SFUNC = aggregate_array, STYPE = ANYARRAY); or CREATE AGGREGATE aggarray (basetype = anyelement, sfunc = array_append, stype = anyarray, initcond = '{}' ); testdb011=> SELECT count(*), aggarray(prijmeni) FROM lide GROUP BY prijmeni ~ '.*á'; regards Pavel Stehule On Fri, 6 Feb 2004, Andy Kriger wrote: > I would like to select strings from a table and return them as an > array For example, select new_array(name) from my_tbl would return > String[] { name1, name2, name3, etc } > > Is this possible with built-in SQL/psql functions? > If not, how hard would it be to write a function that does this? > (given that I have coding experience but none writing pgsql functions) > > Andy Kriger | Software Mechanic | Greater Than One, Inc. > 28 West 27th Street | 7th Floor | New York, NY 10001 > P: 212.252.7197 | F: 212.252.7364 | E: akriger@greaterthanone.com > >
if you can in plpgsql 7.2.x return array of known type, you can replace anyarray and anyelement like varchar[], varchar. But I don't know if it 7.2 supported. Pavel On Fri, 6 Feb 2004, Andy Kriger wrote: > Thank you for your response - I should have mention I'm using Postgres 7.2.x > ANYARRAY does not appear to exist in that version > Is there a workaround? > > -----Original Message----- > From: Pavel Stehule [mailto:stehule@kix.fsv.cvut.cz] > Sent: Friday, February 06, 2004 10:49 AM > To: Andy Kriger > Cc: Pgsql-General > Subject: Re: [GENERAL] how can I select into an array? > > hello, > > try: > > CREATE OR REPLACE FUNCTION aggregate_array(ANYARRAY,ANYELEMENT) RETURNS > ANYARRAY AS ' > SELECT > CASE > WHEN $1 IS NULL > THEN ARRAY[$2] > WHEN $2 IS NULL > THEN $1 > ELSE array_append($1,$2) > END; > ' LANGUAGE 'SQL'; > > CREATE AGGREGATE aggarray (BASETYPE = ANYELEMENT, SFUNC = aggregate_array, > STYPE = ANYARRAY); > > or > > CREATE AGGREGATE aggarray (basetype = anyelement, sfunc = array_append, > stype = anyarray, initcond = '{}' ); > > testdb011=> SELECT count(*), aggarray(prijmeni) FROM lide GROUP BY prijmeni > ~ '.*á'; > > regards > Pavel Stehule > > > > > On Fri, 6 Feb 2004, Andy Kriger wrote: > > > I would like to select strings from a table and return them as an > > array For example, select new_array(name) from my_tbl would return > > String[] { name1, name2, name3, etc } > > > > Is this possible with built-in SQL/psql functions? > > If not, how hard would it be to write a function that does this? > > (given that I have coding experience but none writing pgsql functions) > > > > Andy Kriger | Software Mechanic | Greater Than One, Inc. > > 28 West 27th Street | 7th Floor | New York, NY 10001 > > P: 212.252.7197 | F: 212.252.7364 | E: akriger@greaterthanone.com > > > > > > > ---------------------------(end of broadcast)--------------------------- > TIP 4: Don't 'kill -9' the postmaster >
"Andy Kriger" <akriger@greaterthanone.com> writes: > I would like to select strings from a table and return them as an array You can do that beginning in 7.4 with the ARRAY(sub-select) construct. regression=# select f1 from text_tbl; f1 ------------------- doh! hi de ho neighbor (2 rows) regression=# select array(select f1 from text_tbl); ?column? ---------------------------- {doh!,"hi de ho neighbor"} (1 row) regression=# In prior versions you could probably fake it with a loop in a plpgsql function, but it'd be kinda awkward. regards, tom lane
Pavel Stehule wrote: > CREATE AGGREGATE aggarray (BASETYPE = ANYELEMENT, SFUNC = aggregate_array, > STYPE = ANYARRAY); Or, from the docs, see: http://www.postgresql.org/docs/current/static/xaggr.html CREATE AGGREGATE array_accum ( sfunc = array_append, basetype = anyelement, stype = anyarray, initcond = '{}' ); array_append() is built-in in 7.4 -- and note both Pavel's solution and this one require 7.4.x HTH, Joe
Pavel Stehule wrote: > if you can in plpgsql 7.2.x return array of known type, you can replace > anyarray and anyelement like varchar[], varchar. But I don't know if it > 7.2 supported. PL/pgSQL array support in anything earlier than 7.4 is pretty weak. I would strongly recommend upgrading to 7.4 if arrays are important to you. Joe
-- query must return a column named arrayval
-- $1 = query string
CREATE OR REPLACE FUNCTION array_query(VARCHAR)
RETURNS VARCHAR[]
AS '
DECLARE
query ALIAS FOR $1;
rec RECORD;
str VARCHAR;
arr VARCHAR[];
BEGIN
str := ''{'';
FOR rec IN EXECUTE query LOOP
str := str || ''"'' || rec.arrayval || ''"'' || '','';
END LOOP;
str := str || ''}'';
SELECT INTO arr str;
RETURN arr;
END;
' LANGUAGE 'plpgsql';
From: pgsql-general-owner@postgresql.org [mailto:pgsql-general-owner@postgresql.org] On Behalf Of Andy Kriger
Sent: Friday, February 06, 2004 10:37 AM
To: Pgsql-General
Subject: [GENERAL] how can I select into an array?
I would like to select strings from a table and return them as an array
For example,
select new_array(name) from my_tbl
would return
String[] { name1, name2, name3, etc }
Is this possible with built-in SQL/psql functions?
If not, how hard would it be to write a function that does this? (given that I have coding experience but none writing pgsql functions)
Andy Kriger | Software Mechanic | Greater Than One, Inc.
28 West 27th Street | 7th Floor | New York, NY 10001
P: 212.252.7197 | F: 212.252.7364 | E: akriger@greaterthanone.com
On Fri, Feb 06, 2004 at 12:08:16PM -0500, Tom Lane wrote: > "Andy Kriger" <akriger@greaterthanone.com> writes: > > I would like to select strings from a table and return them as an array > > You can do that beginning in 7.4 with the ARRAY(sub-select) construct. > > regression=# select f1 from text_tbl; > f1 > ------------------- > doh! > hi de ho neighbor > (2 rows) > > regression=# select array(select f1 from text_tbl); > ?column? > ---------------------------- > {doh!,"hi de ho neighbor"} > (1 row) > > regression=# > > In prior versions you could probably fake it with a loop in a plpgsql > function, but it'd be kinda awkward. > > regards, tom lane > > ---------------------------(end of broadcast)--------------------------- > TIP 8: explain analyze is your friend Joe Conway supplied a 7.3 version of function that could help you do this. I have not tested it in 7.2, however. The details of this function for getting the next array index for appending to the array are written up in http://www.varlena.com/GeneralBits/24.html CREATE OR REPLACE FUNCTION array_next(text[]) returns int AS ' DECLARE arr alias for $1; high int; BEGIN high := 1 + replace(split_part(array_dims(arr),'':'',2),'']'','''')::int; RETURN high; END; ' LANGUAGE 'plpgsql' IMMUTABLE STRICT; create table mytable (myarray text[]); insert into mytable values ('{"abc","d e f"}'); update mytable set myarray[array_next(myarray)] = 'new element'; regression=# select * from mytable; myarray ----------------------------- {abc,"d e f","new element"} (1 row) Elein