diff --git a/functions-and-operators/aggregate-group-by-functions.md b/functions-and-operators/aggregate-group-by-functions.md index a0790299dbd5d..ad6bca9e953d9 100644 --- a/functions-and-operators/aggregate-group-by-functions.md +++ b/functions-and-operators/aggregate-group-by-functions.md @@ -21,7 +21,9 @@ This section describes the supported MySQL group (aggregate) functions in TiDB. | [`AVG()`](https://dev.mysql.com/doc/refman/5.7/en/group-by-functions.html#function_avg) | Return the average value of the argument | | [`MAX()`](https://dev.mysql.com/doc/refman/5.7/en/group-by-functions.html#function_max) | Return the maximum value | | [`MIN()`](https://dev.mysql.com/doc/refman/5.7/en/group-by-functions.html#function_min) | Return the minimum value | -| [`GROUP_CONCAT()`](https://dev.mysql.com/doc/refman/5.7/en/group-by-functions.html#function_group-concat) | Return a concatenated string | +| [`GROUP_CONCAT()`](https://dev.mysql.com/doc/refman/5.7/en/group-by-functions.html#function_group-concat) | Return a concatenated string | +| [`VARIANCE()`, `VAR_POP()`](https://dev.mysql.com/doc/refman/5.7/en/aggregate-functions.html#function_var-pop) | Return the population standard variance| +| [`JSON_OBJECTAGG(key, value)`](https://dev.mysql.com/doc/refman/5.7/en/aggregate-functions.html#function_json-objectagg) | Return the result set as a single JSON object containing key-value pairs | - Unless otherwise stated, group functions ignore `NULL` values. - If you use a group function in a statement containing no `GROUP BY` clause, it is equivalent to grouping on all rows. @@ -118,7 +120,5 @@ The following aggregate functions are currently unsupported in TiDB. You can tra - `STD`, `STDDEV`, `STDDEV_POP` - `STDDEV_SAMP` -- `VARIANCE`, `VAR_POP` - `VAR_SAMP` - `JSON_ARRAYAGG` -- `JSON_OBJECTAGG` diff --git a/functions-and-operators/json-functions.md b/functions-and-operators/json-functions.md index 3272b9e553a85..6d666e838188e 100644 --- a/functions-and-operators/json-functions.md +++ b/functions-and-operators/json-functions.md @@ -46,6 +46,8 @@ TiDB supports most of the JSON functions that shipped with the GA release of MyS | [JSON_REPLACE(json_doc, path, val[, path, val] ...)][json_replace] | Replaces existing values in a JSON document and returns the result | | [JSON_SET(json_doc, path, val[, path, val] ...)][json_set] | Inserts or updates data in a JSON document and returns the result | | [JSON_UNQUOTE(json_val)][json_unquote] | Unquotes a JSON value and returns the result as a string | +| [JSON_ARRAY_APPEND(json_doc, path, val[, path, val] ...)][json_array_append] | Appends values to the end of the indicated arrays within a JSON document and returns the result | +| [JSON_ARRAY_INSERT(json_doc, path, val[, path, val] ...)][json_array_insert] | Insert values into the specified location of a JSON document and returns the result | ## Functions that return JSON value attributes @@ -54,16 +56,15 @@ TiDB supports most of the JSON functions that shipped with the GA release of MyS | [JSON_DEPTH(json_doc)][json_depth] | Returns the maximum depth of a JSON document | | [JSON_LENGTH(json_doc[, path])][json_length] | Returns the length of a JSON document, or, if a path argument is given, the length of the value within the path | | [JSON_TYPE(json_val)][json_type] | Returns a string indicating the type of a JSON value | +| [JSON_VALID(json_val)][json_valid] | Returns 0 or 1 to indicate whether a value is valid JSON | ## Unsupported functions The following JSON functions are unsupported in TiDB. You can track the progress in adding them in [TiDB #7546](https://github.com/pingcap/tidb/issues/7546): -* `JSON_ARRAY_INSERT` * `JSON_MERGE_PATCH` * `JSON_PRETTY` * `JSON_STORAGE_SIZE` -* `JSON_VALID` * `JSON_ARRAYAGG` * `JSON_OBJECTAGG` @@ -91,3 +92,5 @@ The following JSON functions are unsupported in TiDB. You can track the progress [json_search]: https://dev.mysql.com/doc/refman/5.7/en/json-search-functions.html#function_json-search [json_append]: https://dev.mysql.com/doc/refman/5.7/en/json-modification-functions.html#function_json-append [json_array_append]: https://dev.mysql.com/doc/refman/5.7/en/json-modification-functions.html#function_json-array-append +[json_array_insert]: https://dev.mysql.com/doc/refman/5.7/en/json-modification-functions.html#function_json-array-insert +[json_search]: https://dev.mysql.com/doc/refman/5.7/en/json-search-functions.html#function_json-search diff --git a/generated-columns.md b/generated-columns.md index 8ae0c92b9b9bb..70761d4eb000d 100644 --- a/generated-columns.md +++ b/generated-columns.md @@ -11,11 +11,23 @@ aliases: ['/docs/dev/generated-columns/','/docs/dev/reference/sql/generated-colu > > This is still an experimental feature. It is **NOT** recommended that you use it in the production environment. -TiDB supports generated columns as part of MySQL 5.7 compatibility. One of the primary use cases for generated columns is to extract data out of a JSON data type and enable it to be indexed. +This document introduces the concept and usage of generated columns. -## Index JSON using generated column +## Basic concepts -In both MySQL 5.7 and TiDB, columns of type JSON can not be indexed directly. i.e. The following table structure is **not supported**: +Unlike general columns, the value of the generated column is calculated by the expression in the column definition. When inserting or updating a generated column, you cannot assign a value, but only use `DEFAULT`. + +There are two kinds of generated columns: virtual and stored. A virtual generated column occupies no storage and is computed when it is read. A stored generated column is computed when it is written (inserted or updated) and occupies storage. Compared with the virtual generated columns, the stored generated columns have better read performance, but take up more disk space. + +You can create an index on a generated column whether it is virtual or stored. + +## Usage + +One of the main usage of generated columns is to extract data from the JSON data type and indexing the data. + +In both MySQL 5.7 and TiDB, columns of type JSON can not be indexed directly. That is, the following table schema is **not supported**: + +{{< copyable "sql" >}} ```sql CREATE TABLE person ( @@ -26,65 +38,119 @@ CREATE TABLE person ( ); ``` -To index a JSON column, you must first extract it as a generated column. +To index a JSON column, you must extract it as a generated column first. + +Using the `city` field in `address_info` as an example, you can create a virtual generated column and add an index for it: -Using the `city` stored generated column as an example, you are then able to add an index: +{{< copyable "sql" >}} ```sql CREATE TABLE person ( id INT NOT NULL AUTO_INCREMENT PRIMARY KEY, name VARCHAR(255) NOT NULL, address_info JSON, - city VARCHAR(64) AS (JSON_UNQUOTE(JSON_EXTRACT(address_info, '$.city'))) STORED, + city VARCHAR(64) AS (JSON_UNQUOTE(JSON_EXTRACT(address_info, '$.city'))), KEY (city) ); ``` -In this table, the `city` column is a **generated column**. As the name implies, the column is generated from other columns in the table, and cannot be assigned a value when inserted or updated. This column is generated based on a defined expression and is stored in the database. Thus this column can be read directly, not in a way that its dependent column `address_info` is read first and then the data is calculated. The index on `city` however is _stored_ and uses the same structure as other indexes of the type `varchar(64)`. +In this table, the `city` column is a **virtual generated column** and has an index. The following query can use the index to speed up the execution: -You can use the index on the stored generated column in order to speed up the following statement: +{{< copyable "sql" >}} ```sql SELECT name, id FROM person WHERE city = 'Beijing'; ``` -If no data exists at path `$.city`, `JSON_EXTRACT` returns `NULL`. If you want to enforce a constraint that `city` must be `NOT NULL`, you can define the virtual column as follows: +{{< copyable "sql" >}} + +```sql +EXPLAIN SELECT name, id FROM person WHERE city = 'Beijing'; +``` + +``` ++---------------------------------+---------+-----------+--------------------------------+-------------------------------------------------------------+ +| id | estRows | task | access object | operator info | ++---------------------------------+---------+-----------+--------------------------------+-------------------------------------------------------------+ +| Projection_4 | 10.00 | root | | test.person.name, test.person.id | +| └─IndexLookUp_10 | 10.00 | root | | | +| ├─IndexRangeScan_8(Build) | 10.00 | cop[tikv] | table:person, index:city(city) | range:["Beijing","Beijing"], keep order:false, stats:pseudo | +| └─TableRowIDScan_9(Probe) | 10.00 | cop[tikv] | table:person | keep order:false, stats:pseudo | ++---------------------------------+---------+-----------+--------------------------------+-------------------------------------------------------------+ +``` + +From the query execution plan, it can be seen that the `city` index is used to read the `HANDLE` of the row that meets the condition `city ='Beijing'`, and then it uses this `HANDLE` to read the data of the row. + +If no data exists at path `$.city`, `JSON_EXTRACT` returns `NULL`. If you want to enforce a constraint that `city` must be `NOT NULL`, you can define the virtual generated column as follows: + +{{< copyable "sql" >}} ```sql CREATE TABLE person ( id INT NOT NULL AUTO_INCREMENT PRIMARY KEY, name VARCHAR(255) NOT NULL, address_info JSON, - city VARCHAR(64) AS (JSON_UNQUOTE(JSON_EXTRACT(address_info, '$.city'))) STORED NOT NULL, + city VARCHAR(64) AS (JSON_UNQUOTE(JSON_EXTRACT(address_info, '$.city'))) NOT NULL, KEY (city) ); ``` +## Validation of generated columns + Both `INSERT` and `UPDATE` statements check virtual column definitions. Rows that do not pass validation return errors: +{{< copyable "sql" >}} + ```sql mysql> INSERT INTO person (name, address_info) VALUES ('Morgan', JSON_OBJECT('Country', 'Canada')); ERROR 1048 (23000): Column 'city' cannot be null ``` -## Use generated virtual columns +## Generated columns index replacement rule -TiDB also supports generated virtual columns. Different from generated store columns, generated virtual columns are **virtual** in that they are generated as needed and are not stored in the database or cached in the memory. +When an expression in a query is equivalent to a generated column with an index, TiDB replaces the expression with the corresponding generated column, so that the optimizer can take that index into account during execution plan construction. + +For example, the following example creates a generated column for the expression `a+1` and adds an index: ```sql -CREATE TABLE person ( - id INT NOT NULL AUTO_INCREMENT PRIMARY KEY, - name VARCHAR(255) NOT NULL, - address_info JSON, - city VARCHAR(64) AS (JSON_UNQUOTE(JSON_EXTRACT(address_info, '$.city'))) VIRTUAL -); +create table t(a int); +desc select a+1 from t where a+1=3; ++---------------------------+----------+-----------+---------------+--------------------------------+ +| id | estRows | task | access object | operator info | ++---------------------------+----------+-----------+---------------+--------------------------------+ +| Projection_4 | 8000.00 | root | | plus(test.t.a, 1)->Column#3 | +| └─TableReader_7 | 8000.00 | root | | data:Selection_6 | +| └─Selection_6 | 8000.00 | cop[tikv] | | eq(plus(test.t.a, 1), 3) | +| └─TableFullScan_5 | 10000.00 | cop[tikv] | table:t | keep order:false, stats:pseudo | ++---------------------------+----------+-----------+---------------+--------------------------------+ +4 rows in set (0.00 sec) + +alter table t add column b bigint as (a+1) virtual; +alter table t add index idx_b(b); +desc select a+1 from t where a+1=3; ++------------------------+---------+-----------+-------------------------+---------------------------------------------+ +| id | estRows | task | access object | operator info | ++------------------------+---------+-----------+-------------------------+---------------------------------------------+ +| IndexReader_6 | 10.00 | root | | index:IndexRangeScan_5 | +| └─IndexRangeScan_5 | 10.00 | cop[tikv] | table:t, index:idx_b(b) | range:[3,3], keep order:false, stats:pseudo | ++------------------------+---------+-----------+-------------------------+---------------------------------------------+ +2 rows in set (0.01 sec) ``` +> **Note:** +> +> Only when the expression type and the generated column type are strictly equal, the replacement is performed. +> +> In the above example, the column type of `a` is int and the column type of `a+1` is bigint. If the type of the generated column is set to int, the replacement will not occur. +> +> For type conversion rules, see [Type Conversion of Expression Evaluation] (/functions-and-operators/type-conversion-in-expression-evaluation.md). + ## Limitations The current limitations of JSON and generated columns are as follows: -- You cannot add the generated column in the storage type of `STORED` through `ALTER TABLE`. -- You can neither convert a generated stored column to a normal column through the `ALTER TABLE` statement nor convert a normal column to a generated stored column. -- You cannot modify the **expression** of a generated stored column through the `ALTER TABLE` statement. -- Not all [JSON functions](/functions-and-operators/json-functions.md) are supported. +- You cannot add a stored generated column through `ALTER TABLE`. +- You can neither convert a stored generated column to a normal column through the `ALTER TABLE` statement nor convert a normal column to a stored generated column. +- You cannot modify the expression of a stored generated column through the `ALTER TABLE` statement. +- Not all [JSON functions](/functions-and-operators/json-functions.md) are supported; +- Currently, the generated column index replacement rule is valid only when the generated column is a virtual generated column. It is not valid on the stored generated column, but the index can still be used by directly using the generated column itself.