Re: aggregate arrays - Mailing list pgsql-general

From Albe Laurenz
Subject Re: aggregate arrays
Date
Msg-id D960CB61B694CF459DCFB4B0128514C207BB6B45@exadv11.host.magwien.gv.at
Whole thread Raw
In response to aggregate arrays  ("Dmitry E. Oboukhov" <unera@debian.org>)
List pgsql-general
Dmitry E. Oboukhov wrote:
> example:
> 
> a query returns a column that contains arrays:
> 
> select * FROM (VALUES (ARRAY[1,2,3,3,4], 1), (ARRAY[1,2,2,3,4], 2)) t;
>    column1   | column2
> -------------+---------
>  {1,2,3,3,4} |       1
>  {1,2,2,3,4} |       2
> (2 rows)
> 
> and then we want aggregate that result.
> 
> example by column2:
> 
> WITH "test" AS (
>     select * FROM (VALUES (ARRAY[1,2,3,3,4], 1), (ARRAY[1,2,2,3,4], 2)) t
> )
> 
> SELECT array_agg(column2) column2 FROM "test";
>  column2
> ---------
>  {1,2}
> (1 row)
> 
> 
> and I want aggregate column1 arrays into one array. I want receive the
> result:
> 
>        column1        |  column2
> ----------------------+-------------
> {1,2,3,3,4,1,2,2,3,4} | {1,2}
> 
> 
> I've tried the statement:
> 
> WITH "test" AS (
>     select * FROM (VALUES (ARRAY[1,2,3,3,4], 1), (ARRAY[1,2,2,3,4], 2)) t
> )
> 
> SELECT
>     array_agg(unnest(column1)) AS column1,
>     array_agg(column2) column2
> FROM
>     "test";
> 
> But I receive the error:
> 
> ERROR:  set-valued function called in context that cannot accept a set
> 
> How can I aggregate arrays into one array?

Create your own aggregate.

CREATE AGGREGATE array_union (anyarray) (SFUNC = array_cat, STYPE = anyarray);

WITH "test" AS (
    select * FROM (VALUES (ARRAY[1,2,3,3,4], 1), (ARRAY[1,2,2,3,4], 2)) t
)
SELECT
    array_union(column1) AS column1,
    array_agg(column2) column2
FROM
    "test";

        column1        | column2
-----------------------+---------
 {1,2,3,3,4,1,2,2,3,4} | {1,2}
(1 row)

Yours,
Laurenz Albe

pgsql-general by date:

Previous
From: Jeff Adams
Date:
Subject: Updating pg_attribute to change field's data type from integer to bigint on very large table
Next
From: Tom Lane
Date:
Subject: Re: Updating pg_attribute to change field's data type from integer to bigint on very large table