Skip to content

Commit

Permalink
docs: move json functions to single file (#1318)
Browse files Browse the repository at this point in the history
Co-authored-by: Yiran <[email protected]>
  • Loading branch information
CookiePieWw and nicecui authored Nov 21, 2024
1 parent 428ea1f commit bd420c2
Show file tree
Hide file tree
Showing 5 changed files with 245 additions and 210 deletions.
121 changes: 121 additions & 0 deletions docs/reference/sql/functions/json.md
Original file line number Diff line number Diff line change
@@ -0,0 +1,121 @@

# JSON Functions

This page lists all json type related functions in GreptimeDB.


## Conversion

Conversion between JSON and other types.

* `parse_json(string)` to parse a JSON string into a JSON value. Illegal JSON strings will return an error.
* `json_to_string(json)` to convert a JSON value to a string.

```sql
SELECT json_to_string(parse_json('{"a": 1, "b": 2}'));

+----------------------------------------------------------+
| json_to_string(parse_json(Utf8("{\"a\": 1, \"b\": 2}"))) |
+----------------------------------------------------------+
| {"a":1,"b":2} |
+----------------------------------------------------------+
```

## Extraction

Extracts values with specific types from JSON values through specific paths.

* `json_get_bool(json, path)` to extract a boolean value from a JSON value by the path.
* `json_get_int(json, path)` to extract an integer value from a JSON value by the path, while boolean values will be converted to integers.
* `json_get_float(json, path)` to extract a float value from a JSON value by the path, while integer and boolean values will be converted to floats.
* `json_get_string(json, path)` to extract a string value from a JSON value by the path. All valid JSON values will be converted to strings, including null values, objects and arrays.

`path` is a string that select and extract elements from a json value. The following operators in the path are supported:

| Operator | Description | Examples |
|--------------------------|--------------------------------------------------------------|--------------------|
| `$` | The root element | `$` |
| `@` | The current element in the filter expression | `$.event?(@ == 1)` |
| `.*` | Selecting all elements in an Object | `$.*` |
| `.<name>` | Selecting element that match the name in an Object | `$.event` |
| `:<name>` | Alias of `.<name>` | `$:event` |
| `["<name>"]` | Alias of `.<name>` | `$["event"]` |
| `[*]` | Selecting all elements in an Array | `$[*]` |
| `[<pos>, ..]` | Selecting 0-based `n-th` elements in an Array | `$[1, 2]` |
| `[last - <pos>, ..]` | Selecting `n-th` element before the last element in an Array | `$[0, last - 1]` |
| `[<pos1> to <pos2>, ..]` | Selecting all elements of a range in an Array | `$[1 to last - 2]` |
| `?(<expr>)` | Selecting all elements that matched the filter expression | `$?(@.price < 10)` |

If the path is invalid, the function will return a NULL value.

```sql
SELECT json_get_int(parse_json('{"a": {"c": 3}, "b": 2}'), 'a.c');

+-----------------------------------------------------------------------+
| json_get_int(parse_json(Utf8("{"a": {"c": 3}, "b": 2}")),Utf8("a.c")) |
+-----------------------------------------------------------------------+
| 3 |
+-----------------------------------------------------------------------+
```

## Validation

Check the type of a JSON value.

* `json_is_null(json)` to check whether a JSON value is a null value.
* `json_is_bool(json)` to check whether a JSON value is a boolean value.
* `json_is_int(json)` to check whether a JSON value is an integer value.
* `json_is_float(json)` to check whether a JSON value is a float value.
* `json_is_string(json)` to check whether a JSON value is a string value.
* `json_is_object(json)` to check whether a JSON value is an object value.
* `json_is_array(json)` to check whether a JSON value is an array value.

```sql
SELECT json_is_array(parse_json('[1, 2, 3]'));

+----------------------------------------------+
| json_is_array(parse_json(Utf8("[1, 2, 3]"))) |
+----------------------------------------------+
| 1 |
+----------------------------------------------+

SELECT json_is_object(parse_json('1'));

+---------------------------------------+
| json_is_object(parse_json(Utf8("1"))) |
+---------------------------------------+
| 0 |
+---------------------------------------+
```

* `json_path_exists(json, path)` to check whether a path exists in a JSON value.

If the path is invalid, the function will return an error.

If the path or the JSON value is `NULL`, the function will return a `NULL` value.

```sql
SELECT json_path_exists(parse_json('{"a": 1, "b": 2}'), 'a');

+------------------------------------------------------------------+
| json_path_exists(parse_json(Utf8("{"a": 1, "b": 2}")),Utf8("a")) |
+------------------------------------------------------------------+
| 1 |
+------------------------------------------------------------------+

SELECT json_path_exists(parse_json('{"a": 1, "b": 2}'), 'c.d');

+--------------------------------------------------------------------+
| json_path_exists(parse_json(Utf8("{"a": 1, "b": 2}")),Utf8("c.d")) |
+--------------------------------------------------------------------+
| 0 |
+--------------------------------------------------------------------+

SELECT json_path_exists(parse_json('{"a": 1, "b": 2}'), NULL);

+-------------------------------------------------------------+
| json_path_exists(parse_json(Utf8("{"a": 1, "b": 2}")),NULL) |
+-------------------------------------------------------------+
| NULL |
+-------------------------------------------------------------+
```
106 changes: 1 addition & 105 deletions docs/reference/sql/functions/overview.md
Original file line number Diff line number Diff line change
Expand Up @@ -228,111 +228,7 @@ GreptimeDB provides `ADMIN` statement to run the administration functions, pleas

### JSON Functions

GreptimeDB provides the following JSON functions to deal with values of JSON type:

* `parse_json(string)` to parse a JSON string into a JSON value. Illegal JSON strings will return an error.
* `json_to_string(json)` to convert a JSON value to a string.

```sql
SELECT json_to_string(parse_json('{"a": 1, "b": 2}'));

+----------------------------------------------------------+
| json_to_string(parse_json(Utf8("{\"a\": 1, \"b\": 2}"))) |
+----------------------------------------------------------+
| {"a":1,"b":2} |
+----------------------------------------------------------+
```

* `json_get_bool(json, path)` to extract a boolean value from a JSON value by the path.
* `json_get_int(json, path)` to extract an integer value from a JSON value by the path, while boolean values will be converted to integers.
* `json_get_float(json, path)` to extract a float value from a JSON value by the path, while integer and boolean values will be converted to floats.
* `json_get_string(json, path)` to extract a string value from a JSON value by the path. All valid JSON values will be converted to strings, including null values, objects and arrays.

`path` is a string that select and extract elements from a json value. The following operators in the path are supported:

| Operator | Description | Examples |
|--------------------------|--------------------------------------------------------------|--------------------|
| `$` | The root element | `$` |
| `@` | The current element in the filter expression | `$.event?(@ == 1)` |
| `.*` | Selecting all elements in an Object | `$.*` |
| `.<name>` | Selecting element that match the name in an Object | `$.event` |
| `:<name>` | Alias of `.<name>` | `$:event` |
| `["<name>"]` | Alias of `.<name>` | `$["event"]` |
| `[*]` | Selecting all elements in an Array | `$[*]` |
| `[<pos>, ..]` | Selecting 0-based `n-th` elements in an Array | `$[1, 2]` |
| `[last - <pos>, ..]` | Selecting `n-th` element before the last element in an Array | `$[0, last - 1]` |
| `[<pos1> to <pos2>, ..]` | Selecting all elements of a range in an Array | `$[1 to last - 2]` |
| `?(<expr>)` | Selecting all elements that matched the filter expression | `$?(@.price < 10)` |

If the path is invalid, the function will return a NULL value.

```sql
SELECT json_get_int(parse_json('{"a": {"c": 3}, "b": 2}'), 'a.c');

+-----------------------------------------------------------------------+
| json_get_int(parse_json(Utf8("{"a": {"c": 3}, "b": 2}")),Utf8("a.c")) |
+-----------------------------------------------------------------------+
| 3 |
+-----------------------------------------------------------------------+
```

* `json_is_null(json)` to check whether a JSON value is a null value.
* `json_is_bool(json)` to check whether a JSON value is a boolean value.
* `json_is_int(json)` to check whether a JSON value is an integer value.
* `json_is_float(json)` to check whether a JSON value is a float value.
* `json_is_string(json)` to check whether a JSON value is a string value.
* `json_is_object(json)` to check whether a JSON value is an object value.
* `json_is_array(json)` to check whether a JSON value is an array value.

```sql
SELECT json_is_array(parse_json('[1, 2, 3]'));

+----------------------------------------------+
| json_is_array(parse_json(Utf8("[1, 2, 3]"))) |
+----------------------------------------------+
| 1 |
+----------------------------------------------+

SELECT json_is_object(parse_json('1'));

+---------------------------------------+
| json_is_object(parse_json(Utf8("1"))) |
+---------------------------------------+
| 0 |
+---------------------------------------+
```

* `json_path_exists(json, path)` to check whether a path exists in a JSON value.

If the path is invalid, the function will return an error.

If the path or the JSON value is `NULL`, the function will return a `NULL` value.

```sql
SELECT json_path_exists(parse_json('{"a": 1, "b": 2}'), 'a');

+------------------------------------------------------------------+
| json_path_exists(parse_json(Utf8("{"a": 1, "b": 2}")),Utf8("a")) |
+------------------------------------------------------------------+
| 1 |
+------------------------------------------------------------------+

SELECT json_path_exists(parse_json('{"a": 1, "b": 2}'), 'c.d');

+--------------------------------------------------------------------+
| json_path_exists(parse_json(Utf8("{"a": 1, "b": 2}")),Utf8("c.d")) |
+--------------------------------------------------------------------+
| 0 |
+--------------------------------------------------------------------+

SELECT json_path_exists(parse_json('{"a": 1, "b": 2}'), NULL);

+-------------------------------------------------------------+
| json_path_exists(parse_json(Utf8("{"a": 1, "b": 2}")),NULL) |
+-------------------------------------------------------------+
| NULL |
+-------------------------------------------------------------+
```
GreptimeDB provide functions for jsons. [Learn more about these functions](./json.md)

## Geospatial Functions

Expand Down
Original file line number Diff line number Diff line change
@@ -0,0 +1,121 @@

# JSON 函数

本页面列出了 GreptimeDB 中所有 JSON 类型相关的函数。


## 转换

JSON 类型与其他类型的值之间的转换。

* `parse_json(string)` 尝试将字符串解析为 JSON 类型。非法的 JSON 字符串将返回错误。
* `json_to_string(json)` 将 JSON 类型的值转换为字符串。

```sql
SELECT json_to_string(parse_json('{"a": 1, "b": 2}'));

+----------------------------------------------------------+
| json_to_string(parse_json(Utf8("{\"a\": 1, \"b\": 2}"))) |
+----------------------------------------------------------+
| {"a":1,"b":2} |
+----------------------------------------------------------+
```

## 提取

通过给定的路径和给定的数据类型,从 JSON 中提取值。

* `json_get_bool(json, path)` 按照路径 `path` 从 JSON 中获取布尔值。
* `json_get_int(json, path)` 按照路径 `path` 从 JSON 中获取整数值。布尔值将被转换为整数。
* `json_get_float(json, path)` 按照路径 `path` 从 JSON 中获取浮点数值。布尔值、整数值将被转换为浮点数。
* `json_get_string(json, path)` 按照路径 `path` 从 JSON 中获取字符串。所有类型的 JSON 值都将被转换为字符串,包括数组、对象和 null。

`path` 是一个用于从 JSON 值中选择和提取元素的字符串。`path` 中支持的操作符有:

| 操作符 | 描述 | 示例 |
|--------------------------|--------------------------------------------------------------|--------------------|
| `$` | 根元素 | `$` |
| `@` | 过滤表达式中的当前元素 | `$.event?(@ == 1)` |
| `.*` | 选择对象中的所有元素 | `$.*` |
| `.<name>` | 选择对象中匹配名称的元素 | `$.event` |
| `:<name>` | `.<name>` 的别名 | `$:event` |
| `["<name>"]` | `.<name>` 的别名 | `$["event"]` |
| `[*]` | 选择数组中的所有元素 | `$[*]` |
| `[<pos>, ..]` | 选择数组中基于0的第 `n` 个元素 | `$[1, 2]` |
| `[last - <pos>, ..]` | 选择数组中最后一个元素之前的第 `n` 个元素 | `$[0, last - 1]` |
| `[<pos1> to <pos2>, ..]` | 选择数组中某个范围内的所有元素 | `$[1 to last - 2]` |
| `?(<expr>)` | 选择所有匹配过滤表达式的元素 | `$?(@.price < 10)` |

如果 `path` 是无效的,函数将返回 `NULL`

```sql
SELECT json_get_int(parse_json('{"a": {"c": 3}, "b": 2}'), 'a.c');

+-----------------------------------------------------------------------+
| json_get_int(parse_json(Utf8("{"a": {"c": 3}, "b": 2}")),Utf8("a.c")) |
+-----------------------------------------------------------------------+
| 3 |
+-----------------------------------------------------------------------+
```

## 验证

检查 JSON 值的类型。

* `json_is_null(json)` 检查 JSON 中的值是否为 `NULL`
* `json_is_bool(json)` 检查 JSON 中的值是否为布尔值。
* `json_is_int(json)` 检查 JSON 中的值是否为整数。
* `json_is_float(json)` 检查 JSON 中的值是否为浮点数。
* `json_is_string(json)` 检查 JSON 中的值是否为字符串。
* `json_is_array(json)` 检查 JSON 中的值是否为数组。
* `json_is_object(json)` 检查 JSON 中的值是否为对象。

```sql
SELECT json_is_array(parse_json('[1, 2, 3]'));

+----------------------------------------------+
| json_is_array(parse_json(Utf8("[1, 2, 3]"))) |
+----------------------------------------------+
| 1 |
+----------------------------------------------+

SELECT json_is_object(parse_json('1'));

+---------------------------------------+
| json_is_object(parse_json(Utf8("1"))) |
+---------------------------------------+
| 0 |
+---------------------------------------+
```

* `json_path_exists(json, path)` 检查 JSON 中是否存在指定的路径。

如果 `path` 是无效的,函数将返回错误。

如果 `path``json``NULL`,函数将返回 `NULL`

```sql
SELECT json_path_exists(parse_json('{"a": 1, "b": 2}'), 'a');

+------------------------------------------------------------------+
| json_path_exists(parse_json(Utf8("{"a": 1, "b": 2}")),Utf8("a")) |
+------------------------------------------------------------------+
| 1 |
+------------------------------------------------------------------+

SELECT json_path_exists(parse_json('{"a": 1, "b": 2}'), 'c.d');

+--------------------------------------------------------------------+
| json_path_exists(parse_json(Utf8("{"a": 1, "b": 2}")),Utf8("c.d")) |
+--------------------------------------------------------------------+
| 0 |
+--------------------------------------------------------------------+

SELECT json_path_exists(parse_json('{"a": 1, "b": 2}'), NULL);

+-------------------------------------------------------------+
| json_path_exists(parse_json(Utf8("{"a": 1, "b": 2}")),NULL) |
+-------------------------------------------------------------+
| NULL |
+-------------------------------------------------------------+
```
Loading

0 comments on commit bd420c2

Please sign in to comment.