- 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.4. Character Set Support
MySQL supports multiple character sets, and character sets can be specified independently at the server, database, table, column, or string constant level. For example, if you want a table’s columns to use latin1 by default, but also to include a Hebrew column and a Greek column, you can do that. In addition, you can explicitly specify collations (sorting orders). It is possible to find out what character sets and collations are available, and to convert data from one character set to another.
This section provides general background on using character set support in MySQL. Chapter 3, “Data Types,” provides more specific discussion of character sets, collations, binary versus nonbinary strings, and how to define and work with character-based table columns.
MySQL provides the following character set features:
- The server supports simultaneous use of multiple character sets.
- A given character set can have one or more collations. You can choose the collation most appropriate for your applications.
- Unicode support is provided by the utf8 and ucs2 character sets, which include Basic Multilingual Plane (BMP) characters, and the utf16, utf32, and utf8mb4 character sets, which include BMP and supplementary characters. MySQL 5.6.1 adds utf16le, which is like utf16 but uses little-endian rather than big-endian encoding.
- You can specify character sets at the server, database, table, column, and string constant level:
- The server has a default character set.
- CREATE DATABASE enables you to assign the database character set, and ALTER DATABASE enables you to change it.
- CREATE TABLE and ALTER TABLE have clauses for table- and column-level character set assignment.
- The character set for string constants is determined by context or can be specified explicitly.
- Several functions and operators are available for converting individual values from one character set to another, and the CHARSET() function returns the character set of a value. Similarly, the COLLATE operator can be used to alter the collation of a string and the COLLATION() function returns the collation of a string.
- SHOW statements and INFORMATION_SCHEMA tables provide information about the available character sets and collations.
- The server automatically reorders indexes when you change the collation of an indexed character column.
You cannot mix character sets within a string, or use different character sets for different rows of a given column. However, you can implement multi-lingual support by using a Unicode character set (which represents characters for many languages within a single encoding).
2.4.1. Specifying Character Sets
Character set and collation assignments can be made at several levels, from the default used by the server to the character set used for individual strings.
The server’s default character set and collation are built in at compile time. You can override them at server startup or at runtime by setting the character_set_server and collation_server system variables, as described in Section 12.6.2, “Selecting the Default Character Set and Collation.” If you specify only the character set, its default collation becomes the server’s default collation. If you specify a collation, it must be compatible with the character set. A collation is compatible with a character set if its name begins with the character set name. For example, utf8_danish_ci is compatible with utf8 but not with latin1.
In SQL statements that create databases and tables, two clauses specify database, table, and column character set and collation values:
CHARACTER SET charset COLLATE collation
CHARSET can be used as a synonym for CHARACTER SET. charset is the name of a character set supported by the server, and collation is the name of one of that character set’s collations. These clauses can be specified together or separately. If both are given, the collation name must be compatible with the character set. If only CHARACTER SET is given, its default collation is used. If only COLLATE is given, the character set is implicit in the first part of the character set name. These rules apply at several levels:
- To specify a default character set and collation for a database when you create it, use this statement:
CREATE DATABASE db_name CHARACTER SET charset COLLATE collation;
If no character set or collation is given, the database uses the server defaults.
- To specify a default character set and collation for a table, use CHARACTER SET and COLLATE table options at table creation time:
CREATE TABLE tbl_name (...) CHARACTER SET charset COLLATE collation;
If no character set or collation is given, the table uses the database defaults.
- Columns in a table can be assigned a character set and collation explicitly with CHARACTER SET and COLLATE attributes. For example:
c CHAR(10) CHARACTER SET charset COLLATE collation
If no character set or collation is given, the column uses the table defaults. These attributes apply to the CHAR, VARCHAR, TEXT, ENUM, and SET data types.
It’s also possible to sort string values according to a specific collation by using the COLLATE operator. For example, if c is a latin1 column that has a collation of latin1_swedish_ci, but you want to order it using Spanish sorting rules, do this:
SELECT c FROM t ORDER BY c COLLATE latin1_spanish_ci;
2.4.2. Determining Character Set Availability and Current Settings
To find out which character sets and collations are available, use these statements:
SHOW CHARACTER SET; SHOW COLLATION;
Each statement supports a LIKE clause that narrows the results to those character set or collation names matching a pattern. For example, the following statements list the Latin-based character sets and the collations available for the utf8 character set:
mysql> SHOW CHARACTER SET LIKE 'latin%'; +---------+-----------------------------+-------------------+--------+ | Charset | Description | Default collation | Maxlen | +---------+-----------------------------+-------------------+--------+ | latin1 | cp1252 West European | latin1_swedish_ci | 1 | | latin2 | ISO 8859-2 Central European | latin2_general_ci | 1 | | latin5 | ISO 8859-9 Turkish | latin5_turkish_ci | 1 | | latin7 | ISO 8859-13 Baltic | latin7_general_ci | 1 | +---------+-----------------------------+-------------------+--------+ mysql> SHOW COLLATION LIKE 'utf8%'; +-----------------------+---------+-----+---------+----------+---------+ | Collation | Charset | Id | Default | Compiled | Sortlen | +-----------------------+---------+-----+---------+----------+---------+ | utf8_general_ci | utf8 | 33 | Yes | Yes | 1 | | utf8_bin | utf8 | 83 | | Yes | 1 | | utf8_unicode_ci | utf8 | 192 | | Yes | 8 | | utf8_icelandic_ci | utf8 | 193 | | Yes | 8 | | utf8_latvian_ci | utf8 | 194 | | Yes | 8 | | utf8_romanian_ci | utf8 | 195 | | Yes | 8 | | utf8_slovenian_ci | utf8 | 196 | | Yes | 8 | ...
Collation names always begin with the character set name. Each character set has at least one collation, and one of them is its default collation.
Information about the available character sets or collations can also be obtained from the CHARACTER_SETS or COLLATIONS table in the INFORMATION_SCHEMA database (see Section 2.7, “Obtaining Database Metadata”).
To display the server’s current character set and collation settings, use SHOW VARIABLES:
mysql> SHOW VARIABLES LIKE 'character\_set\_%'; +--------------------------+--------+ | Variable_name | Value | +--------------------------+--------+ | character_set_client | utf8 | | character_set_connection | utf8 | | character_set_database | latin1 | | character_set_filesystem | binary | | character_set_results | utf8 | | character_set_server | latin1 | | character_set_system | utf8 | +--------------------------+--------+ mysql> SHOW VARIABLES LIKE 'collation\_%'; +----------------------+-------------------+ | Variable_name | Value | +----------------------+-------------------+ | collation_connection | utf8_general_ci | | collation_database | latin1_swedish_ci | | collation_server | latin1_swedish_ci | +----------------------+-------------------+
Several of these system variables affect how a client communicates with the server after establishing a connection. For details, refer to Section 3.1.2.2, “Character Set-Related System Variables.”
2.4.3. Unicode Support
One of the reasons there are so many character sets is that different character encodings have been developed for different languages. This presents several problems. For example, a given character that is common to several languages might be represented by different numeric values in different encodings. Also, different languages require different numbers of bytes to represent characters. The latin1 character set is small enough that every character fits in a single byte, but languages such as those used in Japan and China contain so many characters that they require multiple bytes per character.
Unicode deals with these issues by providing a unified character-encoding system within which character sets for all languages can be represented in a consistent manner.
The utf8 and ucs2 Unicode character sets include only characters in the Basic Multilingual Plane (BMP), which is limited to 65,536 characters. They do not support supplementary characters outside the BMP.
- The ucs2 character set corresponds to the Unicode UCS-2 encoding. It represents each character using 2 bytes, most significant byte first. UCS is an abbreviation for Universal Character Set.
- The utf8 character set has a variable-length format that represents characters using from 1 to 3 bytes. It corresponds to the Unicode UTF-8 encoding. UTF is an abbreviation for Unicode Transformation Format.
Beginning with MySQL 5.5.3, other Unicode character sets are available that include supplementary characters in addition to BMP characters.
- The utf16 and utf32 character sets are like ucs2 but with supplementary characters added. For utf16, BMP characters take 2 bytes (as for ucs2) and supplementary characters take 4 bytes. For utf32, all characters take 4 bytes.
- The utf8mb4 character set contains all the utf8 characters (which take 1 to 3 bytes each), but also supplementary characters that take 4 bytes each.
MySQL 5.6.1 adds utf16le, which is like utf16 but uses little-endian rather than big-endian encoding.