Documentation Home
MySQL 5.7 Reference Manual
Related Documentation Download this Manual
PDF (US Ltr) - 33.8Mb
PDF (A4) - 34.0Mb
PDF (RPM) - 33.2Mb
EPUB - 8.5Mb
HTML Download (TGZ) - 8.2Mb
HTML Download (Zip) - 8.2Mb
HTML Download (RPM) - 7.1Mb
Eclipse Doc Plugin (TGZ) - 9.0Mb
Eclipse Doc Plugin (Zip) - 11.1Mb
Man Pages (TGZ) - 219.4Kb
Man Pages (Zip) - 322.3Kb
Info (Gzip) - 3.2Mb
Info (Zip) - 3.2Mb
Excerpts from this Manual

3.3.4.9 Using More Than one Table

The pet table keeps track of which pets you have. If you want to record other information about them, such as events in their lives like visits to the vet or when litters are born, you need another table. What should this table look like? It needs to contain the following information:

  • The pet name so that you know which animal each event pertains to.

  • A date so that you know when the event occurred.

  • A field to describe the event.

  • An event type field, if you want to be able to categorize events.

Given these considerations, the CREATE TABLE statement for the event table might look like this:

mysql> CREATE TABLE event (name VARCHAR(20), date DATE,
    -> type VARCHAR(15), remark VARCHAR(255));

As with the pet table, it is easiest to load the initial records by creating a tab-delimited text file containing the following information.

namedatetyperemark
Fluffy1995-05-15litter4 kittens, 3 female, 1 male
Buffy1993-06-23litter5 puppies, 2 female, 3 male
Buffy1994-06-19litter3 puppies, 3 female
Chirpy1999-03-21vetneeded beak straightened
Slim1997-08-03vetbroken rib
Bowser1991-10-12kennel
Fang1991-10-12kennel
Fang1998-08-28birthdayGave him a new chew toy
Claws1998-03-17birthdayGave him a new flea collar
Whistler1998-12-09birthdayFirst birthday

Load the records like this:

mysql> LOAD DATA LOCAL INFILE 'event.txt' INTO TABLE event;

Based on what you have learned from the queries that you have run on the pet table, you should be able to perform retrievals on the records in the event table; the principles are the same. But when is the event table by itself insufficient to answer questions you might ask?

Suppose that you want to find out the ages at which each pet had its litters. We saw earlier how to calculate ages from two dates. The litter date of the mother is in the event table, but to calculate her age on that date you need her birth date, which is stored in the pet table. This means the query requires both tables:

mysql> SELECT pet.name,
    -> (YEAR(date)-YEAR(birth)) - (RIGHT(date,5)<RIGHT(birth,5)) AS age,
    -> remark
    -> FROM pet INNER JOIN event
    ->   ON pet.name = event.name
    -> WHERE event.type = 'litter';
+--------+------+-----------------------------+
| name   | age  | remark                      |
+--------+------+-----------------------------+
| Fluffy |    2 | 4 kittens, 3 female, 1 male |
| Buffy  |    4 | 5 puppies, 2 female, 3 male |
| Buffy  |    5 | 3 puppies, 3 female         |
+--------+------+-----------------------------+

There are several things to note about this query:

  • The FROM clause joins two tables because the query needs to pull information from both of them.

  • When combining (joining) information from multiple tables, you need to specify how records in one table can be matched to records in the other. This is easy because they both have a name column. The query uses an ON clause to match up records in the two tables based on the name values.

    The query uses an INNER JOIN to combine the tables. An INNER JOIN permits rows from either table to appear in the result if and only if both tables meet the conditions specified in the ON clause. In this example, the ON clause specifies that the name column in the pet table must match the name column in the event table. If a name appears in one table but not the other, the row will not appear in the result because the condition in the ON clause fails.

  • Because the name column occurs in both tables, you must be specific about which table you mean when referring to the column. This is done by prepending the table name to the column name.

You need not have two different tables to perform a join. Sometimes it is useful to join a table to itself, if you want to compare records in a table to other records in that same table. For example, to find breeding pairs among your pets, you can join the pet table with itself to produce candidate pairs of males and females of like species:

mysql> SELECT p1.name, p1.sex, p2.name, p2.sex, p1.species
    -> FROM pet AS p1 INNER JOIN pet AS p2
    ->   ON p1.species = p2.species AND p1.sex = 'f' AND p2.sex = 'm';
+--------+------+--------+------+---------+
| name   | sex  | name   | sex  | species |
+--------+------+--------+------+---------+
| Fluffy | f    | Claws  | m    | cat     |
| Buffy  | f    | Fang   | m    | dog     |
| Buffy  | f    | Bowser | m    | dog     |
+--------+------+--------+------+---------+

In this query, we specify aliases for the table name to refer to the columns and keep straight which instance of the table each column reference is associated with.


User Comments
  Posted by Steve Seliquini on November 30, 2003
Depending on when this query was run, Bowser might not be available for mating. :) In this case we can add additional criteria to the where clause to ensure that the animal is actually alive to perform.

select p1.name, p1.gender, p2.name, p2.gender, p1.species
from pet as p1, pet as p2
where p1.species = p2.species and p1.gender = 'f' and p2.gender = 'm'
and p1.death is null and p2.death is null;
+--------+--------+-------+--------+---------+
| name | gender | name | gender | species |
+--------+--------+-------+--------+---------+
| Fluffy | f | Claws | m | cat |
| Buffy | f | Fang | m | dog |
+--------+--------+-------+--------+---------+
2 rows in set (0.00 sec)

