- 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.9. Performing Multiple-Table Retrievals with Subqueries
A subquery is a SELECT statement written within parentheses and nested inside another statement. Here’s an example that looks up the IDs for grade event rows that correspond to tests ('T') and uses them to select scores for those tests:
SELECT * FROM score WHERE event_id IN (SELECT event_id FROM grade_event WHERE category = 'T');
Subqueries can return different types of information:
- A scalar subquery returns a single value.
- A column subquery returns a single column of one or more values.
- A row subquery returns a single row of one or more values.
- A table subquery returns a table of one or more rows of one or more columns.
Subquery results can be tested in different ways:
- Scalar subquery results can be evaluated using relative comparison operators such as = or <.
- IN and NOT IN test whether a value is present in a set of values returned by a subquery.
- ALL, ANY, and SOME compare a value to the set of values returned by a subquery.
- EXISTS and NOT EXISTS test whether a subquery result is empty.
A scalar subquery is the most restrictive because it produces only a single value. But as a consequence, scalar subqueries can be used in the widest variety of contexts. They are applicable essentially anywhere that you can use a scalar operand, such as a term of an expression, as a function argument, or in the output column list. Column, row, and table subqueries that return more information cannot be used in contexts that require a single value.
Subqueries can be correlated or uncorrelated. This is a function of whether a subquery refers to and is dependent on values in the outer query.
You can use subqueries with statements other than SELECT. However, for statements that modify tables (DELETE, INSERT, REPLACE, UPDATE, LOAD DATA), MySQL enforces the restriction that the subquery cannot select from the table being modified.
In some cases, subqueries can be rewritten as joins. You might find subquery rewriting techniques useful to see whether the MySQL optimizer does a better job with a join than the equivalent subquery.
The following sections discuss the kinds of operations you can use to test subquery results, how to write correlated subqueries, and how to rewrite subqueries as joins.
2.9.1. Subqueries with Relative Comparison Operators
The =, <>, >, >=, <, and <= operators perform relative-value comparisons. When used with a scalar subquery, they find all rows in the outer query that stand in particular relationship to the value returned by the subquery. For example, to identify the scores for the quiz that took place on '2012-09-23', use a scalar subquery to determine the quiz event ID and then match score table rows against that ID in the outer SELECT:
SELECT * FROM score WHERE event_id = (SELECT event_id FROM grade_event WHERE date = '2012-09-23' AND category = 'Q');
With this form of statement, where the subquery is preceded by a value and a relative comparison operator, the subquery must produce a only single value. That is, it must be a scalar subquery; if it produces multiple values, the statement will fail. In some cases, it may be appropriate to satisfy the single-value requirement by limiting the subquery result with LIMIT 1.
Use of scalar subqueries with relative comparison operators is handy for solving problems for which you’d be tempted to use an aggregate function in a WHERE clause. For example, to determine which of the presidents in the president table was born first, you might try this statement:
SELECT * FROM president WHERE birth = MIN(birth);
That doesn’t work because you can’t use aggregates in WHERE clauses. (The WHERE clause determines which rows to select, but the value of MIN() isn’t known until after the rows have already been selected.) However, you can use a subquery to produce the minimum birth date like this:
SELECT * FROM president WHERE birth = (SELECT MIN(birth) FROM president);
Other aggregate functions can be used to solve similar problems. The following statement uses a subquery to select the above-average scores from a given grade event:
SELECT * FROM score WHERE event_id = 5 AND score > (SELECT AVG(score) FROM score WHERE event_id = 5);
If a subquery returns a single row, you can use a row constructor to compare a set of values (that is, a tuple) to the subquery result. This statement returns rows for presidents who were born in the same city and state as John Adams:
mysql> SELECT last_name, first_name, city, state FROM president -> WHERE (city, state) = -> (SELECT city, state FROM president -> WHERE last_name = 'Adams' AND first_name = 'John'); +-----------+-------------+-----------+-------+ | last_name | first_name | city | state | +-----------+-------------+-----------+-------+ | Adams | John | Braintree | MA | | Adams | John Quincy | Braintree | MA | +-----------+-------------+-----------+-------+
You can also use ROW(city, state) notation, which is equivalent to (city, state). Both act as row constructors.
2.9.2. IN and NOT IN Subqueries
The IN and NOT IN operators can be used when a subquery returns multiple rows to be evaluated in comparison to the outer query. They test whether a comparison value is present in a set of values. IN is true for rows in the outer query that match any row returned by the subquery. NOT IN is true for rows in the outer query that match no rows returned by the subquery. The following statements use IN and NOT IN to find those students who have absences listed in the absence table, and those who have perfect attendance (no absences):
mysql> SELECT * FROM student -> WHERE student_id IN (SELECT student_id FROM absence); +-------+-----+------------+ | name | sex | student_id | +-------+-----+------------+ | Kyle | M | 3 | | Abby | F | 5 | | Peter | M | 10 | | Will | M | 17 | | Avery | F | 20 | +-------+-----+------------+ mysql> SELECT * FROM student -> WHERE student_id NOT IN (SELECT student_id FROM absence); +-----------+-----+------------+ | name | sex | student_id | +-----------+-----+------------+ | Megan | F | 1 | | Joseph | M | 2 | | Katie | F | 4 | | Nathan | M | 6 | | Liesl | F | 7 | ...
IN and NOT IN also work for subqueries that return multiple columns. In other words, you can use them with table subqueries. In this case, use a row constructor to specify the comparison values to test against each column:
mysql> SELECT last_name, first_name, city, state FROM president -> WHERE (city, state) IN -> (SELECT city, state FROM president -> WHERE last_name = 'Roosevelt'); +-----------+-------------+-----------+-------+ | last_name | first_name | city | state | +-----------+-------------+-----------+-------+ | Roosevelt | Theodore | New York | NY | | Roosevelt | Franklin D. | Hyde Park | NY | +-----------+-------------+-----------+-------+
IN and NOT IN actually are synonyms for = ANY and <> ALL, which are covered in the next section.
2.9.3. ALL, ANY, and SOME Subqueries
The ALL and ANY operators are used in conjunction with a relative comparison operator to test the result of a column subquery. They test whether the comparison value stands in particular relationship to all or some of the values returned by the subquery. For example, <= ALL is true if the comparison value is less than or equal to every value that the subquery returns, whereas <= ANY is true if the comparison value is less than or equal to any value that the subquery returns. SOME is a synonym for ANY.
This statement determines which president was born first by selecting the row with a birth date less than or equal to all the birth dates in the president table (only the earliest date satisfies this condition):
mysql> SELECT last_name, first_name, birth FROM president -> WHERE birth <= ALL (SELECT birth FROM president); +------------+------------+------------+ | last_name | first_name | birth | +------------+------------+------------+ | Washington | George | 1732-02-22 | +------------+------------+------------+
Less usefully, the following statement returns all rows because every date is less than or equal to at least one other date (itself):
mysql> SELECT last_name, first_name, birth FROM president -> WHERE birth <= ANY (SELECT birth FROM president); +------------+---------------+------------+ | last_name | first_name | birth | +------------+---------------+------------+ | Washington | George | 1732-02-22 | | Adams | John | 1735-10-30 | | Jefferson | Thomas | 1743-04-13 | | Madison | James | 1751-03-16 | | Monroe | James | 1758-04-28 | ...
When ALL, ANY, or SOME are used with the = comparison operator, the subquery can be a table subquery. In this case, you test return rows using a row constructor to provide the comparison values.
mysql> SELECT last_name, first_name, city, state FROM president -> WHERE (city, state) = ANY -> (SELECT city, state FROM president -> WHERE last_name = 'Roosevelt'); +-----------+-------------+-----------+-------+ | last_name | first_name | city | state | +-----------+-------------+-----------+-------+ | Roosevelt | Theodore | New York | NY | | Roosevelt | Franklin D. | Hyde Park | NY | +-----------+-------------+-----------+-------+
As mentioned in the previous section, IN and NOT IN are shorthand for = ANY and <> ALL. That is, IN means “equal to any of the rows returned by the subquery” and NOT IN means “unequal to all rows returned by the subquery.”
2.9.4. EXISTS and NOT EXISTS Subqueries
The EXISTS and NOT EXISTS operators merely test whether a subquery returns any rows. If it does, EXISTS is true and NOT EXISTS is false. The following statements show some trivial examples of these subqueries. The first returns 0 if the absence table is empty, the second returns 1:
SELECT EXISTS (SELECT * FROM absence); SELECT NOT EXISTS (SELECT * FROM absence);
EXISTS and NOT EXISTS actually are much more commonly used in correlated subqueries. For examples, see Section 2.9.5, “Correlated Subqueries.”
With EXISTS and NOT EXISTS, the subquery uses * as the output column list. There’s no need to name columns explicitly, because the subquery is assessed as true or false based on whether it returns any rows, not based on the particular values that the rows might contain. You can actually write pretty much anything for the subquery column selection list, but if you want to make it explicit that you’re returning a true value when the subquery succeeds, you might write it as SELECT 1 rather than SELECT *.
2.9.5. Correlated Subqueries
Subqueries can be uncorrelated or correlated:
- An uncorrelated subquery contains no references to values from the outer query, so it could be executed by itself as a separate statement. For example, the subquery in the following statement is uncorrelated because it refers only to the table t1 and not to t2:
SELECT j FROM t2 WHERE j IN (SELECT i FROM t1);
- A correlated subquery does contain references to values from the outer query, and thus is dependent on it. Due to this linkage, a correlated subquery cannot be executed by itself as a separate statement. For example, the subquery in the following statement is true for each value of column j in t2 that matches a column i value in t1:
SELECT j FROM t2 WHERE (SELECT i FROM t1 WHERE i = j);
Correlated subqueries commonly are used for EXISTS and NOT EXISTS subqueries, which are useful for finding rows in one table that match or don’t match rows in another. Correlated subqueries work by passing values from the outer query to the subquery to see whether they match the conditions specified in the subquery. For this reason, it’s necessary to qualify column names with table names if they are ambiguous (appear in more than one table).
The following EXISTS subquery identifies matches between the tables—that is, values that are present in both. The statement selects students who have at least one absence listed in the absence table:
SELECT student_id, name FROM student WHERE EXISTS (SELECT * FROM absence WHERE absence.student_id = student.student_id);
NOT EXISTS identifies nonmatches—values in one table that are not present in the other. This statement selects students who have no absences:
SELECT student_id, name FROM student WHERE NOT EXISTS (SELECT * FROM absence WHERE absence.student_id = student.student_id);
2.9.6. Subqueries in the FROM Clause
Subqueries can be used in the FROM clause to generate values. In this case, the result of the subquery acts like a table. A subquery in the FROM clause can participate in joins, its values can be tested in the WHERE clause, and so forth. With this type of subquery, you must provide a table alias to give the subquery result a name:
mysql> SELECT * FROM (SELECT 1, 2) AS t1 INNER JOIN (SELECT 3, 4) AS t2; +---+---+---+---+ | 1 | 2 | 3 | 4 | +---+---+---+---+ | 1 | 2 | 3 | 4 | +---+---+---+---+
2.9.7. Rewriting Subqueries as Joins
It’s often possible to rephrase a query that uses a subquery in terms of a join, and it’s not a bad idea to examine queries that you might be inclined to write in terms of subqueries. A join is sometimes more efficient than a subquery, so if a SELECT written as a subquery takes a long time to execute, try writing it as a join to see whether it performs better. The following discussion shows how to do that.
2.9.7.1. Rewriting Subqueries That Select Matching Values
Here’s an example statement containing a subquery; it selects scores from the score table only for tests (that is, it ignores quiz scores):
SELECT * FROM score WHERE event_id IN (SELECT event_id FROM grade_event WHERE category = 'T');
The same statement can be written without a subquery by converting it to a simple join:
SELECT score.* FROM score INNER JOIN grade_event ON score.event_id = grade_event.event_id WHERE grade_event.category = 'T';
As another example, the following query selects scores for female students:
SELECT * from score WHERE student_id IN (SELECT student_id FROM student WHERE sex = 'F');
This can be converted to a join as follows:
SELECT score.* FROM score INNER JOIN student ON score.student_id = student.student_id WHERE student.sex = 'F';
There is a pattern here. The subquery statements follow this form:
SELECT * FROM table1 WHERE column1 IN (SELECT column2a FROM table2 WHERE column2b = value);
Such queries can be converted to a join using this form:
SELECT table1.* FROM table1 INNER JOIN table2 ON table1.column1 = table2.column2a WHERE table2.column2b = value;
In some cases, the subquery and the join might return different results. This occurs when table2 contains multiple instances of column2a. The subquery form produces only one instance of each column2a value, but the join produces them all and its output includes duplicate rows. To suppress these duplicates, begin the join with SELECT DISTINCT rather than SELECT.
2.9.7.2. Rewriting Subqueries That Select Nonmatching (Missing) Values
Another common type of subquery statement searches for values in one table that are not present in another table. As we’ve seen before, the “which values are not present” type of problem is a clue that a LEFT JOIN may be helpful. Here’s the statement with a subquery seen earlier that tests for students who are not listed in the absence table (it finds those students with perfect attendance):
SELECT * FROM student WHERE student_id NOT IN (SELECT student_id FROM absence);
This query can be rewritten using a LEFT JOIN as follows:
SELECT student.* FROM student LEFT JOIN absence ON student.student_id = absence.student_id WHERE absence.student_id IS NULL;
In general terms, the subquery statement form is as follows:
SELECT * FROM table1 WHERE column1 NOT IN (SELECT column2 FROM table2);
A query having that form can be rewritten like this:
SELECT table1.* FROM table1 LEFT JOIN table2 ON table1.column1 = table2.column2 WHERE table2.column2 IS NULL;
This assumes that table2.column2 is defined as NOT NULL.
The subquery does have the advantage of being more intuitive than the LEFT JOIN. “Not in” is a concept that most people understand without difficulty, because it occurs outside the context of database programming. The same cannot be said for the concept of “left join,” for which there is no such basis for natural understanding.