SELECT
[ALL | DISTINCT | DISTINCTROW ]
[HIGH_PRIORITY]
[STRAIGHT_JOIN]
[SQL_SMALL_RESULT] [SQL_BIG_RESULT] [SQL_BUFFER_RESULT]
[SQL_CACHE | SQL_NO_CACHE] [SQL_CALC_FOUND_ROWS]
select_expr [, select_expr] ...
[into_option]
[FROM table_references
[PARTITION partition_list]]
[WHERE where_condition]
[GROUP BY {col_name | expr | position}
[ASC | DESC], ... [WITH ROLLUP]]
[HAVING where_condition]
[ORDER BY {col_name | expr | position}
[ASC | DESC], ...]
[LIMIT {[offset,] row_count | row_count OFFSET offset}]
[PROCEDURE procedure_name(argument_list)]
[into_option]
[FOR UPDATE | LOCK IN SHARE MODE]
into_option: {
INTO OUTFILE 'file_name'
[CHARACTER SET charset_name]
export_options
| INTO DUMPFILE 'file_name'
| INTO var_name [, var_name] ...
}
export_options:
[{FIELDS | COLUMNS}
[TERMINATED BY 'string']
[[OPTIONALLY] ENCLOSED BY 'char']
[ESCAPED BY 'char']
]
[LINES
[STARTING BY 'string']
[TERMINATED BY 'string']
]
SELECT is used to retrieve rows
selected from one or more tables, and can include
UNION statements and subqueries.
See Section 13.2.9.3, “UNION Clause”, and Section 13.2.10, “Subqueries”.
The most commonly used clauses of
SELECT statements are these:
Each
select_exprindicates a column that you want to retrieve. There must be at least oneselect_expr.table_referencesindicates the table or tables from which to retrieve rows. Its syntax is described in Section 13.2.9.2, “JOIN Clause”.SELECTsupports explicit partition selection using thePARTITIONclause with a list of partitions or subpartitions (or both) following the name of the table in atable_reference(see Section 13.2.9.2, “JOIN Clause”). In this case, rows are selected only from the partitions listed, and any other partitions of the table are ignored. For more information and examples, see Section 22.5, “Partition Selection”.SELECT ... PARTITIONfrom tables using storage engines such asMyISAMthat perform table-level locks (and thus partition locks) lock only the partitions or subpartitions named by thePARTITIONoption.For more information, see Section 22.6.4, “Partitioning and Locking”.
The
WHEREclause, if given, indicates the condition or conditions that rows must satisfy to be selected.where_conditionis an expression that evaluates to true for each row to be selected. The statement selects all rows if there is noWHEREclause.In the
WHEREexpression, you can use any of the functions and operators that MySQL supports, except for aggregate (group) functions. See Section 9.5, “Expressions”, and Chapter 12, Functions and Operators.
SELECT can also be used to retrieve
rows computed without reference to any table.
For example:
mysql> SELECT 1 + 1;
-> 2
You are permitted to specify DUAL as a dummy
table name in situations where no tables are referenced:
mysql> SELECT 1 + 1 FROM DUAL;
-> 2
DUAL is purely for the convenience of people
who require that all SELECT
statements should have FROM and possibly other
clauses. MySQL may ignore the clauses. MySQL does not require
FROM DUAL if no tables are referenced.
In general, clauses used must be given in exactly the order shown
in the syntax description. For example, a
HAVING clause must come after any
GROUP BY clause and before any ORDER
BY clause. The INTO clause, if
present, can appear in any position indicated by the syntax
description, but within a given statement can appear only once,
not in multiple positions. For more information about
INTO, see Section 13.2.9.1, “SELECT ... INTO Statement”.
The list of select_expr terms comprises
the select list that indicates which columns to retrieve. Terms
specify a column or expression or can use
*-shorthand:
A select list consisting only of a single unqualified
*can be used as shorthand to select all columns from all tables:SELECT * FROM t1 INNER JOIN t2 ...can be used as a qualified shorthand to select all columns from the named table:tbl_name.*SELECT t1.*, t2.* FROM t1 INNER JOIN t2 ...Use of an unqualified
*with other items in the select list may produce a parse error. For example:SELECT id, * FROM t1To avoid this problem, use a qualified
reference:tbl_name.*SELECT id, t1.* FROM t1Use qualified
references for each table in the select list:tbl_name.*SELECT AVG(score), t1.* FROM t1 ...
The following list provides additional information about other
SELECT clauses:
A
select_exprcan be given an alias usingAS. The alias is used as the expression's column name and can be used inalias_nameGROUP BY,ORDER BY, orHAVINGclauses. For example:SELECT CONCAT(last_name,', ',first_name) AS full_name FROM mytable ORDER BY full_name;The
ASkeyword is optional when aliasing aselect_exprwith an identifier. The preceding example could have been written like this:SELECT CONCAT(last_name,', ',first_name) full_name FROM mytable ORDER BY full_name;However, because the
ASis optional, a subtle problem can occur if you forget the comma between twoselect_exprexpressions: MySQL interprets the second as an alias name. For example, in the following statement,columnbis treated as an alias name:SELECT columna columnb FROM mytable;For this reason, it is good practice to be in the habit of using
ASexplicitly when specifying column aliases.It is not permissible to refer to a column alias in a
WHEREclause, because the column value might not yet be determined when theWHEREclause is executed. See Section B.3.4.4, “Problems with Column Aliases”.The
FROMclause indicates the table or tables from which to retrieve rows. If you name more than one table, you are performing a join. For information on join syntax, see Section 13.2.9.2, “JOIN Clause”. For each table specified, you can optionally specify an alias.table_referencestbl_name [[AS] alias] [index_hint]The use of index hints provides the optimizer with information about how to choose indexes during query processing. For a description of the syntax for specifying these hints, see Section 8.9.4, “Index Hints”.
You can use
SET max_seeks_for_key=as an alternative way to force MySQL to prefer key scans instead of table scans. See Section 5.1.7, “Server System Variables”.valueYou can refer to a table within the default database as
tbl_name, or asdb_name.tbl_nameto specify a database explicitly. You can refer to a column ascol_name,tbl_name.col_name, ordb_name.tbl_name.col_name. You need not specify atbl_nameordb_name.tbl_nameprefix for a column reference unless the reference would be ambiguous. See Section 9.2.2, “Identifier Qualifiers”, for examples of ambiguity that require the more explicit column reference forms.A table reference can be aliased using
ortbl_nameASalias_nametbl_name alias_name. These statements are equivalent:SELECT t1.name, t2.salary FROM employee AS t1, info AS t2 WHERE t1.name = t2.name; SELECT t1.name, t2.salary FROM employee t1, info t2 WHERE t1.name = t2.name;Columns selected for output can be referred to in
ORDER BYandGROUP BYclauses using column names, column aliases, or column positions. Column positions are integers and begin with 1:SELECT college, region, seed FROM tournament ORDER BY region, seed; SELECT college, region AS r, seed AS s FROM tournament ORDER BY r, s; SELECT college, region, seed FROM tournament ORDER BY 2, 3;To sort in reverse order, add the
DESC(descending) keyword to the name of the column in theORDER BYclause that you are sorting by. The default is ascending order; this can be specified explicitly using theASCkeyword.If
ORDER BYoccurs within a parenthesized query expression and also is applied in the outer query, the results are undefined and may change in a future MySQL version.Use of column positions is deprecated because the syntax has been removed from the SQL standard.
MySQL extends the
GROUP BYclause so that you can also specifyASCandDESCafter columns named in the clause. However, this syntax is deprecated. To produce a given sort order, provide anORDER BYclause.If you use
GROUP BY, output rows are sorted according to theGROUP BYcolumns as if you had anORDER BYfor the same columns. To avoid the overhead of sorting thatGROUP BYproduces, addORDER BY NULL:SELECT a, COUNT(b) FROM test_table GROUP BY a ORDER BY NULL;Relying on implicit
GROUP BYsorting (that is, sorting in the absence ofASCorDESCdesignators) or explicit sorting forGROUP BY(that is, by using explicitASCorDESCdesignators forGROUP BYcolumns) is deprecated. To produce a given sort order, provide anORDER BYclause.When you use
ORDER BYorGROUP BYto sort a column in aSELECT, the server sorts values using only the initial number of bytes indicated by themax_sort_lengthsystem variable.MySQL extends the use of
GROUP BYto permit selecting fields that are not mentioned in theGROUP BYclause. If you are not getting the results that you expect from your query, please read the description ofGROUP BYfound in Section 12.19, “Aggregate Functions”.GROUP BYpermits aWITH ROLLUPmodifier. See Section 12.19.2, “GROUP BY Modifiers”.The
HAVINGclause, like theWHEREclause, specifies selection conditions. TheWHEREclause specifies conditions on columns in the select list, but cannot refer to aggregate functions. TheHAVINGclause specifies conditions on groups, typically formed by theGROUP BYclause. The query result includes only groups satisfying theHAVINGconditions. (If noGROUP BYis present, all rows implicitly form a single aggregate group.)The
HAVINGclause is applied nearly last, just before items are sent to the client, with no optimization. (LIMITis applied afterHAVING.)The SQL standard requires that
HAVINGmust reference only columns in theGROUP BYclause or columns used in aggregate functions. However, MySQL supports an extension to this behavior, and permitsHAVINGto refer to columns in theSELECTlist and columns in outer subqueries as well.If the
HAVINGclause refers to a column that is ambiguous, a warning occurs. In the following statement,col2is ambiguous because it is used as both an alias and a column name:SELECT COUNT(col1) AS col2 FROM t GROUP BY col2 HAVING col2 = 2;Preference is given to standard SQL behavior, so if a
HAVINGcolumn name is used both inGROUP BYand as an aliased column in the select column list, preference is given to the column in theGROUP BYcolumn.Do not use
HAVINGfor items that should be in theWHEREclause. For example, do not write the following:SELECT col_name FROM tbl_name HAVING col_name > 0;Write this instead:
SELECT col_name FROM tbl_name WHERE col_name > 0;The
HAVINGclause can refer to aggregate functions, which theWHEREclause cannot:SELECT user, MAX(salary) FROM users GROUP BY user HAVING MAX(salary) > 10;(This did not work in some older versions of MySQL.)
MySQL permits duplicate column names. That is, there can be more than one
select_exprwith the same name. This is an extension to standard SQL. Because MySQL also permitsGROUP BYandHAVINGto refer toselect_exprvalues, this can result in an ambiguity:SELECT 12 AS a, a FROM t GROUP BY a;In that statement, both columns have the name
a. To ensure that the correct column is used for grouping, use different names for eachselect_expr.MySQL resolves unqualified column or alias references in
ORDER BYclauses by searching in theselect_exprvalues, then in the columns of the tables in theFROMclause. ForGROUP BYorHAVINGclauses, it searches theFROMclause before searching in theselect_exprvalues. (ForGROUP BYandHAVING, this differs from the pre-MySQL 5.0 behavior that used the same rules as forORDER BY.)The
LIMITclause can be used to constrain the number of rows returned by theSELECTstatement.LIMITtakes one or two numeric arguments, which must both be nonnegative integer constants, with these exceptions:Within prepared statements,
LIMITparameters can be specified using?placeholder markers.Within stored programs,
LIMITparameters can be specified using integer-valued routine parameters or local variables.
With two arguments, the first argument specifies the offset of the first row to return, and the second specifies the maximum number of rows to return. The offset of the initial row is 0 (not 1):
SELECT * FROM tbl LIMIT 5,10; # Retrieve rows 6-15To retrieve all rows from a certain offset up to the end of the result set, you can use some large number for the second parameter. This statement retrieves all rows from the 96th row to the last:
SELECT * FROM tbl LIMIT 95,18446744073709551615;With one argument, the value specifies the number of rows to return from the beginning of the result set:
SELECT * FROM tbl LIMIT 5; # Retrieve first 5 rowsIn other words,
LIMITis equivalent torow_countLIMIT 0,.row_countFor prepared statements, you can use placeholders. The following statements return one row from the
tbltable:SET @a=1; PREPARE STMT FROM 'SELECT * FROM tbl LIMIT ?'; EXECUTE STMT USING @a;The following statements return the second to sixth row from the
tbltable:SET @skip=1; SET @numrows=5; PREPARE STMT FROM 'SELECT * FROM tbl LIMIT ?, ?'; EXECUTE STMT USING @skip, @numrows;For compatibility with PostgreSQL, MySQL also supports the
LIMITsyntax.row_countOFFSEToffsetIf
LIMIToccurs within a parenthesized query expression and also is applied in the outer query, the results are undefined and may change in a future MySQL version.A
PROCEDUREclause names a procedure that should process the data in the result set. For an example, see Section 8.4.2.4, “Using PROCEDURE ANALYSE”, which describesANALYSE, a procedure that can be used to obtain suggestions for optimal column data types that may help reduce table sizes.A
PROCEDUREclause is not permitted in aUNIONstatement.NotePROCEDUREsyntax is deprecated as of MySQL 5.7.18, and is removed in MySQL 8.0.The
SELECT ... INTOform ofSELECTenables the query result to be written to a file or stored in variables. For more information, see Section 13.2.9.1, “SELECT ... INTO Statement”.If you use
FOR UPDATEwith a storage engine that uses page or row locks, rows examined by the query are write-locked until the end of the current transaction. UsingLOCK IN SHARE MODEsets a shared lock that permits other transactions to read the examined rows but not to update or delete them. See Section 14.7.2.4, “Locking Reads”.In addition, you cannot use
FOR UPDATEas part of theSELECTin a statement such asCREATE TABLE. (If you attempt to do so, the statement is rejected with the error Can't update table 'new_tableSELECT ... FROMold_table...old_table' while 'new_table' is being created.) This is a change in behavior from MySQL 5.5 and earlier, which permittedCREATE TABLE ... SELECTstatements to make changes in tables other than the table being created.
Following the SELECT keyword, you
can use a number of modifiers that affect the operation of the
statement. HIGH_PRIORITY,
STRAIGHT_JOIN, and modifiers beginning with
SQL_ are MySQL extensions to standard SQL.
The
ALLandDISTINCTmodifiers specify whether duplicate rows should be returned.ALL(the default) specifies that all matching rows should be returned, including duplicates.DISTINCTspecifies removal of duplicate rows from the result set. It is an error to specify both modifiers.DISTINCTROWis a synonym forDISTINCT.HIGH_PRIORITYgives theSELECThigher priority than a statement that updates a table. You should use this only for queries that are very fast and must be done at once. ASELECT HIGH_PRIORITYquery that is issued while the table is locked for reading runs even if there is an update statement waiting for the table to be free. This affects only storage engines that use only table-level locking (such asMyISAM,MEMORY, andMERGE).HIGH_PRIORITYcannot be used withSELECTstatements that are part of aUNION.STRAIGHT_JOINforces the optimizer to join the tables in the order in which they are listed in theFROMclause. You can use this to speed up a query if the optimizer joins the tables in nonoptimal order.STRAIGHT_JOINalso can be used in thetable_referenceslist. See Section 13.2.9.2, “JOIN Clause”.STRAIGHT_JOINdoes not apply to any table that the optimizer treats as aconstorsystemtable. Such a table produces a single row, is read during the optimization phase of query execution, and references to its columns are replaced with the appropriate column values before query execution proceeds. These tables appear first in the query plan displayed byEXPLAIN. See Section 8.8.1, “Optimizing Queries with EXPLAIN”. This exception may not apply toconstorsystemtables that are used on theNULL-complemented side of an outer join (that is, the right-side table of aLEFT JOINor the left-side table of aRIGHT JOIN.SQL_BIG_RESULTorSQL_SMALL_RESULTcan be used withGROUP BYorDISTINCTto tell the optimizer that the result set has many rows or is small, respectively. ForSQL_BIG_RESULT, MySQL directly uses disk-based temporary tables if they are created, and prefers sorting to using a temporary table with a key on theGROUP BYelements. ForSQL_SMALL_RESULT, MySQL uses in-memory temporary tables to store the resulting table instead of using sorting. This should not normally be needed.SQL_BUFFER_RESULTforces the result to be put into a temporary table. This helps MySQL free the table locks early and helps in cases where it takes a long time to send the result set to the client. This modifier can be used only for top-levelSELECTstatements, not for subqueries or followingUNION.SQL_CALC_FOUND_ROWStells MySQL to calculate how many rows there would be in the result set, disregarding anyLIMITclause. The number of rows can then be retrieved withSELECT FOUND_ROWS(). See Section 12.15, “Information Functions”.The
SQL_CACHEandSQL_NO_CACHEmodifiers affect caching of query results in the query cache (see Section 8.10.3, “The MySQL Query Cache”).SQL_CACHEtells MySQL to store the result in the query cache if it is cacheable and the value of thequery_cache_typesystem variable is2orDEMAND. WithSQL_NO_CACHE, the server does not use the query cache. It neither checks the query cache to see whether the result is already cached, nor does it cache the query result.These two modifiers are mutually exclusive and an error occurs if they are both specified. Also, these modifiers are not permitted in subqueries (including subqueries in the
FROMclause), andSELECTstatements in unions other than the firstSELECT.For views,
SQL_NO_CACHEapplies if it appears in anySELECTin the query. For a cacheable query,SQL_CACHEapplies if it appears in the firstSELECTof a view referred to by the query.NoteThe query cache is deprecated as of MySQL 5.7.20, and is removed in MySQL 8.0. Deprecation includes
SQL_CACHEandSQL_NO_CACHE.
A SELECT from a partitioned table using a
storage engine such as MyISAM that
employs table-level locks locks only those partitions containing
rows that match the SELECT statement
WHERE clause. (This does not occur with storage
engines such as InnoDB that employ
row-level locking.) For more information, see
Section 22.6.4, “Partitioning and Locking”.