Other Types
On this page
Data Type |
Size |
Size (Not Null) |
Max cardinality |
Max values per row |
---|---|---|---|---|
ENUM |
4 bytes |
2 bytes |
65,535 unique values |
1 |
SET |
12 bytes |
8 bytes |
64 unique values |
64 |
BIT |
9 bytes |
8 bytes |
Using the ENUM Data Type
An ENUM
is a string value chosen from a user-defined list of values that are specified when creating a table.ENUM
list must be quoted strings, which are distinct from others in the list.ENUM
using the following syntax:
CREATE TABLE table_name (---col_name ENUM('val1','val2',...,'valN'))
The values in an ENUM
list are indexed, starting from 1
.ENUM('Primary','Secondary','Tertiary')
.
Value |
Index |
---|---|
|
|
'' |
0 |
'Primary' |
1 |
'Secondary' |
2 |
'Tertiary' |
3 |
The index of a NULL
value is NULL
.0
.ENUM
value assignments:
SELECT ...WHERE enum_column = 0;
Important
The index of any ENUM
value denotes its position in the list of values.
ENUM
values cannot be expressions or user-defined variables.ENUM
values are sorted based on their index values.NULL
values are sorted first, then the empty strings (with index 0
), followed by the values in the ENUM
list.
The following example shows how ENUM
values are defined and used.
CREATE ROWSTORE TABLE delivery_status(ID VARCHAR(6),Status ENUM('NOT_DISPATCHED','IN_TRANSIT','DELIVERED'));INSERT INTO delivery_status VALUES('xdy',1);INSERT INTO delivery_status VALUES('tsg','IN_TRANSIT');INSERT INTO delivery_status (ID) VALUES('qfc');SELECT * FROM delivery_status ORDER BY Status ASC;
+------+----------------+
| ID | Status |
+------+----------------+
| qfc | NULL |
| xdy | NOT_DISPATCHED |
| tsg | IN_TRANSIT |
+------+----------------+
This example shows that if an integer values is specified, the ENUM
value at that index is inserted.NOT NULL
constraint was not applied on the column, the default value inserted is NULL
.
Additional ENUM
values can be added or modified to an existing rowstore table using the ALTER TABLE
command.ENUM
values "NOT_
ALTER TABLE delivery_status MODIFY Status ENUM ('NOT_DISPATCHED','IN_TRANSIT','DELIVERED','NOT_SHIPPED','RETURNED');
SHOW CREATE TABLE delivery_status;
+-----------------+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+
| Table | Create Table |
+-----------------+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+
| delivery_status | CREATE ROWSTORE TABLE `delivery_status` ( `ID` varchar(3) CHARACTER SET utf8 COLLATE utf8_general_ci DEFAULT NULL, `Status` enum('NOT_DISPATCHED','IN_TRANSIT','DELIVERED','NOT_SHIPPED','RETURNED') CHARACTER SET utf8 COLLATE utf8_general_ci DEFAULT NULL , SHARD KEY () ) AUTOSTATS_CARDINALITY_MODE=PERIODIC AUTOSTATS_HISTOGRAM_MODE=CREATE SQL_MODE='STRICT_ALL_TABLES' |
+-----------------+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+
Creating an index on an ENUM
column on columnstore tables is not supported.ENUM
values via the ALTER TABLE
command on columnstore tables is also not supported because the column segments would need to be re-encoded.
To add ENUM
values in a columnstore table, there are a couple of workarounds that must be processed offline.ENUM
values "NOT_
-
Create a new table with the updated
ENUM
values, copy the old table to the new table, drop the old table, and rename the new table with the dropped table's name:-- Existing columnstore tableCREATE TABLE delivery_status(ID VARCHAR(6),Status ENUM('NOT_DISPATCHED','IN_TRANSIT','DELIVERED'));-- Create a new table and add values to the ENUM columnCREATE TABLE delivery_status_1(ID VARCHAR(6),Status ENUM('NOT_DISPATCHED','IN_TRANSIT','DELIVERED','NOT_SHIPPED','RETURNED'));-- Copy the old table to the new table and check to see if the data is correctINSERT INTO delivery_status_1(SELECT * FROM delivery_status);SELECT * FROM delivery_status_1;-- Once you are sure the data from the old table has been copied correctly, drop the old tableDROP TABLE delivery_status;-- Rename the new table with dropped table's nameALTER TABLE delivery_status_1 RENAME TO delivery_status;If the new
ENUM
values are not correct after copying the data from the old table to the new table, drop the new table (e.g. , delivery_
) and repeat the process from the previous code block.status_ 1 DROP TABLE delivery_status_1; -
Add a new column with the updated
ENUM
values, copy over the values from the oldENUM
column to the newENUM
column, drop the oldENUM
column, and rename the newENUM
column with the droppedENUM
column's name:-- Existing columnstore tableCREATE TABLE delivery_status(ID VARCHAR(6),Status ENUM('NOT_DISPATCHED','IN_TRANSIT','DELIVERED'));-- Add a new column with updated ENUM valuesALTER TABLE delivery_status ADD COLUMN Status1 ENUM ('NOT_DISPATCHED','IN_TRANSIT','DELIVERED','NOT_SHIPPED','RETURNED');-- Copy values from the old column to the new column and check table to see if the data is correctUPDATE delivery_status SET Status = Status1;SELECT * FROM delivery_status;-- Once you are sure the data from the old column have been copied correctly, drop the old columnALTER TABLE delivery_status DROP COLUMN Status;-- Rename the new column with the dropped column's nameALTER TABLE delivery_status CHANGE Status1 Status;If the new
ENUM
values are not correct after copying the data from the old column to the new column, drop the new column (e.g. , Status1
) and repeat the process from the previous code block.ALTER TABLE delivery_status DROP COLUMN Status1;
Using the SET Data Type
The SET data type restricts the values that can be inserted for a table column, and can have zero or more string values.
A SET column value can contain multiple set members, separated by commas.
-
the SET member values should not individually contain commas.
-
the SET member values can be inserted in any order.
The results are retrieved in the same order as listed at the time of table creation. -
even if a SET member value is repeated, the results display the value only once.
The following example displays the usage of the SET data type:
Create a table column with SET data type.
CREATE TABLE setexample (col SET('v1', 'v2', 'v3', 'v4'));
Insert column values as v1,v2
, v2,v1
, v1,v4,v4
, and v3,v4,v3
.
INSERT INTO setexample (col) VALUES ('v1,v2'), ('v2,v1'), ('v1,v4,v4'), ('v3,v4,v3');
The result is retrieved in the same order in which the SET member values were listed during table creation and duplicate values are ignored:
SELECT col FROM setexample;
+------------------------------+
| col |
+------------------------------+
| v1,v2 |
| v1,v2 |
| v1,v4 |
| v3,v4 |
+------------------------------+
Using the BIT Data Type
The BIT
data type is used to represent bit vectors.0
s and 1
s.BIT(n)
can store n
-bit values, where n
can range from 1
to 64
.BIT
type column is not 64
.
Bit-Value Literals
The BIT
data type can also be used to store and represent bit-value literals.BIT
value.
-
b'101'
orB'101'
- the leadingb
is case-insensitive -
0b101
- the leading0b
is case-sensitive
If you assign a value that is less than n
bits long, the value is left-padded with 0
s.b'1100'
to a BIT(7)
column type, the assigned value is b'0001100'
.
Examples
The following example shows that bit-value literals are stored as binary strings.
SELECT b'1100101' AS 'String Value', CHARSET(b'1100101') AS 'Charset';
+--------------+---------+
| String Value | Charset |
+--------------+---------+
| e | binary |
+--------------+---------+
The following example shows how bit-value literals behave as integers in a numerical expression.
SELECT b'1100101' + 9;
+----------------+
| b'1100101' + 9 |
+----------------+
| 110 |
+----------------+
Last modified: May 29, 2024