Generated columns can be virtual or persistent (stored).
MariaDB's generated columns syntax is designed to be similar to the syntax for Microsoft SQL Server's computed columns and Oracle Database's virtual columns. The syntax is also compatible with the syntax for MySQL's generated columns.
MariaDB's generated columns syntax is designed to be similar to the syntax for Microsoft SQL Server's computed columns and Oracle Database's virtual columns. The syntax is not compatible with the syntax for MySQL's generated columns.
A generated column is a column in a table that cannot explicitly be set to a specific value in a . Instead, its value is automatically generated based on an expression. This expression might generate the value based on the values of other columns in the table, or it might generate the value by calling or .
There are two types of generated columns:
PERSISTENT (a.k.a. STORED): This type's value is actually stored in the table.
VIRTUAL: This type's value is not stored at all. Instead, the value is generated dynamically when the table is queried. This type is the default.
Generated columns are also sometimes called computed columns or virtual columns.
Generated columns can only be used with storage engines which support them. If you try to use a storage engine that does not support them, then you will see an error similar to the following:
, , and support generated columns.
A column in a table can be built on a PERSISTENT generated column.
However, a column in a MERGE table can not be defined as a VIRTUAL and PERSISTENT generated column.
All data types are supported when defining generated columns.
Using the column option is supported when defining generated columns.
Using the column option is not supported when defining generated columns.
Using the column option is supported when defining generated columns.
It does not work correctly, though. See .
Using a generated column as a table's primary key is not supported. See for more information. If you try to use one as a primary key, then you will see an error similar to the following:
Using PERSISTENT generated columns as part of a is supported.
Referencing PERSISTENT generated columns as part of a is also supported.
However, using the ON UPDATE CASCADE, ON UPDATE SET NULL, or ON DELETE SET NULL clauses is not supported. If you try to use an unsupported clause, then you will see an error similar to the following:
Defining indexes on both VIRTUAL and PERSISTENT generated columns is supported.
If an index is defined on a generated column, then the optimizer considers using it in the same way as indexes based on "real" columns.
The optimizer can recognize use of indexed virtual column expressions in the WHERE clause and use them to construct range and ref(const) accesses. See .
The optimizer cannot recognize use of indexed virtual column expressions in the WHERE clause and use them to construct range and ref(const) accesses. See .
Generated columns are used in just as if they were "real" columns.
However, VIRTUAL and PERSISTENT generated columns differ in how their data is stored.
Values for PERSISTENT generated columns are generated whenever a inserts or updates the row with the special DEFAULT value. This generates the columns value, and it is stored in the table like the other "real" columns. This value can be read by other just like the other "real" columns.
The statement supports generated columns.
Generated columns can be referenced in the , , and statements.
However, VIRTUAL or PERSISTENT generated columns cannot be explicitly set to any other values than NULL or . If a generated column is explicitly set to any other value, then the outcome depends on whether is enabled in . If it is not enabled, then a warning will be raised and the default generated value will be used instead. If it is enabled, then an error will be raised instead.
The statement has limited support for generated columns.
It supports defining generated columns in a new table.
It supports using generated columns to .
It does not support using the with generated columns.
The statement has limited support for generated columns.
It supports the MODIFY and CHANGE clauses for PERSISTENT generated columns.
It does not support the MODIFY clause for VIRTUAL generated columns if is not set to COPY. See for more information.
The statement supports generated columns.
The statement can be used to check whether a table has generated columns.
You can tell which columns are generated by looking for the ones where the Extra column is set to either VIRTUAL or PERSISTENT. For example:
Generated columns can be properly referenced in the NEW and OLD rows in .
support generated columns.
The statement supports generated columns.
Most legal, deterministic expressions which can be calculated are supported in expressions for generated columns.
Most are supported in expressions for generated columns.
However, some can't be supported for technical reasons. For example, If you try to use an unsupported function in an expression, an error is generated similar to the following:
are not supported in expressions for generated columns because the underlying data can change.
Using anything that depends on data outside the row is not supported in expressions for generated columns.
are not supported in expressions for generated columns. See for more information.
Non-deterministic are supported in expressions for not indexed VIRTUAL generated columns.
Non-deterministic are not supported in expressions for PERSISTENT or indexed VIRTUAL generated columns.
are supported in expressions for generated columns.
However, MariaDB can't check whether a UDF is deterministic, so it is up to the user to be sure that they do not use non-deterministic UDFs with VIRTUAL generated columns.
Defining a generated column based on other generated columns defined before it in the table definition is supported. For example:
However, defining a generated column based on other generated columns defined after in the table definition is not supported in expressions for generation columns because generated columns are calculated in the order they are defined.
Using an expression that exceeds 255 characters in length is supported in expressions for generated columns. The new limit for the entire table definition, including all expressions for generated columns, is 65,535 bytes.
Using constant expressions is supported in expressions for generated columns. For example:
When a generated column is PERSISTENT or indexed, the value of the expression needs to be consistent regardless of the flags in the current session. If it is not, then the table will be seen as corrupted when the value that should actually be returned by the computed expression and the value that was previously stored and/or indexed using a different setting disagree.
There are currently two affected classes of inconsistencies: character padding and unsigned subtraction:
For a VARCHAR or TEXT generated column the length of the value returned can vary depending on the PAD_CHAR_TO_FULL_LENGTH flag. To make the value consistent, create the generated column using an RTRIM() or RPAD() function. Alternately, create the generated column as a CHAR column so that its data is always fully padded.
If a SIGNED generated column is based on the subtraction of an UNSIGNED value, the resulting value can vary depending on how large the value is and the NO_UNSIGNED_SUBTRACTION flag. To make the value consistent, use to ensure that each UNSIGNED
A fatal error is generated when trying to create a generated column whose value can change depending on the when its data is PERSISTENT or indexed. For an existing generated column that has a potentially inconsistent value, a warning about a bad expression is generated the first time it is used (if warnings are enabled).
For an existing generated column that has a potentially inconsistent value, a warning about a bad expression is generated the first time it is used (if warnings are enabled).
A potentially inconsistent generated column outputs a warning when created or first used (without restricting the creation).
A potentially inconsistent generated column does not output a warning when created or first used.
Here is an example of two tables that are warned about:
The warnings look like this:
To work around the issue, force the padding or type to make the generated column's expression return a consistent value. For example:
Here is an example of two tables whose creation is rejected:
The STORED keyword is supported as an alias for the PERSISTENT keyword.
Tables created with MySQL 5.7 or later that contain can be imported into MariaDB without a dump and restore.
Generated columns are subject to various constraints in other DBMSs that are not present in MariaDB's implementation. Generated columns may also be called computed columns or virtual columns in different implementations. The various details for a specific implementation can be found in the documentation for each specific DBMS.
MariaDB's generated columns implementation does not enforce the following restrictions that are present in implementation:
MariaDB allows in generated column expressions, including those that change dynamically, such as .
MariaDB allows the function to be called with a named as an argument, even though time zone names and time offsets are configurable.
MariaDB allows the function to be used with non-unicode , even though character sets are configurable and differ between binaries/versions.
Microsoft SQL Server enforces the above restrictions by doing one of the following things:
Refusing to create computed columns.
Refusing to allow updates to a table containing them.
Refusing to use an index over such a column if it can not be guaranteed that the expression is fully deterministic.
In MariaDB, as long as the , language, and other settings that were in effect during the CREATE TABLE remain unchanged, the generated column expression will always be evaluated the same. If any of these things change, then please be aware that the generated column expression might not be evaluated the same way as it previously was.
If you try to update a virtual column, you will get an error if the default is enabled in , or a warning otherwise.
Generated columns was originally developed by Andrey Zhakov. It was then modified by Sanja Byelkin and Igor Babaev at Monty Program for inclusion in MariaDB. Monty did the work on to lift some of the limitations.
Here is an example table that uses both VIRTUAL andPERSISTENT virtual columns:
If you describe the table, you can easily see which columns are virtual by looking in the "Extra" column:
To find out what function(s) generate the value of the virtual column you can use SHOW CREATE TABLE:
If you try to insert non-default values into a virtual column, you will receive a warning and what you tried to insert will be ignored and the derived value inserted instead:
If the ZEROFILL clause is specified, it should be placed directly after the type definition, before the AS (<expression>):
You can also use virtual columns to implement a "poor man's partial index". See example at the end of .
on the mariadb.com blog.
This page is licensed: CC BY-SA / Gnu FDL
<type> [GENERATED ALWAYS] AS ( <expression> )
[VIRTUAL | PERSISTENT | STORED] [UNIQUE] [UNIQUE KEY] [COMMENT <text>]VIRTUAL generated columns are not stored in the table. Instead, the value is generated dynamically whenever the column is queried. If other columns in a row are queried, but the VIRTUAL generated column is not one of the queried columns, then the column's value is not generated.It does not support the CHANGE clause for VIRTUAL generated columns if ALGORITHM is not set to COPY. See MDEV-17035 for more information.
It does not support altering a table if ALGORITHM is not set to COPY if the table has a VIRTUAL generated column that is indexed. See MDEV-14046 for more information.
It does not support adding a VIRTUAL generated column with the ADD clause if the same statement is also adding other columns if ALGORITHM is not set to COPY. See MDEV-17468 for more information.
It also does not support altering an existing column into a VIRTUAL generated column.
It supports using generated columns to partition tables.
It does not support using the versioning clauses with generated columns.
SIGNEDMicrosoft SQL Server requires the ARITHABORT mode to be set, so that division by zero returns an error, and not a NULL.
ERROR 1910 (HY000): TokuDB storage engine does not support computed columnsERROR 1903 (HY000): Primary key cannot be defined upon a computed columnERROR 1905 (HY000): Cannot define foreign key with ON UPDATE SET NULL clause on a computed columnDESCRIBE table1;
+-------+-------------+------+-----+---------+------------+
| Field | Type | Null | Key | Default | Extra |
+-------+-------------+------+-----+---------+------------+
| a | int(11) | NO | | NULL | |
| b | varchar(32) | YES | | NULL | |
| c | int(11) | YES | | NULL | VIRTUAL |
| d | varchar(5) | YES | | NULL | PERSISTENT |
+-------+-------------+------+-----+---------+------------+ERROR 1901 (HY000): Function or expression 'dayname()' cannot be used in the GENERATED ALWAYS AS clause of `v`CREATE TABLE t1 (a INT AS (1), b INT AS (a));CREATE TABLE t1 (a int as (1));CREATE TABLE bad_pad (
txt CHAR(5),
-- CHAR -> VARCHAR or CHAR -> TEXT can't be persistent or indexed:
vtxt VARCHAR(5) AS (txt) PERSISTENT
);
CREATE TABLE bad_sub (
num1 BIGINT UNSIGNED,
num2 BIGINT UNSIGNED,
-- The resulting value can vary for some large values
vnum BIGINT AS (num1 - num2) VIRTUAL,
KEY(vnum)
);Warning (Code 1901): Function or expression '`txt`' cannot be used in the GENERATED ALWAYS AS clause of `vtxt`
Warning (Code 1105): Expression depends on the @@sql_mode value PAD_CHAR_TO_FULL_LENGTH
Warning (Code 1901): Function or expression '`num1` - `num2`' cannot be used in the GENERATED ALWAYS AS clause of `vnum`
Warning (Code 1105): Expression depends on the @@sql_mode value NO_UNSIGNED_SUBTRACTIONCREATE TABLE good_pad (
txt CHAR(5),
-- Using RTRIM() or RPAD() makes the value consistent:
vtxt VARCHAR(5) AS (RTRIM(txt)) PERSISTENT,
-- When not persistent or indexed, it is OK for the value to vary by mode:
vtxt2 VARCHAR(5) AS (txt) VIRTUAL,
-- CHAR -> CHAR is always OK:
txt2 CHAR(5) AS (txt) PERSISTENT
);
CREATE TABLE good_sub (
num1 BIGINT UNSIGNED,
num2 BIGINT UNSIGNED,
-- The indexed value will always be consistent in this expression:
vnum BIGINT AS (CAST(num1 AS SIGNED) - CAST(num2 AS SIGNED)) VIRTUAL,
KEY(vnum)
);CREATE TABLE bad_pad (
txt CHAR(5),
-- CHAR -> VARCHAR or CHAR -> TEXT can't be persistent or indexed:
vtxt VARCHAR(5) AS (txt) PERSISTENT
);
CREATE TABLE bad_sub (
num1 BIGINT UNSIGNED,
num2 BIGINT UNSIGNED,
-- The resulting value can vary for some large values
vnum BIGINT AS (num1 - num2) VIRTUAL,
KEY(vnum)
);USE TEST;
CREATE TABLE table1 (
a INT NOT NULL,
b VARCHAR(32),
c INT AS (a MOD 10) VIRTUAL,
d VARCHAR(5) AS (LEFT(b,5)) PERSISTENT);DESCRIBE table1;
+-------+-------------+------+-----+---------+------------+
| Field | Type | Null | Key | Default | Extra |
+-------+-------------+------+-----+---------+------------+
| a | int(11) | NO | | NULL | |
| b | varchar(32) | YES | | NULL | |
| c | int(11) | YES | | NULL | VIRTUAL |
| d | varchar(5) | YES | | NULL | PERSISTENT |
+-------+-------------+------+-----+---------+------------+SHOW CREATE TABLE table1;
| table1 | CREATE TABLE `table1` (
`a` int(11) NOT NULL,
`b` varchar(32) DEFAULT NULL,
`c` int(11) AS (a mod 10) VIRTUAL,
`d` varchar(5) AS (left(b,5)) PERSISTENT
) ENGINE=MyISAM DEFAULT CHARSET=latin1 |WARNINGS;
Show warnings enabled.
INSERT INTO table1 VALUES (1, 'some text',default,default);
Query OK, 1 row affected (0.00 sec)
INSERT INTO table1 VALUES (2, 'more text',5,default);
Query OK, 1 row affected, 1 warning (0.00 sec)
Warning (Code 1645): The value specified for computed column 'c' in table 'table1' has been ignored.
INSERT INTO table1 VALUES (123, 'even more text',default,'something');
Query OK, 1 row affected, 2 warnings (0.00 sec)
Warning (Code 1645): The value specified for computed column 'd' in table 'table1' has been ignored.
Warning (Code 1265): Data truncated for column 'd' at row 1
SELECT * FROM table1;
+-----+----------------+------+-------+
| a | b | c | d |
+-----+----------------+------+-------+
| 1 | some text | 1 | some |
| 2 | more text | 2 | more |
| 123 | even more text | 3 | even |
+-----+----------------+------+-------+
3 rows in set (0.00 sec)CREATE TABLE table2 (a INT, b INT ZEROFILL AS (a*2) VIRTUAL);
INSERT INTO table2 (a) VALUES (1);
SELECT * FROM table2;
+------+------------+
| a | b |
+------+------------+
| 1 | 0000000002 |
+------+------------+
1 row in set (0.00 sec)