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 ...]
[FROM table_references
[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 OUTFILE 'file_name'
[CHARACTER SET charset_name]
export_options
| INTO DUMPFILE 'file_name'
| INTO var_name [, var_name]]
[FOR UPDATE | LOCK IN SHARE MODE]]
SELECT is used to retrieve rows
selected from one or more tables, and can include
UNION statements and subqueries.
See Section 12.2.9.3, “UNION Syntax”, and Section 12.2.10, “Subquery Syntax”.
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 12.2.9.1, “JOINSyntax”.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 (summary) functions. See Section 8.5, “Expression Syntax”, and Chapter 11, 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 exception is that the
INTO clause can appear either as shown in the
syntax description or immediately following the
select_expr list.
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. To avoid this problem, use a qualifiedreferencetbl_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 C.5.5.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 12.2.9.1, “table_referencesJOINSyntax”. For each table specified, you can optionally specify an alias.tbl_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 12.2.9.2, “Index Hint Syntax”.
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.4, “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 8.2.1, “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: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 subquery and also is applied in the outer query, the outermostORDER BYtakes precedence. For example, results for the following statement are sorted in descending order, not ascending order:(SELECT ... ORDER BY a) ORDER BY a DESC;
Use of column positions is deprecated because the syntax has been removed from the SQL standard.
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;
MySQL extends the
GROUP BYclause so that you can also specifyASCandDESCafter columns named in the clause:SELECT a, COUNT(b) FROM test_table GROUP BY a DESC;
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 11.16, “Functions and Modifiers for Use withGROUP BYClauses”.GROUP BYpermits aWITH ROLLUPmodifier. See Section 11.16.2, “GROUP BYModifiers”.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 output 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_nameFROMtbl_nameHAVINGcol_name> 0;Write this instead:
SELECT
col_nameFROMtbl_nameWHEREcol_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 as of MySQL 5.5.6.
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-15
To 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 rows
In other words,
LIMITis equivalent torow_countLIMIT 0,.row_countFor prepared statements, you can use placeholders. The following statements will return one row from the
tbltable:SET @a=1; PREPARE STMT FROM 'SELECT * FROM tbl LIMIT ?'; EXECUTE STMT USING @a;
The following statements will 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 subquery and also is applied in the outer query, the outermostLIMITtakes precedence. For example, the following statement produces two rows, not one:(SELECT ... LIMIT 1) LIMIT 2;
A
PROCEDUREclause names a procedure that should process the data in the result set. For an example, see Section 23.4.1, “PROCEDURE ANALYSE”, which describesANALYSE, a procedure that can be used to obtain suggestions for optimal column data types that may help reduce table sizes.The
SELECT ... INTO OUTFILE 'form offile_name'SELECTwrites the selected rows to a file. The file is created on the server host, so you must have theFILEprivilege to use this syntax.file_namecannot be an existing file, which among other things prevents files such as/etc/passwdand database tables from being destroyed. Thecharacter_set_filesystemsystem variable controls the interpretation of the file name.The
SELECT ... INTO OUTFILEstatement is intended primarily to let you very quickly dump a table to a text file on the server machine. If you want to create the resulting file on some other host than the server host, you normally cannot useSELECT ... INTO OUTFILEsince there is no way to write a path to the file relative to the server host's file system.However, if the MySQL client software is installed on the remote machine, you can instead use a client command such as
mysql -e "SELECT ..." >to generate the file on the client host.file_nameIt is also possible to create the resulting file on a different host other than the server host, if the location of the file on the remote host can be accessed using a network-mapped path on the server's file system. In this case, the presence of mysql (or some other MySQL client program) is not required on the target host.
SELECT ... INTO OUTFILEis the complement ofLOAD DATA INFILE. Column values are written converted to the character set specified in theCHARACTER SETclause. If no such clause is present, values are dumped using thebinarycharacter set. In effect, there is no character set conversion. If a table contains columns in several character sets, the output data file will as well and you may not be able to reload the file correctly.The syntax for the
export_optionspart of the statement consists of the sameFIELDSandLINESclauses that are used with theLOAD DATA INFILEstatement. See Section 12.2.6, “LOAD DATA INFILESyntax”, for information about theFIELDSandLINESclauses, including their default values and permissible values.FIELDS ESCAPED BYcontrols how to write special characters. If theFIELDS ESCAPED BYcharacter is not empty, it is used as a prefix that precedes following characters on output:The
FIELDS ESCAPED BYcharacterThe
FIELDS [OPTIONALLY] ENCLOSED BYcharacterThe first character of the
FIELDS TERMINATED BYandLINES TERMINATED BYvaluesASCII
NUL(the zero-valued byte; what is actually written following the escape character is ASCII “0”, not a zero-valued byte)
The
FIELDS TERMINATED BY,ENCLOSED BY,ESCAPED BY, orLINES TERMINATED BYcharacters must be escaped so that you can read the file back in reliably. ASCIINULis escaped to make it easier to view with some pagers.The resulting file does not have to conform to SQL syntax, so nothing else need be escaped.
If the
FIELDS ESCAPED BYcharacter is empty, no characters are escaped andNULLis output asNULL, not\N. It is probably not a good idea to specify an empty escape character, particularly if field values in your data contain any of the characters in the list just given.Here is an example that produces a file in the comma-separated values (CSV) format used by many programs:
SELECT a,b,a+b INTO OUTFILE '/tmp/result.txt' FIELDS TERMINATED BY ',' OPTIONALLY ENCLOSED BY '"' LINES TERMINATED BY '\n' FROM test_table;
If you use
INTO DUMPFILEinstead ofINTO OUTFILE, MySQL writes only one row into the file, without any column or line termination and without performing any escape processing. This is useful if you want to store aBLOBvalue in a file.- Note
Any file created by
INTO OUTFILEorINTO DUMPFILEis writable by all users on the server host. The reason for this is that the MySQL server cannot create a file that is owned by anyone other than the user under whose account it is running. (You should never run mysqld asrootfor this and other reasons.) The file thus must be world-writable so that you can manipulate its contents.If the
secure_file_privsystem variable is set to a nonempty directory name, the file to be written must be located in that directory. The
INTOclause can name a list of one or more variables, which can be user-defined variables, or parameters or local variables within a stored function or procedure body (see Section 12.7.3.3, “SELECT ... INTOStatement”). The selected values are assigned to the variables. The number of variables must match the number of columns. The query should return a single row. If the query returns no rows, a warning with error code 1329 occurs (No data), and the variable values remain unchanged. If the query returns multiple rows, error 1172 occurs (Result consisted of more than one row). If it is possible that the statement may retrieve multiple rows, you can useLIMIT 1to limit the result set to a single row.In the context of such statements that occur as part of events executed by the Event Scheduler, diagnostics messages (not only errors, but also warnings) are written to the error log, and, on Windows, to the application event log. For additional information, see Section 19.4.5, “Event Scheduler Status”.
The
SELECTsyntax description at the beginning this section shows theINTOclause near the end of the statement. It is also possible to useINTOimmediately following theselect_exprlist.An
INTOclause should not be used in a nestedSELECTbecause such aSELECTmust return its result to the outer context.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 13.6.9.3, “SELECT ... FOR UPDATEandSELECT ... LOCK IN SHARE MODELocking Reads”.
Following the SELECT keyword, you
can use a number of options that affect the operation of the
statement. HIGH_PRIORITY,
STRAIGHT_JOIN, and options beginning with
SQL_ are MySQL extensions to standard SQL.
The
ALLandDISTINCToptions 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 options.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 12.2.9.1, “JOINSyntax”.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 will appear first in the query plan displayed byEXPLAIN. See Section 7.8.1, “Optimizing Queries withEXPLAIN”. 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 needed, and prefers sorting to using a temporary table with a key on theGROUP BYelements. ForSQL_SMALL_RESULT, MySQL uses fast 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 option 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 11.14, “Information Functions”.The
SQL_CACHEandSQL_NO_CACHEoptions affect caching of query results in the query cache (see Section 7.9.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.SQL_NO_CACHEtells MySQL not to store the result in the query cache.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.As of MySQL 5.5.3, these two options are mutually exclusive and an error occurs if they are both specified. Also, these options are not permitted in subqueries (including subqueries in the
FROMclause), andSELECTstatements in unions other than the firstSELECT.Before MySQL 5.5.3, for a query that uses
UNIONor subqueries, the following rules apply: