- 2.1. The Server SQL Mode
- 2.2. MySQL Identifier Syntax and Naming Rules
- 2.3. Case Sensitivity in SQL Statements
- 2.4. Character Set Support
- 2.5. Selecting, Creating, Dropping, and Altering Databases
- 2.6. Creating, Dropping, Indexing, and Altering Tables
- 2.7. Obtaining Database Metadata
- 2.8. Performing Multiple-Table Retrievals with Joins
- 2.9. Performing Multiple-Table Retrievals with Subqueries
- 2.10. Performing Multiple-Table Retrievals with UNION
- 2.11. Multiple-Table Deletes and Updates
- 2.12. Performing Transactions
- 2.13. Foreign Keys and Referential Integrity
- 2.14. Using FULLTEXT Searches
2.8. Performing Multiple-Table Retrievals with Joins
It does no good to put records in a database unless you retrieve them eventually and do something with them. That’s the purpose of the SELECT statement: to help you get at your data. SELECT probably is used more often than any other statement in the SQL language, but it can also be the trickiest; the conditions you use for choosing rows can be arbitrarily complex and can involve comparisons between columns in many tables.
The basic syntax of the SELECT statement looks like this:
SELECT select_list # the columns to select FROM table_list # the tables from which to select rows WHERE row_constraint # the conditions rows must satisfy GROUP BY grouping_columns # how to group results ORDER BY sorting_columns # how to sort results HAVING group_constraint # the conditions groups must satisfy LIMIT count; # row count limit on results
Everything in this syntax is optional except the word SELECT and the select_list part that specifies what you want to produce as output. Some databases require the FROM clause as well. MySQL does not, which enables you to evaluate expressions without referring to any tables:
SELECT SQRT(POW(3,2)+POW(4,2));
In Chapter 1, “Getting Started with MySQL,” we devoted quite a bit of attention to single-table SELECT statements, concentrating primarily on the output column list and the WHERE, GROUP BY, ORDER BY, HAVING, and LIMIT clauses. This section covers an aspect of SELECT that is often confusing: writing joins; that is, SELECT statements that retrieve rows from multiple tables. We’ll discuss the types of join MySQL supports, what they mean, and how to specify them. This should help you employ MySQL more effectively because, in many cases, the real problem of figuring out how to write a query is determining the proper way to join tables.
One problem with using SELECT is that when you first encounter a new type of problem, it’s not always easy to see how to write a SELECT query to solve it. However, after you figure it out, you can use that experience when you run across similar problems in the future. SELECT is probably the statement for which past experience plays the largest role in being able to use it effectively, simply because of the sheer variety of problems to which it applies. As you gain experience, you’ll be able to adapt joins more easily to new problems, and you’ll find yourself thinking things like, “Oh, yes, that’s one of those LEFT JOIN things,” or, “Aha, that’s a three-way join restricted by the common pairs of key columns.” (You may find it encouraging to hear that experience helps you. Or you may find it alarming to consider that you could wind up thinking in terms like that.)
Many of the examples that demonstrate how to use the forms of join operations that MySQL supports use the following two tables, t1 and t2:
Table t1: Table t2: +----+----+ +----+----+ | i1 | c1 | | i2 | c2 | +----+----+ +----+----+ | 1 | a | | 2 | c | | 2 | b | | 3 | b | | 3 | c | | 4 | a | +----+----+ +----+----+
The tables are deliberately small so the effect of each type of join can be readily seen.
Other types of multiple-table SELECT statement are subqueries (one SELECT nested within another) and UNION statements. These are covered in Section 2.9, “Performing Multiple-Table Retrievals with Subqueries,” and Section 2.10, “Performing Multiple-Table Retrievals with UNION.”
A related multiple-table feature that MySQL supports is the capability of deleting or updating rows in one table based on the contents of another. For example, you might want to remove rows in one table that aren’t matched by any row in another, or copy values from columns in one table to columns in another. Section 2.11, “Multiple-Table Deletes and Updates,” discusses these types of operations.
2.8.1. Inner Joins
If a SELECT statement names multiple tables in the FROM clause with the names separated by INNER JOIN, MySQL performs an inner join, which produces results by matching rows in one table with rows in another table. For example, if you join t1 and t2 as follows, each row in t1 is combined with each row in t2:
mysql> SELECT * FROM t1 INNER JOIN t2; +----+----+----+----+ | i1 | c1 | i2 | c2 | +----+----+----+----+ | 1 | a | 2 | c | | 2 | b | 2 | c | | 3 | c | 2 | c | | 1 | a | 3 | b | | 2 | b | 3 | b | | 3 | c | 3 | b | | 1 | a | 4 | a | | 2 | b | 4 | a | | 3 | c | 4 | a | +----+----+----+----+
In this statement, SELECT * means “select every column from every table named in the FROM clause.” You could also write this as SELECT t1.*, t2.*:
SELECT t1.*, t2.* FROM t1 INNER JOIN t2;
If you don’t want to select all columns or you want to display them in a different left-to-right order, name each desired column, separated by commas.
A join that combines each row of each table with each row in every other table to produce all possible combinations is known as the “cartesian product.” Joining tables this way has the potential to produce a very large number of rows because the possible row count is the product of the number of rows in each table. A join between three tables that contain 100, 200, and 300 rows, respectively, could return 100 × 200 × 300 = 6 million rows. That’s a lot of rows, even though the individual tables are small. In cases like this, normally a WHERE clause is useful for reducing the result set to a more manageable size.
If you add a WHERE clause causing tables to be matched on the values of certain columns, the join selects only rows with equal values in those columns:
mysql> SELECT t1.*, t2.* FROM t1 INNER JOIN t2 WHERE t1.i1 = t2.i2; +----+----+----+----+ | i1 | c1 | i2 | c2 | +----+----+----+----+ | 2 | b | 2 | c | | 3 | c | 3 | b | +----+----+----+----+
The CROSS JOIN and JOIN join types are the same as INNER JOIN, so these statements are equivalent:
SELECT t1.*, t2.* FROM t1 INNER JOIN t2 WHERE t1.i1 = t2.i2; SELECT t1.*, t2.* FROM t1 CROSS JOIN t2 WHERE t1.i1 = t2.i2; SELECT t1.*, t2.* FROM t1 JOIN t2 WHERE t1.i1 = t2.i2;
The ‘,’ (comma) join operator is similar as well:
SELECT t1.*, t2.* FROM t1, t2 WHERE t1.i1 = t2.i2;
However, the comma operator has a different precedence from the other join types, and it can sometimes produce syntax errors when the other types will not. I recommend that you avoid the comma operator.
INNER JOIN, CROSS JOIN, and JOIN (but not the comma operator) support alternative syntaxes for specifying how to match table columns:
- One syntax uses an ON clause rather than a WHERE clause. The following example shows this using INNER JOIN:
SELECT t1.*, t2.* FROM t1 INNER JOIN t2 ON t1.i1 = t2.i2;
ON can be used regardless of whether the joined columns have the same name.
- The other syntax involves a USING() clause; this is similar in concept to ON, but the name of the joined column or columns must be the same in each table. For example, the following query joins mytbl1.b to mytbl2.b:
SELECT mytbl1.*, mytbl2.* FROM mytbl1 INNER JOIN mytbl2 USING (b);
2.8.2. Qualifying References to Columns from Joined Tables
References to each table column throughout a SELECT statement must resolve unambiguously to a single table named in the FROM clause. If only one table is named, there is no ambiguity; all columns must be columns of that table. If multiple tables are named, any column name that appears in only one table is similarly unambiguous. However, if a column name appears in multiple tables, references to the column must be qualified with a table identifier using tbl_name.col_name syntax to specify which table you mean. Suppose that a table mytbl1 contains columns a and b, and a table mytbl2 contains columns b and c. References to columns a or c are unambiguous, but references to b must be qualified as either mytbl1.b or mytbl2.b:
SELECT a, mytbl1.b, mytbl2.b, c FROM mytbl1 INNER JOIN mytbl2 ... ;
Sometimes a table name qualifier is not sufficient to resolve a column reference. For example, if you’re performing a self-join (that is, joining a table to itself), you’re using the table multiple times within the query and it doesn’t help to qualify a column name with the table name. In this case, table aliases are useful for communicating your intent. You can assign an alias to any instance of the table and refer to columns from that instance as alias_name.col_name. The following query joins a table to itself, but assigns an alias to one instance of the table to enable column references to be specified unambiguously:
SELECT mytbl.col1, m.col2 FROM mytbl INNER JOIN mytbl AS m WHERE mytbl.col1 > m.col1;
2.8.3. Left and Right (Outer) Joins
An inner join shows only rows where a match can be found in both tables. An outer join shows matches, too, but can also show rows in one table that have no match in the other table. Two kinds of outer joins are left and right joins. Most of the examples in this section use LEFT JOIN, which identifies rows in the left table that are not matched by the right table. RIGHT JOIN is the same except that the roles of the tables are reversed.
A LEFT JOIN works like this: You specify the columns to be used for matching rows in the two tables. When a row from the left table matches a row from the right table, the contents of the rows are selected as an output row. When a row in the left table has no match, it is still selected for output, but joined with a “fake” row from the right table that contains NULL in each column.
In other words, a LEFT JOIN forces the result set to contain a row for every row selected from the left table, whether or not there is a match for it in the right table. The left-table rows with no match can be identified by the fact that all columns from the right table are NULL. These result rows tell you which rows are missing from the right table. That is an interesting and important property, because this kind of problem comes up in many different contexts. Which customers have not been assigned an account representative? For which inventory items have no sales been recorded? Or, closer to home with our sampdb database: Which students have not taken a particular exam? Which students have no rows in the absence table (that is, which students have perfect attendance)?
Consider once again our two tables, t1 and t2:
Table t1: Table t2: +----+----+ +----+----+ | i1 | c1 | | i2 | c2 | +----+----+ +----+----+ | 1 | a | | 2 | c | | 2 | b | | 3 | b | | 3 | c | | 4 | a | +----+----+ +----+----+
If we use an inner join to match these tables on t1.i1 and t2.i2, we’ll get output only for the values 2 and 3, because those are the values that appear in both tables:
mysql> SELECT t1.*, t2.* FROM t1 INNER JOIN t2 ON t1.i1 = t2.i2; +----+----+----+----+ | i1 | c1 | i2 | c2 | +----+----+----+----+ | 2 | b | 2 | c | | 3 | c | 3 | b | +----+----+----+----+
A left join produces output for every row in t1, whether or not t2 matches it. To write a left join, name the tables with LEFT JOIN in between rather than INNER JOIN:
mysql> SELECT t1.*, t2.* FROM t1 LEFT JOIN t2 ON t1.i1 = t2.i2; +----+----+------+------+ | i1 | c1 | i2 | c2 | +----+----+------+------+ | 1 | a | NULL | NULL | | 2 | b | 2 | c | | 3 | c | 3 | b | +----+----+------+------+
Now there is an output row even for the t1.i1 value of 1, which has no match in t2. All the columns in this row that correspond to t2 columns have a value of NULL.
One thing to watch out for with LEFT JOIN is that unless right-table columns are defined as NOT NULL, you may get problematic rows in the result. For example, if the right table contains columns with NULL values, you won’t be able to distinguish those NULL values from NULL values that identify unmatched rows.
As mentioned earlier, a RIGHT JOIN is like a LEFT JOIN with the roles of the tables reversed. These two statements are equivalent:
SELECT t1.*, t2.* FROM t1 LEFT JOIN t2 ON t1.i1 = t2.i2; SELECT t1.*, t2.* FROM t2 RIGHT JOIN t1 ON t1.i1 = t2.i2;
The following discussion is phrased in terms of LEFT JOIN. To adjust it for RIGHT JOIN, reverse the table roles.
LEFT JOIN is especially useful when you want to find only those left table rows that are unmatched by the right table. Do this by adding a WHERE clause that selects only the rows that have NULL values in a right table column—in other words, the rows in one table that are missing from the other:
mysql> SELECT t1.*, t2.* FROM t1 LEFT JOIN t2 ON t1.i1 = t2.i2 -> WHERE t2.i2 IS NULL; +----+----+------+------+ | i1 | c1 | i2 | c2 | +----+----+------+------+ | 1 | a | NULL | NULL | +----+----+------+------+
Normally, when you write a query like this, your real interest is in the unmatched values in the left table. The NULL columns from the right table are of no interest for display purposes, so you would omit them from the output column list:
mysql> SELECT t1.* FROM t1 LEFT JOIN t2 ON t1.i1 = t2.i2 -> WHERE t2.i2 IS NULL; +----+----+ | i1 | c1 | +----+----+ | 1 | a | +----+----+
Like INNER JOIN, a LEFT JOIN can be written using an ON clause or a USING() clause to specify the matching conditions. As with INNER JOIN, ON can be used whether or not the joined columns from each table have the same name, but USING() requires that they have the same names.
NATURAL LEFT JOIN is similar to LEFT JOIN; it performs a LEFT JOIN, matching all columns that have the same name in the left and right tables. (Thus, no ON or USING clause is given.)
As already mentioned, LEFT JOIN is useful for answering “Which values are missing?” questions. Let’s apply this principle to the tables in the sampdb database and consider a more complex example than those shown earlier using t1 and t2.
For the grade-keeping project, first mentioned in Chapter 1, “Getting Started with MySQL,” we have a student table listing students, a grade_event table listing the grade events that have occurred, and a score table listing scores for each student for each grade event. However, if a student was ill on the day of some quiz or test, the score table wouldn’t contain any score for the student for that event. A makeup quiz or test should be given in such cases, but how do we find these missing rows?
The problem is to determine which students have no score for a given grade event, and to do this for each grade event. That is, we want to find which combinations of student and grade event are not present in the score table. This “which values are not present” wording is a tip-off that we want a LEFT JOIN. The join isn’t as simple as in the previous examples, though: We aren’t just looking for values that are not present in a single column, we’re looking for a two-column combination. The combinations we want are all the student/event combinations. These are produced by joining the student table to the grade_event table:
FROM student INNER JOIN grade_event
Then we take the result of that join and perform a LEFT JOIN with the score table to find the matches for student ID/event ID pairs:
FROM student INNER JOIN grade_event LEFT JOIN score ON student.student_id = score.student.id AND grade_event.event_id = score.event_id
Note that the ON clause causes the rows in the score table to be joined according to matches in different tables named earlier in the join. That’s the key for solving this problem. The LEFT JOIN forces a row to be generated for each row produced by the join of the student and grade_event tables, even when there is no corresponding score table row. The result set rows for these missing score rows can be identified by the fact that the columns from the score table will all be NULL. We can identify these rows by adding a condition in the WHERE clause. Any column from the score table will do, but because we’re looking for missing scores, it’s probably conceptually clearest to test the score column:
WHERE score.score IS NULL
We can also sort the results using an ORDER BY clause. The two most logical orderings are by event per student and by student per event. I’ll choose the first:
ORDER BY student.student_id, grade_event.event_id
Now all we need to do is name the columns we want to see in the output, and we’re done. Here is the final statement:
SELECT student.name, student.student_id, grade_event.date, grade_event.event_id, grade_event.category FROM student INNER JOIN grade_event LEFT JOIN score ON student.student_id = score.student_id AND grade_event.event_id = score.event_id WHERE score.score IS NULL ORDER BY student.student_id, grade_event.event_id;
Running the query produces these results:
+-----------+------------+------------+----------+----------+ | name | student_id | date | event_id | category | +-----------+------------+------------+----------+----------+ | Megan | 1 | 2012-09-16 | 4 | Q | | Joseph | 2 | 2012-09-03 | 1 | Q | | Katie | 4 | 2012-09-23 | 5 | Q | | Devri | 13 | 2012-09-03 | 1 | Q | | Devri | 13 | 2012-10-01 | 6 | T | | Will | 17 | 2012-09-16 | 4 | Q | | Avery | 20 | 2012-09-06 | 2 | Q | | Gregory | 23 | 2012-10-01 | 6 | T | | Sarah | 24 | 2012-09-23 | 5 | Q | | Carter | 27 | 2012-09-16 | 4 | Q | | Carter | 27 | 2012-09-23 | 5 | Q | | Gabrielle | 29 | 2012-09-16 | 4 | Q | | Grace | 30 | 2012-09-23 | 5 | Q | +-----------+------------+------------+----------+----------+
Here’s a subtle point. The output displays the student IDs and the event IDs. The student_id column appears in both the student and score tables, so at first you might think that the output column list could name either student.student_id or score.student_id. That’s not the case, because the entire basis for being able to find the rows we’re interested in is that all the score table columns are returned by the LEFT JOIN as NULL. Selecting score.student_id would produce only a column of NULL values in the output. The same principle applies to deciding which event_id column to display. It appears in both the grade_event and score tables, but the query selects grade_event.event_id because the score.event_id values will always be NULL.