Commit fb310f17 authored by Peter Eisentraut's avatar Peter Eisentraut

doc: Prefer explicit JOIN syntax over old implicit syntax in tutorial

Update src/tutorial/basics.source to match.

Author: Jürgen Purtz <juergen@purtz.de>
Reviewed-by: default avatarThomas Munro <thomas.munro@gmail.com>
Reviewed-by: default avatar"David G. Johnston" <david.g.johnston@gmail.com>
Discussion: https://www.postgresql.org/message-id/flat/158996922318.7035.10603922579567326239@wrigleys.postgresql.org
parent 6b4d23fe
...@@ -440,27 +440,26 @@ SELECT DISTINCT city ...@@ -440,27 +440,26 @@ SELECT DISTINCT city
Thus far, our queries have only accessed one table at a time. Thus far, our queries have only accessed one table at a time.
Queries can access multiple tables at once, or access the same Queries can access multiple tables at once, or access the same
table in such a way that multiple rows of the table are being table in such a way that multiple rows of the table are being
processed at the same time. A query that accesses multiple rows processed at the same time. Queries that access multiple tables
of the same or different tables at one time is called a (or multiple instances of the same table) at one time are called
<firstterm>join</firstterm> query. As an example, say you wish to <firstterm>join</firstterm> queries. They combine rows from one table
list all the weather records together with the location of the with rows from a second table, with an expression specifying which rows
associated city. To do that, we need to compare the <structfield>city</structfield> are to be paired. For example, to return all the weather records together
with the location of the associated city, the database needs to compare
the <structfield>city</structfield>
column of each row of the <structname>weather</structname> table with the column of each row of the <structname>weather</structname> table with the
<structfield>name</structfield> column of all rows in the <structname>cities</structname> <structfield>name</structfield> column of all rows in the <structname>cities</structname>
table, and select the pairs of rows where these values match. table, and select the pairs of rows where these values match.<footnote>
<note>
<para> <para>
This is only a conceptual model. The join is usually performed This is only a conceptual model. The join is usually performed
in a more efficient manner than actually comparing each possible in a more efficient manner than actually comparing each possible
pair of rows, but this is invisible to the user. pair of rows, but this is invisible to the user.
</para> </para>
</note> </footnote>
This would be accomplished by the following query: This would be accomplished by the following query:
<programlisting> <programlisting>
SELECT * SELECT * FROM weather JOIN cities ON city = name;
FROM weather, cities
WHERE city = name;
</programlisting> </programlisting>
<screen> <screen>
...@@ -497,23 +496,13 @@ SELECT * ...@@ -497,23 +496,13 @@ SELECT *
<literal>*</literal>: <literal>*</literal>:
<programlisting> <programlisting>
SELECT city, temp_lo, temp_hi, prcp, date, location SELECT city, temp_lo, temp_hi, prcp, date, location
FROM weather, cities FROM weather JOIN cities ON city = name;
WHERE city = name;
</programlisting> </programlisting>
</para> </para>
</listitem> </listitem>
</itemizedlist> </itemizedlist>
</para> </para>
<formalpara>
<title>Exercise:</title>
<para>
Attempt to determine the semantics of this query when the
<literal>WHERE</literal> clause is omitted.
</para>
</formalpara>
<para> <para>
Since the columns all had different names, the parser Since the columns all had different names, the parser
automatically found which table they belong to. If there automatically found which table they belong to. If there
...@@ -524,8 +513,7 @@ SELECT city, temp_lo, temp_hi, prcp, date, location ...@@ -524,8 +513,7 @@ SELECT city, temp_lo, temp_hi, prcp, date, location
<programlisting> <programlisting>
SELECT weather.city, weather.temp_lo, weather.temp_hi, SELECT weather.city, weather.temp_lo, weather.temp_hi,
weather.prcp, weather.date, cities.location weather.prcp, weather.date, cities.location
FROM weather, cities FROM weather JOIN cities ON weather.city = cities.name;
WHERE cities.name = weather.city;
</programlisting> </programlisting>
It is widely considered good style to qualify all column names It is widely considered good style to qualify all column names
...@@ -535,15 +523,24 @@ SELECT weather.city, weather.temp_lo, weather.temp_hi, ...@@ -535,15 +523,24 @@ SELECT weather.city, weather.temp_lo, weather.temp_hi,
<para> <para>
Join queries of the kind seen thus far can also be written in this Join queries of the kind seen thus far can also be written in this
alternative form: form:
<programlisting> <programlisting>
SELECT * SELECT *
FROM weather INNER JOIN cities ON (weather.city = cities.name); FROM weather, cities
WHERE city = name;
</programlisting> </programlisting>
This syntax is not as commonly used as the one above, but we show This syntax pre-dates the <literal>JOIN</literal>/<literal>ON</literal>
it here to help you understand the following topics. syntax, which was introduced in SQL-92. The tables are simply listed in
the <literal>FROM</literal> clause, and the comparison expression is added
to the <literal>WHERE</literal> clause. The results from this older
implicit syntax and the newer explicit
<literal>JOIN</literal>/<literal>ON</literal> syntax are identical. But
for a reader of the query, the explicit syntax makes its meaning easier to
understand: The join condition is introduced by its own key word whereas
previously the condition was mixed into the <literal>WHERE</literal>
clause together with other conditions.
</para> </para>
<indexterm><primary>join</primary><secondary>outer</secondary></indexterm> <indexterm><primary>join</primary><secondary>outer</secondary></indexterm>
...@@ -556,12 +553,12 @@ SELECT * ...@@ -556,12 +553,12 @@ SELECT *
found we want some <quote>empty values</quote> to be substituted found we want some <quote>empty values</quote> to be substituted
for the <structname>cities</structname> table's columns. This kind for the <structname>cities</structname> table's columns. This kind
of query is called an <firstterm>outer join</firstterm>. (The of query is called an <firstterm>outer join</firstterm>. (The
joins we have seen so far are inner joins.) The command looks joins we have seen so far are <firstterm>inner joins</firstterm>.)
like this: The command looks like this:
<programlisting> <programlisting>
SELECT * SELECT *
FROM weather LEFT OUTER JOIN cities ON (weather.city = cities.name); FROM weather LEFT OUTER JOIN cities ON weather.city = cities.name;
</programlisting> </programlisting>
<screen> <screen>
...@@ -591,10 +588,9 @@ SELECT * ...@@ -591,10 +588,9 @@ SELECT *
</para> </para>
</formalpara> </formalpara>
<para>
<indexterm><primary>join</primary><secondary>self</secondary></indexterm> <indexterm><primary>join</primary><secondary>self</secondary></indexterm>
<indexterm><primary>alias</primary><secondary>for table name in query</secondary></indexterm> <indexterm><primary>alias</primary><secondary>for table name in query</secondary></indexterm>
<para>
We can also join a table against itself. This is called a We can also join a table against itself. This is called a
<firstterm>self join</firstterm>. As an example, suppose we wish <firstterm>self join</firstterm>. As an example, suppose we wish
to find all the weather records that are in the temperature range to find all the weather records that are in the temperature range
...@@ -609,9 +605,8 @@ SELECT * ...@@ -609,9 +605,8 @@ SELECT *
<programlisting> <programlisting>
SELECT w1.city, w1.temp_lo AS low, w1.temp_hi AS high, SELECT w1.city, w1.temp_lo AS low, w1.temp_hi AS high,
w2.city, w2.temp_lo AS low, w2.temp_hi AS high w2.city, w2.temp_lo AS low, w2.temp_hi AS high
FROM weather w1, weather w2 FROM weather w1 JOIN weather w2
WHERE w1.temp_lo &lt; w2.temp_lo ON w1.temp_lo &lt; w2.temp_lo AND w1.temp_hi &gt; w2.temp_hi;
AND w1.temp_hi &gt; w2.temp_hi;
</programlisting> </programlisting>
<screen> <screen>
...@@ -628,8 +623,7 @@ SELECT w1.city, w1.temp_lo AS low, w1.temp_hi AS high, ...@@ -628,8 +623,7 @@ SELECT w1.city, w1.temp_lo AS low, w1.temp_hi AS high,
queries to save some typing, e.g.: queries to save some typing, e.g.:
<programlisting> <programlisting>
SELECT * SELECT *
FROM weather w, cities c FROM weather w JOIN cities c ON w.city = c.name;
WHERE w.city = c.name;
</programlisting> </programlisting>
You will encounter this style of abbreviating quite frequently. You will encounter this style of abbreviating quite frequently.
</para> </para>
......
...@@ -97,42 +97,38 @@ SELECT DISTINCT city ...@@ -97,42 +97,38 @@ SELECT DISTINCT city
-- The following joins the weather table and the cities table. -- The following joins the weather table and the cities table.
SELECT * SELECT * FROM weather JOIN cities ON city = name;
FROM weather, cities
WHERE city = name;
-- This prevents a duplicate city name column: -- This prevents a duplicate city name column:
SELECT city, temp_lo, temp_hi, prcp, date, location SELECT city, temp_lo, temp_hi, prcp, date, location
FROM weather, cities FROM weather JOIN cities ON city = name;
WHERE city = name;
-- since the column names are all different, we don't have to specify the -- since the column names are all different, we don't have to specify the
-- table name. If you want to be clear, you can do the following. They give -- table name. If you want to be clear, you can do the following. They give
-- identical results, of course. -- identical results, of course.
SELECT weather.city, weather.temp_lo, weather.temp_hi, weather.prcp, weather.date, cities.location SELECT weather.city, weather.temp_lo, weather.temp_hi, weather.prcp, weather.date, cities.location
FROM weather, cities FROM weather JOIN cities ON weather.city = cities.name;
WHERE cities.name = weather.city;
-- JOIN syntax -- Old join syntax
SELECT * SELECT *
FROM weather JOIN cities ON (weather.city = cities.name); FROM weather, cities
WHERE city = name;
-- Outer join -- Outer join
SELECT * SELECT *
FROM weather LEFT OUTER JOIN cities ON (weather.city = cities.name); FROM weather LEFT OUTER JOIN cities ON weather.city = cities.name;
-- Suppose we want to find all the records that are in the temperature range -- Suppose we want to find all the records that are in the temperature range
-- of other records. w1 and w2 are aliases for weather. -- of other records. w1 and w2 are aliases for weather.
SELECT w1.city, w1.temp_lo, w1.temp_hi, SELECT w1.city, w1.temp_lo, w1.temp_hi,
w2.city, w2.temp_lo, w2.temp_hi w2.city, w2.temp_lo, w2.temp_hi
FROM weather w1, weather w2 FROM weather w1 JOIN weather w2
WHERE w1.temp_lo < w2.temp_lo ON w1.temp_lo < w2.temp_lo AND w1.temp_hi > w2.temp_hi;
and w1.temp_hi > w2.temp_hi;
----------------------------- -----------------------------
......
Markdown is supported
0% or
You are about to add 0 people to the discussion. Proceed with caution.
Finish editing this message first!
Please register or to comment