|
| 1 | +--- |
| 2 | +title: JQ |
| 3 | +--- |
| 4 | +import FunctionDescription from '@site/src/components/FunctionDescription'; |
| 5 | + |
| 6 | +<FunctionDescription description="Introduced or updated: v1.2.622"/> |
| 7 | + |
| 8 | +The JQ function is a set-returning SQL function that allows you to apply [jq](https://jqlang.github.io/jq/) filters to JSON data stored in Variant columns. With this function, you can process JSON data by applying a specified jq filter, returning the results as a set of rows. |
| 9 | + |
| 10 | +## Syntax |
| 11 | + |
| 12 | +```sql |
| 13 | +JQ (<jq_expression>, <json_data>) |
| 14 | +``` |
| 15 | + |
| 16 | +| Parameter | Description | |
| 17 | +|-----------------|-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------| |
| 18 | +| `jq_expression` | A `jq` filter expression that defines how to process and transform JSON data using the `jq` syntax. This expression can specify how to select, modify, and manipulate data within JSON objects and arrays. For information on the syntax, filters, and functions supported by jq, please refer to the [jq Manual](https://jqlang.github.io/jq/manual/#basic-filters). | |
| 19 | +| `json_data` | The JSON-formatted input that you want to process or transform using the `jq` filter expression. It can be a JSON object, array, or any valid JSON data structure. | |
| 20 | + |
| 21 | +## Return Type |
| 22 | + |
| 23 | +The JQ function returns a set of JSON values, where each value corresponds to an element of the transformed or extracted result based on the `<jq_expression>`. |
| 24 | + |
| 25 | +## Examples |
| 26 | + |
| 27 | +To start, we create a table named `customer_data` with columns for `id` and `profile`, where `profile` is a JSON type to store user information: |
| 28 | + |
| 29 | +```sql |
| 30 | +CREATE TABLE customer_data ( |
| 31 | + id INT, |
| 32 | + profile JSON |
| 33 | +); |
| 34 | + |
| 35 | +INSERT INTO customer_data VALUES |
| 36 | + (1, '{"name": "Alice", "age": 30, "city": "New York"}'), |
| 37 | + (2, '{"name": "Bob", "age": 25, "city": "Los Angeles"}'), |
| 38 | + (3, '{"name": "Charlie", "age": 35, "city": "Chicago"}'); |
| 39 | +``` |
| 40 | + |
| 41 | +This example extracts specific fields from the JSON data: |
| 42 | + |
| 43 | +```sql |
| 44 | +SELECT |
| 45 | + id, |
| 46 | + jq('.name', profile) AS customer_name |
| 47 | +FROM |
| 48 | + customer_data; |
| 49 | + |
| 50 | +┌─────────────────────────────────────┐ |
| 51 | +│ id │ customer_name │ |
| 52 | +├─────────────────┼───────────────────┤ |
| 53 | +│ 1 │ "Alice" │ |
| 54 | +│ 2 │ "Bob" │ |
| 55 | +│ 3 │ "Charlie" │ |
| 56 | +└─────────────────────────────────────┘ |
| 57 | +``` |
| 58 | + |
| 59 | +This example selects the user ID and the age incremented by 1 for each user: |
| 60 | + |
| 61 | +```sql |
| 62 | +SELECT |
| 63 | + id, |
| 64 | + jq('.age + 1', profile) AS updated_age |
| 65 | +FROM |
| 66 | + customer_data; |
| 67 | + |
| 68 | +┌─────────────────────────────────────┐ |
| 69 | +│ id │ updated_age │ |
| 70 | +├─────────────────┼───────────────────┤ |
| 71 | +│ 1 │ 31 │ |
| 72 | +│ 2 │ 26 │ |
| 73 | +│ 3 │ 36 │ |
| 74 | +└─────────────────────────────────────┘ |
| 75 | +``` |
| 76 | + |
| 77 | +This example converts city names to uppercase: |
| 78 | + |
| 79 | +```sql |
| 80 | +SELECT |
| 81 | + id, |
| 82 | + jq('.city | ascii_upcase', profile) AS city_uppercase |
| 83 | +FROM |
| 84 | + customer_data; |
| 85 | + |
| 86 | +┌─────────────────────────────────────┐ |
| 87 | +│ id │ city_uppercase │ |
| 88 | +├─────────────────┼───────────────────┤ |
| 89 | +│ 1 │ "NEW YORK" │ |
| 90 | +│ 2 │ "LOS ANGELES" │ |
| 91 | +│ 3 │ "CHICAGO" │ |
| 92 | +└─────────────────────────────────────┘ |
| 93 | +``` |
0 commit comments