mysql>

  Posted by on December 30, 2003
mysql> SELECT p1.name, p1.sex, p2.name, p2.sex, p1.species
-> FROM pet AS p1, pet AS p2
-> WHERE p1.species = p2.species AND p1.sex = "f" AND p2.sex = "m"
-> AND p1.death IS NULL and p2.death IS NULL;
+--------+------+-------+------+---------+
| name | sex | name | sex | species |
+--------+------+-------+------+---------+
| Fluffy | f | Claws | m | cat |
| Buffy | f | Fang | m | dog |
+--------+------+-------+------+---------+
2 rows in set (0.00 sec)

mysql>

The above follows the naming convention and syntax of the tutorial.
  Posted by Allen Moore on December 2, 2004
Windows users, if your LOAD DATA INFILE... command mangles your input, remember to try adding ...LINES TERMINATED BY '\r\n'.
  Posted by Steve Lawson on January 22, 2005
Here's a query that produces a more succinct version of the "Breeding Pairs" table (that ignores the fact that poor Bowser is dead):

SELECT p1.species as Species, p1.name AS Female, p2.name AS Male
FROM pets AS p1, pets AS p2
WHERE p1.species = p2.species
AND p1.sex = 'f' AND p2.sex = 'm'

+---------+--------+--------+
| Species | Female | Male |
+---------+--------+--------+
| cat | Fluffy | Claws |
| dog | Buffy | Fang |
| dog | Buffy | Bowser |
+---------+--------+--------+

Here it is as a LEFT JOIN:

SELECT p1.species, p1.name AS Male, p2.name AS Female
FROM pets AS p1
LEFT JOIN pets AS p2 ON p1.species = p2.species
WHERE p1.sex = 'm' AND p2.sex = 'f'

and with the dead pet filter:

SELECT p1.species AS Species, p1.name AS Female, p2.name AS Male
FROM pets AS p1, pets AS p2
WHERE p1.species = p2.species
AND p1.sex = 'f' AND p2.sex = 'm'
AND p1.death IS NULL AND p2.death IS NULL

  Posted by Mario Vargas on September 25, 2006
The above queries by Steve, using the naming convention in the tutorial to avoid confusion (Steve's table is named "pets" and not "pet"):

Steve's concise example:

SELECT p1.species AS Species, p1.name AS Female, p2.name AS Male
FROM pet AS p1, pet AS p2
WHERE p1.species = p2.species
AND p1.sex = 'f' AND p2.sex = 'm';

+---------+--------+--------+
| Species | Female | Male |
+---------+--------+--------+
| cat | Fluffy | Claws |
| dog | Buffy | Fang |
| dog | Buffy | Bowser |
+---------+--------+--------+

Using an INNER JOIN (instead of a LEFT JOIN). Also defined the Female pets as alias "p1":

SELECT p1.species AS Species, p1.name AS Female, p2.name AS Male
FROM pet AS p1
INNER JOIN pet AS p2 ON p1.species = p2.species
WHERE p1.sex = 'f' AND p2.sex = 'm';

+---------+--------+--------+
| Species | Female | Male |
+---------+--------+--------+
| cat | Fluffy | Claws |
| dog | Buffy | Fang |
| dog | Buffy | Bowser |
+---------+--------+--------+

Using the dead pet filter:

SELECT p1.species AS Species, p1.name AS Female, p2.name AS Male
FROM pet AS p1, pet AS p2
WHERE p1.species = p2.species
AND p1.sex = 'f' AND p2.sex = 'm'
AND p1.death IS NULL AND p2.death IS NULL;

+---------+--------+-------+
| Species | Female | Male |
+---------+--------+-------+
| cat | Fluffy | Claws |
| dog | Buffy | Fang |
+---------+--------+-------+

The above query with the dead filter but using an INNER JOIN:

SELECT p1.species AS Species, p1.name AS Female, p2.name AS Male
FROM pet AS p1
INNER JOIN pet AS p2 ON p2.species = p1.species
WHERE p1.sex = 'f' AND p2.sex = 'm'
AND p1.death IS NULL AND p2.death IS NULL;

+---------+--------+-------+
| Species | Female | Male |
+---------+--------+-------+
| cat | Fluffy | Claws |
| dog | Buffy | Fang |
+---------+--------+-------+
  Posted by Keith Corlett on February 19, 2007
Bob makes an interesting point... and I think it's probably worth descending into the difference between the ON clause and the WHERE clause at this juncture... as it doth tend to cause newbies grief.

So the lonely pets club query...

select p.name
from pet p left join event e
on e.name = p.name
where e.name is null;
+----------+
| name |
+----------+
| Puffball |
+----------+
finds all the pets which do not have a correlated event.

This is a useful query "pattern" for locating non-nullable foreign key values which have broken the foreign key constraint... and it's fast.

But what about this one?

select p.name
from pet p left join event e
on e.name = p.name
and e.name is null;
+----------+
| name |
+----------+
| Fluffy |
| Claws |
| Buffy |
| Fang |
| Bowser |
| Chirpy |
| Whistler |
| Slim |
| Puffball |
+----------+
This query is a truism... it's just a complicated way of returning all pets names. It's a common mistake.

  Posted by Eladio Mora on March 14, 2014
Why not use timestampdiff function instead which is simpler and directly calculate year difference including month and day?

Ex:

SELECT pet.name,
timestampdiff(year,birth,date) as age,
remark
FROM pet INNER JOIN event
ON pet.name = event.name
WHERE event.type = 'litter';
Sign Up Login You must be logged in to post a comment.