[ < ] | [ > ] | [ << ] | [ Up ] | [ >> ] | [Top] | [Contents] | [Index] | [ ? ] |
SELECT
Syntax
SELECT [STRAIGHT_JOIN] [SQL_SMALL_RESULT] [SQL_BIG_RESULT] [SQL_BUFFER_RESULT] [SQL_CACHE | SQL_NO_CACHE] [SQL_CALC_FOUND_ROWS] [HIGH_PRIORITY] [DISTINCT | DISTINCTROW | ALL] select_expression,... [INTO {OUTFILE | DUMPFILE} 'file_name' export_options] [FROM table_references [WHERE where_definition] [GROUP BY {unsigned_integer | col_name | formula} [ASC | DESC], ... [WITH ROLLUP]] [HAVING where_definition] [ORDER BY {unsigned_integer | col_name | formula} [ASC | DESC] ,...] [LIMIT [offset,] row_count | row_count OFFSET offset] [PROCEDURE procedure_name(argument_list)] [FOR UPDATE | LOCK IN SHARE MODE]] |
SELECT
is used to retrieve rows selected from one or more tables.
Each select_expression
indicates a column you want to retrieve.
SELECT
may also be used to retrieve rows computed without reference to
any table.
For example:
mysql> SELECT 1 + 1; -> 2 |
All 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.
SELECT
expression may be given an alias using AS alias_name
.
The alias is used as the expression's column name and can be used with
ORDER BY
or HAVING
clauses. For example:
mysql> SELECT CONCAT(last_name,', ',first_name) AS full_name FROM mytable ORDER BY full_name; |
The AS
keyword is optional when aliasing a SELECT
expression.
The preceding example could have been written like this:
mysql> SELECT CONCAT(last_name,', ',first_name) full_name FROM mytable ORDER BY full_name; |
Because the AS
is optional, a subtle problem can occur
if you forget the comma between two SELECT
expressions: MySQL will
interpret the second as an alias name. For example, in the following
statement, columnb
is treated as an alias name:
mysql> SELECT columna columnb FROM mytable; |
WHERE
clause,
because the column value may not yet be determined when the
WHERE
clause is executed.
See section A.5.4 Problems with alias
.
FROM table_references
clause indicates the tables from which to
retrieve rows. If you name more than one table, you are performing a
join. For information on join syntax, see JOIN
.
For each table specified, you may optionally specify an alias.
table_name [[AS] alias] [[USE INDEX (key_list)] | [IGNORE INDEX (key_list)] | [FORCE INDEX (key_list)]] |
EXPLAIN
shows that MySQL is
using the wrong index from the list of possible indexes. By specifying
USE INDEX (key_list)
, you can tell MySQL to use only one of the
possible indexes to find rows in the table. The alternative syntax
IGNORE INDEX (key_list)
can be used to tell MySQL to not use some
particular index.
In MySQL 4.0.9 you can also use FORCE INDEX
. This acts likes
USE INDEX (key_list)
but with the addition that a table scan
is assumed to be VERY expensive. In other words a table scan will
only be used if there is no way to use one of the given index to
find rows in the table.
USE/IGNORE/FORCE KEY
are synonyms for USE/IGNORE/FORCE INDEX
.
Note: USE/IGNORE/FORCE INDEX
only affects which indexes are
used when MySQL decides how to find rows in the table and how to do the
join. It doesn't affect whether an index will be used when resolving an
ORDER BY
or GROUP BY
.
In MySQL 4.0.14, you can use SET MAX_SEEKS_FOR_KEY=value
as an
alternative way to force MySQL to prefer key scans instead of table scans.
tbl_name
(within the current database),
or as dbname.tbl_name
to explicitly specify a database.
You can refer to a column as col_name
, tbl_name.col_name
, or
db_name.tbl_name.col_name
. You need not specify a tbl_name
or
db_name.tbl_name
prefix for a column reference in a SELECT
statement unless the reference would be ambiguous. See 10.2 Database, Table, Index, Column, and Alias Names,
for examples of ambiguity that require the more explicit column reference
forms.
DUAL
as a dummy
table name, in situations where no tables are referenced. This is purely
compatibility feature, some other servers require this syntax.
mysql> SELECT 1 + 1 FROM DUAL; -> 2 |
tbl_name [AS] alias_name
:
mysql> SELECT t1.name, t2.salary FROM employee AS t1, info AS t2 -> WHERE t1.name = t2.name; mysql> SELECT t1.name, t2.salary FROM employee t1, info t2 -> WHERE t1.name = t2.name; |
ORDER BY
and
GROUP BY
clauses using column names, column aliases, or column
positions. Column positions begin with 1:
mysql> SELECT college, region, seed FROM tournament -> ORDER BY region, seed; mysql> SELECT college, region AS r, seed AS s FROM tournament -> ORDER BY r, s; mysql> 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 the ORDER BY
clause that you are sorting by.
The default is ascending order; this may be specified explicitly using
the ASC
keyword.
WHERE
clause, you can use any of the functions that
MySQL supports, except for aggregate (summary) functions.
See section 12. Functions and Operators.
HAVING
clause can refer to any column or alias named in the
select_expression
. It is applied nearly last, just before items are
sent to the client, with no optimization. (LIMIT
is applied after
HAVING
.) Don't use HAVING
for items that
should be in the WHERE
clause. For example, do not write this:
mysql> SELECT col_name FROM tbl_name HAVING col_name > 0; |
Write this instead:
mysql> SELECT col_name FROM tbl_name WHERE col_name > 0; |
In MySQL Version 3.22.5 or later, you can also write queries like this:
mysql> SELECT user,MAX(salary) FROM users -> GROUP BY user HAVING MAX(salary)>10; |
In older MySQL versions, you can write this instead:
mysql> SELECT user,MAX(salary) AS sum FROM users -> group by user HAVING sum>10; |
DISTINCT
, DISTINCTROW
and ALL
specify
whether duplicate rows should be returned. The default is (ALL
),
all matching rows are returned. DISTINCT
and DISTINCTROW
are synonyms and specify that duplicate rows in the result set should
be removed.
STRAIGHT_JOIN
, HIGH_PRIORITY
, and options beginning with
SQL_
are MySQL extensions to SQL-99.
STRAIGHT_JOIN
forces the optimizer to join the tables in the order in
which they are listed in the FROM
clause. You can use this to speed up
a query if the optimizer joins the tables in non-optimal order.
See section EXPLAIN
.
HIGH_PRIORITY
will give the SELECT
higher 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. A SELECT HIGH_PRIORITY
query will run if the table is locked for read even if there is an update
statement that is waiting for the table to be free.
SQL_BIG_RESULT
can be used with GROUP BY
or DISTINCT
to tell the optimizer that the result set will have many rows. In this case,
MySQL will directly use disk-based temporary tables if needed.
MySQL will also, in this case, prefer sorting to doing a
temporary table with a key on the GROUP BY
elements.
SQL_BUFFER_RESULT
forces 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.
SQL_SMALL_RESULT
, a MySQL-specific option, can be used
with GROUP BY
or DISTINCT
to tell the optimizer that the
result set will be small. In this case, MySQL uses fast
temporary tables to store the resulting table instead of using sorting. In
MySQL Version 3.23 this shouldn't normally be needed.
SQL_CALC_FOUND_ROWS
(version 4.0.0 and up) tells MySQL to calculate
how many rows there would be in the result set, disregarding any
LIMIT
clause.
The number of rows can then be retrieved with SELECT FOUND_ROWS()
.
See section 12.6.4 Miscellaneous Functions.
Please note that in versions prior to 4.1.0 this does not work with
LIMIT 0
, which is optimized to return instantly (resulting in a
row count of 0). See section 7.2.10 How MySQL Optimizes LIMIT
.
SQL_CACHE
tells MySQL to store the query result in the query cache
if you are using QUERY_CACHE_TYPE=2
(DEMAND
).
See section 13.8 MySQL Query Cache. For a query that uses UNION
or subqueries, this
option takes effect to be used in any SELECT
of the query.
SQL_NO_CACHE
tells MySQL not to store the query result
in the query cache. See section 13.8 MySQL Query Cache.
For a query that uses UNION
or subqueries, this
option takes effect to be used in any SELECT
of the query.
GROUP BY
, the output rows will be sorted according to the
GROUP BY
as if you had an ORDER BY
over all the fields
in the GROUP BY
. MySQL has extended the GROUP BY
clause so that
you can also specify ASC
and DESC
after columns named in the
clause:
SELECT a,COUNT(b) FROM test_table GROUP BY a DESC |
GROUP BY
to allow you to
select fields that are not mentioned in the GROUP BY
clause.
If you are not getting the results you expect from your query, please
read the GROUP BY
description.
See section 12.7 Functions and Modifiers for Use with GROUP BY
Clauses.
GROUP BY
allows a WITH ROLLUP
modifier.
See section GROUP BY
Modifiers.
LIMIT
clause can be used to constrain the number of rows returned
by the SELECT
statement. LIMIT
takes one or two numeric
arguments, which must be integer constants.
With one argument, the value specifies the number of rows to return from the beginning of the result set. 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):
To be compatible with PostgreSQL MySQL also supports the syntax:
LIMIT row_count OFFSET offset
.
mysql> SELECT * FROM table 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:
mysql> SELECT * FROM table LIMIT 95,18446744073709551615; # Retrieve rows 96-last. |
If one argument is given, it indicates the maximum number of rows to return:
mysql> SELECT * FROM table LIMIT 5; # Retrieve first 5 rows |
In other words, LIMIT n
is equivalent to LIMIT 0,n
.
SELECT ... INTO OUTFILE 'file_name'
form of SELECT
writes
the selected rows to a file. The file is created on the server host and
cannot already exist (among other things, this prevents database tables and
files such as `/etc/passwd' from being destroyed). You must have the
FILE
privilege on the server host to use this form of SELECT
.
The SELECT ... INTO OUTFILE
statement is intended primarily to let you very
quickly dump a table on the server machine. If you want to create the
resulting file on some other host than the server host, you can't use
SELECT ... INTO OUTFILE
. In that case, you should instead use some
client program like mysqldump --tab
or mysql -e "SELECT
..." > outfile
to generate the file.
SELECT ... INTO OUTFILE
is the complement of LOAD DATA
INFILE
; the syntax for the export_options
part of the statement
consists of the same FIELDS
and LINES
clauses that are used
with the LOAD DATA INFILE
statement.
See section LOAD DATA
.
In the resulting text file, only the following characters are escaped by
the ESCAPED BY
character:
ESCAPED BY
character
FIELDS TERMINATED BY
LINES TERMINATED BY
Additionally, ASCII 0
is converted to ESCAPED BY
followed by 0
(ASCII 48
).
The reason for the above is that you must escape any FIELDS
TERMINATED BY
, ESCAPED BY
, or LINES TERMINATED BY
characters to reliably be able to read the file back. ASCII 0
is
escaped to make it easier to view with some pagers.
As the resulting file doesn't have to conform to the SQL syntax, nothing else need be escaped.
Here follows an example of getting a file in the format used by many old programs.
SELECT a,b,a+b INTO OUTFILE "/tmp/result.text" FIELDS TERMINATED BY ',' OPTIONALLY ENCLOSED BY '"' LINES TERMINATED BY "\n" FROM test_table; |
INTO DUMPFILE
instead of INTO OUTFILE
, MySQL
will write only one row into the file, without any column or line
terminations and without performing any escape processing. This is useful if you want to
store a BLOB
value in a file.
INTO OUTFILE
and INTO
DUMPFILE
will be writable by all users on the server host! The reason is that the
MySQL server can't create a file that is owned by anyone else
than the user it's running as (you should never run mysqld
as
root
).
The file thus must be world-writable so that you can manipulate its contents.
PROCEDURE
clause names a procedure that should process the data
in the result set. For an example, see 21.3.1 Procedure Analyse.
FOR UPDATE
on a storage engine with page or row locks,
the examined rows are write-locked until the end of the current
transaction.
13.1.7.1 JOIN Syntax | ||
13.1.7.2 UNION Syntax |
[ < ] | [ > ] | [ << ] | [ Up ] | [ >> ] | [Top] | [Contents] | [Index] | [ ? ] |