Add tests cases and fix documentation for JSON functions.

This commit is contained in:
Vitaly Baranov 2019-05-16 16:35:31 +03:00
parent cae2221b92
commit ae4f472bc7
3 changed files with 91 additions and 49 deletions

View File

@ -14,13 +14,18 @@ a
--JSONType--
Object
Array
--JSONExtract<type>--
hello
hello
--JSONExtract<numeric>--
-100
200
300
1
--JSONExtractString--
hello
hello
\n\0
--JSONExtract (generic)--
('hello',[-100,200,300])
('hello',[-100,200,300])
@ -36,8 +41,14 @@ hello
-100
200
\N
1
Thursday
Friday
--JSONExtractKeysAndValues--
[('a','hello')]
[('b',[-100,200,300])]
[('a','hello'),('b','world')]
[('a',5),('b',7),('c',11)]
--JSONExtractRaw--
{"a":"hello","b":[-100,200,300]}
"hello"
@ -50,8 +61,5 @@ Friday
{"passed":true}
{}
--JSONExtractKeysAndValues--
[('a','hello')]
[('b',[-100,200,300])]
[('a','hello'),('b','world')]
[('a',5),('b',7),('c',11)]
"\\n\\u0000"
"☺"

View File

@ -18,14 +18,20 @@ SELECT '--JSONType--';
SELECT JSONType('{"a": "hello", "b": [-100, 200.0, 300]}');
SELECT JSONType('{"a": "hello", "b": [-100, 200.0, 300]}', 'b');
SELECT '--JSONExtract<type>--';
SELECT JSONExtractString('{"a": "hello", "b": [-100, 200.0, 300]}', 'a');
SELECT JSONExtractString('{"a": "hello", "b": [-100, 200.0, 300]}', 1);
SELECT '--JSONExtract<numeric>--';
SELECT JSONExtractInt('{"a": "hello", "b": [-100, 200.0, 300]}', 'b', 1);
SELECT JSONExtractFloat('{"a": "hello", "b": [-100, 200.0, 300]}', 'b', 2);
SELECT JSONExtractUInt('{"a": "hello", "b": [-100, 200.0, 300]}', 'b', -1);
SELECT JSONExtractBool('{"passed": true}', 'passed');
SELECT '--JSONExtractString--';
SELECT JSONExtractString('{"a": "hello", "b": [-100, 200.0, 300]}', 'a');
SELECT JSONExtractString('{"a": "hello", "b": [-100, 200.0, 300]}', 1);
select JSONExtractString('{"abc":"\\n\\u0000"}', 'abc');
select JSONExtractString('{"abc":"\\u263a"}', 'abc');
select JSONExtractString('{"abc":"\\u263"}', 'abc');
select JSONExtractString('{"abc":"hello}', 'abc');
SELECT '--JSONExtract (generic)--';
SELECT JSONExtract('{"a": "hello", "b": [-100, 200.0, 300]}', 'Tuple(String, Array(Float64))');
SELECT JSONExtract('{"a": "hello", "b": [-100, 200.0, 300]}', 'Tuple(a String, b Array(Float64))');
@ -41,9 +47,16 @@ SELECT JSONExtract('{"a": "hello", "b": [-100, 200.0, 300]}', 'b', 'Array(Nullab
SELECT JSONExtract('{"a": "hello", "b": [-100, 200.0, 300]}', 'b', 1, 'Int8');
SELECT JSONExtract('{"a": "hello", "b": [-100, 200.0, 300]}', 'b', 2, 'Int32');
SELECT JSONExtract('{"a": "hello", "b": [-100, 200.0, 300]}', 'b', 4, 'Nullable(Int64)');
SELECT JSONExtract('{"passed": true}', 'passed', 'UInt8');
SELECT JSONExtract('{"day": "Thursday"}', 'day', 'Enum8(\'Sunday\' = 0, \'Monday\' = 1, \'Tuesday\' = 2, \'Wednesday\' = 3, \'Thursday\' = 4, \'Friday\' = 5, \'Saturday\' = 6)');
SELECT JSONExtract('{"day": 5}', 'day', 'Enum8(\'Sunday\' = 0, \'Monday\' = 1, \'Tuesday\' = 2, \'Wednesday\' = 3, \'Thursday\' = 4, \'Friday\' = 5, \'Saturday\' = 6)');
SELECT '--JSONExtractKeysAndValues--';
SELECT JSONExtractKeysAndValues('{"a": "hello", "b": [-100, 200.0, 300]}', 'String');
SELECT JSONExtractKeysAndValues('{"a": "hello", "b": [-100, 200.0, 300]}', 'Array(Float64)');
SELECT JSONExtractKeysAndValues('{"a": "hello", "b": "world"}', 'String');
SELECT JSONExtractKeysAndValues('{"x": {"a": 5, "b": 7, "c": 11}}', 'x', 'Int8');
SELECT '--JSONExtractRaw--';
SELECT JSONExtractRaw('{"a": "hello", "b": [-100, 200.0, 300]}');
SELECT JSONExtractRaw('{"a": "hello", "b": [-100, 200.0, 300]}', 'a');
@ -56,9 +69,5 @@ SELECT JSONExtractRaw('{"a": "hello", "b": [-100, 200.0, 300], "c":{"d":[121,144
SELECT JSONExtractRaw('{"a": "hello", "b": [-100, 200.0, 300], "c":{"d":[121,144]}}', 'c', 'd', 3);
SELECT JSONExtractRaw('{"passed": true}');
SELECT JSONExtractRaw('{}');
SELECT '--JSONExtractKeysAndValues--';
SELECT JSONExtractKeysAndValues('{"a": "hello", "b": [-100, 200.0, 300]}', 'String');
SELECT JSONExtractKeysAndValues('{"a": "hello", "b": [-100, 200.0, 300]}', 'Array(Float64)');
SELECT JSONExtractKeysAndValues('{"a": "hello", "b": "world"}', 'String');
SELECT JSONExtractKeysAndValues('{"x": {"a": 5, "b": 7, "c": 11}}', 'x', 'Int8');
select JSONExtractRaw('{"abc":"\\n\\u0000"}', 'abc');
select JSONExtractRaw('{"abc":"\\u263a"}', 'abc');

View File

@ -60,20 +60,20 @@ There is currently no support for code points in the format `\uXXXX\uYYYY` that
The following functions are based on [simdjson](https://github.com/lemire/simdjson) designed for more complex JSON parsing requirements. The assumption 2 mentioned above still applies.
## JSONHas(params[, accessors]...)
## JSONHas(json[, indices_or_keys]...)
If the value exists in the JSON document, `1` will be returned.
If the value does not exist, `null` will be returned.
If the value does not exist, `0` will be returned.
Examples:
```
select JSONHas('{"a": "hello", "b": [-100, 200.0, 300]}', 'b') = 1
select JSONHas('{"a": "hello", "b": [-100, 200.0, 300]}', 'b', 4) = null
select JSONHas('{"a": "hello", "b": [-100, 200.0, 300]}', 'b', 4) = 0
```
An accessor can be either a string, a positive integer or a negative integer.
`indices_or_keys` is a list of zero or more arguments each of them can be either string or integer.
* String = access object member by key.
* Positive integer = access the n-th member/key from the beginning.
@ -91,11 +91,11 @@ select JSONExtractKey('{"a": "hello", "b": [-100, 200.0, 300]}', -2) = 'a'
select JSONExtractString('{"a": "hello", "b": [-100, 200.0, 300]}', 1) = 'hello'
```
## JSONLength(params[, accessors]...)
## JSONLength(json[, indices_or_keys]...)
Return the length of a JSON array or a JSON object.
If the value does not exist or has a wrong type, `null` will be returned.
If the value does not exist or has a wrong type, `0` will be returned.
Examples:
@ -104,13 +104,11 @@ select JSONLength('{"a": "hello", "b": [-100, 200.0, 300]}', 'b') = 3
select JSONLength('{"a": "hello", "b": [-100, 200.0, 300]}') = 2
```
The usage of accessors is the same as above.
## JSONType(params[, accessors]...)
## JSONType(json[, indices_or_keys]...)
Return the type of a JSON value.
If the value does not exist, `null` will be returned.
If the value does not exist, `Null` will be returned.
Examples:
@ -120,53 +118,80 @@ select JSONType('{"a": "hello", "b": [-100, 200.0, 300]}', 'a') = 'String'
select JSONType('{"a": "hello", "b": [-100, 200.0, 300]}', 'b') = 'Array'
```
The usage of accessors is the same as above.
## JSONExtractUInt(json[, indices_or_keys]...)
## JSONExtractInt(json[, indices_or_keys]...)
## JSONExtractFloat(json[, indices_or_keys]...)
## JSONExtractBool(json[, indices_or_keys]...)
## JSONExtractUInt(params[, accessors]...)
## JSONExtractInt(params[, accessors]...)
## JSONExtractFloat(params[, accessors]...)
## JSONExtractBool(params[, accessors]...)
## JSONExtractString(params[, accessors]...)
Parses a JSON and extract a value. These functions are similar to `visitParam` functions.
Parse data from JSON values which is similar to `visitParam` functions.
If the value does not exist or has a wrong type, `null` will be returned.
If the value does not exist or has a wrong type, `0` will be returned.
Examples:
```
select JSONExtractString('{"a": "hello", "b": [-100, 200.0, 300]}', 'a') = 'hello'
select JSONExtractInt('{"a": "hello", "b": [-100, 200.0, 300]}', 'b', 1) = -100
select JSONExtractFloat('{"a": "hello", "b": [-100, 200.0, 300]}', 'b', 2) = 200.0
select JSONExtractUInt('{"a": "hello", "b": [-100, 200.0, 300]}', 'b', -1) = 300
```
The usage of accessors is the same as above.
## JSONExtractString(json[, indices_or_keys]...)
## JSONExtract(params[, accessors...], type)
Parses a JSON and extract a string. This function is similar to `visitParamExtractString` functions.
Parse data from JSON values with a given ClickHouse data type.
If the value does not exist or has a wrong type, an empty string will be returned.
If the value does not exist or has a wrong type, `null` will be returned.
The value is unescaped. If unescaping failed, it returns an empty string.
Examples:
```
select JSONExtract('{"a": "hello", "b": [-100, 200.0, 300]}', 'b', 1, 'Int8') = -100
select JSONExtract('{"a": "hello", "b": [-100, 200.0, 300]}', 'Tuple(String, String, String, Array(Float64))') = ('a', 'hello', 'b', [-100.0, 200.0, 300.0])
select JSONExtractString('{"a": "hello", "b": [-100, 200.0, 300]}', 'a') = 'hello'
select JSONExtractString('{"abc":"\\n\\u0000"}', 'abc') = '\n\0'
select JSONExtractString('{"abc":"\\u263a"}', 'abc') = '☺'
select JSONExtractString('{"abc":"\\u263"}', 'abc') = ''
select JSONExtractString('{"abc":"hello}', 'abc') = ''
```
The usage of accessors is the same as above.
## JSONExtract(json[, indices_or_keys...], return_type)
## JSONExtractRaw(params[, accessors]...)
Parses a JSON and extract a value of the given ClickHouse data type.
This is a generalization of the previous `JSONExtract<type>` functions.
This means
`JSONExtract(..., 'String')` returns exactly the same as `JSONExtractString()`,
`JSONExtract(..., 'Float64')` returns exactly the same as `JSONExtractFloat()`.
Examples:
```
SELECT JSONExtract('{"a": "hello", "b": [-100, 200.0, 300]}', 'Tuple(String, Array(Float64))') = ('hello',[-100,200,300])
SELECT JSONExtract('{"a": "hello", "b": [-100, 200.0, 300]}', 'Tuple(b Array(Float64), a String)') = ([-100,200,300],'hello')
SELECT JSONExtract('{"a": "hello", "b": [-100, 200.0, 300]}', 'b', 'Array(Nullable(Int8))') = [-100, NULL, NULL]
SELECT JSONExtract('{"a": "hello", "b": [-100, 200.0, 300]}', 'b', 4, 'Nullable(Int64)') = NULL
SELECT JSONExtract('{"passed": true}', 'passed', 'UInt8') = 1
SELECT JSONExtract('{"day": "Thursday"}', 'day', 'Enum8(\'Sunday\' = 0, \'Monday\' = 1, \'Tuesday\' = 2, \'Wednesday\' = 3, \'Thursday\' = 4, \'Friday\' = 5, \'Saturday\' = 6)') = 'Thursday'
SELECT JSONExtract('{"day": 5}', 'day', 'Enum8(\'Sunday\' = 0, \'Monday\' = 1, \'Tuesday\' = 2, \'Wednesday\' = 3, \'Thursday\' = 4, \'Friday\' = 5, \'Saturday\' = 6)') = 'Friday'
```
## JSONExtractKeysAndValues(json[, indices_or_keys...], value_type)
Parse key-value pairs from a JSON where the values are of the given ClickHouse data type.
Example:
```
SELECT JSONExtractKeysAndValues('{"x": {"a": 5, "b": 7, "c": 11}}', 'x', 'Int8') = [('a',5),('b',7),('c',11)];
```
## JSONExtractRaw(json[, indices_or_keys]...)
Returns a part of JSON.
If the part does not exist or has a wrong type, `null` will be returned.
Examples:
If the part does not exist or has a wrong type, an empty string will be returned.
Example:
```
select JSONExtractRaw('{"a": "hello", "b": [-100, 200.0, 300]}', 'b') = '[-100, 200.0, 300]'
```
The usage of accessors is the same as above.