JSON 路径表达式

适用于:勾选“是” Databricks SQL 勾选“是” Databricks Runtime

JSON 路径表达式用于从 JSON 字符串中提取值或使用 : 运算符VARIANT

语法

{ { identifier | [ field ] | [ * ] | [ index ] }
  [ . identifier | [ field ] | [ * ] | [ index ] ] [...] }

field*index 周围的括号是实际括号,并不表示可选语法。

参数

  • 标识符:JSON 字段的标识符。 对于 JSON STRING 类型,标识符不区分大小写。 对于 VARIANT 类型,区分大小写。
  • [ field ]:括号中区分大小写的 STRING 文本,用于标识 JSON 字段。
  • [ * ]:用于标识 JSON 数组中的所有元素。 VARIANT 不支持此语法。
  • [ index ]:一个整数文本,用于标识基于 0 的 JSON 数组中的特定元素。

返回

如果导航的表达式是 STRING,则为 STRING。 如果导航的表达式是 VARIANT,则为 VARIANT

如果存在具有未分隔的 null 值的 JSON 字段,则会收到该列的 SQL NULL 值,而不是 null 文本值。

可以使用 :: 运算符将值转换为基本数据类型。

使用 from_json 函数将嵌套结果转换为更复杂的数据类型,例如数组或结构。

备注

如果一个 JSON STRING 字段的名称不包含空格或特殊字符,且在不同情况下没有相同名称的字段,则可以使用未分隔标识符来引用该字段。

如果不存在不同大小写的同名字段,则可以使用分隔标识符。

[ field ] 表示法始终可以使用,但需要与字段的大小写完全匹配。

如果 Azure Databricks 无法唯一地标识字段,则会返回错误。 如果找不到任何字段的匹配项,则 Azure Databricks 将返回 NULL

可以在 VARIANT 中对 NULL 值进行编码,该值不是 SQL NULL。 因此,parse_json('null') IS NULLfalse,但 is_variant_null(parse_json('null'))true。 通过将 VARIANT 编码的 null 转换为 SQL NULL,可将其转换为某种类型。 例如,parse_json('null')::int IS NULLtrue

示例

下面的示例使用在示例数据中通过语句创建的数据。

本节内容:

使用标识符和分隔符进行提取

> SELECT raw:owner, raw:OWNER, raw:['owner'], raw:['OWNER'] FROM store_data;
  amy  amy  amy  NULL

-- Use backticks to escape special characters. References are case insensitive when you use backticks.
-- Use brackets to make them case sensitive.
> SELECT raw:`zip code`, raw:`Zip Code`, raw:['fb:testid'] FROM store_data;
  94025      94025      1234

提取嵌套字段

-- Use dot notation
> SELECT raw:store.bicycle FROM store_data;
  '{ "price":19.95, "color":"red" }'

-- Use brackets
> SELECT raw:['store']['bicycle'] FROM store_data;
  '{ "price":19.95, "color":"red" }'

从数组中提取值

-- Index elements
> SELECT raw:store.fruit[0], raw:store.fruit[1] FROM store_data;
  '{ "weight":8, "type":"apple" }'  '{ "weight":9, "type":"pear" }'

-- Extract subfields from arrays
> SELECT raw:store.book[*].isbn FROM store_data;
  '[ null, "0-553-21311-3", "0-395-19395-8" ]'

-- Access arrays within arrays or structs within arrays
> SELECT raw:store.basket[*],
         raw:store.basket[*][0] first_of_baskets,
         raw:store.basket[0][*] first_basket,
         raw:store.basket[*][*] all_elements_flattened,
         raw:store.basket[0][2].b subfield
  FROM store_data;
  basket                       first_of_baskets   first_basket          all_elements_flattened            subfield
 ---------------------------- ------------------ --------------------- --------------------------------- ----------
  [                            [                  [                     [1,2,{"b":"y","a":"x"},3,4,5,6]   y
    [1,2,{"b":"y","a":"x"}],     1,                 1,
    [3,4],                       3,                 2,
    [5,6]                        5                  {"b":"y","a":"x"}
  ]                            ]                  ]

NULL 行为

> SELECT '{"key":null}':key IS NULL sql_null, '{"key":"null"}':key IS NULL;
  true          false

强制转换值

-- price is returned as a double, not a string
> SELECT raw:store.bicycle.price::double FROM store_data
  19.95

-- use from_json to cast into more complex types
> SELECT from_json(raw:store.bicycle, 'price double, color string') bicycle FROM store_data
  '{ "price":19.95, "color":"red" }'

-- the column returned is an array of string arrays
> SELECT from_json(raw:store.basket[*], 'array<array<string>>') baskets FROM store_data
  '[
    ["1","2","{\"b\":\"y\",\"a\":\"x\"}]",
    ["3","4"],
    ["5","6"]
  ]'

VARIANT 表达式

-- Using JSON paths for VARIANT
> SELECT raw:store.bicycle FROM store_data_variant;
  '{ "price":19.95, "color":"red" }'

-- Extracting from VARIANT arrays
> SELECT raw:store.fruit[0], raw_variant:store.fruit[1] FROM store_data_variant;
  '{ "weight":8, "type":"apple" }'  '{ "weight":9, "type":"pear" }'

-- SQL NULL behavior of VARIANT NULL values
> SELECT
  parse_json(NULL) IS NULL AS sql_null,
  parse_json('null') IS NULL AS variant_null,
  parse_json('{ "field_a": null }'):field_a IS NULL AS variant_null_value,
  parse_json('{ "field_a": null }'):missing IS NULL AS missing_sql_value_null
  true  false  false  true

-- price is returned as a double, not a VARIANT
> SELECT raw:store.bicycle.price::double FROM store_data_variant
  19.95

示例数据

> CREATE TABLE store_data AS SELECT
'{
   "store":{
      "fruit": [
        {"weight":8,"type":"apple"},
        {"weight":9,"type":"pear"}
      ],
      "basket":[
        [1,2,{"b":"y","a":"x"}],
        [3,4],
        [5,6]
      ],
      "book":[
        {
          "author":"Nigel Rees",
          "title":"Sayings of the Century",
          "category":"reference",
          "price":8.95
        },
        {
          "author":"Herman Melville",
          "title":"Moby Dick",
          "category":"fiction",
          "price":8.99,
          "isbn":"0-553-21311-3"
        },
        {
          "author":"J. R. R. Tolkien",
          "title":"The Lord of the Rings",
          "category":"fiction",
          "reader":[
            {"age":25,"name":"bob"},
            {"age":26,"name":"jack"}
          ],
          "price":22.99,
          "isbn":"0-395-19395-8"
        }
      ],
      "bicycle":{
        "price":19.95,
        "color":"red"
      }
    },
    "owner":"amy",
    "zip code":"94025",
    "fb:testid":"1234"
 }' as raw

 > CREATE TABLE store_data_variant AS SELECT parse_json(raw) FROM store_data;