- MySQL Naming Rules
- The Server SQL Mode
- Character Set Support
- Selecting, Creating, Dropping, and Altering Databases
- Creating, Dropping, Indexing, and Altering Tables
- Getting Information About Databases and Tables
- Performing Multiple-Table Retrievals with Joins
- Performing Multiple-Table Retrievals with Subqueries
- Performing Multiple-Table Retrievals with UNION
- Multiple-Table Deletes and Updates
- Performing Transactions
- Foreign Keys and Referential Integrity
- Using FULLTEXT Searches
- New Features in MySQL 5.0
Character Set Support
Prior to MySQL 4.1, the server operates using a single character set at a time. As of MySQL 4.1, the server can support multiple character sets simultaneously, 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 also 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 MySQL's character set support. Chapter 3 provides more specific discussion of character sets, collations, binary versus non-binary strings, and how to define character-based table columns and work with them. Chapter 11 discusses how to configure which character sets the server makes available. That chapter also includes notes on what to do when upgrading older tables to MySQL 4.1 so that you can use the new features.
Character Set Support Before MySQL 4.1
Prior to MySQL 4.1, string values in MySQL have no explicit character set. Instead, string constants and column values always are interpreted with respect to the server's character set. By default, this is the character set selected when the server was built (usually latin1), but the built-in value may be overridden at runtime with the --default-character-set option. This is very simple but quite limiting. For example, you cannot have a table that stores values using different character sets for different columns.
The single-character-set model also can lead to index-related problems if you change the server's character set after having already created tables and loaded character data into them. These problems occur due to the fact that index values for character columns are stored in sorted order according to the collating sequence of the character set that happens to be in force at the time the index entries are created. Character sets have different collating sequences, so if you load a table while the server is using one character set and then reconfigure the server to use a different set, it's possible that the index entries no longer will be in the correct order with respect to the collating sequence of the new character set. Worse, if you add new rows to the table, the index that was initially created using the sort order of the original character set will be updated using the order of the new set. Consequently, index-based queries might not work correctly.
The solution to this problem is to rebuild the indexes for each existing table that has character-based indexes to use the collating order of the new character set. A table can be converted in various ways:
Dump the table with mysqldump, drop it, and reload it from the dump file. This operation causes the indexes to be rebuilt as the file is reloaded. It works for any storage engine.
Drop the indexes and add them again (for example, with ALTER TABLE, or with DROP INDEX and CREATE INDEX). This works for any storage engine, but requires that you know the exact index definitions so that you can re-create them properly.
For MyISAM tables, you can rebuild indexes by running myisamchk with the --recover and --quick options, together with a --set-character-set option that specifies the character set to use. Equivalent alternatives are to use the mysqlcheck program with the --repair and --quick options, or a REPAIR TABLE statement with the QUICK option. mysqlcheck and REPAIR TABLE are more convenient because the server does the work and it knows which character set to use. myisamchk must be run with the tables offline and you have to specify the character set explicitly.
Despite the methods available for reordering indexes if you change the server's character set, the fact that you need to do it at all is a bother. MySQL 4.1 eliminates the need. Each character column is associated with a character set and collation that determines its ordering, so if you change the server character set, it has no impact on individual columns. Also, if you change a column's character set or collation, MySQL automatically reorders the indexes without manual intervention.
When you upgrade an older server to MySQL 4.1 or newer, your old tables can still be used but you should convert them to 4.1 format so that you can take full advantage of the improved character set support instituted in 4.1. Instructions for doing this can be found in "Upgrading Tables When Character Set Conversion Is Necessary," in Chapter 11.
Character Set Support in MySQL 4.1 and Up
In MySQL 4.1, character set support was revised considerably to provide the following features:
-
The server supports use of multiple character sets simultaneously.
-
Unicode support is provided by the utf8 and ucs2 character sets.
-
You can specify character sets at the server, database, table, column, and string constant level, not just at the server level:
-
CREATE DATABASE allows you to assign the database character set, and ALTER DATABASE allows you to change it.
-
CREATE TABLE and ALTER TABLE have clauses for table- and column-level character set assignment. (Details are given in Chapter 3.)
-
Functions and operators are available for converting individual values from one character set to another or for determining the character set of a value.
-
A given character set can have one or more collations. You can choose the collation most appropriate for your applications.
-
The COLLATE operator can be used to alter the collation of a string and the COLLATION() function returns the collation of a string.
-
The SHOW CHARACTER SET and SHOW COLLATION statements list 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, by using a Unicode character set (which represents the encodings for many languages within a single character set), you may be able to implement multi-lingual support of the type you desire.
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 time by using the --character-set-server and --collation-server options. 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 are used for specifying database, table, and column character set and collation values:
CHARACTER SET charset COLLATE collation
charset is the name of a character set supported by the server, and collation is the name of one of the 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.
-
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 server defaults are used for the database.
To change a database default character set and collation, use this statement:
ALTER DATABASE db_name CHARACTER SET charset COLLATE collation;
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 database defaults are used for the table.
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 table defaults are used for the column. Data types for which these attributes may be given are CHAR, VARCHAR, TEXT, ENUM, and SET.
It's also possible to sort string values using a specific collation by using the COLLATE operator. For example, if c is a latin1 column that has the default 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;
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 of them supports a LIKE clause that narrows the results to those character set or collation names matching a pattern. For example, this statement lists the Latin-based character sets:
mysql> SHOW CHARACTER SET LIKE 'latin%'; +---------+-----------------------------+-------------------+--------+ | Charset | Description | Default collation | Maxlen | +---------+-----------------------------+-------------------+--------+ | latin1 | ISO 8859-1 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 | +---------+-----------------------------+-------------------+--------+
This statement lists the collations available for the utf8 character set:
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 | | utf8_polish_ci | utf8 | 197 | | Yes | 8 | | utf8_estonian_ci | utf8 | 198 | | Yes | 8 | | utf8_spanish_ci | utf8 | 199 | | Yes | 8 | | utf8_swedish_ci | utf8 | 200 | | Yes | 8 | | utf8_turkish_ci | utf8 | 201 | | Yes | 8 | | utf8_czech_ci | utf8 | 202 | | Yes | 8 | | utf8_danish_ci | utf8 | 203 | | Yes | 8 | | utf8_lithuanian_ci | utf8 | 204 | | Yes | 8 | | utf8_slovak_ci | utf8 | 205 | | Yes | 8 | | utf8_spanish2_ci | utf8 | 206 | | Yes | 8 | +--------------------+---------+-----+---------+----------+---------+
As can be seen in the output from these statements, each character set has at least one collation and one of them is its default collation.
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 | latin1 | | character_set_connection | latin1 | | character_set_database | latin1 | | character_set_results | latin1 | | character_set_server | latin1 | | character_set_system | utf8 | +--------------------------+--------+ mysql> SHOW VARIABLES LIKE 'collation\_%'; +----------------------+-------------------+ | Variable_name | Value | +----------------------+-------------------+ | collation_connection | latin1_swedish_ci | | collation_database | latin1_swedish_ci | | collation_server | latin1_swedish_ci | +----------------------+-------------------+
Unicode Support
One of the reasons there are so many character sets is that different 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.
The goal of Unicode is to provide a unified character-encoding system within which character sets for all languages can be represented in a consistent manner. In MySQL, Unicode support is provided through two character sets:
-
The ucs2 character set corresponds to the Unicode UCS-2 encoding. It represents each character using two bytes, most significant byte first. This character set does not represent characters that require more than two bytes. UCS is an abbreviation for Universal Character Set.
-
The utf8 character set has a variable-length format in which characters are represented using from one to three bytes. It corresponds to the Unicode UTF-8 encoding. (UTF-8 allows for encodings using up to four bytes, but the MySQL utf8 character set currently does not include any characters that use more than three bytes.) UTF is an abbreviation for UCS Transformation Format.