Обсуждение: array variables
Hi all. Can anyone help me solve this problem ? Say I have something like this:<br /><br />CREATE TEMP TABLE idx (id integer,p integer, idd integer);<br />INSERT INTO idx (id, p, idd) VALUES (3048, 1, 12043);<br />INSERT INTO idx (id, p,idd) VALUES (3048, 2, 2321);<br /> INSERT INTO idx (id, p, idd) VALUES (3048, 5, 12002);<br />INSERT INTO idx (id, p, idd)VALUES (3048, 6, 2387);<br />INSERT INTO idx (id, p, idd) VALUES (3048, 13, 4301);<br />INSERT INTO idx (id, p, idd)VALUES (3048, 16, 1022);<br /> INSERT INTO idx (id, p, idd) VALUES (3048, 19, 321);<br />INSERT INTO idx (id, p, idd)VALUES (3049, 2, 7543);<br />INSERT INTO idx (id, p, idd) VALUES (3050, 1, 56324);<br />INSERT INTO idx (id, p, idd)VALUES (3050, 2, 8746);<br /><br />How do I put (SELECT * FROM idx) into multidimensional array variable ? (plpgsql)Is is possible at all ?<br /><br /><br />regards<br />mk<br />
I know I can do one column like this : <br /><br />a := ARRAY(SELECT id FROM idx);<br /><br />but how about more than one?<br />Because if I try this :<br /><br />a := ARRAY(SELECT id, p FROM idx);<br /><br />I get<br />ERROR: subquery mustreturn only one column<br /> SQL state: 42601<br /><br />regards<br />mk<br />
Hello
2008/11/13 Marcin Krawczyk <jankes.mk@gmail.com>:
> I know I can do one column like this :
>
> a := ARRAY(SELECT id FROM idx);
>
> but how about more than one ?
> Because if I try this :
>
> a := ARRAY(SELECT id, p FROM idx);
>
> I get
> ERROR: subquery must return only one column
> SQL state: 42601
>
you can't do it directly :( now.
postgres=# create or replace function accum() returns int[] as
$$declare s int[] = '{}'; r record; begin for r in select * from f2
loop s := s || array[[r.a, r.b]]; end loop; return s; end;$$ language
plpgsql;
\CREATE FUNCTION
postgres=# select accum(); accum
-------------------{{10,10},{20,20}}
(1 row)
postgres=# select * from f2;a | b
----+----10 | 1020 | 20
(2 rows)
regards
Pavel Stehule
> regards
> mk
>
Thank you guys, I appreciate your help.<br /><br /><br />regards<br />mk<br /><br />
Στις Thursday 13 November 2008 11:13:30 ο/η Marcin Krawczyk έγραψε: > I know I can do one column like this : > > a := ARRAY(SELECT id FROM idx); > > but how about more than one ? > Because if I try this : > > a := ARRAY(SELECT id, p FROM idx); > > I get > ERROR: subquery must return only one column > SQL state: 42601 how about smth like: SELECT ARRAY[ARRAY(SELECT id FROM idx),ARRAY(SELECT p FROM idx)]; you will get 2 rows with "select count(*) from idx" columns each. you can access it like SELECT (ARRAY[ARRAY(SELECT id FROM idx),ARRAY(SELECT p FROM idx)])[i][j]; 1<=i<=2 1<=j<=select count(*) from idx > > regards > mk > -- Achilleas Mantzios
"Pavel Stehule" <pavel.stehule@gmail.com> writes:
> 2008/11/13 Marcin Krawczyk <jankes.mk@gmail.com>:
>> Because if I try this :
>> a := ARRAY(SELECT id, p FROM idx);
>> I get
>> ERROR: subquery must return only one column
> you can't do it directly :( now.
Sure you can, if you're using a version new enough to have arrays of
composite types.
regression=# create table t1 (f1 int, f2 text);
CREATE TABLE
regression=# insert into t1 values (1,'one');
INSERT 0 1
regression=# insert into t1 values (2,'two');
INSERT 0 1
regression=# select array(select row(t1.*)::t1 from t1); ?column?
-----------------------{"(1,one)","(2,two)"}
(1 row)
Whether this is a good idea for a large table is a different question ;-)
regards, tom lane
2008/11/13 Tom Lane <tgl@sss.pgh.pa.us>:
> "Pavel Stehule" <pavel.stehule@gmail.com> writes:
>> 2008/11/13 Marcin Krawczyk <jankes.mk@gmail.com>:
>>> Because if I try this :
>>> a := ARRAY(SELECT id, p FROM idx);
>>> I get
>>> ERROR: subquery must return only one column
>
>> you can't do it directly :( now.
>
> Sure you can, if you're using a version new enough to have arrays of
> composite types.
>
> regression=# create table t1 (f1 int, f2 text);
> CREATE TABLE
> regression=# insert into t1 values (1,'one');
> INSERT 0 1
> regression=# insert into t1 values (2,'two');
> INSERT 0 1
> regression=# select array(select row(t1.*)::t1 from t1);
> ?column?
> -----------------------
> {"(1,one)","(2,two)"}
> (1 row)
>
> Whether this is a good idea for a large table is a different question ;-)
I don't expect so user use devel version ;) - and result is array of
some composite type, not two dimensional array (but arrays of records
is nice feature too).
regards
Pavel
>
> regards, tom lane
>
"Pavel Stehule" <pavel.stehule@gmail.com> writes:
> 2008/11/13 Tom Lane <tgl@sss.pgh.pa.us>:
>> Sure you can, if you're using a version new enough to have arrays of
>> composite types.
> I don't expect so user use devel version ;)
My example was done in 8.3.
> - and result is array of
> some composite type, not two dimensional array
Well, if the columns are of different types then you'll never be able to
represent them as a 2-D array, so I thought this was a more general answer.
regards, tom lane
2008/11/13 Tom Lane <tgl@sss.pgh.pa.us>: > "Pavel Stehule" <pavel.stehule@gmail.com> writes: >> 2008/11/13 Tom Lane <tgl@sss.pgh.pa.us>: >>> Sure you can, if you're using a version new enough to have arrays of >>> composite types. > >> I don't expect so user use devel version ;) > > My example was done in 8.3. > >> - and result is array of >> some composite type, not two dimensional array > I tested it with error: postgres=# create table f(a int, b int); CREATE TABLE postgres=# insert into f values(10,20); INSERT 0 1 postgres=# select array(select row(a,b) from f); ERROR: could not find array type for datatype record postgres=# select version(); version ----------------------------------------------------------------------------------------------------PostgreSQL 8.3.0 on i686-pc-linux-gnu,compiled by GCC gcc (GCC) 4.1.2 20070925 (Red Hat 4.1.2-33) (1 row) I forgot on casting, so I was confused. Regards Pavel Stehule > Well, if the columns are of different types then you'll never be able to > represent them as a 2-D array, so I thought this was a more general answer. ok > > regards, tom lane >
"Pavel Stehule" <pavel.stehule@gmail.com> writes:
> 2008/11/13 Tom Lane <tgl@sss.pgh.pa.us>:
>> My example was done in 8.3.
> I tested it with error:
> postgres=# select array(select row(a,b) from f);
> ERROR: could not find array type for datatype record
You left out the cast to a named rowtype --- that's not optional,
unfortunately.
regards, tom lane
2008/11/13 Tom Lane <tgl@sss.pgh.pa.us>:
> "Pavel Stehule" <pavel.stehule@gmail.com> writes:
>> 2008/11/13 Tom Lane <tgl@sss.pgh.pa.us>:
>>> My example was done in 8.3.
>
>> I tested it with error:
>
>> postgres=# select array(select row(a,b) from f);
>> ERROR: could not find array type for datatype record
>
> You left out the cast to a named rowtype --- that's not optional,
> unfortunately.
>
it works on devel
[pavel@localhost pgsql]$ psql postgres
\psql (8.4devel)
Type "help" for help.
postgres=# create table foo(a int, b varchar);
CREATE TABLE
postgres=# insert into foo values(10, 'kuku'),(20,'aba');
INSERT 0 2
postgres=# select array(select row(a,b) from foo); ?column?
--------------------------{"(10,kuku)","(20,aba)"}
(1 row)
regards
Pavel Stehule
> regards, tom lane
>