Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

sql, README: improve JSON doc #949

Merged
merged 4 commits into from
Nov 2, 2018
Merged
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
2 changes: 1 addition & 1 deletion README.md
Original file line number Diff line number Diff line change
Expand Up @@ -68,7 +68,7 @@
- [Prepared SQL 语句语法](sql/prepare.md)
- [实用工具语句](sql/util.md)
- [TiDB SQL 语法图](https://pingcap.github.io/sqlgram/)
- [JSON 支持](sql/json-functions-generated-column.md)
- [Generated Column](sql/generated-columns.md)
- [Connectors 和 API](sql/connection-and-APIs.md)
- [TiDB 事务隔离级别](sql/transaction-isolation.md)
- [错误码与故障诊断](sql/error.md)
Expand Down
69 changes: 69 additions & 0 deletions sql/generated-columns.md
Original file line number Diff line number Diff line change
@@ -0,0 +1,69 @@
---
title: Generated Column
summary: 本文档介绍如何使用 generated column
category: user guide
---

# Generated Column

为了在功能上兼容 MySQL 5.7,TiDB 支持 generated column。Generated column 的主要的作用之一:从 JSON 数据类型中解出数据,并为该数据建立索引。

## 使用 generated column 对 JSON 建索引

MySQL 5.7 及 TiDB 都不能直接为 JSON 类型的列添加索引,即**不支持**如下表结构:

```sql
CREATE TABLE person (
id INT NOT NULL AUTO_INCREMENT PRIMARY KEY,
name VARCHAR(255) NOT NULL,
address_info JSON,
KEY (address_info)
);
```

为 JSON 列添加索引之前,首先必须抽取该列为 generated column。以 `city` generated column 为例,你可以添加索引:

```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,
KEY (city)
);
```

该表中,`city` 列是一个 **generated column**。顾名思义,此列由该表的其他列生成,对此列进行插入或更新操作时,并不能对之赋值。此列按需生成,并不存储在数据库中,也不占用内存空间,因而是**虚拟的**。`city` 列的索引**存储在数据库中**,并使用和 `varchar(64)` 类的其他索引相同的结构。

可使用 generated column 的索引,以提高如下语句的执行速度:

```sql
SELECT name, id FROM person WHERE city = 'Beijing';
```

如果 `$.city` 路径中无数据,则 `JSON_EXTRACT` 返回 `NULL`。如果你想增加约束:`city` 列必须是`NOT NULL`,则可按照以下方式定义 virtual column:

```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 NOT NULL,
KEY (city)
);
```

`INSERT` 和 `UPDATE` 语句都会检查 virtual column 的定义。未通过有效性检测的行会返回错误:

```sql
mysql> INSERT INTO person (name, address_info) VALUES ('Morgan', JSON_OBJECT('Country', 'Canada'));
ERROR 1048 (23000): Column 'city' cannot be null
```

## 局限性

目前 JSON and generated column 有以下局限性:

- 不能通过 `ALTER TABLE` 增加 `STORED` 存储方式的 generated column;
- 不能通过 `ALTER TABLE` 在 generated column 上增加索引;
- 并未支持所有的 [JSON 函数](../sql/json-functions.md)。
121 changes: 0 additions & 121 deletions sql/json-functions-generated-column.md

This file was deleted.

77 changes: 63 additions & 14 deletions sql/json-functions.md
Original file line number Diff line number Diff line change
@@ -1,26 +1,68 @@
---
title: JSON 相关的函数和语法糖
title: JSON 函数及语法糖
category: user guide
---

# JSON 相关的函数和语法糖
# JSON 函数及语法糖

| 函数或语法糖 | 功能描述 |
TiDB 支持 MySQL 5.7 GA 版本发布的大多数 JSON 函数。MySQL 5.7 发布后,又增加了更多 JSON 函数,TiDB 并未支持所有这些函数(参见[未支持的函数](#unsupported-functions))。

## 创建 JSON 值的函数

| 函数及语法糖 | 功能描述 |
| ------------------------------------------------------------------ | ---------------------------------------------------------- |
| [JSON_ARRAY([val[, val] ...])][json_array] | 根据一系列元素创建一个 JSON 文档 |
| [JSON_OBJECT(key, val[, key, val] ...)][json_object] | 根据一系列 K/V 对创建一个 JSON 文档 |

## 搜索 JSON 值的函数

| 函数及语法糖 | 功能描述 |
| ------------------------------------------------------------------ | ---------------------------------------------------------- |
| [JSON_CONTAINS(target, candidate[, path])][json_contains] | 通过返回 1 或 0 来表示目标 JSON 文档中是否包含给定的 candidate JSON 文档 |
| [JSON_CONTAINS_PATH(json_doc, one_or_all, path[, path] ...)][json_contains_path] | 通过返回 0 或 1 来表示一个 JSON 文档在给定路径是否包含数据 |
| [JSON_EXTRACT(json_doc, path[, path] ...)][json_extract] | 从 JSON 文档中解出某一路径对应的子文档 |
| [JSON_UNQUOTE(json_val)][json_unquote] | 去掉 JSON 文档外面的引号 |
| [JSON_TYPE(json_val)][json_type] | 检查某 JSON 文档内部内容的类型 |
| [JSON_SET(json_doc, path, val[, path, val] ...)][json_set] | 在 JSON 文档中为某一路径设置子文档 |
| [JSON_INSERT(json_doc, path, val[, path, val] ...)][json_insert] | 在 JSON 文档中在某一路径下插入子文档 |
| [JSON_REPLACE(json_doc, path, val[, path, val] ...)][json_replace] | 替换 JSON 文档中的某一路径下的子文档 |
| [JSON_REMOVE(json_doc, path[, path] ...)][json_remove] | 移除 JSON 文档中某一路径下的子文档 |
| [JSON_MERGE(json_doc, json_doc[, json_doc] ...)][json_merge] | 将多个 JSON 文档合并成一个文档,其类型为数组 |
| [JSON_OBJECT(key, val[, key, val] ...)][json_object] | 根据一系列 K/V 对创建一个 JSON 文档 |
| [JSON_ARRAY([val[, val] ...])][json_array] | 根据一系列元素创建一个 JSON 文档 |
| -> | JSON_EXTRACT(doc, path_literal) 的语法糖 |
| ->> | JSON_UNQUOTE(JSONJSON_EXTRACT(doc, path_literal)) 的语法糖 |
| [->][json_short_extract] | 返回执行路径后面的 JSON 列的值;`JSON_EXTRACT(doc, path_literal)` 的语法糖 |
| [->>][json_short_extract_unquote] | 返回执行路径后面的 JSON 列的值和转义后的结果; `JSON_UNQUOTE(JSON_EXTRACT(doc, path_literal))` 的语法糖 |
| [JSON_KEYS(json_doc[, path])][json_keys] | 返回从 JSON 对象的顶级值作为 JSON array 的键,如果给定了路径参数,则从选定路径中获取顶级键 |

## 修改 JSON 值的函数

| 函数及语法糖 | 功能描述 |
| --------------------------------- | ----------- |
| [JSON_INSERT(json_doc, path, val[, path, val] ...)][json_insert] | 在 JSON 文档中在某一路径下插入子文档 |
| [JSON_MERGE(json_doc, json_doc[, json_doc] ...)][json_merge] | 将多个 JSON 文档合并成一个文档,其类型为数组 |
| [JSON_REMOVE(json_doc, path[, path] ...)][json_remove] | 移除 JSON 文档中某一路径下的子文档 |
| [JSON_REPLACE(json_doc, path, val[, path, val] ...)][json_replace] | 替换 JSON 文档中的某一路径下的子文档 |
| [JSON_SET(json_doc, path, val[, path, val] ...)][json_set] | 在 JSON 文档中为某一路径设置子文档 |
| [JSON_UNQUOTE(json_val)][json_unquote] | 去掉 JSON 文档外面的引号 |

## 返回 JSON 值属性的函数

| 函数及语法糖 | 功能描述 |
| --------------------------------- | ----------- |
| [JSON_LENGTH(json_doc[, path])][json_length] | 返回 JSON 文档的长度;如果路径参数已定,则返回该路径下值的长度 |
| [JSON_TYPE(json_val)][json_type] | 检查某 JSON 文档内部内容的类型 |

## 未支持的函数

TiDB 暂未支持以下 JSON 函数。相关进展参见 [TiDB #7546](https://github.com/pingcap/tidb/issues/7546):

* `JSON_APPEND` 及其别名 `JSON_ARRAY_APPEND`
* `JSON_ARRAY_INSERT`
* `JSON_DEPTH`
* `JSON_MERGE_PATCH`
* `JSON_MERGE_PRESERVE`,使用别名 `JSON_MERGE` 替代
* `JSON_PRETTY`
* `JSON_QUOTE`
* `JSON_SEARCH`
* `JSON_STORAGE_SIZE`
* `JSON_VALID`
* `JSON_ARRAYAGG`
* `JSON_OBJECTAGG`

[json_extract]: https://dev.mysql.com/doc/refman/5.7/en/json-search-functions.html#function_json-extract
[json_short_extract]: https://dev.mysql.com/doc/refman/5.7/en/json-search-functions.html#operator_json-column-path
[json_short_extract_unquote]: https://dev.mysql.com/doc/refman/5.7/en/json-search-functions.html#operator_json-inline-path
[json_unquote]: https://dev.mysql.com/doc/refman/5.7/en/json-modification-functions.html#function_json-unquote
[json_type]: https://dev.mysql.com/doc/refman/5.7/en/json-attribute-functions.html#function_json-type
[json_set]: https://dev.mysql.com/doc/refman/5.7/en/json-modification-functions.html#function_json-set
Expand All @@ -30,3 +72,10 @@ category: user guide
[json_merge]: https://dev.mysql.com/doc/refman/5.7/en/json-modification-functions.html#function_json-merge
[json_object]: https://dev.mysql.com/doc/refman/5.7/en/json-creation-functions.html#function_json-object
[json_array]: https://dev.mysql.com/doc/refman/5.7/en/json-creation-functions.html#function_json-array
[json_keys]: https://dev.mysql.com/doc/refman/5.7/en/json-search-functions.html#function_json-keys
Copy link
Member

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Please also check and update the links. If it links to no place, please remove it.

[json_length]: https://dev.mysql.com/doc/refman/5.7/en/json-attribute-functions.html#function_json-length
[json_valid]: https://dev.mysql.com/doc/refman/5.7/en/json-attribute-functions.html#function_json-valid
[json_quote]: https://dev.mysql.com/doc/refman/5.7/en/json-creation-functions.html#function_json-quote
[json_contains]: https://dev.mysql.com/doc/refman/5.7/en/json-search-functions.html#function_json-contains
[json_contains_path]: https://dev.mysql.com/doc/refman/5.7/en/json-search-functions.html#function_json-contains-path
[json_arrayagg]: https://dev.mysql.com/doc/refman/5.7/en/group-by-functions.html#function_json-arrayagg