The string data types are CHAR,
        VARCHAR,
        BINARY,
        VARBINARY,
        BLOB,
        TEXT,
        ENUM, and
        SET.
      
        In some cases, MySQL may change a string column to a type
        different from that given in a CREATE
        TABLE or ALTER TABLE
        statement. See Section 15.1.20.7, “Silent Column Specification Changes”.
      
        For definitions of character string columns
        (CHAR,
        VARCHAR, and the
        TEXT types), MySQL interprets
        length specifications in character units. For definitions of
        binary string columns (BINARY,
        VARBINARY, and the
        BLOB types), MySQL interprets
        length specifications in byte units.
      
        Column definitions for character string data types
        CHAR,
        VARCHAR, the
        TEXT types,
        ENUM,
        SET, and any synonyms) can
        specify the column character set and collation:
- CHARACTER SETspecifies the character set. If desired, a collation for the character set can be specified with the- COLLATEattribute, along with any other attributes. For example:- CREATE TABLE t ( c1 VARCHAR(20) CHARACTER SET utf8mb4, c2 TEXT CHARACTER SET latin1 COLLATE latin1_general_cs );- This table definition creates a column named - c1that has a character set of- utf8mb4with the default collation for that character set, and a column named- c2that has a character set of- latin1and a case-sensitive (- _cs) collation.- The rules for assigning the character set and collation when either or both of - CHARACTER SETand the- COLLATEattribute are missing are described in Section 12.3.5, “Column Character Set and Collation”.- CHARSETis a synonym for- CHARACTER SET.
- Specifying the - CHARACTER SET binaryattribute for a character string data type causes the column to be created as the corresponding binary string data type:- CHARbecomes- BINARY,- VARCHARbecomes- VARBINARY, and- TEXTbecomes- BLOB. For the- ENUMand- SETdata types, this does not occur; they are created as declared. Suppose that you specify a table using this definition:- CREATE TABLE t ( c1 VARCHAR(10) CHARACTER SET binary, c2 TEXT CHARACTER SET binary, c3 ENUM('a','b','c') CHARACTER SET binary );- The resulting table has this definition: - CREATE TABLE t ( c1 VARBINARY(10), c2 BLOB, c3 ENUM('a','b','c') CHARACTER SET binary );
- The - BINARYattribute is a nonstandard MySQL extension that is shorthand for specifying the binary (- _bin) collation of the column character set (or of the table default character set if no column character set is specified). In this case, comparison and sorting are based on numeric character code values. Suppose that you specify a table using this definition:- CREATE TABLE t ( c1 VARCHAR(10) CHARACTER SET latin1 BINARY, c2 TEXT BINARY ) CHARACTER SET utf8mb4;- The resulting table has this definition: - CREATE TABLE t ( c1 VARCHAR(10) CHARACTER SET latin1 COLLATE latin1_bin, c2 TEXT CHARACTER SET utf8mb4 COLLATE utf8mb4_bin ) CHARACTER SET utf8mb4;- In MySQL 9.0, the - BINARYattribute is deprecated and you should expect support for it to be removed in a future version of MySQL. Applications should be adjusted to use an explicit- _bincollation instead.- The use of - BINARYto specify a data type or character set remains unchanged.
- The - ASCIIattribute is shorthand for- CHARACTER SET latin1. Supported in older MySQL releases,- ASCIIis deprecated; use- CHARACTER SETinstead.
- The - UNICODEattribute is shorthand for- CHARACTER SET ucs2. Supported in older MySQL releases,- UNICODEis deprecated; use- CHARACTER SETinstead.
        Character column comparison and sorting are based on the
        collation assigned to the column. For the
        CHAR,
        VARCHAR,
        TEXT,
        ENUM, and
        SET data types, you can declare a
        column with a binary (_bin) collation or the
        BINARY attribute to cause comparison and
        sorting to use the underlying character code values rather than
        a lexical ordering.
      
