Available in versions: Dev (3.21) | Latest (3.20) | 3.19 | 3.18

JSON_GET_ATTRIBUTE_AS_TEXT

Supported by ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

JSON object attributes can be accessed by key as follows:

SELECT
  '{"a":"b"}'::json->'a'
create.select(jsonGetAttributeAsText(json("{\"a\":\"b\"}"), "a"))
      .fetch();

The result would look like this:

+----------------------------+
| json_get_attribute_as_text |
+----------------------------+
| b                          |
+----------------------------+

The API is PostgreSQL inspired, and as such, there are two ways of accessing attributes:

Dialect support

This example using jOOQ:

jsonGetAttributeAsText(json("{\"a\":1}"), "a")

Translates to the following dialect specific expressions:

Aurora Postgres, CockroachDB, Postgres, YugabyteDB

(CAST('{"a":1}' AS json)->>'a')

BigQuery

json_value(
  ('{"a":1}')['a'],
  '$'
)

ClickHouse

JSONExtractString('{"a":1}', 'a')

DB2

coalesce(
  json_value(
    '{"a":1}',
    ('$.' || CAST('a' AS varchar(3998)))
  ),
  json_query(
    '{"a":1}',
    ('$.' || CAST('a' AS varchar(3998)))
  )
)

DuckDB

('{"a":1}'->>'a')

MariaDB

json_unquote(nullif(
  CAST(json_extract(
    '{"a":1}',
    concat('$.', 'a')
  ) AS char),
  'null'
))

MySQL

json_unquote(nullif(
  json_extract(
    '{"a":1}',
    concat('$.', 'a')
  ),
  CAST('null' AS json)
))

Oracle

coalesce(
  json_value(
    '{"a":1}',
    '$.a'
  ),
  nullif(
    json_query(
      '{"a":1}',
      '$.a'
    ),
    'null'
  )
)

SQLite

json_extract(
  '{"a":1}',
  ('$.' || 'a')
)

SQLServer

coalesce(
  json_query(
    '{"a":1}',
    ('$.' + 'a')
  ),
  json_value(
    '{"a":1}',
    ('$.' + 'a')
  )
)

Trino

coalesce(
  json_extract_scalar(
    json_parse('{"a":1}'),
    ('$.' || 'a')
  ),
  json_format(nullif(
    json_extract(
      json_parse('{"a":1}'),
      ('$.' || 'a')
    ),
    json_parse('null')
  ))
)

ASE, Access, Aurora MySQL, Databricks, Exasol, Firebird, H2, HSQLDB, Hana, Informix, MemSQL, Redshift, SQLDataWarehouse, Snowflake, Spanner, Sybase, Teradata, Vertica

/* UNSUPPORTED */
Generated with jOOQ 3.21. Support in older jOOQ versions may differ. Translate your own SQL on our website

Feedback

Do you have any feedback about this page? We'd love to hear it!

The jOOQ Logo