Re: multiple lookup per row - Mailing list pgsql-sql

From Tom Lane
Subject Re: multiple lookup per row
Date
Msg-id 3691.995644067@sss.pgh.pa.us
Whole thread Raw
In response to Re: multiple lookup per row  ("Josh Berkus" <josh@agliodbs.com>)
List pgsql-sql
"Josh Berkus" <josh@agliodbs.com> writes:
> ... LEFT OUTER JOIN ...

Another way is correlated subselects in the output list:

SELECT mid, name, address,   (SELECT phone FROM phones    WHERE members.mid = phones.mid and ptype = 'home') AS
home_phone,  (SELECT phone FROM phones    WHERE members.mid = phones.mid and ptype = 'work') AS work_phone,   (SELECT
phoneFROM phones    WHERE members.mid = phones.mid and ptype = 'cell') AS cell_phone
 
FROM members;

With either of these approaches, you'll get NULLs for cases where the
member has no phone number of the given type.  However, what you ought
to think about is what happens if the member has more than one phone
number of a single type.  With the outer join you will get multiple
output rows for that member, which is likely not what you want.  With
my way, you'd get an execution error, which is definitely not what you
want...  but you could patch it by including LIMIT 1 in the sub-SELECTs,
and perhaps also an ORDER BY to determine *which* phone number is the
single one shown.

BTW, I second Josh' recommendation of "SQL for Smarties".
        regards, tom lane


pgsql-sql by date:

Previous
From: Raymond Chui
Date:
Subject: When PostgreSQL compliant JDBC 2.0?
Next
From: "Magnus Landahl"
Date:
Subject: Get the tables names?