Thread: Expressing a result set as an array (and vice versa)?
Good day, Is it possible to construct an array from an appropriate select expression that generates a result set of unknown cardinality? To focus on the simple case: Is it possible to construct a one- dimensional array from a select of a single column in a table with an unknown number of rows? Conversely, is it possible to construct a (single column) result set from a select expression on a one-dimensional array with an unknown number of elements? Thanks for any hints! Regards, Don Maier
CREATE OR REPLACE FUNCTION foreach( liste INTEGER[] ) RETURNS SETOF INTEGER AS $$ DECLARE i INTEGER; BEGIN FOR i IN 1..icount(liste) LOOP RETURN NEXT liste[i]; END LOOP; END; $$ LANGUAGE plpgsql; CREATE AGGREGATE array_accum ( sfunc = array_append, basetype = anyelement, stype = anyarray, initcond = '{}' ); SELECT array_accum( DISTINCT list_id ) FROM bookmarks; array_accum --------------- {1,2,3,4,5,7} SELECT * FROM foreach( '{1,2,3,4,5,7}' ); foreach --------- 1 2 3 4 5 7 On Thu, 23 Mar 2006 20:44:32 +0100, Don Maier <dMaier@genome.stanford.edu> wrote: > Good day, > > Is it possible to construct an array from an appropriate select > expression that generates a result set of unknown cardinality? > To focus on the simple case: Is it possible to construct a one- > dimensional array from a select of a single column in a table with an > unknown number of rows? > > Conversely, is it possible to construct a (single column) result set > from a select expression on a one-dimensional array with an unknown > number of elements? > > Thanks for any hints! > > Regards, > Don Maier > > > > ---------------------------(end of broadcast)--------------------------- > TIP 1: if posting/reading through Usenet, please send an appropriate > subscribe-nomail command to majordomo@postgresql.org so that your > message can get through to the mailing list cleanly
On Thu, 23 Mar 2006 11:44:32 -0800 Don Maier <dMaier@genome.stanford.edu> threw this fish to the penguins: > Is it possible to construct an array from an appropriate select > expression that generates a result set of unknown cardinality? > To focus on the simple case: Is it possible to construct a one- > dimensional array from a select of a single column in a table with an > unknown number of rows? select array(select some_int_field from my_table where something); produces an array of integers. No user defined function is required. > Conversely, is it possible to construct a (single column) result set > from a select expression on a one-dimensional array with an unknown > number of elements? Not so easy without a custom function. > Thanks for any hints! > > Regards, > Don Maier > > > > ---------------------------(end of broadcast)--------------------------- > TIP 1: if posting/reading through Usenet, please send an appropriate > subscribe-nomail command to majordomo@postgresql.org so that your > message can get through to the mailing list cleanly > -- "Are the gods not just?" "Oh no, child. What would become of us if they were?" (CSL)
On Mar 25 10:11, george young wrote: > On Mar 23 11:44, Don Maier <dMaier@genome.stanford.edu> wrote: > > Conversely, is it possible to construct a (single column) result set > > from a select expression on a one-dimensional array with an unknown > > number of elements? > > Not so easy without a custom function. But not that hard: test=> SELECT id, val FROM t_arr;id | val ----+--------------- 1 | {1,2,3} 2 | {4,5,6} 3 | {7,8,9} 4 | {10,11,12,13} (4 rows) -- -- First Way -- test=> SELECT id, val[s.i] test-> FROM t_arr test-> LEFT OUTER JOIN test-> (SELECT g.s test(> FROM generate_series(1, (SELECT max(array_upper(val, 1)) FROM t_arr)) AS g(s) test(> ) AS s(i) test-> ON (s.i <= array_upper(val, 1));id | val ----+----- 1 | 1 1 | 2 1 | 3 2 | 4 2 | 5 2 | 6 3 | 7 3 | 8 3 | 9 4 | 10 4 | 11 4 | 12 4 | 13 (13 rows) -- -- Second Way (by using contrib/intagg) -- SELECT id, int_array_enum(val) FROM t_arr; Regards.
On Sat, Mar 25, 2006 at 12:17:08AM +0100, PFC wrote: > > > CREATE OR REPLACE FUNCTION foreach( liste INTEGER[] ) RETURNS SETOF > INTEGER AS $$ > DECLARE > i INTEGER; > BEGIN > FOR i IN 1..icount(liste) LOOP > RETURN NEXT liste[i]; > END LOOP; > END; > $$ LANGUAGE plpgsql; Seems like this should really exist in the backend... > CREATE AGGREGATE array_accum ( > sfunc = array_append, > basetype = anyelement, > stype = anyarray, > initcond = '{}' > ); > > SELECT array_accum( DISTINCT list_id ) FROM bookmarks; > array_accum > --------------- > {1,2,3,4,5,7} Couldn't you just use array()? -- Jim C. Nasby, Sr. Engineering Consultant jnasby@pervasive.com Pervasive Software http://pervasive.com work: 512-231-6117 vcard: http://jim.nasby.net/pervasive.vcf cell: 512-569-9461
>> SELECT array_accum( DISTINCT list_id ) FROM bookmarks; >> array_accum >> --------------- >> {1,2,3,4,5,7} > > Couldn't you just use array()? Yes, you can do this : SELECT ARRAY( SELECT something with one column ); However, array_accum() as an aggregate is more interesting because you can use GROUP BY. For instance : SELECT parent, array_accum( child ) FROM table GROUP BY parent; I have another question. Suppose I have these tables : CREATE TABLE items (id SERIAL PRIMARY KEY,category INTEGER NOT NULL,name TEXT NOT NULL, ); CREATE TABLE comments (item_id INTEGER NOT NULL REFERENCES items(id),id SERIAL PRIMARY KEY,comment TEXTNOT NULL,added TIMESTAMP NOT NULL DEFAULT now() ) Say I want to display some items and the associated comments : SELECT * FROM items WHERE category = ... Then, I gather the item ids which were returned by this query, and do : SELECT * FROM comments WHERE item_id IN ( the ids ) ORDER BY item_id, added; Is there a more elegant and efficient way which would avoid making a big IN() query ? I could join comments with items, but in my case the search condition on items is quite complicated and slow ; hence I only want to do the search once. And I have several different tables in the same style of the "comments" table, and so I make several queries using the same IN (...) term. It isn't very elegant... is there a better way ? Use a temporary table ? How do you do it ?