├── .gitignore ├── .travis.yml ├── META.json ├── Makefile ├── README.md ├── expected └── jsonbx.out ├── jsonbx--1.0.sql ├── jsonbx.c ├── jsonbx.control ├── jsonbx.h ├── jsonbx_utils.c └── sql └── jsonbx.sql /.gitignore: -------------------------------------------------------------------------------- 1 | # Object files 2 | *.o 3 | *.ko 4 | *.obj 5 | *.elf 6 | 7 | # Libraries 8 | *.lib 9 | *.a 10 | 11 | # Shared objects (inc. Windows DLLs) 12 | *.dll 13 | *.so 14 | *.so.* 15 | *.dylib 16 | 17 | # Executables 18 | *.exe 19 | *.app 20 | *.i*86 21 | *.x86_64 22 | *.hex 23 | 24 | # tests output 25 | results 26 | -------------------------------------------------------------------------------- /.travis.yml: -------------------------------------------------------------------------------- 1 | language: c 2 | services: 3 | - postgresql 4 | addons: 5 | postgresql: "9.4" 6 | before_install: 7 | - sudo apt-get update -qq 8 | before_script: 9 | - sudo apt-get install postgresql-server-dev-9.4 10 | - sudo apt-get install postgresql-common 11 | script: 12 | - make && sudo make install && make installcheck 13 | -------------------------------------------------------------------------------- /META.json: -------------------------------------------------------------------------------- 1 | { 2 | "name": "jsonbx", 3 | "abstract": "Backport of PostgreSQL 9.5 JSONB features for 9.4", 4 | "description": "PostgreSQL 9.5 comes with a bunch of new functions and operators for JSONB, including ||, json_set and json_delete. This extension makes them available to users of PostgreSQL 9.4", 5 | "version": "1.0.0", 6 | "maintainer": [ 7 | "Dmitry Dolgov <9erthalion6@gmail.com>", 8 | "Andrew Dunstan " 9 | ], 10 | "license": { 11 | "PostgreSQL": "http://www.postgresql.org/about/licence" 12 | }, 13 | "prereqs": { 14 | "runtime": { 15 | "requires": { 16 | "PostgreSQL": ">= 9.4.0, < 9.5.0" 17 | } 18 | } 19 | }, 20 | "provides": { 21 | "jsonbx": { 22 | "file": "sql/jsonbx.sql", 23 | "docfile": "README.md", 24 | "version": "1.0.0", 25 | "abstract": "Extra JSONB functions and operators for PostgreSQL 9.4" 26 | } 27 | }, 28 | "resources": { 29 | "homepage": "https://github.com/erthalion/jsonbx", 30 | "bugtracker": { 31 | "web": "https://github.com/erthalion/jsonbx/issues" 32 | }, 33 | "repository": { 34 | "url": "https://github.com/erthalion/jsonbx.git", 35 | "web": "https://github.com/erthalion/jsonbx", 36 | "type": "git" 37 | } 38 | }, 39 | "generated_by": "Josh Berkus", 40 | "meta-spec": { 41 | "version": "1.0.0", 42 | "url": "http://pgxn.org/meta/spec.txt" 43 | }, 44 | "tags": [ 45 | "JSON", 46 | "function", 47 | "operator", 48 | "backport" 49 | ] 50 | } 51 | -------------------------------------------------------------------------------- /Makefile: -------------------------------------------------------------------------------- 1 | MODULE_big = jsonbx 2 | OBJS = jsonbx.o jsonbx_utils.o 3 | 4 | DATA = jsonbx--1.0.sql 5 | EXTENSION = jsonbx 6 | 7 | REGRESS = jsonbx 8 | 9 | PG_CONFIG = pg_config 10 | PGXS := $(shell $(PG_CONFIG) --pgxs) 11 | include $(PGXS) 12 | -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | [![Build Status](https://travis-ci.org/erthalion/jsonbx.svg?branch=master)](https://travis-ci.org/erthalion/jsonbx) 2 | 3 | jsonbx 4 | ====== 5 | 6 | As you know, PostgreSQL introduced Jsonb [support](http://obartunov.livejournal.com/177247.html) at the 9.4 version, and hstore v2.0 saved in separate [repository](http://www.sigaev.ru/git/gitweb.cgi?p=hstore.git;a=summary). But although PostgreSQL has this support at the core level, there are many useful functions, which wasn't implemented for Jsonb, particularly there are not so many functions and operators for manipulation with jsonb. This repo will accumulate the implementation such kind of functions. Part of this functionality was already incorporated into PostgreSQL 9.5 (see this [commit](http://git.postgresql.org/gitweb/?p=postgresql.git;a=commit;h=c6947010ceb42143d9f047c65c1eac2b38928ab7)). 7 | 8 | 9 | List of implemented functions 10 | --------------------------------- 11 | 12 | * jsonb_pretty (in 9.5) 13 | * jsonb_concat (in 9.5) 14 | * jsonb_delete(jsonb, text) (in 9.5) 15 | * jsonb_delete_idx(jsonb, int) (in 9.5) 16 | * jsonb_delete_path(jsonb, text[]) (in 9.5) 17 | * jsonb_set(jsonb, text[], jsonb) (in 9.5) 18 | 19 | List of implemented operators 20 | --------------------------------- 21 | 22 | * concatenation operator (||) (in 9.5) 23 | * delete key operator (jsonb - text) (in 9.5) 24 | * delete key by index operator (jsonb - int) (in 9.5) 25 | * delete key by path operator (jsonb - text[]) (in 9.5) 26 | 27 | License 28 | ------- 29 | 30 | jsonbx is licensed under [the same license as PostgreSQL itself](http://www.postgresql.org/about/licence/) 31 | 32 | Contributors 33 | ------------ 34 | 35 | jsonbx was created by Dmitry Dolgov 36 | portions written by Andrew Dunstan 37 | -------------------------------------------------------------------------------- /expected/jsonbx.out: -------------------------------------------------------------------------------- 1 | CREATE EXTENSION jsonbx; 2 | select jsonb_pretty('{"a": "test", "b": [1, 2, 3], "c": "test3", "d":{"dd": "test4", "dd2":{"ddd": "test5"}}}'::jsonb); 3 | jsonb_pretty 4 | ---------------------------- 5 | { + 6 | "a": "test", + 7 | "b": + 8 | [ + 9 | 1, + 10 | 2, + 11 | 3 + 12 | ], + 13 | "c": "test3", + 14 | "d": + 15 | { + 16 | "dd": "test4", + 17 | "dd2": + 18 | { + 19 | "ddd": "test5"+ 20 | } + 21 | } + 22 | } 23 | (1 row) 24 | 25 | select jsonb_concat('{"d": "test", "a": [1, 2]}'::jsonb, '{"g": "test2", "c": {"c1":1, "c2":2}}'::jsonb); 26 | jsonb_concat 27 | ------------------------------------------------------------------- 28 | {"a": [1, 2], "c": {"c1": 1, "c2": 2}, "d": "test", "g": "test2"} 29 | (1 row) 30 | 31 | select '{"aa":1 , "b":2, "cq":3}'::jsonb || '{"cq":"l", "b":"g", "fg":false}'; 32 | ?column? 33 | --------------------------------------------- 34 | {"b": "g", "aa": 1, "cq": "l", "fg": false} 35 | (1 row) 36 | 37 | select '{"aa":1 , "b":2, "cq":3}'::jsonb || '{"aq":"l"}'; 38 | ?column? 39 | --------------------------------------- 40 | {"b": 2, "aa": 1, "aq": "l", "cq": 3} 41 | (1 row) 42 | 43 | select '{"aa":1 , "b":2, "cq":3}'::jsonb || '{"aa":"l"}'; 44 | ?column? 45 | ------------------------------ 46 | {"b": 2, "aa": "l", "cq": 3} 47 | (1 row) 48 | 49 | select '{"aa":1 , "b":2, "cq":3}'::jsonb || '{}'; 50 | ?column? 51 | ---------------------------- 52 | {"b": 2, "aa": 1, "cq": 3} 53 | (1 row) 54 | 55 | select '["a", "b"]'::jsonb || '["c"]'; 56 | ?column? 57 | ----------------- 58 | ["a", "b", "c"] 59 | (1 row) 60 | 61 | select '["a", "b"]'::jsonb || '["c", "d"]'; 62 | ?column? 63 | ---------------------- 64 | ["a", "b", "c", "d"] 65 | (1 row) 66 | 67 | select '["c"]' || '["a", "b"]'::jsonb; 68 | ?column? 69 | ----------------- 70 | ["c", "a", "b"] 71 | (1 row) 72 | 73 | select '["a", "b"]'::jsonb || '"c"'; 74 | ?column? 75 | ----------------- 76 | ["a", "b", "c"] 77 | (1 row) 78 | 79 | select '"c"' || '["a", "b"]'::jsonb; 80 | ?column? 81 | ----------------- 82 | ["c", "a", "b"] 83 | (1 row) 84 | 85 | select '"a"'::jsonb || '{"a":1}'; 86 | ERROR: invalid concatnation of jsonb objects 87 | select '{"a":1}' || '"a"'::jsonb; 88 | ERROR: invalid concatnation of jsonb objects 89 | select '["a", "b"]'::jsonb || '{"c":1}'; 90 | ?column? 91 | ---------------------- 92 | ["a", "b", {"c": 1}] 93 | (1 row) 94 | 95 | select '{"c": 1}'::jsonb || '["a", "b"]'; 96 | ?column? 97 | ---------------------- 98 | [{"c": 1}, "a", "b"] 99 | (1 row) 100 | 101 | select '{}'::jsonb || '{"cq":"l", "b":"g", "fg":false}'; 102 | ?column? 103 | ------------------------------------ 104 | {"b": "g", "cq": "l", "fg": false} 105 | (1 row) 106 | 107 | select pg_column_size('{}'::jsonb || '{}'::jsonb) = pg_column_size('{}'::jsonb); 108 | ?column? 109 | ---------- 110 | t 111 | (1 row) 112 | 113 | select pg_column_size('{"aa":1}'::jsonb || '{"b":2}'::jsonb) = pg_column_size('{"aa":1, "b":2}'::jsonb); 114 | ?column? 115 | ---------- 116 | t 117 | (1 row) 118 | 119 | select pg_column_size('{"aa":1, "b":2}'::jsonb || '{}'::jsonb) = pg_column_size('{"aa":1, "b":2}'::jsonb); 120 | ?column? 121 | ---------- 122 | t 123 | (1 row) 124 | 125 | select pg_column_size('{}'::jsonb || '{"aa":1, "b":2}'::jsonb) = pg_column_size('{"aa":1, "b":2}'::jsonb); 126 | ?column? 127 | ---------- 128 | t 129 | (1 row) 130 | 131 | select jsonb_delete('{"a":1 , "b":2, "c":3}'::jsonb, 'a'); 132 | jsonb_delete 133 | ------------------ 134 | {"b": 2, "c": 3} 135 | (1 row) 136 | 137 | select jsonb_delete('{"a":1}'::jsonb, 'a'); 138 | jsonb_delete 139 | -------------- 140 | {} 141 | (1 row) 142 | 143 | select jsonb_delete('"a"'::jsonb, 'a'); 144 | ERROR: cannot delete from scalar 145 | select jsonb_delete('{"a":null , "b":2, "c":3}'::jsonb, 'a'); 146 | jsonb_delete 147 | ------------------ 148 | {"b": 2, "c": 3} 149 | (1 row) 150 | 151 | select jsonb_delete('{"a":1 , "b":2, "c":3}'::jsonb, 'b'); 152 | jsonb_delete 153 | ------------------ 154 | {"a": 1, "c": 3} 155 | (1 row) 156 | 157 | select jsonb_delete('{"a":1 , "b":2, "c":3}'::jsonb, 'c'); 158 | jsonb_delete 159 | ------------------ 160 | {"a": 1, "b": 2} 161 | (1 row) 162 | 163 | select jsonb_delete('{"a":1 , "b":2, "c":3}'::jsonb, 'd'); 164 | jsonb_delete 165 | -------------------------- 166 | {"a": 1, "b": 2, "c": 3} 167 | (1 row) 168 | 169 | select '{"a":1}'::jsonb - 'a'::text; 170 | ?column? 171 | ---------- 172 | {} 173 | (1 row) 174 | 175 | select '"a"'::jsonb - 'a'::text; 176 | ERROR: cannot delete from scalar 177 | select '{"a":1 , "b":2, "c":3}'::jsonb - 'a'::text; 178 | ?column? 179 | ------------------ 180 | {"b": 2, "c": 3} 181 | (1 row) 182 | 183 | select '{"a":null , "b":2, "c":3}'::jsonb - 'a'::text; 184 | ?column? 185 | ------------------ 186 | {"b": 2, "c": 3} 187 | (1 row) 188 | 189 | select '{"a":1 , "b":2, "c":3}'::jsonb - 'b'::text; 190 | ?column? 191 | ------------------ 192 | {"a": 1, "c": 3} 193 | (1 row) 194 | 195 | select '{"a":1 , "b":2, "c":3}'::jsonb - 'c'::text; 196 | ?column? 197 | ------------------ 198 | {"a": 1, "b": 2} 199 | (1 row) 200 | 201 | select '{"a":1 , "b":2, "c":3}'::jsonb - 'd'::text; 202 | ?column? 203 | -------------------------- 204 | {"a": 1, "b": 2, "c": 3} 205 | (1 row) 206 | 207 | select pg_column_size('{"a":1 , "b":2, "c":3}'::jsonb - 'b'::text) = pg_column_size('{"a":1, "b":2}'::jsonb); 208 | ?column? 209 | ---------- 210 | t 211 | (1 row) 212 | 213 | select '["a","b","c"]'::jsonb - 3; 214 | ?column? 215 | ----------------- 216 | ["a", "b", "c"] 217 | (1 row) 218 | 219 | select '["a","b","c"]'::jsonb - 2; 220 | ?column? 221 | ------------ 222 | ["a", "b"] 223 | (1 row) 224 | 225 | select '["a","b","c"]'::jsonb - 1; 226 | ?column? 227 | ------------ 228 | ["a", "c"] 229 | (1 row) 230 | 231 | select '["a","b","c"]'::jsonb - 0; 232 | ?column? 233 | ------------ 234 | ["b", "c"] 235 | (1 row) 236 | 237 | select '["a","b","c"]'::jsonb - -1; 238 | ?column? 239 | ------------ 240 | ["a", "b"] 241 | (1 row) 242 | 243 | select '["a","b","c"]'::jsonb - -2; 244 | ?column? 245 | ------------ 246 | ["a", "c"] 247 | (1 row) 248 | 249 | select '["a","b","c"]'::jsonb - -3; 250 | ?column? 251 | ------------ 252 | ["b", "c"] 253 | (1 row) 254 | 255 | select '["a","b","c"]'::jsonb - -4; 256 | ?column? 257 | ----------------- 258 | ["a", "b", "c"] 259 | (1 row) 260 | 261 | select '{"a":1, "b":2, "c":3}'::jsonb - 3; 262 | ?column? 263 | -------------------------- 264 | {"a": 1, "b": 2, "c": 3} 265 | (1 row) 266 | 267 | select '{"a":1, "b":2, "c":3}'::jsonb - 2; 268 | ?column? 269 | ------------------ 270 | {"a": 1, "b": 2} 271 | (1 row) 272 | 273 | select '{"a":1, "b":2, "c":3}'::jsonb - 1; 274 | ?column? 275 | ------------------ 276 | {"a": 1, "c": 3} 277 | (1 row) 278 | 279 | select '{"a":1, "b":2, "c":3}'::jsonb - 0; 280 | ?column? 281 | ------------------ 282 | {"b": 2, "c": 3} 283 | (1 row) 284 | 285 | select '{"a":1, "b":2, "c":3}'::jsonb - -1; 286 | ?column? 287 | ------------------ 288 | {"a": 1, "b": 2} 289 | (1 row) 290 | 291 | select '{"a":1, "b":2, "c":3}'::jsonb - -2; 292 | ?column? 293 | ------------------ 294 | {"a": 1, "c": 3} 295 | (1 row) 296 | 297 | select '{"a":1, "b":2, "c":3}'::jsonb - -3; 298 | ?column? 299 | ------------------ 300 | {"b": 2, "c": 3} 301 | (1 row) 302 | 303 | select '{"a":1, "b":2, "c":3}'::jsonb - -4; 304 | ?column? 305 | -------------------------- 306 | {"a": 1, "b": 2, "c": 3} 307 | (1 row) 308 | 309 | select jsonb_delete('{"a":1, "b":2, "c":3}'::jsonb, '{d, e}'::text[]); 310 | jsonb_delete 311 | -------------------------- 312 | {"a": 1, "b": 2, "c": 3} 313 | (1 row) 314 | 315 | select jsonb_delete('{"a":1, "b":2, "c":3}'::jsonb, '{b}'::text[]); 316 | jsonb_delete 317 | ------------------ 318 | {"a": 1, "c": 3} 319 | (1 row) 320 | 321 | select jsonb_delete('{"a":{"c":1, "d": 2}, "b":3}'::jsonb, '{a, c}'::text[]); 322 | jsonb_delete 323 | ------------------------- 324 | {"a": {"d": 2}, "b": 3} 325 | (1 row) 326 | 327 | select jsonb_delete('{"a":{"c":1, "d":{"f": 3, "g": 4}}, "b":5}'::jsonb, '{a, d, g}'::text[]); 328 | jsonb_delete 329 | ---------------------------------------- 330 | {"a": {"c": 1, "d": {"f": 3}}, "b": 5} 331 | (1 row) 332 | 333 | select jsonb_delete('{"a":1, "b":2, "c":3}'::jsonb, '{}'::text[]); 334 | jsonb_delete 335 | -------------------------- 336 | {"a": 1, "b": 2, "c": 3} 337 | (1 row) 338 | 339 | select '{"a":1, "b":2, "c":3}'::jsonb - '{d, e}'::text[]; 340 | ?column? 341 | -------------------------- 342 | {"a": 1, "b": 2, "c": 3} 343 | (1 row) 344 | 345 | select '{"a":1, "b":2, "c":3}'::jsonb - '{b}'::text[]; 346 | ?column? 347 | ------------------ 348 | {"a": 1, "c": 3} 349 | (1 row) 350 | 351 | select '{"a":{"c":1, "d":2}, "b":3}'::jsonb - '{a, c}'::text[]; 352 | ?column? 353 | ------------------------- 354 | {"a": {"d": 2}, "b": 3} 355 | (1 row) 356 | 357 | select '{"a":{"c":1, "d":{"f": 3, "g": 4}}, "b":5}'::jsonb - '{a, d, g}'::text[]; 358 | ?column? 359 | ---------------------------------------- 360 | {"a": {"c": 1, "d": {"f": 3}}, "b": 5} 361 | (1 row) 362 | 363 | select '{"a":1, "b":2, "c":3}'::jsonb - '{}'::text[]; 364 | ?column? 365 | -------------------------- 366 | {"a": 1, "b": 2, "c": 3} 367 | (1 row) 368 | 369 | select pg_column_size('{"a":1, "b":2, "c":3}'::jsonb - '{a}'::text[]) 370 | = pg_column_size('{"b":2, "c":3}'::jsonb); 371 | ?column? 372 | ---------- 373 | t 374 | (1 row) 375 | 376 | select pg_column_size('{"a":1, "b":2, "c":3}'::jsonb - '{}'::text[]) 377 | = pg_column_size('{"a":1, "b":2, "c":3}'::jsonb); 378 | ?column? 379 | ---------- 380 | t 381 | (1 row) 382 | 383 | select jsonb_set('{"a":1,"b":[0,1,2,3,4,5,6,7,8,9,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1],"c":{"d":1}}','{"b",-101}','123'); 384 | jsonb_set 385 | ---------------------------------------------------------------------------------------------------------------- 386 | {"a": 1, "b": [123, 0, 1, 2, 3, 4, 5, 6, 7, 8, 9, 1, 1, 1, 1, 1, 1, 1, 1, 1, 1, 1, 1, 1, 1, 1], "c": {"d": 1}} 387 | (1 row) 388 | 389 | select jsonb_set('"a"'::jsonb, '{a}', '[1,2,3]'); 390 | ERROR: cannot set path in scalar 391 | select jsonb_set('{"n":null, "a":1, "b":[1,2], "c":{"1":2}, "d":{"1":[2,3]}}'::jsonb, '{n}', '[1,2,3]'); 392 | jsonb_set 393 | -------------------------------------------------------------------------- 394 | {"a": 1, "b": [1, 2], "c": {"1": 2}, "d": {"1": [2, 3]}, "n": [1, 2, 3]} 395 | (1 row) 396 | 397 | select jsonb_set('{"n":null, "a":1, "b":[1,2], "c":{"1":2}, "d":{"1":[2,3]}}'::jsonb, '{b,-1}', '[1,2,3]'); 398 | jsonb_set 399 | ----------------------------------------------------------------------------- 400 | {"a": 1, "b": [1, [1, 2, 3]], "c": {"1": 2}, "d": {"1": [2, 3]}, "n": null} 401 | (1 row) 402 | 403 | select jsonb_set('{"n":null, "a":1, "b":[1,2], "c":{"1":2}, "d":{"1":[2,3]}}'::jsonb, '{d,1,0}', '[1,2,3]'); 404 | jsonb_set 405 | ----------------------------------------------------------------------------- 406 | {"a": 1, "b": [1, 2], "c": {"1": 2}, "d": {"1": [[1, 2, 3], 3]}, "n": null} 407 | (1 row) 408 | 409 | select jsonb_set('{"n":null, "a":1, "b":[1,2], "c":{"1":2}, "d":{"1":[2,3]}}'::jsonb, '{d,NULL,0}', '[1,2,3]'); 410 | ERROR: path element at the position 2 is NULL 411 | select jsonb_set('{"n":null, "a":1, "b":[1,2], "c":{"1":2}, "d":{"1":[2,3]}}'::jsonb, '{n}', '{"1": 2}'); 412 | jsonb_set 413 | ------------------------------------------------------------------------- 414 | {"a": 1, "b": [1, 2], "c": {"1": 2}, "d": {"1": [2, 3]}, "n": {"1": 2}} 415 | (1 row) 416 | 417 | select jsonb_set('{"n":null, "a":1, "b":[1,2], "c":{"1":2}, "d":{"1":[2,3]}}'::jsonb, '{b,-1}', '{"1": 2}'); 418 | jsonb_set 419 | ---------------------------------------------------------------------------- 420 | {"a": 1, "b": [1, {"1": 2}], "c": {"1": 2}, "d": {"1": [2, 3]}, "n": null} 421 | (1 row) 422 | 423 | select jsonb_set('{"n":null, "a":1, "b":[1,2], "c":{"1":2}, "d":{"1":[2,3]}}'::jsonb, '{d,1,0}', '{"1": 2}'); 424 | jsonb_set 425 | ---------------------------------------------------------------------------- 426 | {"a": 1, "b": [1, 2], "c": {"1": 2}, "d": {"1": [{"1": 2}, 3]}, "n": null} 427 | (1 row) 428 | 429 | select jsonb_set('{"n":null, "a":1, "b":[1,2], "c":{"1":2}, "d":{"1":[2,3]}}'::jsonb, '{d,NULL,0}', '{"1": 2}'); 430 | ERROR: path element at the position 2 is NULL 431 | select jsonb_set('{"n":null, "a":1, "b":[1,2], "c":{"1":2}, "d":{"1":[2,3]}}'::jsonb, '{b,-1}', '"test"'); 432 | jsonb_set 433 | -------------------------------------------------------------------------- 434 | {"a": 1, "b": [1, "test"], "c": {"1": 2}, "d": {"1": [2, 3]}, "n": null} 435 | (1 row) 436 | 437 | select jsonb_set('{"n":null, "a":1, "b":[1,2], "c":{"1":2}, "d":{"1":[2,3]}}'::jsonb, '{b,-1}', '{"f": "test"}'); 438 | jsonb_set 439 | --------------------------------------------------------------------------------- 440 | {"a": 1, "b": [1, {"f": "test"}], "c": {"1": 2}, "d": {"1": [2, 3]}, "n": null} 441 | (1 row) 442 | 443 | -- empty structure and error conditions for delete and replace 444 | select '"a"'::jsonb - 'a'; -- error 445 | ERROR: cannot delete from scalar 446 | select '{}'::jsonb - 'a'; 447 | ?column? 448 | ---------- 449 | {} 450 | (1 row) 451 | 452 | select '[]'::jsonb - 'a'; 453 | ?column? 454 | ---------- 455 | [] 456 | (1 row) 457 | 458 | select '"a"'::jsonb - 1; -- error 459 | ERROR: cannot delete from scalar 460 | select '{}'::jsonb - 1 ; 461 | ?column? 462 | ---------- 463 | {} 464 | (1 row) 465 | 466 | select '[]'::jsonb - 1; 467 | ?column? 468 | ---------- 469 | [] 470 | (1 row) 471 | 472 | select '"a"'::jsonb - '{a}'::text[]; -- error 473 | ERROR: cannot delete path in scalar 474 | select '{}'::jsonb - '{a}'::text[]; 475 | ?column? 476 | ---------- 477 | {} 478 | (1 row) 479 | 480 | select '[]'::jsonb - '{a}'::text[]; 481 | ?column? 482 | ---------- 483 | [] 484 | (1 row) 485 | 486 | select jsonb_set('"a"','{a}','"b"'); --error 487 | ERROR: cannot set path in scalar 488 | select jsonb_set('{}','{a}','"b"', false); 489 | jsonb_set 490 | ----------- 491 | {} 492 | (1 row) 493 | 494 | select jsonb_set('[]','{1}','"b"', false); 495 | jsonb_set 496 | ----------- 497 | [] 498 | (1 row) 499 | 500 | -- jsonb_set adding instead of replacing 501 | -- prepend to array 502 | select jsonb_set('{"a":1,"b":[0,1,2],"c":{"d":4}}','{b,-33}','{"foo":123}'); 503 | jsonb_set 504 | ------------------------------------------------------- 505 | {"a": 1, "b": [{"foo": 123}, 0, 1, 2], "c": {"d": 4}} 506 | (1 row) 507 | 508 | -- append to array 509 | select jsonb_set('{"a":1,"b":[0,1,2],"c":{"d":4}}','{b,33}','{"foo":123}'); 510 | jsonb_set 511 | ------------------------------------------------------- 512 | {"a": 1, "b": [0, 1, 2, {"foo": 123}], "c": {"d": 4}} 513 | (1 row) 514 | 515 | -- check nesting levels addition 516 | select jsonb_set('{"a":1,"b":[4,5,[0,1,2],6,7],"c":{"d":4}}','{b,2,33}','{"foo":123}'); 517 | jsonb_set 518 | --------------------------------------------------------------------- 519 | {"a": 1, "b": [4, 5, [0, 1, 2, {"foo": 123}], 6, 7], "c": {"d": 4}} 520 | (1 row) 521 | 522 | -- add new key 523 | select jsonb_set('{"a":1,"b":[0,1,2],"c":{"d":4}}','{c,e}','{"foo":123}'); 524 | jsonb_set 525 | ------------------------------------------------------------ 526 | {"a": 1, "b": [0, 1, 2], "c": {"d": 4, "e": {"foo": 123}}} 527 | (1 row) 528 | 529 | -- adding doesn't do anything if elements before last aren't present 530 | select jsonb_set('{"a":1,"b":[0,1,2],"c":{"d":4}}','{x,-33}','{"foo":123}'); 531 | jsonb_set 532 | ----------------------------------------- 533 | {"a": 1, "b": [0, 1, 2], "c": {"d": 4}} 534 | (1 row) 535 | 536 | select jsonb_set('{"a":1,"b":[0,1,2],"c":{"d":4}}','{x,y}','{"foo":123}'); 537 | jsonb_set 538 | ----------------------------------------- 539 | {"a": 1, "b": [0, 1, 2], "c": {"d": 4}} 540 | (1 row) 541 | 542 | -- add to empty object 543 | select jsonb_set('{}','{x}','{"foo":123}'); 544 | jsonb_set 545 | --------------------- 546 | {"x": {"foo": 123}} 547 | (1 row) 548 | 549 | --add to empty array 550 | select jsonb_set('[]','{0}','{"foo":123}'); 551 | jsonb_set 552 | ---------------- 553 | [{"foo": 123}] 554 | (1 row) 555 | 556 | select jsonb_set('[]','{99}','{"foo":123}'); 557 | jsonb_set 558 | ---------------- 559 | [{"foo": 123}] 560 | (1 row) 561 | 562 | select jsonb_set('[]','{-99}','{"foo":123}'); 563 | jsonb_set 564 | ---------------- 565 | [{"foo": 123}] 566 | (1 row) 567 | 568 | -- verify path correctness 569 | select jsonb_set('{"a": [1, 2, 3]}', '{a, non_integer}', '"new_value"'); 570 | ERROR: path element at the position 2 is not an integer 571 | select jsonb_set('{"a": {"b": [1, 2, 3]}}', '{a, b, non_integer}', '"new_value"'); 572 | ERROR: path element at the position 3 is not an integer 573 | select jsonb_set('{"a": {"b": [1, 2, 3]}}', '{a, b, NULL}', '"new_value"'); 574 | ERROR: path element at the position 3 is NULL 575 | -------------------------------------------------------------------------------- /jsonbx--1.0.sql: -------------------------------------------------------------------------------- 1 | -- complain if script is sourced in psql, rather than via CREATE EXTENSION 2 | \echo Use "CREATE EXTENSION jsonbx" to load this file. \quit 3 | 4 | 5 | CREATE FUNCTION jsonb_pretty(jsonb) 6 | RETURNS text 7 | AS 'MODULE_PATHNAME', 'jsonb_pretty' 8 | LANGUAGE C STRICT; 9 | 10 | CREATE FUNCTION jsonb_concat(jsonb, jsonb) 11 | RETURNS jsonb 12 | AS 'MODULE_PATHNAME', 'jsonb_concat' 13 | LANGUAGE C STRICT; 14 | 15 | CREATE OPERATOR || ( 16 | LEFTARG = jsonb, 17 | RIGHTARG = jsonb, 18 | PROCEDURE = jsonb_concat 19 | ); 20 | 21 | CREATE FUNCTION jsonb_delete(jsonb,text) 22 | RETURNS jsonb 23 | AS 'MODULE_PATHNAME','jsonb_delete' 24 | LANGUAGE C STRICT; 25 | 26 | CREATE OPERATOR - ( 27 | LEFTARG = jsonb, 28 | RIGHTARG = text, 29 | PROCEDURE = jsonb_delete 30 | ); 31 | 32 | CREATE FUNCTION jsonb_delete(jsonb,int) 33 | RETURNS jsonb 34 | AS 'MODULE_PATHNAME','jsonb_delete_idx' 35 | LANGUAGE C STRICT; 36 | 37 | CREATE OPERATOR - ( 38 | LEFTARG = jsonb, 39 | RIGHTARG = int, 40 | PROCEDURE = jsonb_delete 41 | ); 42 | 43 | CREATE FUNCTION jsonb_delete(jsonb,text[]) 44 | RETURNS jsonb 45 | AS 'MODULE_PATHNAME','jsonb_delete_path' 46 | LANGUAGE C STRICT; 47 | 48 | CREATE OPERATOR - ( 49 | LEFTARG = jsonb, 50 | RIGHTARG = text[], 51 | PROCEDURE = jsonb_delete 52 | ); 53 | 54 | CREATE FUNCTION jsonb_set( 55 | jsonb_in jsonb, 56 | path text[], 57 | replacement jsonb, 58 | create_if_missing boolean DEFAULT true 59 | ) 60 | RETURNS jsonb 61 | AS 'MODULE_PATHNAME','jsonb_set' 62 | LANGUAGE C STRICT; 63 | -------------------------------------------------------------------------------- /jsonbx.c: -------------------------------------------------------------------------------- 1 | #include "postgres.h" 2 | 3 | #include "catalog/pg_type.h" 4 | #include "utils/jsonb.h" 5 | #include "utils/builtins.h" 6 | 7 | #include "jsonbx.h" 8 | 9 | PG_MODULE_MAGIC; 10 | 11 | PG_FUNCTION_INFO_V1(jsonb_pretty); 12 | Datum jsonb_pretty(PG_FUNCTION_ARGS); 13 | 14 | PG_FUNCTION_INFO_V1(jsonb_concat); 15 | Datum jsonb_concat(PG_FUNCTION_ARGS); 16 | 17 | PG_FUNCTION_INFO_V1(jsonb_delete); 18 | Datum jsonb_delete(PG_FUNCTION_ARGS); 19 | 20 | PG_FUNCTION_INFO_V1(jsonb_delete_idx); 21 | Datum jsonb_delete_idx(PG_FUNCTION_ARGS); 22 | 23 | PG_FUNCTION_INFO_V1(jsonb_delete_path); 24 | Datum jsonb_delete_path(PG_FUNCTION_ARGS); 25 | 26 | PG_FUNCTION_INFO_V1(jsonb_set); 27 | Datum jsonb_set(PG_FUNCTION_ARGS); 28 | 29 | /* 30 | * jsonb_pretty: 31 | * Pretty-printed text for the jsonb 32 | */ 33 | Datum 34 | jsonb_pretty(PG_FUNCTION_ARGS) 35 | { 36 | Jsonb *jb = PG_GETARG_JSONB(0); 37 | StringInfo str = makeStringInfo(); 38 | 39 | JsonbToCStringWorker(str, &jb->root, VARSIZE(jb), true); 40 | 41 | PG_RETURN_TEXT_P(cstring_to_text_with_len(str->data, str->len)); 42 | } 43 | 44 | 45 | /* 46 | * jsonb_concat: 47 | * Concatenation of two jsonb. There are few allowed combinations: 48 | * - concatenation of two objects 49 | * - concatenation of two arrays 50 | * - concatenation of object and array 51 | * 52 | * The result for first two is new object and array accordingly. 53 | * The last one return new array, which contains all elements from 54 | * original array, and one extra element (which is actually 55 | * other argument of this function with type jbvObject) at the first or last position. 56 | */ 57 | Datum 58 | jsonb_concat(PG_FUNCTION_ARGS) 59 | { 60 | Jsonb *jb1 = PG_GETARG_JSONB(0); 61 | Jsonb *jb2 = PG_GETARG_JSONB(1); 62 | Jsonb *out = palloc(VARSIZE(jb1) + VARSIZE(jb2)); 63 | JsonbParseState *state = NULL; 64 | JsonbValue *res; 65 | JsonbIterator *it1, *it2; 66 | 67 | /* 68 | * If one of the jsonb is empty, 69 | * just return other. 70 | */ 71 | if (JB_ROOT_COUNT(jb1) == 0) 72 | { 73 | memcpy(out, jb2, VARSIZE(jb2)); 74 | PG_RETURN_POINTER(out); 75 | } 76 | else if (JB_ROOT_COUNT(jb2) == 0) 77 | { 78 | memcpy(out, jb1, VARSIZE(jb1)); 79 | PG_RETURN_POINTER(out); 80 | } 81 | 82 | it1 = JsonbIteratorInit(&jb1->root); 83 | it2 = JsonbIteratorInit(&jb2->root); 84 | 85 | res = IteratorConcat(&it1, &it2, &state); 86 | 87 | if (res == NULL || (res->type == jbvArray && res->val.array.nElems == 0) || 88 | (res->type == jbvObject && res->val.object.nPairs == 0) ) 89 | { 90 | SET_VARSIZE(out, VARHDRSZ); 91 | } 92 | else 93 | { 94 | if (res->type == jbvArray && res->val.array.nElems > 1) 95 | res->val.array.rawScalar = false; 96 | 97 | out = JsonbValueToJsonb(res); 98 | } 99 | 100 | PG_RETURN_JSONB(out); 101 | } 102 | 103 | 104 | /* 105 | * jsonb_delete: 106 | * Return copy of jsonb with the specified item removed. 107 | * Item is a one key or element from jsonb, specified by name. 108 | * If there are many keys or elements with than name, 109 | * the first one will be removed. 110 | */ 111 | Datum 112 | jsonb_delete(PG_FUNCTION_ARGS) 113 | { 114 | Jsonb *in = PG_GETARG_JSONB(0); 115 | text *key = PG_GETARG_TEXT_PP(1); 116 | char *keyptr = VARDATA_ANY(key); 117 | int keylen = VARSIZE_ANY_EXHDR(key); 118 | JsonbParseState *state = NULL; 119 | JsonbIterator *it; 120 | uint32 r; 121 | JsonbValue v, *res = NULL; 122 | bool skipped = false; 123 | 124 | if (JB_ROOT_IS_SCALAR(in)) 125 | ereport(ERROR, 126 | (errcode(ERRCODE_INVALID_PARAMETER_VALUE), 127 | errmsg("cannot delete from scalar"))); 128 | 129 | if (JB_ROOT_COUNT(in) == 0) 130 | { 131 | PG_RETURN_JSONB(in); 132 | } 133 | 134 | it = JsonbIteratorInit(&in->root); 135 | 136 | while((r = JsonbIteratorNext(&it, &v, false)) != 0) 137 | { 138 | if (!skipped && (r == WJB_ELEM || r == WJB_KEY) && 139 | (v.type == jbvString && keylen == v.val.string.len && 140 | memcmp(keyptr, v.val.string.val, keylen) == 0)) 141 | { 142 | /* we should delete only one key/element */ 143 | skipped = true; 144 | 145 | if (r == WJB_KEY) 146 | { 147 | /* skip corresponding value */ 148 | JsonbIteratorNext(&it, &v, true); 149 | } 150 | 151 | continue; 152 | } 153 | 154 | res = pushJsonbValue(&state, r, r < WJB_BEGIN_ARRAY ? &v : NULL); 155 | } 156 | 157 | Assert(res != NULL); 158 | PG_RETURN_JSONB(JsonbValueToJsonb(res)); 159 | } 160 | 161 | 162 | /* 163 | * jsonb_delete_idx: 164 | * Return a copy of jsonb withour specified items. 165 | * Delete key (only from the top level of object) or element from jsonb by index (idx). 166 | * Negative idx value is supported, and it implies the countdown from the last key/element. 167 | * If idx is more, than numbers of keys/elements, or equal - nothing will be deleted. 168 | * If idx is negative and -idx is more, than number of keys/elements - the last one will be deleted. 169 | * 170 | * TODO: take care about nesting values. 171 | */ 172 | Datum 173 | jsonb_delete_idx(PG_FUNCTION_ARGS) 174 | { 175 | Jsonb *in = PG_GETARG_JSONB(0); 176 | int idx = PG_GETARG_INT32(1); 177 | JsonbParseState *state = NULL; 178 | JsonbIterator *it; 179 | uint32 r, i = 0, n; 180 | JsonbValue v, *res = NULL; 181 | 182 | if (JB_ROOT_IS_SCALAR(in)) 183 | ereport(ERROR, 184 | (errcode(ERRCODE_INVALID_PARAMETER_VALUE), 185 | errmsg("cannot delete from scalar"))); 186 | 187 | if (JB_ROOT_COUNT(in) == 0) 188 | { 189 | PG_RETURN_JSONB(in); 190 | } 191 | 192 | it = JsonbIteratorInit(&in->root); 193 | 194 | r = JsonbIteratorNext(&it, &v, false); 195 | if (r == WJB_BEGIN_ARRAY) 196 | n = v.val.array.nElems; 197 | else 198 | n = v.val.object.nPairs; 199 | 200 | if (idx < 0) 201 | { 202 | if (-idx > n) 203 | idx = n; 204 | else 205 | idx = n + idx; 206 | } 207 | 208 | if (idx >= n) 209 | { 210 | PG_RETURN_JSONB(in); 211 | } 212 | 213 | pushJsonbValue(&state, r, r < WJB_BEGIN_ARRAY ? &v : NULL); 214 | 215 | while((r = JsonbIteratorNext(&it, &v, true)) != 0) 216 | { 217 | if (r == WJB_ELEM || r == WJB_KEY) 218 | { 219 | if (i++ == idx) 220 | { 221 | if (r == WJB_KEY) 222 | JsonbIteratorNext(&it, &v, true); /* skip value */ 223 | continue; 224 | } 225 | } 226 | 227 | res = pushJsonbValue(&state, r, r < WJB_BEGIN_ARRAY ? &v : NULL); 228 | } 229 | 230 | Assert (res != NULL); 231 | PG_RETURN_JSONB(JsonbValueToJsonb(res)); 232 | } 233 | 234 | /* 235 | * jsonb_set: 236 | * Replace/create value of jsonb key or jsonb element, which can be found by the specified path. 237 | * Path must be replesented as an array of key names or indexes. If indexes will be used, 238 | * the same rules implied as for jsonb_delete_idx (negative indexing and edge cases) 239 | */ 240 | Datum 241 | jsonb_set(PG_FUNCTION_ARGS) 242 | { 243 | Jsonb *in = PG_GETARG_JSONB(0); 244 | ArrayType *path = PG_GETARG_ARRAYTYPE_P(1); 245 | Jsonb *newval = PG_GETARG_JSONB(2); 246 | bool create = PG_GETARG_BOOL(3); 247 | JsonbValue *res = NULL; 248 | Datum *path_elems; 249 | bool *path_nulls; 250 | int path_len; 251 | JsonbIterator *it; 252 | JsonbParseState *st = NULL; 253 | 254 | 255 | if (ARR_NDIM(path) > 1) 256 | ereport(ERROR, 257 | (errcode(ERRCODE_ARRAY_SUBSCRIPT_ERROR), 258 | errmsg("wrong number of array subscripts"))); 259 | 260 | if (JB_ROOT_IS_SCALAR(in)) 261 | ereport(ERROR, 262 | (errcode(ERRCODE_INVALID_PARAMETER_VALUE), 263 | errmsg("cannot set path in scalar"))); 264 | 265 | 266 | if (JB_ROOT_COUNT(in) == 0 && !create) 267 | { 268 | PG_RETURN_JSONB(in); 269 | } 270 | 271 | deconstruct_array(path, TEXTOID, -1, false, 'i', 272 | &path_elems, &path_nulls, &path_len); 273 | 274 | if (path_len == 0) 275 | { 276 | PG_RETURN_JSONB(in); 277 | } 278 | 279 | it = JsonbIteratorInit(&in->root); 280 | 281 | res = setPath(&it, path_elems, path_nulls, path_len, &st, 0, newval, create); 282 | 283 | Assert (res != NULL); 284 | PG_RETURN_JSONB(JsonbValueToJsonb(res)); 285 | } 286 | 287 | 288 | /* 289 | * jsonb_delete_path: 290 | */ 291 | Datum 292 | jsonb_delete_path(PG_FUNCTION_ARGS) 293 | { 294 | Jsonb *in = PG_GETARG_JSONB(0); 295 | ArrayType *path = PG_GETARG_ARRAYTYPE_P(1); 296 | JsonbValue *res = NULL; 297 | Datum *path_elems; 298 | bool *path_nulls; 299 | int path_len; 300 | JsonbIterator *it; 301 | JsonbParseState *st = NULL; 302 | 303 | if (ARR_NDIM(path) > 1) 304 | ereport(ERROR, 305 | (errcode(ERRCODE_ARRAY_SUBSCRIPT_ERROR), 306 | errmsg("wrong number of array subscripts"))); 307 | 308 | if (JB_ROOT_IS_SCALAR(in)) 309 | ereport(ERROR, 310 | (errcode(ERRCODE_INVALID_PARAMETER_VALUE), 311 | errmsg("cannot delete path in scalar"))); 312 | 313 | if (JB_ROOT_COUNT(in) == 0) 314 | { 315 | PG_RETURN_JSONB(in); 316 | } 317 | 318 | deconstruct_array(path, TEXTOID, -1, false, 'i', 319 | &path_elems, &path_nulls, &path_len); 320 | 321 | if (path_len == 0) 322 | { 323 | PG_RETURN_JSONB(in); 324 | } 325 | 326 | it = JsonbIteratorInit(&in->root); 327 | 328 | res = setPath(&it, path_elems, path_nulls, path_len, &st, 0, NULL, false); 329 | 330 | Assert (res != NULL); 331 | PG_RETURN_JSONB(JsonbValueToJsonb(res)); 332 | } 333 | -------------------------------------------------------------------------------- /jsonbx.control: -------------------------------------------------------------------------------- 1 | # test extension 2 | comment = 'Jsonb extension' 3 | default_version = '1.0' 4 | module_pathname = '$libdir/jsonbx' 5 | relocatable = true 6 | -------------------------------------------------------------------------------- /jsonbx.h: -------------------------------------------------------------------------------- 1 | #ifndef __JSONBX_H__ 2 | #define __JSONBX_H__ 3 | 4 | 5 | extern char * JsonbToCStringWorker(StringInfo out, JsonbContainer *in, int estimated_len, bool pretty_print); 6 | extern JsonbValue* setPath(JsonbIterator **it, Datum *path_elems, bool *path_nulls, int path_len, 7 | JsonbParseState **st, int level, Jsonb *newval, bool create); 8 | 9 | extern JsonbValue * IteratorConcat(JsonbIterator **it1, JsonbIterator **it2, JsonbParseState **state); 10 | 11 | #endif 12 | -------------------------------------------------------------------------------- /jsonbx_utils.c: -------------------------------------------------------------------------------- 1 | #include "postgres.h" 2 | 3 | #include 4 | 5 | #include "utils/builtins.h" 6 | #include "utils/json.h" 7 | #include "utils/jsonb.h" 8 | 9 | #include "jsonbx.h" 10 | 11 | #define choice_array(flag_val, a, b) flag_val == WJB_BEGIN_ARRAY ? a : b 12 | #define choice_object(flag_val, a, b) flag_val == WJB_BEGIN_OBJECT ? a : b 13 | 14 | #define is_array(flag_val, it) flag_val == WJB_BEGIN_ARRAY && !(*it)->isScalar 15 | 16 | typedef bool (*walk_condition)(JsonbParseState**, JsonbValue*, uint32 /* token */, uint32 /* level */); 17 | void add_indent(StringInfo out, bool indent, int level); 18 | void jsonb_put_escaped_value(StringInfo out, JsonbValue * scalarVal); 19 | bool h_atoi(char *c, int *acc); 20 | JsonbValue *walkJsonb(JsonbIterator **it, JsonbParseState **state, bool stop_at_level_zero); 21 | bool untilLast(JsonbParseState **state, JsonbValue *v, uint32 token, uint32 level); 22 | void addJsonbToParseState(JsonbParseState **jbps, Jsonb * jb); 23 | 24 | static void setPathObject(JsonbIterator **it, Datum *path_elems, bool *path_nulls, 25 | int path_len, JsonbParseState **st, int level, 26 | Jsonb *newval, uint32 nelems, bool create); 27 | static void setPathArray(JsonbIterator **it, Datum *path_elems, bool *path_nulls, 28 | int path_len, JsonbParseState **st, int level, 29 | Jsonb *newval, uint32 npairs, bool create); 30 | 31 | 32 | 33 | /* 34 | * JsonbToCStringExtended: 35 | * Convert jsonb value to a C-string taking into account "pretty_print" mode. 36 | * See the original function JsonbToCString in the jsonb.c 37 | * Only one considerable change is printCR and printIndent functions, 38 | * which add required line breaks and spaces accordingly to the nesting level. 39 | */ 40 | char * 41 | JsonbToCStringWorker(StringInfo out, JsonbContainer *in, int estimated_len, bool indent) 42 | { 43 | bool first = true; 44 | JsonbIterator *it; 45 | int type = 0; 46 | JsonbValue v; 47 | int level = 0; 48 | bool redo_switch = false; 49 | /* If we are indenting, don't add a space after a comma */ 50 | int ispaces = indent ? 1 : 2; 51 | /* 52 | * Don't indent the very first item. This gets set to the indent flag 53 | * at the bottom of the loop. 54 | */ 55 | bool use_indent = false; 56 | bool raw_scalar = false; 57 | 58 | if (out == NULL) 59 | out = makeStringInfo(); 60 | 61 | enlargeStringInfo(out, (estimated_len >= 0) ? estimated_len : 64); 62 | 63 | it = JsonbIteratorInit(in); 64 | 65 | while (redo_switch || 66 | ((type = JsonbIteratorNext(&it, &v, false)) != WJB_DONE)) 67 | { 68 | redo_switch = false; 69 | switch (type) 70 | { 71 | case WJB_BEGIN_ARRAY: 72 | if (!first) 73 | { 74 | appendBinaryStringInfo(out, ", ", ispaces); 75 | } 76 | first = true; 77 | 78 | if (!v.val.array.rawScalar) 79 | { 80 | add_indent(out, use_indent, level); 81 | appendStringInfoCharMacro(out, '['); 82 | } 83 | else 84 | { 85 | raw_scalar = true; 86 | } 87 | level++; 88 | break; 89 | case WJB_BEGIN_OBJECT: 90 | if (!first) 91 | appendBinaryStringInfo(out, ", ", ispaces); 92 | first = true; 93 | 94 | add_indent(out, use_indent, level); 95 | appendStringInfoCharMacro(out, '{'); 96 | 97 | level++; 98 | break; 99 | case WJB_KEY: 100 | if (!first) 101 | appendBinaryStringInfo(out, ", ", ispaces); 102 | first = true; 103 | 104 | add_indent(out, use_indent, level); 105 | 106 | /* json rules guarantee this is a string */ 107 | jsonb_put_escaped_value(out, &v); 108 | appendBinaryStringInfo(out, ": ", 2); 109 | 110 | type = JsonbIteratorNext(&it, &v, false); 111 | if (type == WJB_VALUE) 112 | { 113 | first = false; 114 | jsonb_put_escaped_value(out, &v); 115 | } 116 | else 117 | { 118 | Assert(type == WJB_BEGIN_OBJECT || type == WJB_BEGIN_ARRAY); 119 | 120 | /* 121 | * We need to rerun the current switch() since we need to 122 | * output the object which we just got from the iterator 123 | * before calling the iterator again. 124 | */ 125 | redo_switch = true; 126 | } 127 | break; 128 | case WJB_ELEM: 129 | if (!first) 130 | { 131 | appendBinaryStringInfo(out, ", ", ispaces); 132 | } 133 | 134 | first = false; 135 | 136 | if (!raw_scalar) 137 | { 138 | add_indent(out, use_indent, level); 139 | } 140 | 141 | jsonb_put_escaped_value(out, &v); 142 | break; 143 | case WJB_END_ARRAY: 144 | level--; 145 | 146 | if (!raw_scalar) 147 | { 148 | add_indent(out, use_indent, level); 149 | appendStringInfoChar(out, ']'); 150 | } 151 | first = false; 152 | break; 153 | case WJB_END_OBJECT: 154 | level--; 155 | 156 | add_indent(out, use_indent, level); 157 | appendStringInfoCharMacro(out, '}'); 158 | first = false; 159 | break; 160 | default: 161 | elog(ERROR, "unknown flag of jsonb iterator"); 162 | } 163 | use_indent = indent; 164 | } 165 | 166 | Assert(level == 0); 167 | 168 | return out->data; 169 | } 170 | 171 | 172 | void 173 | add_indent(StringInfo out, bool indent, int level) 174 | { 175 | if (indent) 176 | { 177 | int i; 178 | 179 | appendStringInfoCharMacro(out, '\n'); 180 | for (i = 0; i < level; i++) 181 | { 182 | appendBinaryStringInfo(out, " ", 4); 183 | } 184 | } 185 | } 186 | 187 | 188 | /* 189 | * jsonb_put_escaped_value: 190 | * Return string representation of jsonb value. 191 | */ 192 | void 193 | jsonb_put_escaped_value(StringInfo out, JsonbValue * scalarVal) 194 | { 195 | switch (scalarVal->type) 196 | { 197 | case jbvNull: 198 | appendBinaryStringInfo(out, "null", 4); 199 | break; 200 | case jbvString: 201 | escape_json(out, pnstrdup(scalarVal->val.string.val, scalarVal->val.string.len)); 202 | break; 203 | case jbvNumeric: 204 | appendStringInfoString(out, 205 | DatumGetCString(DirectFunctionCall1(numeric_out, 206 | PointerGetDatum(scalarVal->val.numeric)))); 207 | break; 208 | case jbvBool: 209 | if (scalarVal->val.boolean) 210 | appendBinaryStringInfo(out, "true", 4); 211 | else 212 | appendBinaryStringInfo(out, "false", 5); 213 | break; 214 | default: 215 | elog(ERROR, "unknown jsonb scalar type"); 216 | } 217 | } 218 | 219 | 220 | /* 221 | * Iterate over all jsonb objects and merge them into one. 222 | * The logic of this function copied from the same hstore function, 223 | * except the case, when it1 & it2 represents jbvObject. 224 | * In that case we just append the content of it2 to it1 without any 225 | * verifications. 226 | */ 227 | JsonbValue * 228 | IteratorConcat(JsonbIterator **it1, JsonbIterator **it2, 229 | JsonbParseState **state) 230 | { 231 | uint32 r1, r2, rk1, rk2; 232 | JsonbValue v1, v2, *res = NULL; 233 | 234 | r1 = rk1 = JsonbIteratorNext(it1, &v1, false); 235 | r2 = rk2 = JsonbIteratorNext(it2, &v2, false); 236 | 237 | /* 238 | * Both elements are objects. 239 | */ 240 | if (rk1 == WJB_BEGIN_OBJECT && rk2 == WJB_BEGIN_OBJECT) 241 | { 242 | int level = 1; 243 | 244 | /* 245 | * Append the all tokens from v1 to res, exept 246 | * last WJB_END_OBJECT (because res will not be finished yet). 247 | */ 248 | (void) pushJsonbValue(state, r1, NULL); 249 | while((r1 = JsonbIteratorNext(it1, &v1, false)) != 0) 250 | { 251 | if (r1 == WJB_BEGIN_OBJECT) { 252 | ++level; 253 | } 254 | else if (r1 == WJB_END_OBJECT) { 255 | --level; 256 | } 257 | 258 | if (level != 0) { 259 | res = pushJsonbValue(state, r1, r1 < WJB_BEGIN_ARRAY ? &v1 : NULL); 260 | } 261 | } 262 | 263 | /* 264 | * Append the all tokens from v2 to res, include 265 | * last WJB_END_OBJECT (the concatenation will be completed). 266 | */ 267 | while((r2 = JsonbIteratorNext(it2, &v2, false)) != 0) 268 | { 269 | res = pushJsonbValue(state, r2, r2 < WJB_BEGIN_ARRAY ? &v2 : NULL); 270 | } 271 | } 272 | /* 273 | * Both elements are arrays (either can be scalar). 274 | */ 275 | else if (rk1 == WJB_BEGIN_ARRAY && rk2 == WJB_BEGIN_ARRAY) 276 | { 277 | res = pushJsonbValue(state, r1, NULL); 278 | for(;;) 279 | { 280 | r1 = JsonbIteratorNext(it1, &v1, true); 281 | if (r1 == WJB_END_OBJECT || r1 == WJB_END_ARRAY) 282 | break; 283 | Assert(r1 == WJB_KEY || r1 == WJB_VALUE || r1 == WJB_ELEM); 284 | pushJsonbValue(state, r1, &v1); 285 | } 286 | 287 | while((r2 = JsonbIteratorNext(it2, &v2, true)) != 0) 288 | { 289 | if (!(r2 == WJB_END_OBJECT || r2 == WJB_END_ARRAY)) 290 | { 291 | if (rk1 == WJB_BEGIN_OBJECT) 292 | { 293 | pushJsonbValue(state, WJB_KEY, NULL); 294 | r2 = JsonbIteratorNext(it2, &v2, true); 295 | Assert(r2 == WJB_ELEM); 296 | pushJsonbValue(state, WJB_VALUE, &v2); 297 | } 298 | else 299 | { 300 | pushJsonbValue(state, WJB_ELEM, &v2); 301 | } 302 | } 303 | } 304 | 305 | 306 | res = pushJsonbValue(state, 307 | (rk1 == WJB_BEGIN_OBJECT) ? WJB_END_OBJECT : WJB_END_ARRAY, 308 | NULL /* signal to sort */ ); 309 | } 310 | /* 311 | * One of the elements is object, another is array. 312 | * There is only one reasonable approach to handle this - 313 | * include object into array as one of the elements. 314 | * Position of this new element will depends on the arguments 315 | * order: 316 | * - if the first argument is object, then it will be the first element in array 317 | * - if the second argument is object, then it will be the last element in array 318 | */ 319 | else if ((is_array(rk1, it1) && rk2 == WJB_BEGIN_OBJECT) || 320 | (rk1 == WJB_BEGIN_OBJECT && is_array(rk2, it2))) 321 | { 322 | JsonbIterator** it_array = choice_array(rk1, it1, it2); 323 | JsonbIterator** it_object = choice_object(rk1, it1, it2); 324 | 325 | bool prepend = (rk1 == WJB_BEGIN_OBJECT) ? true : false; 326 | 327 | pushJsonbValue(state, WJB_BEGIN_ARRAY, NULL); 328 | if (prepend) 329 | { 330 | pushJsonbValue(state, WJB_BEGIN_OBJECT, NULL); 331 | walkJsonb(it_object, state, false); 332 | 333 | res = walkJsonb(it_array, state, false); 334 | } 335 | else 336 | { 337 | walkJsonb(it_array, state, true); 338 | 339 | pushJsonbValue(state, WJB_BEGIN_OBJECT, NULL); 340 | walkJsonb(it_object, state, false); 341 | 342 | res = pushJsonbValue(state, WJB_END_ARRAY, NULL); 343 | } 344 | } 345 | else 346 | { 347 | elog(ERROR, "invalid concatnation of jsonb objects"); 348 | } 349 | 350 | return res; 351 | } 352 | 353 | /* 354 | * One of possible conditions for walkJsonb. 355 | * This condition implies, that entire Jsonb should be converted. 356 | */ 357 | bool 358 | untilLast(JsonbParseState **state, JsonbValue *v, uint32 token, uint32 level) 359 | { 360 | return level == 0; 361 | } 362 | 363 | 364 | /* 365 | * walkJsonb: 366 | * Copy elements from the iterator to the parse state 367 | * stopping at level zero if required. 368 | */ 369 | JsonbValue* 370 | walkJsonb(JsonbIterator **it, JsonbParseState **state, bool stop_at_level_zero) 371 | { 372 | uint32 r, level = 1; 373 | JsonbValue v, *res = NULL; 374 | 375 | while((r = JsonbIteratorNext(it, &v, false)) != WJB_DONE) 376 | { 377 | if (r == WJB_BEGIN_OBJECT || r == WJB_BEGIN_ARRAY) { 378 | ++level; 379 | } 380 | else if (r == WJB_END_OBJECT || r == WJB_END_ARRAY) { 381 | --level; 382 | } 383 | 384 | if(stop_at_level_zero && level == 0) 385 | break; 386 | 387 | res = pushJsonbValue(state, r, r < WJB_BEGIN_ARRAY ? &v : NULL); 388 | } 389 | 390 | return res; 391 | } 392 | 393 | /* 394 | * setPath: 395 | * Recursive replacement/creation function for jsonb_set. 396 | * Replace/create value of jsonb key or jsonb element, which can be found by the specified path on the specific level. 397 | * For jbvArray level is the current element, for jbvObject is the current nesting level. 398 | * For each recursion step, level value will be incremented, and an array element or object key will be replaces or created, 399 | * if current level is path_len - 1 (it does mean, that we've reached the last element in the path). 400 | * If indexes will be used, the same rules implied as for jsonb_delete_idx (negative indexing and edge cases) 401 | */ 402 | JsonbValue* 403 | setPath(JsonbIterator **it, Datum *path_elems, 404 | bool *path_nulls, int path_len, 405 | JsonbParseState **st, int level, Jsonb *newval, bool create) 406 | { 407 | JsonbValue v, *res = NULL; 408 | int r; 409 | 410 | r = JsonbIteratorNext(it, &v, false); 411 | if (path_nulls[level]) 412 | elog(ERROR, "path element at the position %d is NULL", level + 1); 413 | 414 | switch (r) 415 | { 416 | case WJB_BEGIN_ARRAY: 417 | (void) pushJsonbValue(st, r, NULL); 418 | setPathArray(it, path_elems, path_nulls, path_len, st, level, 419 | newval, v.val.array.nElems, create); 420 | r = JsonbIteratorNext(it, &v, false); 421 | Assert(r == WJB_END_ARRAY); 422 | res = pushJsonbValue(st, r, NULL); 423 | 424 | break; 425 | case WJB_BEGIN_OBJECT: 426 | (void) pushJsonbValue(st, r, NULL); 427 | setPathObject(it, path_elems, path_nulls, path_len, st, level, 428 | newval, v.val.object.nPairs, create); 429 | r = JsonbIteratorNext(it, &v, true); 430 | Assert(r == WJB_END_OBJECT); 431 | res = pushJsonbValue(st, r, NULL); 432 | 433 | break; 434 | case WJB_ELEM: 435 | case WJB_VALUE: 436 | res = pushJsonbValue(st, r, &v); 437 | break; 438 | default: 439 | elog(PANIC, "impossible state"); 440 | } 441 | 442 | return res; 443 | } 444 | 445 | /* 446 | * Object walker for setPath 447 | */ 448 | static void 449 | setPathObject(JsonbIterator **it, Datum *path_elems, bool *path_nulls, 450 | int path_len, JsonbParseState **st, int level, 451 | Jsonb *newval, uint32 npairs, bool create) 452 | { 453 | JsonbValue v; 454 | int i; 455 | JsonbValue k; 456 | bool done = false; 457 | 458 | if (level >= path_len || path_nulls[level]) 459 | done = true; 460 | 461 | /* empty object is a special case for create */ 462 | if ((npairs == 0) && create && (level == path_len - 1)) 463 | { 464 | JsonbValue newkey; 465 | 466 | newkey.type = jbvString; 467 | newkey.val.string.len = VARSIZE_ANY_EXHDR(path_elems[level]); 468 | newkey.val.string.val = VARDATA_ANY(path_elems[level]); 469 | 470 | (void) pushJsonbValue(st, WJB_KEY, &newkey); 471 | addJsonbToParseState(st, newval); 472 | } 473 | 474 | /* iterate over object keys */ 475 | for (i = 0; i < npairs; i++) 476 | { 477 | int r = JsonbIteratorNext(it, &k, true); 478 | Assert(r == WJB_KEY); 479 | 480 | if (!done && 481 | k.val.string.len == VARSIZE_ANY_EXHDR(path_elems[level]) && 482 | memcmp(k.val.string.val, VARDATA_ANY(path_elems[level]), 483 | k.val.string.len) == 0) 484 | { 485 | /* 486 | * The current path item was found. 487 | * If we reached the end of path, current element will be replaced 488 | * Otherwise level value will be incremented, and the next step of 489 | * recursion will be started. 490 | */ 491 | if (level == path_len - 1) 492 | { 493 | r = JsonbIteratorNext(it, &v, true); /* skip */ 494 | if (newval != NULL) 495 | { 496 | (void) pushJsonbValue(st, WJB_KEY, &k); 497 | addJsonbToParseState(st, newval); 498 | } 499 | done = true; 500 | } 501 | else 502 | { 503 | (void) pushJsonbValue(st, r, &k); 504 | setPath(it, path_elems, path_nulls, path_len, 505 | st, level + 1, newval, create); 506 | } 507 | } 508 | else 509 | { 510 | if (create && !done && level == path_len - 1 && i == npairs - 1) 511 | { 512 | JsonbValue new = k; 513 | new.val.string.len = VARSIZE_ANY_EXHDR(path_elems[level]); 514 | new.val.string.val = VARDATA_ANY(path_elems[level]); 515 | 516 | (void) pushJsonbValue(st, WJB_KEY, &new); 517 | addJsonbToParseState(st, newval); 518 | } 519 | 520 | /* We are out of the specified path, skip the rest of elements */ 521 | (void) pushJsonbValue(st, r, &k); 522 | r = JsonbIteratorNext(it, &v, false); 523 | 524 | (void) pushJsonbValue(st, r, r < WJB_BEGIN_ARRAY ? &v : NULL); 525 | if (r == WJB_BEGIN_ARRAY || r == WJB_BEGIN_OBJECT) 526 | { 527 | int walking_level = 1; 528 | 529 | while (walking_level != 0) 530 | { 531 | r = JsonbIteratorNext(it, &v, false); 532 | 533 | if (r == WJB_BEGIN_ARRAY || r == WJB_BEGIN_OBJECT) 534 | { 535 | ++walking_level; 536 | } 537 | if (r == WJB_END_ARRAY || r == WJB_END_OBJECT) 538 | { 539 | --walking_level; 540 | } 541 | 542 | (void) pushJsonbValue(st, r, r < WJB_BEGIN_ARRAY ? &v : NULL); 543 | } 544 | } 545 | } 546 | } 547 | } 548 | 549 | /* 550 | * Array walker for setPath 551 | */ 552 | static void 553 | setPathArray(JsonbIterator **it, Datum *path_elems, bool *path_nulls, 554 | int path_len, JsonbParseState **st, int level, 555 | Jsonb *newval, uint32 nelems, bool create) 556 | { 557 | JsonbValue v; 558 | int idx, 559 | i; 560 | char *badp; 561 | bool done = false; 562 | 563 | /* If we can't convert path element to integer index, 564 | * the last element will be used. 565 | */ 566 | if (level < path_len && !path_nulls[level]) 567 | { 568 | char *c = TextDatumGetCString(path_elems[level]); 569 | long lindex; 570 | 571 | errno = 0; 572 | lindex = strtol(c, &badp, 10); 573 | if (errno != 0 || badp == c || *badp != '\0' || lindex > INT_MAX || 574 | lindex < INT_MIN) 575 | elog(ERROR, "path element at the position %d is not an integer", 576 | level + 1); 577 | else 578 | idx = lindex; 579 | } 580 | /* Otherwise we should take care about negative indexes, 581 | * it implies the countdown from the last element. 582 | * If -idx is more, than number of elements - the last element will be used 583 | */ 584 | else 585 | { 586 | idx = nelems; 587 | } 588 | 589 | if (idx < 0) 590 | { 591 | if (-idx > nelems) 592 | idx = -1; 593 | else 594 | idx = nelems + idx; 595 | } 596 | 597 | if (idx > 0 && idx > nelems) 598 | idx = nelems; 599 | 600 | /* 601 | * if we're creating, and idx == -1, we prepend the new value to the array 602 | * also if the array is empty - in which case we don't really care what the 603 | * idx value is 604 | */ 605 | 606 | if ((idx == -1 || nelems == 0) && create && (level == path_len - 1)) 607 | { 608 | Assert(newval != NULL); 609 | addJsonbToParseState(st, newval); 610 | done = true; 611 | } 612 | 613 | /* iterate over the array elements */ 614 | for (i = 0; i < nelems; i++) 615 | { 616 | int r; 617 | 618 | if (i == idx && level < path_len) 619 | { 620 | /* 621 | * The current path item was found. 622 | * If we reached the end of path, current element will be replaced 623 | * Otherwise level value will be incremented, and the next step of 624 | * recursion will be started. 625 | */ 626 | if (level == path_len - 1) 627 | { 628 | r = JsonbIteratorNext(it, &v, true); /* skip */ 629 | if (newval != NULL) 630 | { 631 | addJsonbToParseState(st, newval); 632 | } 633 | done = true; 634 | } 635 | else 636 | (void) setPath(it, path_elems, path_nulls, path_len, 637 | st, level + 1, newval, create); 638 | } 639 | else 640 | { 641 | /* We are out of the specified path, skip the rest of elements */ 642 | r = JsonbIteratorNext(it, &v, false); 643 | 644 | (void) pushJsonbValue(st, r, r < WJB_BEGIN_ARRAY ? &v : NULL); 645 | 646 | if (r == WJB_BEGIN_ARRAY || r == WJB_BEGIN_OBJECT) 647 | { 648 | int walking_level = 1; 649 | 650 | while (walking_level != 0) 651 | { 652 | r = JsonbIteratorNext(it, &v, false); 653 | 654 | if (r == WJB_BEGIN_ARRAY || r == WJB_BEGIN_OBJECT) 655 | { 656 | ++walking_level; 657 | } 658 | if (r == WJB_END_ARRAY || r == WJB_END_OBJECT) 659 | { 660 | --walking_level; 661 | } 662 | 663 | (void) pushJsonbValue(st, r, r < WJB_BEGIN_ARRAY ? &v : NULL); 664 | } 665 | } 666 | 667 | if (create && !done && level == path_len - 1 && i == nelems - 1) 668 | { 669 | addJsonbToParseState(st, newval); 670 | } 671 | 672 | } 673 | } 674 | } 675 | 676 | 677 | /* 678 | * Add values from the jsonb to the parse state. 679 | * 680 | * If the parse state container is an object, the jsonb is pushed as 681 | * a value, not a key. 682 | * 683 | * This needs to be done using an iterator because pushJsonbValue doesn't 684 | * like getting jbvBinary values, so we can't just push jb as a whole. 685 | */ 686 | void 687 | addJsonbToParseState(JsonbParseState **jbps, Jsonb * jb) 688 | { 689 | 690 | JsonbIterator *it; 691 | JsonbValue *o = &(*jbps)->contVal; 692 | int type; 693 | JsonbValue v; 694 | 695 | it = JsonbIteratorInit(&jb->root); 696 | 697 | Assert(o->type == jbvArray || o->type == jbvObject); 698 | 699 | if (JB_ROOT_IS_SCALAR(jb)) 700 | { 701 | (void) JsonbIteratorNext(&it, &v, false); /* skip array header */ 702 | (void) JsonbIteratorNext(&it, &v, false); /* fetch scalar value */ 703 | 704 | switch (o->type) 705 | { 706 | case jbvArray: 707 | (void) pushJsonbValue(jbps, WJB_ELEM, &v); 708 | break; 709 | case jbvObject: 710 | (void) pushJsonbValue(jbps, WJB_VALUE, &v); 711 | break; 712 | default: 713 | elog(ERROR, "unexpected parent of nested structure"); 714 | } 715 | } 716 | else 717 | { 718 | while ((type = JsonbIteratorNext(&it, &v, false)) != WJB_DONE) 719 | { 720 | if (type == WJB_KEY || type == WJB_VALUE || type == WJB_ELEM) 721 | (void) pushJsonbValue(jbps, type, &v); 722 | else 723 | (void) pushJsonbValue(jbps, type, NULL); 724 | } 725 | } 726 | } 727 | -------------------------------------------------------------------------------- /sql/jsonbx.sql: -------------------------------------------------------------------------------- 1 | CREATE EXTENSION jsonbx; 2 | 3 | select jsonb_pretty('{"a": "test", "b": [1, 2, 3], "c": "test3", "d":{"dd": "test4", "dd2":{"ddd": "test5"}}}'::jsonb); 4 | 5 | select jsonb_concat('{"d": "test", "a": [1, 2]}'::jsonb, '{"g": "test2", "c": {"c1":1, "c2":2}}'::jsonb); 6 | 7 | select '{"aa":1 , "b":2, "cq":3}'::jsonb || '{"cq":"l", "b":"g", "fg":false}'; 8 | select '{"aa":1 , "b":2, "cq":3}'::jsonb || '{"aq":"l"}'; 9 | select '{"aa":1 , "b":2, "cq":3}'::jsonb || '{"aa":"l"}'; 10 | select '{"aa":1 , "b":2, "cq":3}'::jsonb || '{}'; 11 | 12 | select '["a", "b"]'::jsonb || '["c"]'; 13 | select '["a", "b"]'::jsonb || '["c", "d"]'; 14 | select '["c"]' || '["a", "b"]'::jsonb; 15 | 16 | select '["a", "b"]'::jsonb || '"c"'; 17 | select '"c"' || '["a", "b"]'::jsonb; 18 | 19 | select '"a"'::jsonb || '{"a":1}'; 20 | select '{"a":1}' || '"a"'::jsonb; 21 | 22 | select '["a", "b"]'::jsonb || '{"c":1}'; 23 | select '{"c": 1}'::jsonb || '["a", "b"]'; 24 | 25 | select '{}'::jsonb || '{"cq":"l", "b":"g", "fg":false}'; 26 | 27 | select pg_column_size('{}'::jsonb || '{}'::jsonb) = pg_column_size('{}'::jsonb); 28 | select pg_column_size('{"aa":1}'::jsonb || '{"b":2}'::jsonb) = pg_column_size('{"aa":1, "b":2}'::jsonb); 29 | select pg_column_size('{"aa":1, "b":2}'::jsonb || '{}'::jsonb) = pg_column_size('{"aa":1, "b":2}'::jsonb); 30 | select pg_column_size('{}'::jsonb || '{"aa":1, "b":2}'::jsonb) = pg_column_size('{"aa":1, "b":2}'::jsonb); 31 | 32 | select jsonb_delete('{"a":1 , "b":2, "c":3}'::jsonb, 'a'); 33 | select jsonb_delete('{"a":1}'::jsonb, 'a'); 34 | select jsonb_delete('"a"'::jsonb, 'a'); 35 | select jsonb_delete('{"a":null , "b":2, "c":3}'::jsonb, 'a'); 36 | select jsonb_delete('{"a":1 , "b":2, "c":3}'::jsonb, 'b'); 37 | select jsonb_delete('{"a":1 , "b":2, "c":3}'::jsonb, 'c'); 38 | select jsonb_delete('{"a":1 , "b":2, "c":3}'::jsonb, 'd'); 39 | select '{"a":1}'::jsonb - 'a'::text; 40 | select '"a"'::jsonb - 'a'::text; 41 | select '{"a":1 , "b":2, "c":3}'::jsonb - 'a'::text; 42 | select '{"a":null , "b":2, "c":3}'::jsonb - 'a'::text; 43 | select '{"a":1 , "b":2, "c":3}'::jsonb - 'b'::text; 44 | select '{"a":1 , "b":2, "c":3}'::jsonb - 'c'::text; 45 | select '{"a":1 , "b":2, "c":3}'::jsonb - 'd'::text; 46 | select pg_column_size('{"a":1 , "b":2, "c":3}'::jsonb - 'b'::text) = pg_column_size('{"a":1, "b":2}'::jsonb); 47 | 48 | select '["a","b","c"]'::jsonb - 3; 49 | select '["a","b","c"]'::jsonb - 2; 50 | select '["a","b","c"]'::jsonb - 1; 51 | select '["a","b","c"]'::jsonb - 0; 52 | select '["a","b","c"]'::jsonb - -1; 53 | select '["a","b","c"]'::jsonb - -2; 54 | select '["a","b","c"]'::jsonb - -3; 55 | select '["a","b","c"]'::jsonb - -4; 56 | 57 | select '{"a":1, "b":2, "c":3}'::jsonb - 3; 58 | select '{"a":1, "b":2, "c":3}'::jsonb - 2; 59 | select '{"a":1, "b":2, "c":3}'::jsonb - 1; 60 | select '{"a":1, "b":2, "c":3}'::jsonb - 0; 61 | select '{"a":1, "b":2, "c":3}'::jsonb - -1; 62 | select '{"a":1, "b":2, "c":3}'::jsonb - -2; 63 | select '{"a":1, "b":2, "c":3}'::jsonb - -3; 64 | select '{"a":1, "b":2, "c":3}'::jsonb - -4; 65 | 66 | select jsonb_delete('{"a":1, "b":2, "c":3}'::jsonb, '{d, e}'::text[]); 67 | select jsonb_delete('{"a":1, "b":2, "c":3}'::jsonb, '{b}'::text[]); 68 | select jsonb_delete('{"a":{"c":1, "d": 2}, "b":3}'::jsonb, '{a, c}'::text[]); 69 | select jsonb_delete('{"a":{"c":1, "d":{"f": 3, "g": 4}}, "b":5}'::jsonb, '{a, d, g}'::text[]); 70 | select jsonb_delete('{"a":1, "b":2, "c":3}'::jsonb, '{}'::text[]); 71 | select '{"a":1, "b":2, "c":3}'::jsonb - '{d, e}'::text[]; 72 | select '{"a":1, "b":2, "c":3}'::jsonb - '{b}'::text[]; 73 | select '{"a":{"c":1, "d":2}, "b":3}'::jsonb - '{a, c}'::text[]; 74 | select '{"a":{"c":1, "d":{"f": 3, "g": 4}}, "b":5}'::jsonb - '{a, d, g}'::text[]; 75 | select '{"a":1, "b":2, "c":3}'::jsonb - '{}'::text[]; 76 | select pg_column_size('{"a":1, "b":2, "c":3}'::jsonb - '{a}'::text[]) 77 | = pg_column_size('{"b":2, "c":3}'::jsonb); 78 | select pg_column_size('{"a":1, "b":2, "c":3}'::jsonb - '{}'::text[]) 79 | = pg_column_size('{"a":1, "b":2, "c":3}'::jsonb); 80 | 81 | select jsonb_set('{"a":1,"b":[0,1,2,3,4,5,6,7,8,9,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1],"c":{"d":1}}','{"b",-101}','123'); 82 | 83 | select jsonb_set('"a"'::jsonb, '{a}', '[1,2,3]'); 84 | select jsonb_set('{"n":null, "a":1, "b":[1,2], "c":{"1":2}, "d":{"1":[2,3]}}'::jsonb, '{n}', '[1,2,3]'); 85 | select jsonb_set('{"n":null, "a":1, "b":[1,2], "c":{"1":2}, "d":{"1":[2,3]}}'::jsonb, '{b,-1}', '[1,2,3]'); 86 | select jsonb_set('{"n":null, "a":1, "b":[1,2], "c":{"1":2}, "d":{"1":[2,3]}}'::jsonb, '{d,1,0}', '[1,2,3]'); 87 | select jsonb_set('{"n":null, "a":1, "b":[1,2], "c":{"1":2}, "d":{"1":[2,3]}}'::jsonb, '{d,NULL,0}', '[1,2,3]'); 88 | 89 | select jsonb_set('{"n":null, "a":1, "b":[1,2], "c":{"1":2}, "d":{"1":[2,3]}}'::jsonb, '{n}', '{"1": 2}'); 90 | select jsonb_set('{"n":null, "a":1, "b":[1,2], "c":{"1":2}, "d":{"1":[2,3]}}'::jsonb, '{b,-1}', '{"1": 2}'); 91 | select jsonb_set('{"n":null, "a":1, "b":[1,2], "c":{"1":2}, "d":{"1":[2,3]}}'::jsonb, '{d,1,0}', '{"1": 2}'); 92 | select jsonb_set('{"n":null, "a":1, "b":[1,2], "c":{"1":2}, "d":{"1":[2,3]}}'::jsonb, '{d,NULL,0}', '{"1": 2}'); 93 | 94 | select jsonb_set('{"n":null, "a":1, "b":[1,2], "c":{"1":2}, "d":{"1":[2,3]}}'::jsonb, '{b,-1}', '"test"'); 95 | select jsonb_set('{"n":null, "a":1, "b":[1,2], "c":{"1":2}, "d":{"1":[2,3]}}'::jsonb, '{b,-1}', '{"f": "test"}'); 96 | 97 | -- empty structure and error conditions for delete and replace 98 | 99 | select '"a"'::jsonb - 'a'; -- error 100 | select '{}'::jsonb - 'a'; 101 | select '[]'::jsonb - 'a'; 102 | select '"a"'::jsonb - 1; -- error 103 | select '{}'::jsonb - 1 ; 104 | select '[]'::jsonb - 1; 105 | select '"a"'::jsonb - '{a}'::text[]; -- error 106 | select '{}'::jsonb - '{a}'::text[]; 107 | select '[]'::jsonb - '{a}'::text[]; 108 | select jsonb_set('"a"','{a}','"b"'); --error 109 | select jsonb_set('{}','{a}','"b"', false); 110 | select jsonb_set('[]','{1}','"b"', false); 111 | 112 | -- jsonb_set adding instead of replacing 113 | 114 | -- prepend to array 115 | select jsonb_set('{"a":1,"b":[0,1,2],"c":{"d":4}}','{b,-33}','{"foo":123}'); 116 | -- append to array 117 | select jsonb_set('{"a":1,"b":[0,1,2],"c":{"d":4}}','{b,33}','{"foo":123}'); 118 | -- check nesting levels addition 119 | select jsonb_set('{"a":1,"b":[4,5,[0,1,2],6,7],"c":{"d":4}}','{b,2,33}','{"foo":123}'); 120 | -- add new key 121 | select jsonb_set('{"a":1,"b":[0,1,2],"c":{"d":4}}','{c,e}','{"foo":123}'); 122 | -- adding doesn't do anything if elements before last aren't present 123 | select jsonb_set('{"a":1,"b":[0,1,2],"c":{"d":4}}','{x,-33}','{"foo":123}'); 124 | select jsonb_set('{"a":1,"b":[0,1,2],"c":{"d":4}}','{x,y}','{"foo":123}'); 125 | -- add to empty object 126 | select jsonb_set('{}','{x}','{"foo":123}'); 127 | --add to empty array 128 | select jsonb_set('[]','{0}','{"foo":123}'); 129 | select jsonb_set('[]','{99}','{"foo":123}'); 130 | select jsonb_set('[]','{-99}','{"foo":123}'); 131 | 132 | -- verify path correctness 133 | select jsonb_set('{"a": [1, 2, 3]}', '{a, non_integer}', '"new_value"'); 134 | select jsonb_set('{"a": {"b": [1, 2, 3]}}', '{a, b, non_integer}', '"new_value"'); 135 | select jsonb_set('{"a": {"b": [1, 2, 3]}}', '{a, b, NULL}', '"new_value"'); 136 | --------------------------------------------------------------------------------