Re: Need a SQL to create sets of hobbies

From: Harald Fuchs <hf0731x(at)protecting(dot)net>
To: pgsql-sql(at)postgresql(dot)org
Subject: Re: Need a SQL to create sets of hobbies
Date: 2006-09-20 11:33:01
Message-ID: puhcz2kc2a.fsf@srv.protecting.net
Views: Raw Message | Whole Thread | Download mbox | Resend email
Thread:
Lists: pgsql-sql

In article <1158729519(dot)6421(dot)271361727(at)webmail(dot)messagingengine(dot)com>,
"CN" <cnliou9(at)fastmail(dot)fm> writes:

> select * from x1;

> name | hobby
> -------+----------
> John | music
> John | arts
> Bob | arts
> Bob | music
> Rocky | computer
> Steve | arts
> Steve | football
> Tom | computer
> Tom | music
> (9 rows)

> Now we have 4 sets of hobbies:

> set 1: music, arts
> set 2: computer
> set 3: arts, football
> set 4: computer, music

> I am looking for an SQL that creates sets of hobbies in table x2 by
> selecting from table x1:

> CREATE TABLE x2 (sid INTEGER, hobby TEXT, PRIMARY KEY(sid,hobby));

> and makes x2 contain rows:

> sid | hobby
> -------+----------
> 1 | music
> 1 | arts
> 2 | computer
> 3 | arts
> 3 | football
> 4 | computer
> 4 | music

> where gid starts from 1.

You could use something like that:

CREATE TEMP TABLE tmp (
id SERIAL NOT NULL,
name TEXT NOT NULL,
PRIMARY KEY (id)
);

INSERT INTO tmp (name)
SELECT DISTINCT ON (ARRAY (
SELECT y1.hobby
FROM x1 y1
WHERE y1.name = y2.name
ORDER BY y1.name, y1.hobby
))
y2.name
FROM x1 y2;

INSERT INTO x2 (sid, hobby)
SELECT tmp.id, x1.hobby
FROM tmp
JOIN x1 ON x1.name = tmp.name;

In response to

Browse pgsql-sql by date

  From Date Subject
Next Message Aaron Bono 2006-09-20 17:24:09 Re: Dividing results from two tables with different time frames
Previous Message Markus Schaber 2006-09-20 09:24:14 Re: Make Trigger run after completion of ENTIRE transaction