Documentation Home
MySQL 5.7 Reference Manual
Related Documentation Download this Manual
PDF (US Ltr) - 38.1Mb
PDF (A4) - 38.1Mb
PDF (RPM) - 37.3Mb
HTML Download (TGZ) - 10.2Mb
HTML Download (Zip) - 10.3Mb
HTML Download (RPM) - 8.9Mb
Man Pages (TGZ) - 217.0Kb
Man Pages (Zip) - 329.8Kb
Info (Gzip) - 3.5Mb
Info (Zip) - 3.5Mb
Excerpts from this Manual

MySQL 5.7 Reference Manual  /  ...  /  The INFORMATION_SCHEMA INNODB_SYS_VIRTUAL Table

24.31.25 The INFORMATION_SCHEMA INNODB_SYS_VIRTUAL Table

The INNODB_SYS_VIRTUAL table provides metadata about InnoDB virtual generated columns and columns upon which virtual generated columns are based, equivalent to information in the SYS_VIRTUAL table in the InnoDB data dictionary.

A row appears in the INNODB_SYS_VIRTUAL table for each column upon which a virtual generated column is based.

Table 24.27 INNODB_SYS_VIRTUAL Columns

Column nameDescription
TABLE_IDAn identifier representing the table associated with the virtual column; the same value as INNODB_SYS_TABLES.TABLE_ID.
POSThe position value of the virtual generated column. The value is large because it encodes the column sequence number and ordinal position. The formula used to calculate the value uses a bitwise operation. The formula is ((nth virtual generated column for the InnoDB instance + 1) << 16) + the ordinal position of the virtual generated column. For example, if the first virtual generated column in the InnoDB instance is the third column of the table, the formula is (0 + 1) << 16) + 2. The first virtual generated column in the InnoDB instance is always number 0. As the third column in the table, the ordinal position of the virtual generated column is 2. Ordinal positions are counted from 0.
BASE_POSThe ordinal position of the columns upon which a virtual generated column is based.

Example:

mysql> CREATE TABLE `t1` (
         `a` int(11) DEFAULT NULL,
         `b` int(11) DEFAULT NULL,
         `c` int(11) GENERATED ALWAYS AS (a+b) VIRTUAL,
         `h` varchar(10) DEFAULT NULL
       ) ENGINE=InnoDB DEFAULT CHARSET=latin1;
mysql> SELECT * FROM INFORMATION_SCHEMA.INNODB_SYS_VIRTUAL
       WHERE TABLE_ID IN (SELECT TABLE_ID FROM INFORMATION_SCHEMA.INNODB_SYS_TABLES WHERE NAME LIKE "test/t1");
+----------+-------+----------+
| TABLE_ID | POS   | BASE_POS |
+----------+-------+----------+
|       95 | 65538 |        0 |
|       95 | 65538 |        1 |
+----------+-------+----------+

Notes:

  • If a constant value is assigned to a virtual generated column, as in the following example, an entry for the column does not appear in the INNODB_SYS_VIRTUAL table. For an entry to appear, a virtual generated column must have a base column.

    mysql> CREATE TABLE `t1` (
             `a` int(11) DEFAULT NULL,
             `b` int(11) DEFAULT NULL,
             `c` int(11) GENERATED ALWAYS AS (5) VIRTUAL
           ) ENGINE=InnoDB DEFAULT CHARSET=latin1;

    However, metadata for such a column appears in the INNODB_SYS_COLUMNS table.

  • Use DESCRIBE or SHOW COLUMNS to view additional information about the columns of this table including data types and default values.

  • You must have the PROCESS privilege to query this table.


User Comments
Sign Up Login You must be logged in to post a comment.