Обсуждение: joining from multiple tables

Поиск
Список
Период
Сортировка

joining from multiple tables

От
Joseph Shraibman
Дата:
I have a table I want to join on, but the conditions that restrict it span more than one 
table.  For example:

create table num_tab (thekey int primary key, val int, class char);
create table class_tab (class char primary key, tkey int);
create table txt_tab (thekey int primary key, class int, txt text);

insert into num_tab values (1, 1, 'o');
insert into num_tab values (2, 2, 'e');
insert into num_tab values (3, 3, 'o');
insert into num_tab values (4, 4, 'e');
insert into num_tab values (5, 5, 'o');
insert into num_tab values (6, 6, 'e');

insert into class_tab values('o', 1);
insert into class_tab values('e', 2);

insert into txt_tab values (2, 2,'two');
insert into txt_tab values (4, 2,'four');
insert into txt_tab values (6, 2,'six');

select distinct n.thekey, n.val, t.txt  FROM  num_tab n LEFT JOIN txt_tab t ON n.thekey = 
t.thekey
WHERE  n.thekey < 5 AND t.class = class_tab.tkey AND n.class = class_tab.class;
produces:
 thekey | val | txt
--------+-----+------      2 |   2 | two      4 |   4 | four
... which is not what we want, because 1,3, and 5 aren't included, but:

select distinct n.thekey, n.val, t.txt  FROM  num_tab n LEFT JOIN txt_tab t ON n.thekey = 
t.thekey  AND t.class = class_tab.tkey AND n.class = class_tab.class
WHERE  n.thekey < 5; produces:
NOTICE:  Adding missing FROM-clause entry for table "class_tab"
ERROR:  JOIN/ON clause refers to "class_tab", which is not part of JOIN

So how do I do this?



Re: joining from multiple tables

От
Stephan Szabo
Дата:
On Wed, 15 Jan 2003, Joseph Shraibman wrote:

> select distinct n.thekey, n.val, t.txt  FROM  num_tab n LEFT JOIN txt_tab t ON n.thekey =
> t.thekey
> WHERE  n.thekey < 5 AND t.class = class_tab.tkey AND n.class = class_tab.class;
> produces:

Note that the above uses the non-standard postgres behavior of adding from
clauses, it's not technically valid SQL.

>   thekey | val | txt
> --------+-----+------
>        2 |   2 | two
>        4 |   4 | four
> ... which is not what we want, because 1,3, and 5 aren't included, but:
>
> select distinct n.thekey, n.val, t.txt  FROM  num_tab n LEFT JOIN txt_tab t ON n.thekey =
> t.thekey  AND t.class = class_tab.tkey AND n.class = class_tab.class
> WHERE  n.thekey < 5;
>   produces:
> NOTICE:  Adding missing FROM-clause entry for table "class_tab"
> ERROR:  JOIN/ON clause refers to "class_tab", which is not part of JOIN
>
> So how do I do this?

I think you want something like:

select distinct n.thekey, n.val, t.txt  FROM class_tab JOIN num_tab n
using (class) LEFT JOIN txt_tab t on (t.thekey=n.thekey and t.class =
class_tab.tkey);