Natural joins
Taking the idea of the named columns join a step further, a natural join performs an automatic equi-join on all the columns that have the same name in the left and right table.The data types of these columns must be compatible.
Note
|
Natural joins are not supported in Dialect 1 databases. |
<natural-join> ::= <table-reference> NATURAL [<join-type>] JOIN <table-primary> <join-type> ::= INNER | {LEFT | RIGHT | FULL} [OUTER]
Given these two tables:
create table TA (
a bigint,
s varchar(12),
ins_date date
);
create table TB (
a bigint,
descr varchar(12),
x float,
ins_date date
);
A natural join on TA
and TB
would involve the columns a
and ins_date
, and the following two statements would have the same effect:
select * from TA
natural join TB;
select * from TA
join TB using (a, ins_date);
Like all joins, natural joins are inner joins by default, but you can turn them into outer joins by specifying LEFT
, RIGHT
or FULL
before the JOIN
keyword.
Caution
|
If there are no columns with the same name in the two source relations, a |