├── .github └── FUNDING.yml ├── .gitignore ├── Dockerfile ├── LICENSE ├── Makefile ├── README.md ├── pgjq-demo.gif ├── pgjq.c ├── pgjq.control ├── sql └── pgjq--0.1.0.sql └── test ├── expected └── basic.out └── sql └── basic.sql /.github/FUNDING.yml: -------------------------------------------------------------------------------- 1 | github: [Florents-Tselai] 2 | -------------------------------------------------------------------------------- /.gitignore: -------------------------------------------------------------------------------- 1 | /dist/ 2 | /log/ 3 | /results/ 4 | /tmp_check/ 5 | regression.* 6 | *.o 7 | *.so 8 | *.bc 9 | *.dll 10 | *.dylib 11 | *.obj 12 | *.lib 13 | *.exp 14 | .deps/ 15 | .idea/ 16 | build/ 17 | 18 | -------------------------------------------------------------------------------- /Dockerfile: -------------------------------------------------------------------------------- 1 | ARG PG_MAJOR=16 2 | FROM postgres:$PG_MAJOR 3 | ARG PG_MAJOR 4 | 5 | COPY . /tmp/pgjq 6 | 7 | RUN apt-get update && \ 8 | apt-mark hold locales && \ 9 | apt-get install -y --no-install-recommends build-essential postgresql-server-dev-$PG_MAJOR jq libjq-dev && \ 10 | cd /tmp/pgjq && \ 11 | make clean && \ 12 | make OPTFLAGS="" && \ 13 | make install && \ 14 | mkdir /usr/share/doc/pgjq && \ 15 | cp LICENSE README.md /usr/share/doc/pgjq && \ 16 | rm -r /tmp/pgjq && \ 17 | apt-get remove -y build-essential postgresql-server-dev-$PG_MAJOR && \ 18 | apt-get autoremove -y && \ 19 | apt-mark unhold locales && \ 20 | rm -rf /var/lib/apt/lists/* -------------------------------------------------------------------------------- /LICENSE: -------------------------------------------------------------------------------- 1 | MIT License 2 | 3 | Copyright (c) 2023 Florents Tselai 4 | 5 | Permission is hereby granted, free of charge, to any person obtaining a copy 6 | of this software and associated documentation files (the "Software"), to deal 7 | in the Software without restriction, including without limitation the rights 8 | to use, copy, modify, merge, publish, distribute, sublicense, and/or sell 9 | copies of the Software, and to permit persons to whom the Software is 10 | furnished to do so, subject to the following conditions: 11 | 12 | The above copyright notice and this permission notice shall be included in all 13 | copies or substantial portions of the Software. 14 | 15 | THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR 16 | IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY, 17 | FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE 18 | AUTHORS OR COPYRIGHT HOLDERS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER 19 | LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM, 20 | OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN THE 21 | SOFTWARE. -------------------------------------------------------------------------------- /Makefile: -------------------------------------------------------------------------------- 1 | PG_CONFIG ?= pg_config 2 | 3 | EXTENSION = pgjq 4 | EXTVERSION = 0.1.0 5 | 6 | MODULE_big = $(EXTENSION) 7 | OBJS = pgjq.o 8 | PGFILEDESC = "Use jq in Postgres" 9 | 10 | DATA = $(wildcard sql/*--*.sql) 11 | 12 | TESTS = $(wildcard test/sql/*.sql) 13 | REGRESS = $(patsubst test/sql/%.sql,%,$(TESTS)) 14 | REGRESS_OPTS = --inputdir=test --load-extension=pgjq 15 | 16 | 17 | # Change this if you have jq installed somewhere else 18 | current_dir = $(shell pwd) 19 | JQ_PREFIX ?= $(current_dir)/jq/build 20 | 21 | PG_CPPFLAGS += -I$(JQ_PREFIX)/include 22 | PG_LDFLAGS += -L$(JQ_PREFIX)/lib 23 | SHLIB_LINK += -ljq 24 | 25 | PGXS := $(shell $(PG_CONFIG) --pgxs) 26 | include $(PGXS) 27 | 28 | tdd: clean all uninstall install installcheck -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | # pgJQ: Use `jq` in Postgres 2 | 3 | Docker Pulls 4 | GitHub Repo stars 5 | 6 | 7 | 8 | 9 | *Note*: If you like this idea check out: [liteJQ: jq extension for SQLite](https://github.com/Florents-Tselai/liteJQ) 10 | 11 | The **pgJQ** extension embeds the standard jq compiler and brings the much loved [jq](https://github.com/jqlang/jq) lang to Postgres. 12 | 13 | It adds a `jqprog` data type to express `jq` programs 14 | and a `jq(jsonb, jqprog)` function to execute them on `jsonb` objects. 15 | It works seamlessly with standard `jsonb` functions, operators, and `jsonpath`. 16 | 17 | ```sql 18 | SELECT jq('[{"bar": "baz", "balance": 7.77, "active":false}]'::jsonb, '.[0].bar'); 19 | ``` 20 | 21 | ``` 22 | jq 23 | ------- 24 | "baz" 25 | (1 row) 26 | ``` 27 | 28 | ![til](./pgjq-demo.gif) 29 | 30 | 31 | 32 | ## Usage 33 | 34 | ### Filters 35 | 36 | You can run basic filters: 37 | 38 | ```sql 39 | SELECT jq('[{"bar": "baz", "balance": 7.77, "active":false}]'::jsonb, '.[0].bar'); 40 | ``` 41 | 42 | ``` 43 | jq 44 | ------- 45 | "baz" 46 | (1 row) 47 | ``` 48 | 49 | ### `jsonb` `@@` `jqprog` 50 | 51 | If you're a syntactic sugar addict, you can use the `@@` operator to achieve the same. 52 | It's better be explicit with the `::jqprog` when using operators. 53 | 54 | ```sql 55 | SELECT '[{"bar": "baz", "balance": 7.77, "active":false}]' @@ '.[0].bar'::jqprog; 56 | ``` 57 | 58 | ``` 59 | jq 60 | ------- 61 | "baz" 62 | (1 row) 63 | ``` 64 | 65 | ### Complex Programs 66 | 67 | You can run more complex `jq` programs too: 68 | 69 | ```sql 70 | SELECT jq('[true,false,[5,true,[true,[false]],false]]', 71 | '(..|select(type=="boolean")) |= if . then 1 else 0 end'); 72 | ``` 73 | ``` 74 | jq 75 | ----------------------------- 76 | [1, 0, [5, 1, [1, [0]], 0]] 77 | (1 row) 78 | ``` 79 | 80 | ```sql 81 | SELECT jq('[1,5,3,0,7]' , '(.[] | select(. >= 2)) |= empty'); 82 | ``` 83 | ``` 84 | jq 85 | -------- 86 | [1, 0] 87 | (1 row) 88 | ``` 89 | 90 | ### Passing Arguments to `jqprog` 91 | 92 | If you want to pass dynamic arguments to `jqprog`, 93 | you can pass them as a `jsonb` object 94 | and refer to them as `$var`. 95 | 96 | ```sql 97 | select jq('{ 98 | "runner": 1, 99 | "message": "jobStatus", 100 | "jobs": [ 101 | { 102 | "id": 9, 103 | "is_successfull": true 104 | }, 105 | { 106 | "id": 100, 107 | "is_successfull": false, 108 | "metdata": { 109 | "environ": "prod" 110 | } 111 | } 112 | ] 113 | }'::jsonb, '.jobs[] | select(.is_successfull == $is_success and .id == 100) | .', '{"is_success": false, "id": 100}'); 114 | ``` 115 | ``` 116 | jq 117 | ---------------------------------------------------------------------- 118 | {"id": 100, "metdata": {"environ": "prod"}, "is_successfull": false} 119 | (1 row) 120 | ``` 121 | 122 | ### `jq` and `jsonpath` 123 | 124 | You can even chain `jq` and `jsonpath` together! 125 | 126 | Note here that the later part `- '{trans}' @> '{"cust": "baz"}'` is `jsonpath`, not `jq` code. 127 | ```sql 128 | SELECT jq('[ 129 | { 130 | "cust": "baz", 131 | "trans": { 132 | "balance": 100, 133 | "date": "2023-08-01" 134 | }, 135 | "active": true, 136 | "geo": { 137 | "branch": "paloukia" 138 | } 139 | } 140 | ]', '(.[] | select(.active == true))') - '{trans}' @> '{"cust": "baz"}'; 141 | ``` 142 | ``` 143 | ?column? 144 | ---------- 145 | t 146 | (1 row) 147 | ``` 148 | 149 | If you opt for using operators here, you should help the parser by adding parentheses and explicit casts. 150 | 151 | ```sql 152 | SELECT ('[ 153 | { 154 | "cust": "baz", 155 | "trans": { 156 | "balance": 100, 157 | "date": "2023-08-01" 158 | }, 159 | "active": true, 160 | "geo": { 161 | "branch": "paloukia" 162 | } 163 | } 164 | ]' @@ '(.[] | select(.active == true))'::jqprog) - '{trans}' @> '{"cust": "baz"}'; 165 | ``` 166 | 167 | It is strongly recommended to be explicit 168 | with type casts and ordering when using overloaded operators, 169 | especially when you're working a lot with text. 170 | Otherwise, you'll find yourself in an obfuscated labyrinth of 171 | `jqprog`s, `jsonb`s, `jsonpath`s and possibly `tsvector`s , 172 | impossible to escape from. 173 | 174 | ### Working with Files 175 | 176 | If you have superuser privileges in Postgres you can use the `pg_read_file` 177 | to run your queries on JSON files. 178 | 179 | ```sql 180 | SELECT jq(pg_read_file('/path/to/f.json', '.[]')) 181 | ``` 182 | 183 | You can see more examples in the [test cases](test/sql/basic.sql) 184 | or try reproducing the [`jq` manual](https://jqlang.github.io/jq/manual/) . 185 | 186 | ## Installation 187 | 188 | ```sh 189 | git clone https://github.com/Florents-Tselai/pgJQ.git 190 | cd pgJQ 191 | make install # set PG_CONFIG=/path/to/bin/pg_config if necessary. 192 | make installcheck 193 | ``` 194 | 195 | In a Postgres session run 196 | 197 | ```sql 198 | CREATE EXTENSION pgjq 199 | ``` 200 | 201 | ## How it Works 202 | 203 | pgJQ does not re-implement the `jq` lang in Postgres. 204 | It instead embeds the standard `jq` compiler and uses it to parse `jq` programs supplied in SQL queries. 205 | These programs are fed with `jsonb` objects as input. 206 | 207 | ## Issues 208 | 209 | `jq` has evolved from *just a cli tool* to a full-fledged DSL, 210 | but it still remains a 20-80 tool. 211 | 212 | **pgJQ** has been TDDed against those 20% of the cases. 213 | If you come across regressions between vanilla `jq` and pgJQ, 214 | especially around piped filters or complex functions, 215 | please do add an issue, along with a test case! 216 | 217 | Keeping in mind, though, that there's probably not much point reproducing the whole 218 | DSL in an RDBMS context. 219 | 220 | Some known issues are: 221 | * Only string, bool and numeric arguments can be passed to `jqprog`. 222 | * Currently, `jq` programs including pipes, like `.[] | .name` are buggy and unpredictable. 223 | * Modules are not supported, but they could be theoretically supported, given that Postgres is fairly open to dynamic loading. 224 | -------------------------------------------------------------------------------- /pgjq-demo.gif: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/Florents-Tselai/pgJQ/57a326b591117adfc2d2709bfdc545c1be905cc0/pgjq-demo.gif -------------------------------------------------------------------------------- /pgjq.c: -------------------------------------------------------------------------------- 1 | #include "postgres.h" 2 | #include "utils/jsonb.h" 3 | 4 | #include "utils/builtins.h" 5 | 6 | #include "stdlib.h" 7 | #include "stdio.h" 8 | #include "utils/numeric.h" 9 | 10 | #include "jq.h" 11 | 12 | 13 | PG_MODULE_MAGIC; 14 | 15 | /* This is useed recursively so we have to declare it here first */ 16 | static JsonbValue *JvObject_to_JsonbValue(jv *obj, JsonbParseState **jsonb_state, bool is_elem); 17 | 18 | /* -------------- 19 | * Missing JQ API 20 | * 21 | * As JQ misses an API intended to be used as a library, 22 | * The following have been copied & reverse-engineered from jq/src/main.c 23 | * 24 | * You'll see a lot "variable not used" warnings there. 25 | * I know. Don't remove them just to make the compiler happy. 26 | * We may need them once bugs are discovered. 27 | * 28 | * -------------- 29 | * */ 30 | enum { 31 | SLURP = 1, 32 | RAW_INPUT = 2, 33 | PROVIDE_NULL = 4, 34 | RAW_OUTPUT = 8, 35 | RAW_OUTPUT0 = 16, 36 | ASCII_OUTPUT = 32, 37 | COLOR_OUTPUT = 64, 38 | NO_COLOR_OUTPUT = 128, 39 | SORTED_OUTPUT = 256, 40 | FROM_FILE = 512, 41 | RAW_NO_LF = 1024, 42 | UNBUFFERED_OUTPUT = 2048, 43 | EXIT_STATUS = 4096, 44 | EXIT_STATUS_EXACT = 8192, 45 | SEQ = 16384, 46 | RUN_TESTS = 32768, 47 | /* debugging only */ 48 | DUMP_DISASM = 65536, 49 | }; 50 | 51 | enum { 52 | JQ_OK = 0, 53 | JQ_OK_NULL_KIND = -1, /* exit 0 if --exit-status is not set*/ 54 | JQ_ERROR_SYSTEM = 2, 55 | JQ_ERROR_COMPILE = 3, 56 | JQ_OK_NO_OUTPUT = -4, /* exit 0 if --exit-status is not set*/ 57 | JQ_ERROR_UNKNOWN = 5, 58 | }; 59 | 60 | /* jq/src/util.h:priv_fwrite() */ 61 | static void jq_priv_fwrite(const char *s, size_t len, FILE *fout, int is_tty) { 62 | #ifdef WIN32 63 | if (is_tty) 64 | WriteFile((HANDLE)_get_osfhandle(fileno(fout)), s, len, NULL, NULL); 65 | else 66 | fwrite(s, 1, len, fout); 67 | #else 68 | fwrite(s, 1, len, fout); 69 | #endif 70 | } 71 | 72 | static int jq_process(jq_state *jq, jv value, int flags, int dumpopts, int options, jv *out_result) { 73 | jv result; 74 | 75 | int ret = JQ_OK_NO_OUTPUT; // No valid results && -e -> exit(4) 76 | jq_start(jq, value, flags); 77 | while (jv_is_valid(result = jq_next(jq))) { 78 | 79 | if ((options & RAW_OUTPUT) && jv_get_kind(result) == JV_KIND_STRING) { 80 | 81 | if (options & ASCII_OUTPUT) { 82 | jv_dumpf(jv_copy(result), stdout, JV_PRINT_ASCII); 83 | } else if ((options & RAW_OUTPUT0) && 84 | strlen(jv_string_value(result)) != (unsigned long) jv_string_length_bytes(jv_copy(result))) { 85 | jv_free(result); 86 | result = jv_invalid_with_msg(jv_string( 87 | "Cannot dump a string containing NUL with --raw-output0 option")); 88 | break; 89 | } else { 90 | jq_priv_fwrite(jv_string_value(result), jv_string_length_bytes(jv_copy(result)), 91 | stdout, dumpopts & JV_PRINT_ISATTY); 92 | } 93 | ret = JQ_OK; 94 | jv_free(result); 95 | } else { 96 | if (jv_get_kind(result) == JV_KIND_FALSE || jv_get_kind(result) == JV_KIND_NULL) 97 | ret = JQ_OK_NULL_KIND; 98 | else 99 | ret = JQ_OK; 100 | if (options & SEQ) 101 | jq_priv_fwrite("\036", 1, stdout, dumpopts & JV_PRINT_ISATTY); 102 | 103 | *out_result = jv_copy(result); 104 | 105 | } 106 | if (!(options & RAW_NO_LF)) 107 | jq_priv_fwrite("\n", 1, stdout, dumpopts & JV_PRINT_ISATTY); 108 | if (options & RAW_OUTPUT0) 109 | jq_priv_fwrite("\0", 1, stdout, dumpopts & JV_PRINT_ISATTY); 110 | if (options & UNBUFFERED_OUTPUT) 111 | 112 | fflush(stdout); 113 | } 114 | if (jq_halted(jq)) { 115 | // jq program invoked `halt` or `halt_error` 116 | options |= EXIT_STATUS_EXACT; 117 | jv exit_code = jq_get_exit_code(jq); 118 | if (!jv_is_valid(exit_code)) 119 | ret = JQ_OK; 120 | else if (jv_get_kind(exit_code) == JV_KIND_NUMBER) 121 | ret = jv_number_value(exit_code); 122 | else 123 | ret = JQ_ERROR_UNKNOWN; 124 | jv_free(exit_code); 125 | jv error_message = jq_get_error_message(jq); 126 | if (jv_get_kind(error_message) == JV_KIND_STRING) { 127 | // No prefix should be added to the output of `halt_error`. 128 | jq_priv_fwrite(jv_string_value(error_message), jv_string_length_bytes(jv_copy(error_message)), 129 | stderr, dumpopts & JV_PRINT_ISATTY); 130 | } else if (jv_get_kind(error_message) == JV_KIND_NULL) { 131 | // Halt with no output 132 | } else if (jv_is_valid(error_message)) { 133 | error_message = jv_dump_string(error_message, 0); 134 | ereport(ERROR, 135 | (errmsg("%s\n", jv_string_value(error_message)))); 136 | 137 | } // else no message on stderr; use --debug-trace to see a message 138 | fflush(stderr); 139 | jv_free(error_message); 140 | } else if (jv_invalid_has_msg(jv_copy(result))) { 141 | // Uncaught jq exception 142 | jv msg = jv_invalid_get_msg(jv_copy(result)); 143 | jv input_pos = jq_util_input_get_position(jq); 144 | if (jv_get_kind(msg) == JV_KIND_STRING) { 145 | 146 | fprintf(stderr, "jq: BOOOM error (at %s): %s\n", 147 | jv_string_value(input_pos), jv_string_value(msg)); 148 | 149 | } else { 150 | msg = jv_dump_string(msg, 0); 151 | fprintf(stderr, "jq: error (at %s) (not a string): %s\n", 152 | jv_string_value(input_pos), jv_string_value(msg)); 153 | } 154 | ret = JQ_ERROR_UNKNOWN; 155 | jv_free(input_pos); 156 | jv_free(msg); 157 | } 158 | jv_free(result); 159 | return ret; 160 | } 161 | 162 | /* 163 | * jqprog is basically a text 164 | * 165 | * */ 166 | 167 | typedef text jqprog; 168 | #define DatumGetJqProgP(X) ((jqprog *) PG_DETOAST_DATUM(X)) 169 | #define DatumGetJqProgPP(X) ((jqprog *) PG_DETOAST_DATUM_PACKED(X)) 170 | #define JqPGetDatum(X) PointerGetDatum(X) 171 | 172 | #define PG_GETARG_JQPROG_P(n) DatumGetJqP(PG_GETARG_DATUM(n)) 173 | #define PG_GETARG_JQPROG_PP(n) DatumGetJqPP(PG_GETARG_DATUM(n)) 174 | #define PG_RETURN_JQPROG_P(x) PG_RETURN_POINTER(x) 175 | 176 | PG_FUNCTION_INFO_V1(jqprog_in); 177 | 178 | Datum 179 | jqprog_in(PG_FUNCTION_ARGS) { 180 | char *s = PG_GETARG_CSTRING(0); 181 | jqprog *vardata; 182 | 183 | /* TODO: validate here = compile the expression */ 184 | 185 | vardata = (jqprog *) cstring_to_text(s); 186 | PG_RETURN_JQPROG_P(vardata); 187 | } 188 | 189 | PG_FUNCTION_INFO_V1(jqprog_out); 190 | 191 | Datum 192 | jqprog_out(PG_FUNCTION_ARGS) { 193 | Datum arg = PG_GETARG_DATUM(0); 194 | 195 | PG_RETURN_CSTRING(TextDatumGetCString(arg)); 196 | } 197 | 198 | /* 199 | * A recursive parser that converts a jv (jq) object to a JsonbValue (Postgres) 200 | */ 201 | 202 | static void JvNumber_ToJsonbValue(jv *obj, JsonbValue *jbvElem) { 203 | jbvElem->type = jbvNumeric; 204 | 205 | jbvElem->val.numeric = DatumGetNumeric(DirectFunctionCall1(float8_numeric, Float8GetDatum(jv_number_value(*obj)))); 206 | } 207 | 208 | static void JvString_ToJsonbValue(jv *obj, JsonbValue *jbvElem) { 209 | jbvElem->type = jbvString; 210 | jbvElem->val.string.val = jv_string_value(*obj); 211 | jbvElem->val.string.len = strlen(jbvElem->val.string.val); 212 | } 213 | 214 | static JsonbValue *JvArray_ToJsonbValue(jv *obj, JsonbParseState **jsonb_state) { 215 | Assert(jv_get_kind(*obj) == JV_KIND_ARRAY); 216 | 217 | jv *volatile value = NULL; 218 | 219 | value = palloc(sizeof(jv)); 220 | 221 | pushJsonbValue(jsonb_state, WJB_BEGIN_ARRAY, NULL); 222 | 223 | /* FIXME: is there maybe a memory leak around here with how value is handled ? */ 224 | jv_array_foreach(*obj, idx, elem) { 225 | *value = jv_copy(elem); 226 | (void) JvObject_to_JsonbValue(value, jsonb_state, true); 227 | } 228 | 229 | return pushJsonbValue(jsonb_state, WJB_END_ARRAY, NULL); 230 | } 231 | 232 | static JsonbValue *JvJsonObject_ToJsonbValue(jv *obj, JsonbParseState **jsonb_state) { 233 | Assert(jv_get_kind(*obj) == JV_KIND_OBJECT); 234 | 235 | JsonbValue *volatile out; 236 | 237 | pushJsonbValue(jsonb_state, WJB_BEGIN_OBJECT, NULL); 238 | 239 | jv_object_foreach(*obj, obj_key, obj_item) { 240 | JsonbValue jbvKey; 241 | 242 | if (jv_get_kind(obj_item) == JV_KIND_NULL) { 243 | /* FIXME: should this ever happend? */ 244 | } else { 245 | JvString_ToJsonbValue(&obj_key, &jbvKey); 246 | } 247 | 248 | (void) pushJsonbValue(jsonb_state, WJB_KEY, &jbvKey); 249 | (void) JvObject_to_JsonbValue(&obj_item, jsonb_state, false); 250 | } 251 | out = pushJsonbValue(jsonb_state, WJB_END_OBJECT, NULL); 252 | 253 | return out; 254 | } 255 | 256 | static JsonbValue *JvObject_to_JsonbValue(jv *obj, JsonbParseState **jsonb_state, bool is_elem) { 257 | JsonbValue *out; 258 | 259 | if (jv_get_kind(*obj) != JV_KIND_STRING) { 260 | if (jv_get_kind(*obj) == JV_KIND_ARRAY) 261 | return JvArray_ToJsonbValue(obj, jsonb_state); 262 | else if (jv_get_kind(*obj) == JV_KIND_OBJECT) 263 | return JvJsonObject_ToJsonbValue(obj, jsonb_state); 264 | 265 | } 266 | 267 | out = palloc(sizeof(JsonbValue)); 268 | 269 | if (jv_get_kind(*obj) == JV_KIND_NULL) 270 | out->type = jbvNull; 271 | 272 | else if (jv_get_kind(*obj) == JV_KIND_STRING) 273 | JvString_ToJsonbValue(obj, out); 274 | 275 | else if ((jv_get_kind(*obj) == JV_KIND_TRUE) || (jv_get_kind(*obj) == JV_KIND_FALSE)) { 276 | out->type = jbvBool; 277 | if (jv_get_kind(*obj) == JV_KIND_TRUE) 278 | out->val.boolean = true; 279 | else if (jv_get_kind(*obj) == JV_KIND_FALSE) 280 | out->val.boolean = false; 281 | else 282 | /* Shouldn't happen */ 283 | ereport(ERROR, 284 | (errcode(ERRCODE_ASSERT_FAILURE), 285 | errmsg("something really bad happened with jv boolean stuff"))); 286 | 287 | } else if (jv_get_kind(*obj) == JV_KIND_NUMBER) 288 | JvNumber_ToJsonbValue(obj, out); 289 | 290 | else 291 | ereport(ERROR, 292 | (errcode(ERRCODE_FEATURE_NOT_SUPPORTED), 293 | errmsg("JV type \"%s\" cannot be transformed to jsonb", 294 | jv_kind_name(jv_get_kind(*obj))))); 295 | return (*jsonb_state ? 296 | pushJsonbValue(jsonb_state, is_elem ? WJB_ELEM : WJB_VALUE, out) : 297 | out); 298 | } 299 | 300 | PG_FUNCTION_INFO_V1(jq); 301 | 302 | Datum 303 | jq(PG_FUNCTION_ARGS) { 304 | 305 | /* Input JSON and accompanying metadata */ 306 | Jsonb *jsonb = PG_GETARG_JSONB_P(0); 307 | JsonbValue *jbvIn; 308 | jbvIn = palloc(sizeof(JsonbValue)); 309 | 310 | if (jbvIn == NULL) 311 | ereport(ERROR, (errmsg("could not allocate jsonbValueIn"))); 312 | 313 | JsonbToJsonbValue(jsonb, jbvIn); 314 | 315 | char *json_string = JsonbToCString(NULL, &jsonb->root, VARSIZE(jsonb)); 316 | 317 | /* The JQ program to execute */ 318 | char *program = text_to_cstring(PG_GETARG_TEXT_PP(1)); 319 | 320 | /* --argjson --- */ 321 | Jsonb *jsonbArgs = PG_GETARG_JSONB_P(2); 322 | JsonbValue *jbvArgs; 323 | JsonbIterator *argsIt; 324 | JsonbValue argsV; 325 | JsonbIteratorToken argsToken; 326 | 327 | /* As jq works with stream, let's make the input json char* act like a stream */ 328 | FILE *file_json = fmemopen(json_string, strlen(json_string), "r"); 329 | 330 | 331 | if (file_json == NULL) 332 | ereport(ERROR, (errmsg("error in fmemopen(file_json))"))); 333 | 334 | /* Output */ 335 | 336 | /* The jv_result above is converted to this datum which is returned */ 337 | JsonbValue *jbvOut; 338 | JsonbParseState *jsonb_state = NULL; 339 | 340 | /* Now start building the jq processor like in src/jq/main.c */ 341 | 342 | jv ARGS; 343 | jv program_arguments; 344 | 345 | jq_state *jq = NULL; 346 | int ret = JQ_OK_NO_OUTPUT; 347 | int compiled = 0; 348 | int parser_flags = 0; 349 | int last_result = -1; /* -1 = no result, 0=null or false, 1=true */ 350 | int options = 0; 351 | int dumpopts; 352 | int jq_flags; 353 | 354 | jv value; /* The json value being parsed by jq parsers */ 355 | jv obj; /* The result of jq processing */ 356 | 357 | /* Now start jq processing */ 358 | 359 | /* Init jq */ 360 | ARGS = jv_object(); /* This is actually not used in pgjq, probably never will */ 361 | program_arguments = jv_object(); /*looks like that's the object storing --argson args*/ 362 | 363 | /* set program_arguments 364 | * Iterate over argsV and set them to program_arguments 365 | * */ 366 | jbvArgs = palloc(sizeof(JsonbValue)); 367 | argsIt = JsonbIteratorInit(&jsonbArgs->root); 368 | bool skipNested = true; 369 | while ((argsToken = JsonbIteratorNext(&argsIt, &argsV, skipNested)) != WJB_DONE) { 370 | skipNested = true; 371 | if (argsToken == WJB_KEY) { 372 | text *key; 373 | Datum values[2]; /* TODO: looks like this is not used */ 374 | bool nulls[2] = {false, false}; 375 | 376 | 377 | key = cstring_to_text_with_len(argsV.val.string.val, argsV.val.string.len); 378 | 379 | /* 380 | * The next thing the iterator fetches should be the value, no 381 | * matter what shape it is. 382 | */ 383 | argsToken = JsonbIteratorNext(&argsIt, &argsV, skipNested); 384 | Assert(argsToken != WJB_DONE); 385 | 386 | values[0] = PointerGetDatum(key); 387 | 388 | if (argsV.type == jbvNull) { 389 | /* a json null is an sql null in text mode */ 390 | nulls[1] = true; 391 | values[1] = (Datum) NULL; 392 | } else { 393 | values[1] = PointerGetDatum(JsonbValueToJsonb(&argsV)); 394 | 395 | if (argsV.type == jbvNumeric) { 396 | /* TODO: extract the conversion as a separate function */ 397 | jv_object_set(program_arguments, jv_string(text_to_cstring(key)), 398 | jv_number(DatumGetFloat8( 399 | DirectFunctionCall1(numeric_float8, NumericGetDatum(argsV.val.numeric))))); 400 | } else if (argsV.type == jbvString) { 401 | jv_object_set(program_arguments, jv_string(text_to_cstring(key)), 402 | jv_string(argsV.val.string.val)); 403 | 404 | } else if (argsV.type == jbvBool) { 405 | jv_object_set(program_arguments, 406 | jv_string(text_to_cstring(key)), 407 | jv_bool(argsV.val.boolean)); 408 | 409 | } else { 410 | ereport(ERROR, 411 | (errcode(ERRCODE_FEATURE_NOT_SUPPORTED), 412 | errmsg("Currently only numeric, string and bool arguments can be passed to jqprog"))); 413 | 414 | } 415 | 416 | } 417 | 418 | 419 | } 420 | 421 | } 422 | 423 | 424 | jq = jq_init(); 425 | if (jq == NULL) 426 | ereport(ERROR, (errmsg("pgjq: error initializing JQ (malloc)"))); 427 | 428 | 429 | dumpopts = JV_PRINT_INDENT_FLAGS(2); 430 | 431 | /* This if-else has been implemented in a: 432 | * this-combination-looks-like-it-works 433 | * Need to make this more predictable. 434 | * */ 435 | if (jbvIn->type == jbvArray) 436 | options |= SLURP; 437 | else 438 | options |= PROVIDE_NULL; 439 | 440 | dumpopts &= ~(JV_PRINT_TAB | JV_PRINT_INDENT_FLAGS(7)); /* --compact-output */ 441 | 442 | jq_flags = 0; 443 | 444 | /* Compile the program */ 445 | compiled = jq_compile_args(jq, program, jv_copy(program_arguments)); 446 | 447 | if (compiled < 1) 448 | ereport(ERROR, 449 | (errmsg("pgjq: could not compile program: %s . Check your syntax\n", program))); 450 | 451 | 452 | jq_util_input_state *input_state = jq_util_input_init(NULL, NULL); // XXX add err_cb 453 | 454 | if ((options & RAW_INPUT)) 455 | jq_util_input_set_parser(input_state, NULL, (options & SLURP) ? 1 : 0); 456 | else 457 | jq_util_input_set_parser(input_state, jv_parser_new(parser_flags), (options & SLURP) ? 1 : 0); 458 | 459 | value = jv_parse(json_string); 460 | ret = jq_process(jq, value, jq_flags, dumpopts, options, &obj); 461 | 462 | /* Start building the result */ 463 | jbvOut = JvObject_to_JsonbValue(&obj, &jsonb_state, true); 464 | 465 | /* free */ 466 | jv_free(ARGS); 467 | jv_free(program_arguments); 468 | jq_util_input_free(&input_state); 469 | jq_teardown(&jq); 470 | jv_free(obj); 471 | pfree(jbvIn); 472 | pfree(jbvArgs); 473 | fclose(file_json); 474 | 475 | PG_RETURN_JSONB_P(JsonbValueToJsonb(jbvOut)); 476 | } 477 | -------------------------------------------------------------------------------- /pgjq.control: -------------------------------------------------------------------------------- 1 | comment = 'jq in Postgres' 2 | default_version = '0.1.0' 3 | module_pathname = '$libdir/pgjq' 4 | relocatable = true 5 | comment = 'Use jq in Postgres' -------------------------------------------------------------------------------- /sql/pgjq--0.1.0.sql: -------------------------------------------------------------------------------- 1 | CREATE TYPE jqprog; 2 | 3 | CREATE FUNCTION jqprog_in(cstring) RETURNS jqprog 4 | IMMUTABLE 5 | STRICT 6 | LANGUAGE C 7 | AS 8 | 'MODULE_PATHNAME'; 9 | 10 | CREATE FUNCTION jqprog_out(jqprog) RETURNS cstring 11 | IMMUTABLE 12 | STRICT 13 | LANGUAGE C 14 | AS 15 | 'MODULE_PATHNAME'; 16 | 17 | CREATE TYPE jqprog 18 | ( 19 | INTERNALLENGTH = -1, 20 | INPUT = jqprog_in, 21 | OUTPUT = jqprog_out 22 | ); 23 | 24 | 25 | CREATE CAST (jqprog AS text) WITH INOUT AS ASSIGNMENT; 26 | CREATE CAST (text AS jqprog) WITH INOUT AS ASSIGNMENT; 27 | 28 | CREATE FUNCTION jq(jsonb, jqprog, jsonb DEFAULT '{}') RETURNS jsonb 29 | AS 30 | 'MODULE_PATHNAME' LANGUAGE C IMMUTABLE 31 | STRICT 32 | PARALLEL SAFE; 33 | 34 | CREATE FUNCTION __op_jq_jsonb_jqprog(jsonb, jqprog) RETURNS jsonb 35 | AS 36 | 'SELECT jq($1, $2)' 37 | LANGUAGE SQL 38 | IMMUTABLE 39 | STRICT 40 | PARALLEL SAFE; 41 | 42 | CREATE OPERATOR @@ ( 43 | LEFTARG = jsonb, 44 | RIGHTARG = jqprog, 45 | FUNCTION = __op_jq_jsonb_jqprog 46 | ); 47 | 48 | -------------------------------------------------------------------------------- /test/expected/basic.out: -------------------------------------------------------------------------------- 1 | /* --- Type creation and casts --- */ 2 | select 'gsdfgf'::jqprog; 3 | jqprog 4 | -------- 5 | gsdfgf 6 | (1 row) 7 | 8 | select 1345::jqprog; 9 | ERROR: cannot cast type integer to jqprog 10 | LINE 1: select 1345::jqprog; 11 | ^ 12 | /* --- Arrays as input --- */ 13 | select jq('[{"bar": "baz", "balance": 7.77, "active":false}]'::jsonb, '.[0].bar'); 14 | jq 15 | ------- 16 | "baz" 17 | (1 row) 18 | 19 | select jq('[{"bar": "baz", "balance": 7.77, "active":false}]'::jsonb, '.[0].balance'); 20 | jq 21 | ------ 22 | 7.77 23 | (1 row) 24 | 25 | select jq('[{"bar": "baz", "balance": 7.77, "balance_int": 7, "active":false}]'::jsonb, '.[0].balance_int'); 26 | jq 27 | ---- 28 | 7 29 | (1 row) 30 | 31 | select jq('[{"bar": "baz", "balance": 7.77, "active":false}]'::jsonb, '.[0].active'); 32 | jq 33 | ------- 34 | false 35 | (1 row) 36 | 37 | select jq('[{"bar": "baz", "balance": 7.77, "active":false, "keno": null}]'::jsonb, '.[0].keno'); 38 | jq 39 | ------ 40 | null 41 | (1 row) 42 | 43 | select jq('[{"bar": "baz", "balance": 7.77, "active":false, "keno": null}]'::jsonb, '.[0].keno'); 44 | jq 45 | ------ 46 | null 47 | (1 row) 48 | 49 | select jq('[["a", "b", "c"]]'::jsonb, '.[0]'); 50 | jq 51 | ----------------- 52 | ["a", "b", "c"] 53 | (1 row) 54 | 55 | select jq('[["a", "b", "c"]]'::jsonb, '.[0].[0]'); 56 | jq 57 | ----- 58 | "a" 59 | (1 row) 60 | 61 | select jq('[["a", "b", "c"]]'::jsonb, '.[0].[1]'); 62 | jq 63 | ----- 64 | "b" 65 | (1 row) 66 | 67 | select jq('[["a", "b", "c"]]'::jsonb, '.[0].[1000]'); 68 | jq 69 | ------ 70 | null 71 | (1 row) 72 | 73 | select jq('[{"bar": "baz", "balance": 7.77, "active":false}]'::jsonb, '.[0]'); 74 | jq 75 | -------------------------------------------------- 76 | {"bar": "baz", "active": false, "balance": 7.77} 77 | (1 row) 78 | 79 | select jq('[{"bar": "baz", "balance": 7.77, "active":false}]'::jsonb, '.[100]'); 80 | jq 81 | ------ 82 | null 83 | (1 row) 84 | 85 | select jq('[{"bar": "baz", "balance": 7.77, "active":false}]'::jsonb, '.[0].bar'); 86 | jq 87 | ------- 88 | "baz" 89 | (1 row) 90 | 91 | select jq('[{"bar": "baz", "balance": 7.77, "active":false}]'::jsonb, '.[0].gdfgdf'); 92 | jq 93 | ------ 94 | null 95 | (1 row) 96 | 97 | /* --- Single object as input --- */ 98 | select jq('{"bar": "baz", "balance": 7.77, "active":false}'::jsonb, '.'); 99 | jq 100 | -------------------------------------------------- 101 | {"bar": "baz", "active": false, "balance": 7.77} 102 | (1 row) 103 | 104 | select jq('{"bar": "baz", "balance": 7.77, "active":false}'::jsonb, '.baz'); 105 | jq 106 | ------ 107 | null 108 | (1 row) 109 | 110 | select jq('{"bar": "baz", "balance": 7.77, "active":false}'::jsonb, '.balance'); 111 | jq 112 | ------ 113 | 7.77 114 | (1 row) 115 | 116 | select jq('{"bar": "baz", "balance": 7.77, "active":false}'::jsonb, '.gdfgfd'); 117 | jq 118 | ------ 119 | null 120 | (1 row) 121 | 122 | select jq('{"user":"stedolan", "projects": ["jq", "wikiflow"]}', '.user, .projects[]'); 123 | jq 124 | ------------ 125 | "wikiflow" 126 | (1 row) 127 | 128 | /* --- Nested object --- */ 129 | select jq('{"bar": "baz", "balance": 7.77, "active":false, "inner": {"key": "value"}}'::jsonb, '.gdfgfd'); 130 | jq 131 | ------ 132 | null 133 | (1 row) 134 | 135 | select jq('{"bar": "baz", "balance": 7.77, "active":false, "inner": {"key": "value"}}'::jsonb, '.inner'); 136 | jq 137 | ------------------ 138 | {"key": "value"} 139 | (1 row) 140 | 141 | select jq('{"bar": "baz", "balance": 7.77, "active":false, "inner": {"key": "value"}}'::jsonb, '.inner.key'); 142 | jq 143 | --------- 144 | "value" 145 | (1 row) 146 | 147 | select jq('{"bar": "baz", "balance": 7.77, "active":false, "inner": {"key": "value"}}'::jsonb, '.gdfgfd'); 148 | jq 149 | ------ 150 | null 151 | (1 row) 152 | 153 | /* --- pick --- */ 154 | select jq('{"a": [123]}', '.a[]'); 155 | jq 156 | ----- 157 | 123 158 | (1 row) 159 | 160 | /* --- assignment --- */ 161 | select jq('[true,false,[5,true,[true,[false]],false]]', '(..|select(type=="boolean")) |= if . then 1 else 0 end'); 162 | jq 163 | ----------------------------- 164 | [1, 0, [5, 1, [1, [0]], 0]] 165 | (1 row) 166 | 167 | select jq('{"foo": 42}', '.foo += 1'); 168 | jq 169 | ------------- 170 | {"foo": 43} 171 | (1 row) 172 | 173 | select jq('{"a": {"b": 10}, "b": 20}', '.a = .b'); 174 | jq 175 | -------------------- 176 | {"a": 20, "b": 20} 177 | (1 row) 178 | 179 | /* --- select --- */ 180 | select jq('[1,5,3,0,7]' , '(.[] | select(. >= 2)) |= empty'); 181 | jq 182 | -------- 183 | [1, 0] 184 | (1 row) 185 | 186 | select jq('[1,5,3,0,7]', '.[] |= select(. >= 4)'); 187 | jq 188 | -------- 189 | [5, 7] 190 | (1 row) 191 | 192 | select jq('[1,5,3,0,7]', '.[] |= select(. == 2)'); 193 | jq 194 | ---- 195 | [] 196 | (1 row) 197 | 198 | /* --- if/else conditionals --- */ 199 | select jq('2', '.<5'); 200 | jq 201 | ------ 202 | true 203 | (1 row) 204 | 205 | select jq('{"prod": "life", "price": 10}', 'if .price > 0 then "it is expensive" else {"oh": "well"} end'); 206 | jq 207 | ------------------- 208 | "it is expensive" 209 | (1 row) 210 | 211 | select jq('{"prod": "life", "price": 10}', 'if .price > 100 then "it is expensive" else {"oh": "well"} end'); 212 | jq 213 | ---------------- 214 | {"oh": "well"} 215 | (1 row) 216 | 217 | select jq('2', 'if . == 0 then "zero" elif . == 1 then "one" else "many" end'); 218 | jq 219 | -------- 220 | "many" 221 | (1 row) 222 | 223 | select jq('3', 'if . == 0 then "zero" elif . == 1 then "one" else {"big": "object"} end'); 224 | jq 225 | ------------------- 226 | {"big": "object"} 227 | (1 row) 228 | 229 | /* --- builtin functions --- */ 230 | select jq('1', '[repeat(.*2, error)?]'); 231 | jq 232 | ----- 233 | [2] 234 | (1 row) 235 | 236 | select jq('4', '[.,1]|until(.[0] < 1; [.[0] - 1, .[1] * .[0]])|.[1]'); 237 | jq 238 | ---- 239 | 24 240 | (1 row) 241 | 242 | select jq('[[4, 1, 7], [8, 5, 2], [3, 6, 9]]', 'walk(if type == "array" then sort else . end)'); 243 | jq 244 | ----------------------------------- 245 | [[1, 4, 7], [2, 5, 8], [3, 6, 9]] 246 | (1 row) 247 | 248 | select jq('[ { "_a": { "__b": 2 } } ]', 'walk( if type == "object" then with_entries( .key |= sub( "^_+"; "") ) else . end )'); 249 | jq 250 | ------------------- 251 | [{"a": {"b": 2}}] 252 | (1 row) 253 | 254 | select jq('[0,1]', 'bsearch(0)'); 255 | jq 256 | ---- 257 | 0 258 | (1 row) 259 | 260 | select jq('[1,2,3]', 'bsearch(0)'); 261 | jq 262 | ---- 263 | -1 264 | (1 row) 265 | 266 | select jq('[1,2,3]', 'bsearch(0)'); 267 | jq 268 | ---- 269 | -1 270 | (1 row) 271 | 272 | select jq('[1,2,3]', 'bsearch(4) as $ix | if $ix < 0 then .[-(1+$ix)] = 4 else . end'); 273 | jq 274 | -------------- 275 | [1, 2, 3, 4] 276 | (1 row) 277 | 278 | /* --- convert to/from JSON --- */ 279 | select jq('[1, "foo", ["foo"]]', '[.[]|tostring]'); 280 | jq 281 | --------------------------- 282 | ["1", "foo", "[\"foo\"]"] 283 | (1 row) 284 | 285 | select jq('[1, "foo", ["foo"]]', '[.[]|tojson]'); 286 | jq 287 | ------------------------------- 288 | ["1", "\"foo\"", "[\"foo\"]"] 289 | (1 row) 290 | 291 | select jq('[1,"foo",["foo"]]', '[.[]|tojson|fromjson]'); 292 | jq 293 | --------------------- 294 | [1, "foo", ["foo"]] 295 | (1 row) 296 | 297 | /* --- chain with jsonpath --- */ 298 | select jq('[ 299 | { 300 | "cust": "baz", 301 | "trans": { 302 | "balance": 100, 303 | "date": "2023-08-01" 304 | }, 305 | "active": true, 306 | "geo": { 307 | "branch": "paloukia" 308 | } 309 | }]', 310 | '(.[] | select(.active == true))') #- '{trans}' @> '{"cust": "baz"}'; 311 | ?column? 312 | ---------- 313 | t 314 | (1 row) 315 | 316 | /* --- ---argjson --- */ 317 | -- test numeric argument 318 | select jq('{ 319 | "success": true, 320 | "message": "jobStatus", 321 | "jobStatus": [ 322 | { 323 | "ID": 9, 324 | "status": "Successful" 325 | }, 326 | { 327 | "ID": 2, 328 | "status": "Successful" 329 | }, 330 | { 331 | "ID": 99, 332 | "status": "Failed" 333 | } 334 | ] 335 | }'::jsonb, '.jobStatus[] | select(.ID == $job_id) | .status', '{"job_id": 2}'); 336 | jq 337 | -------------- 338 | "Successful" 339 | (1 row) 340 | 341 | -- test string argument 342 | select jq('{ 343 | "success": true, 344 | "message": "jobStatus", 345 | "jobStatus": [ 346 | { 347 | "ID": 9, 348 | "status": "Successful" 349 | }, 350 | { 351 | "ID": 2, 352 | "status": "Successful" 353 | }, 354 | { 355 | "ID": 99, 356 | "status": "Failed" 357 | } 358 | ] 359 | }'::jsonb, '.jobStatus[] | select(.status == $status) | .', '{"status": "Failed"}'); 360 | jq 361 | -------------------------------- 362 | {"ID": 99, "status": "Failed"} 363 | (1 row) 364 | 365 | -- test boolean argument 366 | select jq('{ 367 | "success": true, 368 | "message": "jobStatus", 369 | "jobs": [ 370 | { 371 | "ID": 9, 372 | "is_successfull": true 373 | }, 374 | { 375 | "ID": 100, 376 | "is_successfull": false 377 | } 378 | ] 379 | }'::jsonb, '.jobs[] | select(.is_successfull == $is_success) | .', '{"is_success": true}'); 380 | jq 381 | ----------------------------------- 382 | {"ID": 9, "is_successfull": true} 383 | (1 row) 384 | 385 | -- test multiple arguments 386 | select jq('{ 387 | "runner": 1, 388 | "message": "jobStatus", 389 | "jobs": [ 390 | { 391 | "id": 9, 392 | "is_successfull": true 393 | }, 394 | { 395 | "id": 100, 396 | "is_successfull": false, 397 | "metdata": { 398 | "environ": "prod" 399 | } 400 | } 401 | ] 402 | }'::jsonb, '.jobs[] | select(.is_successfull == $is_success and .id == 100) | .', '{"is_success": false, "id": 100}'); 403 | jq 404 | ---------------------------------------------------------------------- 405 | {"id": 100, "metdata": {"environ": "prod"}, "is_successfull": false} 406 | (1 row) 407 | 408 | -------------------------------------------------------------------------------- /test/sql/basic.sql: -------------------------------------------------------------------------------- 1 | 2 | /* --- Type creation and casts --- */ 3 | 4 | select 'gsdfgf'::jqprog; 5 | select 1345::jqprog; 6 | 7 | /* --- Arrays as input --- */ 8 | 9 | select jq('[{"bar": "baz", "balance": 7.77, "active":false}]'::jsonb, '.[0].bar'); 10 | select jq('[{"bar": "baz", "balance": 7.77, "active":false}]'::jsonb, '.[0].balance'); 11 | select jq('[{"bar": "baz", "balance": 7.77, "balance_int": 7, "active":false}]'::jsonb, '.[0].balance_int'); 12 | select jq('[{"bar": "baz", "balance": 7.77, "active":false}]'::jsonb, '.[0].active'); 13 | select jq('[{"bar": "baz", "balance": 7.77, "active":false, "keno": null}]'::jsonb, '.[0].keno'); 14 | select jq('[{"bar": "baz", "balance": 7.77, "active":false, "keno": null}]'::jsonb, '.[0].keno'); 15 | select jq('[["a", "b", "c"]]'::jsonb, '.[0]'); 16 | select jq('[["a", "b", "c"]]'::jsonb, '.[0].[0]'); 17 | select jq('[["a", "b", "c"]]'::jsonb, '.[0].[1]'); 18 | select jq('[["a", "b", "c"]]'::jsonb, '.[0].[1000]'); 19 | 20 | select jq('[{"bar": "baz", "balance": 7.77, "active":false}]'::jsonb, '.[0]'); 21 | select jq('[{"bar": "baz", "balance": 7.77, "active":false}]'::jsonb, '.[100]'); 22 | select jq('[{"bar": "baz", "balance": 7.77, "active":false}]'::jsonb, '.[0].bar'); 23 | select jq('[{"bar": "baz", "balance": 7.77, "active":false}]'::jsonb, '.[0].gdfgdf'); 24 | 25 | /* --- Single object as input --- */ 26 | 27 | select jq('{"bar": "baz", "balance": 7.77, "active":false}'::jsonb, '.'); 28 | select jq('{"bar": "baz", "balance": 7.77, "active":false}'::jsonb, '.baz'); 29 | select jq('{"bar": "baz", "balance": 7.77, "active":false}'::jsonb, '.balance'); 30 | select jq('{"bar": "baz", "balance": 7.77, "active":false}'::jsonb, '.gdfgfd'); 31 | 32 | select jq('{"user":"stedolan", "projects": ["jq", "wikiflow"]}', '.user, .projects[]'); 33 | 34 | /* --- Nested object --- */ 35 | 36 | select jq('{"bar": "baz", "balance": 7.77, "active":false, "inner": {"key": "value"}}'::jsonb, '.gdfgfd'); 37 | select jq('{"bar": "baz", "balance": 7.77, "active":false, "inner": {"key": "value"}}'::jsonb, '.inner'); 38 | select jq('{"bar": "baz", "balance": 7.77, "active":false, "inner": {"key": "value"}}'::jsonb, '.inner.key'); 39 | select jq('{"bar": "baz", "balance": 7.77, "active":false, "inner": {"key": "value"}}'::jsonb, '.gdfgfd'); 40 | 41 | /* --- pick --- */ 42 | 43 | select jq('{"a": [123]}', '.a[]'); 44 | 45 | /* --- assignment --- */ 46 | 47 | select jq('[true,false,[5,true,[true,[false]],false]]', '(..|select(type=="boolean")) |= if . then 1 else 0 end'); 48 | select jq('{"foo": 42}', '.foo += 1'); 49 | select jq('{"a": {"b": 10}, "b": 20}', '.a = .b'); 50 | 51 | /* --- select --- */ 52 | 53 | select jq('[1,5,3,0,7]' , '(.[] | select(. >= 2)) |= empty'); 54 | select jq('[1,5,3,0,7]', '.[] |= select(. >= 4)'); 55 | select jq('[1,5,3,0,7]', '.[] |= select(. == 2)'); 56 | 57 | /* --- if/else conditionals --- */ 58 | select jq('2', '.<5'); 59 | select jq('{"prod": "life", "price": 10}', 'if .price > 0 then "it is expensive" else {"oh": "well"} end'); 60 | select jq('{"prod": "life", "price": 10}', 'if .price > 100 then "it is expensive" else {"oh": "well"} end'); 61 | 62 | select jq('2', 'if . == 0 then "zero" elif . == 1 then "one" else "many" end'); 63 | select jq('3', 'if . == 0 then "zero" elif . == 1 then "one" else {"big": "object"} end'); 64 | 65 | /* --- builtin functions --- */ 66 | 67 | select jq('1', '[repeat(.*2, error)?]'); 68 | select jq('4', '[.,1]|until(.[0] < 1; [.[0] - 1, .[1] * .[0]])|.[1]'); 69 | select jq('[[4, 1, 7], [8, 5, 2], [3, 6, 9]]', 'walk(if type == "array" then sort else . end)'); 70 | select jq('[ { "_a": { "__b": 2 } } ]', 'walk( if type == "object" then with_entries( .key |= sub( "^_+"; "") ) else . end )'); 71 | 72 | select jq('[0,1]', 'bsearch(0)'); 73 | select jq('[1,2,3]', 'bsearch(0)'); 74 | select jq('[1,2,3]', 'bsearch(0)'); 75 | select jq('[1,2,3]', 'bsearch(4) as $ix | if $ix < 0 then .[-(1+$ix)] = 4 else . end'); 76 | 77 | /* --- convert to/from JSON --- */ 78 | select jq('[1, "foo", ["foo"]]', '[.[]|tostring]'); 79 | select jq('[1, "foo", ["foo"]]', '[.[]|tojson]'); 80 | select jq('[1,"foo",["foo"]]', '[.[]|tojson|fromjson]'); 81 | 82 | /* --- chain with jsonpath --- */ 83 | 84 | select jq('[ 85 | { 86 | "cust": "baz", 87 | "trans": { 88 | "balance": 100, 89 | "date": "2023-08-01" 90 | }, 91 | "active": true, 92 | "geo": { 93 | "branch": "paloukia" 94 | } 95 | }]', 96 | '(.[] | select(.active == true))') #- '{trans}' @> '{"cust": "baz"}'; 97 | 98 | /* --- ---argjson --- */ 99 | 100 | -- test numeric argument 101 | select jq('{ 102 | "success": true, 103 | "message": "jobStatus", 104 | "jobStatus": [ 105 | { 106 | "ID": 9, 107 | "status": "Successful" 108 | }, 109 | { 110 | "ID": 2, 111 | "status": "Successful" 112 | }, 113 | { 114 | "ID": 99, 115 | "status": "Failed" 116 | } 117 | ] 118 | }'::jsonb, '.jobStatus[] | select(.ID == $job_id) | .status', '{"job_id": 2}'); 119 | 120 | -- test string argument 121 | 122 | 123 | select jq('{ 124 | "success": true, 125 | "message": "jobStatus", 126 | "jobStatus": [ 127 | { 128 | "ID": 9, 129 | "status": "Successful" 130 | }, 131 | { 132 | "ID": 2, 133 | "status": "Successful" 134 | }, 135 | { 136 | "ID": 99, 137 | "status": "Failed" 138 | } 139 | ] 140 | }'::jsonb, '.jobStatus[] | select(.status == $status) | .', '{"status": "Failed"}'); 141 | 142 | -- test boolean argument 143 | 144 | select jq('{ 145 | "success": true, 146 | "message": "jobStatus", 147 | "jobs": [ 148 | { 149 | "ID": 9, 150 | "is_successfull": true 151 | }, 152 | { 153 | "ID": 100, 154 | "is_successfull": false 155 | } 156 | ] 157 | }'::jsonb, '.jobs[] | select(.is_successfull == $is_success) | .', '{"is_success": true}'); 158 | 159 | -- test multiple arguments 160 | 161 | select jq('{ 162 | "runner": 1, 163 | "message": "jobStatus", 164 | "jobs": [ 165 | { 166 | "id": 9, 167 | "is_successfull": true 168 | }, 169 | { 170 | "id": 100, 171 | "is_successfull": false, 172 | "metdata": { 173 | "environ": "prod" 174 | } 175 | } 176 | ] 177 | }'::jsonb, '.jobs[] | select(.is_successfull == $is_success and .id == 100) | .', '{"is_success": false, "id": 100}'); --------------------------------------------------------------------------------