- 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.2. MySQL Identifier Syntax and Naming Rules
Almost every SQL statement uses identifiers in some way to refer to a database or its constituent elements such as tables, views, columns, indexes, stored routines, triggers, or events. When you refer to elements of databases, identifiers must conform to the following rules.
Legal characters in identifiers. Unquoted identifiers may consist of latin letters a-z in any lettercase, digits 0-9, dollar, underscore, and Unicode extended characters in the range U+0080 to U+FFFF. Identifiers can start with any character that is legal in an identifier, including a digit. However, an unquoted identifier cannot consist entirely of digits because that would make it indistinguishable from a number. MySQL’s support for identifiers that begin with a number is somewhat unusual among database systems. If you use such an identifier, take particular care if it contains an ‘E’ or ‘e’ because those characters can lead to ambiguous expressions. For example, the expression 23e + 14 (with spaces surrounding the ‘+’ sign) means column 23e plus the number 14, but what about 23e+14? Does it mean the same thing, or is it a number in scientific notation?
Identifiers can be quoted (delimited) within backtick characters (‘`’), which permits use of any character except a NUL byte or Unicode supplementary characters (U+10000 and up):
CREATE TABLE `my table` (`my-int-column` INT);
Quoting is useful when an identifier is an SQL reserved word or contains spaces or other special characters. Quoting an identifier also enables it to be entirely numeric, something not true of unquoted identifiers. To include an identifier quote character within a quoted identifier, double it.
Your operating system might impose additional constraints on database and table identifiers. See Section 11.2.6, “Operating System Constraints on Database Object Names.”
Aliases for column and table names can be fairly arbitrary. You should quote an alias within identifier quoting characters if it is an SQL reserved word, is entirely numeric, or contains spaces or other special characters. Column aliases also can be quoted with single quotes or double quotes.
Server SQL mode. If the ANSI_QUOTES SQL mode is enabled, you can quote identifiers with double quotes (although backticks still are permitted).
CREATE TABLE "my table" ("my-int-column" INT);
Enabling ANSI_QUOTES has the additional effect that string literals must be written using single quotes. If you use double quotes, the server interprets the value as an identifier, not as a string.
Names of built-in functions normally are not reserved and can be used as identifiers without quotes. However, if the IGNORE_SPACE SQL mode is enabled, function names become reserved and must be quoted if used as identifiers.
For instructions on setting the SQL mode, see Section 2.1, “The Server SQL Mode.”
Identifier length. Most identifiers have a maximum length of 64 characters. The maximum length for aliases is 256 characters.
Identifier qualifiers. Depending on context, an identifier might need to be qualified to clarify what it refers to. To refer to a database, just specify its name:
USE db_name; SHOW TABLES FROM db_name;
To refer to a table, you have two choices:
- A fully qualified table name consists of a database identifier and a table identifier:
SHOW COLUMNS FROM db_name.tbl_name; SELECT * FROM db_name.tbl_name;
- A table identifier by itself refers to a table in the default (current) database. If sampdb is the default database, the following statements are equivalent:
SELECT * FROM member; SELECT * FROM sampdb.member;
If no database is selected, it is an error to refer to a table without a database qualifier because the database to which the table belongs is unknown.
The same considerations about qualifying table names apply to names of views (which are “virtual” tables) and stored programs.
To refer to a table column, you have three choices:
- A name written as db_name.tbl_name.col_name is fully qualified.
- A partially qualified name written as tbl_name.col_name refers to a column in the named table in the default database.
- An unqualified name written simply as col_name refers to whatever table the surrounding context indicates. The following two queries use the same column names, but the context supplied by the FROM clause of each statement indicates the table from which to select the columns:
SELECT last_name, first_name FROM president; SELECT last_name, first_name FROM member;
Usually, it’s unnecessary to supply fully qualified names, although it’s always legal to do so. If you select a database with a USE statement, it becomes the default database for subsequent statements and is implicit in every unqualified table reference. If you write a SELECT statement that refers to only one table, that table is implicit for every column reference in the statement. It’s necessary to qualify identifiers only when a table or database cannot be determined from context. For example, if a statement refers to tables from multiple databases, you must reference any table not in the default database using db_name.tbl_name syntax to let MySQL know which database contains the table. Similarly, if a query uses multiple tables and refers to a column name that is used in more than one table, qualify the column identifier with a table identifier to make it clear which column you mean.
If you use quotes when referring to a qualified name, quote individual identifiers within the name separately. For example:
SELECT * FROM `sampdb`.`member` WHERE `sampdb`.`member`.`member_id` > 100;
Do not quote the name as a whole. This statement is incorrect:
SELECT * FROM `sampdb.member` WHERE `sampdb.member.member_id` > 100;
The requirement that a reserved word be quoted if used as an identifier is waived if the word follows a qualifier period because context then dictates that the reserved word is an identifier.