Table of Contents
MySQL supports a number of data types in several categories: numeric types, date and time types, and string (character) types. This chapter first gives an overview of these data types, and then provides a more detailed description of the properties of the types in each category, and a summary of the data type storage requirements. The initial overview is intentionally brief. The more detailed descriptions later in the chapter should be consulted for additional information about particular data types, such as the allowable formats in which you can specify values.
MySQL also supports extensions for handing spatial data. Chapter 16, Spatial Extensions, provides information about these data types.
Several of the data type descriptions use these conventions:
indicates the
maximum display width for integer types. For floating-point and
fixed-point types, M
M
is the total
number of digits. For string types, M
is the maximum length. The maximum allowable value of
M
depends on the data type.
applies to
floating-point and fixed-point types and indicates the number of
digits following the decimal point. The maximum possible value
is 30, but should be no greater than
D
M
–2.
Square brackets (‘[
’ and
‘]
’) indicate optional parts of
type definitions.
A summary of the numeric data types follows. For additional information, see Section 11.2, “Numeric Types”. Storage requirements are given in Section 11.5, “Data Type Storage Requirements”.
M
indicates the maximum display
width. The maximum legal display width is 255. Display width is
unrelated to the storage size or range of values a type can
contain, as described in Section 11.2, “Numeric Types”.
If you specify ZEROFILL
for a numeric column,
MySQL automatically adds the UNSIGNED
attribute to the column.
SERIAL
is an alias for BIGINT
UNSIGNED NOT NULL AUTO_INCREMENT UNIQUE
.
SERIAL DEFAULT VALUE
in the definition of an
integer column is an alias for NOT NULL AUTO_INCREMENT
UNIQUE
.
Warning: When you use
subtraction between integer values where one is of type
UNSIGNED
, the result is unsigned unless the
NO_UNSIGNED_SUBTRACTION
SQL mode is enabled.
See Section 12.8, “Cast Functions and Operators”.
A bit-field type. M
indicates the
number of bits per value, from 1 to 64. The default is 1 if
M
is omitted.
This data type was added in MySQL 5.0.3 for
MyISAM
, and extended in 5.0.5 to
MEMORY
, InnoDB
, and
BDB
. Before 5.0.3, BIT
is a synonym for TINYINT(1)
.
TINYINT[(
M
)] [UNSIGNED]
[ZEROFILL]
A very small integer. The signed range is
-128
to 127
. The
unsigned range is 0
to
255
.
These types are synonyms for TINYINT(1)
.
A value of zero is considered false. Non-zero values are
considered true:
mysql>SELECT IF(0, 'true', 'false');
+------------------------+ | IF(0, 'true', 'false') | +------------------------+ | false | +------------------------+ mysql>SELECT IF(1, 'true', 'false');
+------------------------+ | IF(1, 'true', 'false') | +------------------------+ | true | +------------------------+ mysql>SELECT IF(2, 'true', 'false');
+------------------------+ | IF(2, 'true', 'false') | +------------------------+ | true | +------------------------+
However, the values TRUE
and
FALSE
are merely synonyms for
0
and 1
, respectively,
as shown here:
mysql>SELECT IF(0 = FALSE, 'true', 'false');
+--------------------------------+ | IF(0 = FALSE, 'true', 'false') | +--------------------------------+ | true | +--------------------------------+ mysql>SELECT IF(1 = TRUE, 'true', 'false');
+-------------------------------+ | IF(1 = TRUE, 'true', 'false') | +-------------------------------+ | true | +-------------------------------+ mysql>SELECT IF(2 = TRUE, 'true', 'false');
+-------------------------------+ | IF(2 = TRUE, 'true', 'false') | +-------------------------------+ | false | +-------------------------------+ mysql>SELECT IF(2 = FALSE, 'true', 'false');
+--------------------------------+ | IF(2 = FALSE, 'true', 'false') | +--------------------------------+ | false | +--------------------------------+
The last two statements display the results shown because
2
is equal to neither
1
nor 0
.
We intend to implement full boolean type handling, in accordance with standard SQL, in a future MySQL release.
SMALLINT[(
M
)] [UNSIGNED]
[ZEROFILL]
A small integer. The signed range is
-32768
to 32767
. The
unsigned range is 0
to
65535
.
MEDIUMINT[(
M
)]
[UNSIGNED] [ZEROFILL]
A medium-sized integer. The signed range is
-8388608
to 8388607
.
The unsigned range is 0
to
16777215
.
INT[(
M
)] [UNSIGNED]
[ZEROFILL]
A normal-size integer. The signed range is
-2147483648
to
2147483647
. The unsigned range is
0
to 4294967295
.
INTEGER[(
M
)] [UNSIGNED]
[ZEROFILL]
This type is a synonym for INT
.
BIGINT[(
M
)] [UNSIGNED]
[ZEROFILL]
A large integer. The signed range is
-9223372036854775808
to
9223372036854775807
. The unsigned range
is 0
to
18446744073709551615
.
Some things you should be aware of with respect to
BIGINT
columns:
All arithmetic is done using signed
BIGINT
or DOUBLE
values, so you should not use unsigned big integers
larger than 9223372036854775807
(63
bits) except with bit functions! If you do that, some of
the last digits in the result may be wrong because of
rounding errors when converting a
BIGINT
value to a
DOUBLE
.
MySQL can handle BIGINT
in the
following cases:
When using integers to store large unsigned values
in a BIGINT
column.
In
MIN(
or
col_name
)MAX(
,
where col_name
)col_name
refers to
a BIGINT
column.
When using operators (+
,
-
, *
, and so
on) where both operands are integers.
You can always store an exact integer value in a
BIGINT
column by storing it using a
string. In this case, MySQL performs a string-to-number
conversion that involves no intermediate
double-precision representation.
The -
, +
, and
*
operators use
BIGINT
arithmetic when both operands
are integer values. This means that if you multiply two
big integers (or results from functions that return
integers), you may get unexpected results when the
result is larger than
9223372036854775807
.
FLOAT[(
M
,D
)]
[UNSIGNED] [ZEROFILL]
A small (single-precision) floating-point number. Allowable
values are -3.402823466E+38
to
-1.175494351E-38
, 0
,
and 1.175494351E-38
to
3.402823466E+38
. These are the
theoretical limits, based on the IEEE standard. The actual
range might be slightly smaller depending on your hardware
or operating system.
M
is the total number of decimal
digits and D
is the number of
digits following the decimal point. If
M
and
D
are omitted, values are stored
to the limits allowed by the hardware. A single-precision
floating-point number is accurate to approximately 7 decimal
places.
UNSIGNED
, if specified, disallows
negative values.
Using FLOAT
might give you some
unexpected problems because all calculations in MySQL are
done with double precision. See
Section A.5.7, “Solving Problems with No Matching Rows”.
DOUBLE[(
M
,D
)]
[UNSIGNED] [ZEROFILL]
A normal-size (double-precision) floating-point number.
Allowable values are
-1.7976931348623157E+308
to
-2.2250738585072014E-308
,
0
, and
2.2250738585072014E-308
to
1.7976931348623157E+308
. These are the
theoretical limits, based on the IEEE standard. The actual
range might be slightly smaller depending on your hardware
or operating system.
M
is the total number of decimal
digits and D
is the number of
digits following the decimal point. If
M
and
D
are omitted, values are stored
to the limits allowed by the hardware. A double-precision
floating-point number is accurate to approximately 15
decimal places.
UNSIGNED
, if specified, disallows
negative values.
DOUBLE
PRECISION[(
,
M
,D
)]
[UNSIGNED] [ZEROFILL]REAL[(
M
,D
)]
[UNSIGNED] [ZEROFILL]
These types are synonyms for DOUBLE
.
Exception: If the REAL_AS_FLOAT
SQL mode
is enabled, REAL
is a synonym for
FLOAT
rather than
DOUBLE
.
FLOAT(
p
) [UNSIGNED]
[ZEROFILL]
A floating-point number. p
represents the precision in bits, but MySQL uses this value
only to determine whether to use FLOAT
or
DOUBLE
for the resulting data type. If
p
is from 0 to 24, the data type
becomes FLOAT
with no
M
or D
values. If p
is from 25 to 53,
the data type becomes DOUBLE
with no
M
or D
values. The range of the resulting column is the same as for
the single-precision FLOAT
or
double-precision DOUBLE
data types
described earlier in this section.
DECIMAL[(
M
[,D
])]
[UNSIGNED] [ZEROFILL]
For MySQL 5.0.3 and above:
A packed “exact” fixed-point number.
M
is the total number of decimal
digits (the precision) and D
is
the number of digits after the decimal point (the scale).
The decimal point and (for negative numbers) the
‘-
’ sign are not counted in
M
. If
D
is 0, values have no decimal
point or fractional part. The maximum number of digits
(M
) for
DECIMAL
is 65 (64 from 5.0.3 to 5.0.5).
The maximum number of supported decimals
(D
) is 30. If
D
is omitted, the default is 0.
If M
is omitted, the default is
10.
UNSIGNED
, if specified, disallows
negative values.
All basic calculations (+, -, *, /
) with
DECIMAL
columns are done with a precision
of 65 digits.
Before MySQL 5.0.3:
An unpacked fixed-point number. Behaves like a
CHAR
column; “unpacked”
means the number is stored as a string, using one character
for each digit of the value. M
is
the total number of digits and D
is the number of digits after the decimal point. The decimal
point and (for negative numbers) the
‘-
’ sign are not counted in
M
, although space for them is
reserved. If D
is 0, values have
no decimal point or fractional part. The maximum range of
DECIMAL
values is the same as for
DOUBLE
, but the actual range for a given
DECIMAL
column may be constrained by the
choice of M
and
D
. If
D
is omitted, the default is 0.
If M
is omitted, the default is
10.
UNSIGNED
, if specified, disallows
negative values.
The behavior used by the server for
DECIMAL
columns in a table depends on the
version of MySQL used to create the table. If your server is
from MySQL 5.0.3 or higher, but you have
DECIMAL
columns in tables that were
created before 5.0.3, the old behavior still applies to
those columns. To convert the tables to the newer
DECIMAL
format, dump them with
mysqldump and reload them.
DEC[(
,
M
[,D
])]
[UNSIGNED] [ZEROFILL]NUMERIC[(
,
M
[,D
])]
[UNSIGNED] [ZEROFILL]FIXED[(
M
[,D
])]
[UNSIGNED] [ZEROFILL]
These types are synonyms for DECIMAL
. The
FIXED
synonym is available for
compatibility with other database systems.
A summary of the temporal data types follows. For additional information, see Section 11.3, “Date and Time Types”. Storage requirements are given in Section 11.5, “Data Type Storage Requirements”.
For the DATETIME
and DATE
range descriptions, “supported” means that although
earlier values might work, there is no guarantee.
The SUM()
and AVG()
aggregate functions do not work with temporal values. (They
convert the values to numbers, which loses the part after the
first non-numeric character.) To work around this problem, you
can convert to numeric units, perform the aggregate operation,
and convert back to a temporal value. Examples:
SELECT SEC_TO_TIME(SUM(TIME_TO_SEC(time_col
))) FROMtbl_name
; SELECT FROM_DAYS(SUM(TO_DAYS(date_col
))) FROMtbl_name
;
A date. The supported range is
'1000-01-01'
to
'9999-12-31'
. MySQL displays
DATE
values in
'YYYY-MM-DD'
format, but allows you to
assign values to DATE
columns using
either strings or numbers.
A date and time combination. The supported range is
'1000-01-01 00:00:00'
to
'9999-12-31 23:59:59'
. MySQL displays
DATETIME
values in 'YYYY-MM-DD
HH:MM:SS'
format, but allows you to assign values
to DATETIME
columns using either strings
or numbers.
A timestamp. The range is '1970-01-01
00:00:00'
to partway through the year
2037
.
A TIMESTAMP
column is useful for
recording the date and time of an INSERT
or UPDATE
operation. By default, the
first TIMESTAMP
column in a table is
automatically set to the date and time of the most recent
operation if you do not assign it a value yourself. You can
also set any TIMESTAMP
column to the
current date and time by assigning it a
NULL
value. Variations on automatic
initialization and update properties are described in
Section 11.3.1.1, “TIMESTAMP
Properties as of MySQL 4.1”.
A TIMESTAMP
value is returned as a string
in the format 'YYYY-MM-DD HH:MM:SS'
with
a display width fixed at 19 characters. To obtain the value
as a number, you should add +0
to the
timestamp column.
Note: The
TIMESTAMP
format that was used prior to
MySQL 4.1 is not supported in MySQL 5.0; see
MySQL 3.23, 4.0, 4.1 Reference Manual for information
regarding the old format.
A time. The range is '-838:59:59'
to
'838:59:59'
. MySQL displays
TIME
values in
'HH:MM:SS'
format, but allows you to
assign values to TIME
columns using
either strings or numbers.
A year in two-digit or four-digit format. The default is
four-digit format. In four-digit format, the allowable
values are 1901
to
2155
, and 0000
. In
two-digit format, the allowable values are
70
to 69
, representing
years from 1970 to 2069. MySQL displays
YEAR
values in YYYY
format, but allows you to assign values to
YEAR
columns using either strings or
numbers.
A summary of the string data types follows. For additional information, see Section 11.4, “String Types”. Storage requirements are given in Section 11.5, “Data Type Storage Requirements”.
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 13.1.5.1, “Silent Column Specification Changes”.
In MySQL 4.1 and up, string data types include some features that you may not have encountered in working with versions of MySQL prior to 4.1:
MySQL interprets length specifications in character column
definitions in character units. (Before MySQL 4.1, column
lengths were interpreted in bytes.) This applies to
CHAR
, VARCHAR
, and the
TEXT
types.
Column definitions for many string data types can include
attributes that specify the character set or collation of
the column. These attributes apply to the
CHAR
, VARCHAR
, the
TEXT
types, ENUM
, and
SET
data types:
The CHARACTER SET
attribute specifies
the character set, and the COLLATE
attribute specifies a collation for the the character
set. For example:
CREATE TABLE t ( c1 VARCHAR(20) CHARACTER SET utf8, c2 TEXT CHARACTER SET latin1 COLLATE latin1_general_cs );
This table definition creates a column named
c1
that has a character set of
utf8
with the default collation for
that character set, and a column named
c2
that has a character set of
latin1
and a case-sensitive
collation.
CHARSET
is a synonym for
CHARACTER SET
.
The ASCII
attribute is shorthand for
CHARACTER SET latin1
.
The UNICODE
attribute is shorthand
for CHARACTER SET ucs2
.
The BINARY
attribute is shorthand for
specifying the binary collation of the column character
set. In this case, sorting and comparison are based on
numeric character values. (Before MySQL 4.1,
BINARY
caused a column to store
binary strings and sorting and comparison were based on
numeric byte values. This is the same as using character
values for single-byte character sets, but not for
multi-byte character sets.)
Character column sorting and comparison are based on the
character set assigned to the column. (Before MySQL 4.1,
sorting and comparison were based on the collation of the
server character set.) For the CHAR
,
VARCHAR
, TEXT
,
ENUM
, and SET
data
types, you can declare a column with a binary collation or
the BINARY
attribute to cause sorting and
comparison to use the underlying character code values
rather than a lexical ordering.
Chapter 10, Character Set Support, provides additional information about use of character sets in MySQL.
[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.
M
represents the column length.
The range of M
is 0 to 255
characters.
Note: Trailing spaces are
removed when CHAR
values are retrieved.
Before MySQL 5.0.3, a CHAR
column with a
length specification greater than 255 is converted to the
smallest TEXT
type that can hold values
of the given length. For example,
CHAR(500)
is converted to
TEXT
, and CHAR(200000)
is converted to MEDIUMTEXT
. This is a
compatibility feature. However, this conversion causes the
column to become a variable-length column, and also affects
trailing-space removal.
In MySQL 5.0.3 and later, if you attempt to set the length
of a CHAR
greater than 255, the
CREATE TABLE
or ALTER
TABLE
statement in which this is done fails with
an error:
mysql>CREATE TABLE c1 (col1 INT, col2 CHAR(500));
ERROR 1074 (42000): Column length too big for column 'col' (max = 255); use BLOB or TEXT instead mysql>SHOW CREATE TABLE c1;
ERROR 1146 (42S02): Table 'test.c1' doesn't exist
CHAR
is shorthand for
CHARACTER
. NATIONAL
CHAR
(or its equivalent short form,
NCHAR
) is the standard SQL way to define
that a CHAR
column should use some
predefined character set. MySQL 4.1 and up uses
utf8
as this predefined character set.
Section 10.3.6, “National Character Set”.
The CHAR BYTE
data type is an alias for
the BINARY
data type. This is a
compatibility feature.
MySQL allows you to create a column of type
CHAR(0)
. This is useful primarily when
you have to 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) NULL
occupies only one bit and can take only the values
NULL
and ''
(the empty
string).
CHAR [CHARACTER SET
charset_name
] [COLLATE
collation_name
]
This type is a synonym for CHAR(1)
.
[NATIONAL] VARCHAR(
M
)
[CHARACTER SET charset_name
]
[COLLATE
collation_name
]
A variable-length string. M
represents the maximum column length. In MySQL
5.0, the range of M
is 0 to 255 before MySQL 5.0.3, and 0 to 65,535 in MySQL
5.0.3 and later. (The actual maximum length of a
VARCHAR
in MySQL 5.0 is determined by the
maximum row size and the character set you use. The maximum
effective length starting with MySQL
5.0.3 is 65,532 bytes.)
Note: Before 5.0.3,
trailing spaces were removed when VARCHAR
values were stored, which differs from the standard SQL
specification.
Prior to MySQL 5.0.3, a VARCHAR
column
with a length specification greater than 255 was converted
to the smallest TEXT
type that could hold
values of the given length. For example,
VARCHAR(500)
was converted to
TEXT
, and
VARCHAR(200000)
was converted to
MEDIUMTEXT
. This was a compatibility
feature. However, this conversion affected trailing-space
removal.
VARCHAR
is shorthand for
CHARACTER VARYING
.
VARCHAR
values are stored using as many
characters as are needed, plus one byte to record the length
(two bytes for columns that are declared with a length
longer than 255).
The BINARY
type is similar to the
CHAR
type, but stores binary byte strings
rather than non-binary character strings.
The VARBINARY
type is similar to the
VARCHAR
type, but stores binary byte
strings rather than non-binary character strings.
A BLOB
column with a maximum length of
255 (28 – 1) bytes.
TINYTEXT [CHARACTER SET
charset_name
] [COLLATE
collation_name
]
A TEXT
column with a maximum length of
255 (28 – 1) characters.
A BLOB
column with a maximum length of
65,535 (216 – 1) bytes.
An optional length M
can be given
for this type. If this is done, MySQL creates the column as
the smallest BLOB
type large enough to
hold values M
bytes long.
TEXT[(
M
)] [CHARACTER SET
charset_name
] [COLLATE
collation_name
]
A TEXT
column with a maximum length of
65,535 (216 – 1)
characters.
An optional length M
can be given
for this type. If this is done, MySQL creates the column as
the smallest TEXT
type large enough to
hold values M
characters long.
A BLOB
column with a maximum length of
16,777,215 (224 – 1) bytes.
MEDIUMTEXT [CHARACTER SET
charset_name
] [COLLATE
collation_name
]
A TEXT
column with a maximum length of
16,777,215 (224 – 1)
characters.
A BLOB
column with a maximum length of
4,294,967,295 or 4GB (232 –
1) bytes. The maximum effective
(permitted) length of LONGBLOB
columns
depends on the configured maximum packet size in the
client/server protocol and available memory.
LONGTEXT [CHARACTER SET
charset_name
] [COLLATE
collation_name
]
A TEXT
column with a maximum length of
4,294,967,295 or 4GB (232 –
1) characters. The maximum effective
(permitted) length of LONGTEXT
columns
depends on the configured maximum packet size in the
client/server protocol and available memory.
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
'...
, NULL
or the
special ''
error value. An
ENUM
column can have a maximum of 65,535
distinct values. ENUM
values are
represented internally as integers.
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
'...
A SET
column can
have a maximum of 64 members. SET
values
are represented internally as integers.
The DEFAULT
clause in a data type specification indicates a default value
for a column. With one exception, the default value must be a
constant; it cannot be a function or an expression. This means,
for example, that you cannot set the default for a date column
to be the value of a function such as value
NOW()
or CURRENT_DATE
. The exception is that you
can specify CURRENT_TIMESTAMP
as the default
for a TIMESTAMP
column. See
Section 11.3.1.1, “TIMESTAMP
Properties as of MySQL 4.1”.
Prior to MySQL 5.0.2, if a column definition includes no
explicit DEFAULT
value, MySQL determines the
default value as follows:
If the column can take NULL
as a value, the
column is defined with an explicit DEFAULT
NULL
clause.
If the column cannot take NULL
as the value,
MySQL defines the column with an explicit
DEFAULT
clause, using the implicit default
value for the column data type. Implicit defaults are defined as
follows:
For numeric types other than integer types declared with the
AUTO_INCREMENT
attribute, the default is
0
. For an
AUTO_INCREMENT
column, the default value
is the next value in the sequence.
For date and time types other than
TIMESTAMP
, the default is the appropriate
“zero” value for the type. For the first
TIMESTAMP
column in a table, the default
value is the current date and time. See
Section 11.3, “Date and Time Types”.
For string types other than ENUM
, the
default value is the empty string. For
ENUM
, the default is the first
enumeration value.
BLOB
and TEXT
columns
cannot be assigned a default value.
As of MySQL 5.0.2, if a column definition includes no explicit
DEFAULT
value, MySQL determines the default
value as follows:
If the column can take NULL
as a value, the
column is defined with an explicit DEFAULT
NULL
clause. This is the same as before 5.0.2.
If the column cannot take NULL
as the value,
MySQL defines the column with no explicit
DEFAULT
clause. For data entry, if an
INSERT
or REPLACE
statement includes no value for the column, MySQL handles the
column according to the SQL mode in effect at the time:
If strict SQL mode is not enabled, MySQL sets the column to the implicit default value for the column data type.
If strict mode is enabled, an error occurs for transactional tables and the statement is rolled back. For non-transactional tables, an error occurs, but if this happens for the second or subsequent row of a multiple-row statement, the preceding rows will have been inserted.
Suppose that a table t
is defined as follows:
CREATE TABLE t (i INT NOT NULL);
In this case, i
has no explicit default, so
in strict mode each of the following statements produce an error
and no row is inserted. When not using strict mode, only the
third statement produces an error; the implicit default is
inserted for the first two statements, but the third fails
because DEFAULT(i)
cannot produce a value:
INSERT INTO t VALUES(); INSERT INTO t VALUES(DEFAULT); INSERT INTO t VALUES(DEFAULT(i));
See Section 5.2.5, “The Server SQL Mode”.
For a given table, you can use the SHOW CREATE
TABLE
statement to see which columns have an explicit
DEFAULT
clause.