Re: join with an array

From: Achilleas Mantzios <achill(at)matrix(dot)gatewaynet(dot)com>
To: pgsql-sql(at)postgresql(dot)org
Subject: Re: join with an array
Date: 2010-02-24 14:39:00
Message-ID: 201002241639.00331.achill@matrix.gatewaynet.com
Views: Raw Message | Whole Thread | Download mbox | Resend email
Thread:
Lists: pgsql-sql

Στις Wednesday 24 February 2010 15:34:48 ο/η Louis-David Mitterrand έγραψε:

> Here is a test case I built. I want to list all cruises by cruise_type
> but after merging cruise_type that have the same cruise_type_name:
>
> drop table cruise;
> drop table cruise_type;
>
> create table cruise_type (
> id_cruise_type serial primary key,
> cruise_type_name text
> );
>
> create table cruise (
> id_cruise serial,
> id_cruise_type integer references cruise_type,
> cruise_date timestamp default now()
> );
>
> insert into cruise_type (cruise_type_name) values
> ('5 day eastern carribean cruise'),
> ('5 day western carribean cruise'),
> ('5 day eastern carribean cruise'),
> ('5 day western carribean cruise')
> ;
>
> insert into cruise (id_cruise_type) values
> (1),
> (2),
> (3),
> (4),
> (1),
> (2),
> (3),
> (4)
> ;
>
> select array_agg(ct.id_cruise_type),ct.cruise_type_name from cruise_type ct join cruise c on (c.id_cruise = any(array_agg)) group by cruise_type_name;
>

You dont specify (in english) what you exactly want to achive, but here is my shot:
1st, get the cruises by cruise type:
select ct.id_cruise_type,array_agg(c.id_cruise) as "List of Cruises" from cruise_type ct, cruise c WHERE c.id_cruise_type=ct.id_cruise_type GROUP BY ct.id_cruise_type ORDER BY ct.id_cruise_type;
id_cruise_type | List of Cruises
----------------+-----------------
1 | {1,5}
2 | {2,6}
3 | {3,7}
4 | {4,8}
(4 rows)

test=#
Then you may pretify this to include the name of each cruise type as well:

select ct.id_cruise_type,ct.cruise_type_name,array_agg(c.id_cruise) as "List of Cruises" from cruise_type ct, cruise c WHERE c.id_cruise_type=ct.id_cruise_type GROUP BY ct.id_cruise_type,ct.cruise_type_name ORDER BY ct.id_cruise_type;
id_cruise_type | cruise_type_name | List of Cruises
----------------+--------------------------------+-----------------
1 | 5 day eastern carribean cruise | {1,5}
2 | 5 day western carribean cruise | {2,6}
3 | 5 day eastern carribean cruise | {3,7}
4 | 5 day western carribean cruise | {4,8}
(4 rows)

EXERCISE:
Why cant we exclude ct.id_cruise_type from the select clause and group by of the above query?

--
Achilleas Mantzios

In response to

Browse pgsql-sql by date

  From Date Subject
Next Message Aron 2010-02-25 15:19:32 Using new.id in the WHERE condition of one UPDATE inside ON INSERT rule
Previous Message Ricardo S. Carvalho 2010-02-24 13:42:20 Microsoft Sync Framework