Database, table, index, column, and alias names are identifiers. This section describes the allowable syntax for identifiers in MySQL.
The following table describes the maximum length for each type of identifier.
Identifier | Maximum Length |
Database | 64 |
Table | 64 |
Column | 64 |
Index | 64 |
Alias | 255 |
There are some restrictions on the characters that may appear in identifiers:
-
No identifier can contain ASCII 0 (
0x00
) or a byte with a value of 255. -
The use of identifier quote characters in identifiers is permitted, although it is best to avoid doing so if possible.
-
Database, table, and column names should not end with space characters.
-
Database names cannot contain ‘
/
’, ‘\
’, ‘.
’, or characters that are not allowed in a directory name. -
Table names cannot contain ‘
/
’, ‘\
’, ‘.
’, or characters that are not allowed in a filename.
Identifiers are stored using Unicode (UTF-8). This applies to
identifiers in table definitions that are stored in
.frm
files and to identifiers stored in the
grant tables in the mysql
database. The sizes
of the string columns in the grant tables (and in any other
tables) in MySQL 5.0 are given as number of
characters. This means that (unlike some earlier versions of
MySQL) you can use multi-byte characters without reducing the
number of characters allowed for values stored in these columns.
An identifier may be quoted or unquoted. If an identifier is a
reserved word or contains special characters, you
must quote it whenever you refer to it.
(Exception: A word that follows a period in a qualified name must
be an identifier, so it is not necessary to quote it, even if it
is a reserved word.) For a list of reserved words, see
Section 9.5, “Treatment of Reserved Words in MySQL”. Special characters are those
outside the set of alphanumeric characters from the current
character set, ‘_
’, and
‘$
’.
The identifier quote character is the backtick
(‘`
’):
mysql> SELECT * FROM `select` WHERE `select`.id > 100;
If the ANSI_QUOTES
SQL mode is enabled, it is
also allowable to quote identifiers within double quotes:
mysql>CREATE TABLE "test" (col INT);
ERROR 1064: You have an error in your SQL syntax. (...) mysql>SET sql_mode='ANSI_QUOTES';
mysql>CREATE TABLE "test" (col INT);
Query OK, 0 rows affected (0.00 sec)
Note: Because the ANSI_QUOTES
mode causes the
server to interpret double-quoted strings as identifiers, string
literals must be enclosed within single quotes when this mode is
enabled. They cannot be enclosed within double quotes.
The server SQL mode is controlled as described in Section 5.2.5, “The Server SQL Mode”.
Identifier quote characters can be included within an identifier
if you quote the identifier. If the character
to be included within the identifier is the same as that used to
quote the identifier itself, then you need to double the
character. The following statement creates a table named
a`b
that contains a column named
c"d
:
mysql> CREATE TABLE `a``b` (`c"d` INT);
It is recommended that you do not use names of the form
M
e or
M
eN
,
where M
and
N
are integers. For example, avoid
using 1e
or 2e2
as
identifiers, because an expression such as 1e+3
is ambiguous. Depending on context, it might be interpreted as the
expression 1e + 3
or as the number
1e+3
.
Be careful when using MD5()
to produce table
names because it can produce names in illegal or ambiguous formats
such as those just described.
MySQL allows names that consist of a single identifier or
multiple identifiers. The components of a multiple-part name
should be separated by period
(‘.
’) characters. The initial
parts of a multiple-part name act as qualifiers that affect the
context within which the final identifier is interpreted.
In MySQL you can refer to a column using any of the following forms:
Column Reference | Meaning |
col_name
|
The column col_name from whichever table used
in the statement contains a column of that name. |
tbl_name.col_name
|
The column col_name from table
tbl_name of the default
database. |
db_name.tbl_name.col_name
|
The column col_name from table
tbl_name of the database
db_name . |
If any components of a multiple-part name require quoting, quote
them individually rather than quoting the name as a whole. For
example, write `my-table`.`my-column`
, not
`my-table.my-column`
.
You need not specify a tbl_name
or
db_name.tbl_name
prefix for a column
reference in a statement unless the reference would be
ambiguous. Suppose that tables t1
and
t2
each contain a column
c
, and you retrieve c
in a
SELECT
statement that uses both
t1
and t2
. In this case,
c
is ambiguous because it is not unique among
the tables used in the statement. You must qualify it with a
table name as t1.c
or t2.c
to indicate which table you mean. Similarly, to retrieve from a
table t
in database db1
and from a table t
in database
db2
in the same statement, you must refer to
columns in those tables as
db1.t.
col_name
and
db2.t.
col_name
.
A word that follows a period in a qualified name must be an identifier, so it is not necessary to quote it, even if it is a reserved word.
The syntax .tbl_name
means the table
tbl_name
in the default database.
This syntax is accepted for ODBC compatibility because some ODBC
programs prefix table names with a
‘.
’ character.
In MySQL, databases correspond to directories within the data
directory. Each table within a database corresponds to at least
one file within the database directory (and possibly more,
depending on the storage engine). Consequently, the case
sensitivity of the underlying operating system determines the
case sensitivity of database and table names. This means
database and table names are case sensitive in most varieties of
Unix, and not case sensitive in Windows. One notable exception
is Mac OS X, which is Unix-based but uses a default filesystem
type (HFS+) that is not case sensitive. However, Mac OS X also
supports UFS volumes, which are case sensitive just as on any
Unix. See Section 1.9.4, “MySQL Extensions to Standard SQL”. The
lower_case_table_names
system variable also
affects how the server handles identifier case sensitivity, as
described later in this section.
Note: Although database and
table names are not case sensitive on some platforms, you should
not refer to a given database or table using different cases
within the same statement. The following statement would not
work because it refers to a table both as
my_table
and as MY_TABLE
:
mysql> SELECT * FROM my_table WHERE MY_TABLE.col=1;
Column, index and stored routine names are not case sensitive on any platform, nor are column aliases. Trigger names are case sensitive.
By default, table aliases are case sensitive on Unix, but not so
on Windows or Mac OS X. The following statement would not work
on Unix, because it refers to the alias both as
a
and as A
:
mysql>SELECT
col_name
FROMtbl_name
AS a ->WHERE a.
col_name
= 1 OR A.col_name
= 2;
However, this same statement is permitted on Windows. To avoid problems caused by such differences, it is best to adopt a consistent convention, such as always creating and referring to databases and tables using lowercase names. This convention is recommended for maximum portability and ease of use.
How table and database names are stored on disk and used in
MySQL is affected by the
lower_case_table_names
system variable, which
you can set when starting mysqld.
lower_case_table_names
can take the values
shown in the following table. On Unix, the default value of
lower_case_table_names
is 0. On Windows the
default value is 1. On Mac OS X, the default value is 2.
Value | Meaning |
0
|
Table and database names are stored on disk using the lettercase
specified in the CREATE TABLE or
CREATE DATABASE statement. Name
comparisons are case sensitive. Note that if you force
this variable to 0 with
--lower-case-table-names=0 on a
case-insensitive filesystem and access
MyISAM tablenames using different
lettercases, index corruption may result. |
1
|
Table names are stored in lowercase on disk and name comparisons are not case sensitive. MySQL converts all table names to lowercase on storage and lookup. This behavior also applies to database names and table aliases. |
2
|
Table and database names are stored on disk using the lettercase
specified in the CREATE TABLE or
CREATE DATABASE statement, but MySQL
converts them to lowercase on lookup. Name comparisons
are not case sensitive.
Note: This works
only on filesystems that are not
case sensitive! InnoDB table names
are stored in lowercase, as for
lower_case_table_names=1 . |
If you are using MySQL on only one platform, you don't normally
have to change the lower_case_table_names
variable. However, you may encounter difficulties if you want to
transfer tables between platforms that differ in filesystem case
sensitivity. For example, on Unix, you can have two different
tables named my_table
and
MY_TABLE
, but on Windows these two names are
considered identical. To avoid data transfer problems stemming
from lettercase of database or table names, you have two
options:
-
Use
lower_case_table_names=1
on all systems. The main disadvantage with this is that when you useSHOW TABLES
orSHOW DATABASES
, you don't see the names in their original lettercase. -
Use
lower_case_table_names=0
on Unix andlower_case_table_names=2
on Windows. This preserves the lettercase of database and table names. The disadvantage of this is that you must ensure that your statements always refer to your database and table names with the correct lettercase on Windows. If you transfer your statements to Unix, where lettercase is significant, they do not work if the lettercase is incorrect.Exception: If you are using
InnoDB
tables, you should setlower_case_table_names
to 1 on all platforms to force names to be converted to lowercase.
Note that if you plan to set the
lower_case_table_names
system variable to 1
on Unix, you must first convert your old database and table
names to lowercase before restarting mysqld
with the new variable setting.