For additional information about use of character sets in MySQL, see Chapter 12, Character Sets, Collations, Unicode.
- [NATIONAL] CHAR[(- M)] [CHARACTER SET- charset_name] [COLLATE- collation_name]- A fixed-length string that is always right-padded with spaces to the specified length when stored. - Mrepresents the column length in characters. The range of- Mis 0 to 255. If- Mis omitted, the length is 1.Note- Trailing spaces are removed when - CHARvalues are retrieved unless the- PAD_CHAR_TO_FULL_LENGTHSQL mode is enabled.- CHARis shorthand for- CHARACTER.- NATIONAL CHAR(or its equivalent short form,- NCHAR) is the standard SQL way to define that a- CHARcolumn should use some predefined character set. MySQL uses- utf8mb3as this predefined character set. Section 12.3.7, “The National Character Set”.- The - CHAR BYTEdata type is an alias for the- BINARYdata type. This is a compatibility feature.- MySQL permits you to create a column of type - CHAR(0). This is useful primarily when you must be compliant with old applications that depend on the existence of a column but that do not actually use its value.- CHAR(0)is also quite nice when you need a column that can take only two values: A column that is defined as- CHAR(0) NULLoccupies only one bit and can take only the values- NULLand- ''(the empty string).
- [NATIONAL] VARCHAR(- M) [CHARACTER SET- charset_name] [COLLATE- collation_name]- A variable-length string. - Mrepresents the maximum column length in characters. The range of- Mis 0 to 65,535. The effective maximum length of a- VARCHARis subject to the maximum row size (65,535 bytes, which is shared among all columns) and the character set used. For example,- utf8mb3characters can require up to three bytes per character, so a- VARCHARcolumn that uses the- utf8mb3character set can be declared to be a maximum of 21,844 characters. See Section 10.4.7, “Limits on Table Column Count and Row Size”.- MySQL stores - VARCHARvalues as a 1-byte or 2-byte length prefix plus data. The length prefix indicates the number of bytes in the value. A- VARCHARcolumn uses one length byte if values require no more than 255 bytes, two length bytes if values may require more than 255 bytes.Note- MySQL follows the standard SQL specification, and does not remove trailing spaces from - VARCHARvalues.- VARCHARis shorthand for- CHARACTER VARYING.- NATIONAL VARCHARis the standard SQL way to define that a- VARCHARcolumn should use some predefined character set. MySQL uses- utf8mb3as this predefined character set. Section 12.3.7, “The National Character Set”.- NVARCHARis shorthand for- NATIONAL VARCHAR.
- The - BINARYtype is similar to the- CHARtype, but stores binary byte strings rather than nonbinary character strings. An optional length- Mrepresents the column length in bytes. If omitted,- Mdefaults to 1.
- The - VARBINARYtype is similar to the- VARCHARtype, but stores binary byte strings rather than nonbinary character strings.- Mrepresents the maximum column length in bytes.
- A - BLOBcolumn with a maximum length of 255 (28 − 1) bytes. Each- TINYBLOBvalue is stored using a 1-byte length prefix that indicates the number of bytes in the value.
- TINYTEXT [CHARACTER SET- charset_name] [COLLATE- collation_name]- A - TEXTcolumn with a maximum length of 255 (28 − 1) characters. The effective maximum length is less if the value contains multibyte characters. Each- TINYTEXTvalue is stored using a 1-byte length prefix that indicates the number of bytes in the value.
- A - BLOBcolumn with a maximum length of 65,535 (216 − 1) bytes. Each- BLOBvalue is stored using a 2-byte length prefix that indicates the number of bytes in the value.- An optional length - Mcan be given for this type. If this is done, MySQL creates the column as the smallest- BLOBtype large enough to hold values- Mbytes long.
- TEXT[(- M)] [CHARACTER SET- charset_name] [COLLATE- collation_name]- A - TEXTcolumn with a maximum length of 65,535 (216 − 1) characters. The effective maximum length is less if the value contains multibyte characters. Each- TEXTvalue is stored using a 2-byte length prefix that indicates the number of bytes in the value.- An optional length - Mcan be given for this type. If this is done, MySQL creates the column as the smallest- TEXTtype large enough to hold values- Mcharacters long.
- A - BLOBcolumn with a maximum length of 16,777,215 (224 − 1) bytes. Each- MEDIUMBLOBvalue is stored using a 3-byte length prefix that indicates the number of bytes in the value.
- MEDIUMTEXT [CHARACTER SET- charset_name] [COLLATE- collation_name]- A - TEXTcolumn with a maximum length of 16,777,215 (224 − 1) characters. The effective maximum length is less if the value contains multibyte characters. Each- MEDIUMTEXTvalue is stored using a 3-byte length prefix that indicates the number of bytes in the value.
- A - BLOBcolumn with a maximum length of 4,294,967,295 or 4GB (232 − 1) bytes. The effective maximum length of- LONGBLOBcolumns depends on the configured maximum packet size in the client/server protocol and available memory. Each- LONGBLOBvalue is stored using a 4-byte length prefix that indicates the number of bytes in the value.
- LONGTEXT [CHARACTER SET- charset_name] [COLLATE- collation_name]- A - TEXTcolumn with a maximum length of 4,294,967,295 or 4GB (232 − 1) characters. The effective maximum length is less if the value contains multibyte characters. The effective maximum length of- LONGTEXTcolumns also depends on the configured maximum packet size in the client/server protocol and available memory. Each- LONGTEXTvalue is stored using a 4-byte length prefix that indicates the number of bytes in the value.
- ENUM('- value1','- value2',...) [CHARACTER SET- charset_name] [COLLATE- collation_name]- An enumeration. A string object that can have only one value, chosen from the list of values - ',- value1'- ',- value2'- ...,- NULLor the special- ''error value.- ENUMvalues are represented internally as integers.- An - ENUMcolumn can have a maximum of 65,535 distinct elements.- The maximum supported length of an individual - ENUMelement is- M<= 255 and (- Mx- w) <= 1020, where- Mis the element literal length and- wis the number of bytes required for the maximum-length character in the character set.
- SET('- value1','- value2',...) [CHARACTER SET- charset_name] [COLLATE- collation_name]- A set. A string object that can have zero or more values, each of which must be chosen from the list of values - ',- value1'- ',- value2'- ...- SETvalues are represented internally as integers.- A - SETcolumn can have a maximum of 64 distinct members.- The maximum supported length of an individual - SETelement is- M<= 255 and (- Mx- w) <= 1020, where- Mis the element literal length and- wis the number of bytes required for the maximum-length character in the character set.