├── License ├── META.json ├── Makefile ├── README.md ├── doc └── json_build.md ├── json_build.control ├── sql ├── json_build--1.0.0--1.1.0.sql ├── json_build--1.1.0.sql └── json_build.sql ├── src └── json_build.c └── test ├── expected └── json_build.out └── sql └── json_build.sql /License: -------------------------------------------------------------------------------- 1 | This software, json_build extension for PostgreSQL, is released under 2 | the terms of the PostgreSQL License. 3 | 4 | Copyright (c) 2012-2013, Andrew Dunstan 5 | 6 | Permission to use, copy, modify, and distribute this software and its 7 | documentation for any purpose, without fee, and without a written agreement 8 | is hereby granted, provided that the above copyright notice and this paragraph 9 | and the following two paragraphs appear in all copies. 10 | 11 | IN NO EVENT SHALL Andrew Dunstan BE LIABLE TO ANY PARTY FOR DIRECT, INDIRECT, 12 | SPECIAL, INCIDENTAL, OR CONSEQUENTIAL DAMAGES, INCLUDING LOST PROFITS, ARISING 13 | OUT OF THE USE OF THIS SOFTWARE AND ITS DOCUMENTATION, EVEN IF Andrew Dunstan 14 | HAS BEEN ADVISED OF THE POSSIBILITY OF SUCH DAMAGE. 15 | 16 | Andrew Dunstan SPECIFICALLY DISCLAIMS ANY WARRANTIES, INCLUDING, BUT NOT 17 | LIMITED TO, THE IMPLIED WARRANTIES OF MERCHANTABILITY AND FITNESS FOR A 18 | PARTICULAR PURPOSE. THE SOFTWARE PROVIDED HEREUNDER IS ON AN "AS IS" BASIS, 19 | AND Andrew Dunstan HAS NO OBLIGATIONS TO PROVIDE MAINTENANCE, SUPPORT, 20 | UPDATES, ENHANCEMENTS, OR MODIFICATIONS. 21 | -------------------------------------------------------------------------------- /META.json: -------------------------------------------------------------------------------- 1 | { 2 | "name": "json_build", 3 | "abstract": "Functions to help build JSON objects", 4 | "description": "Helper functions to make it easier to build complex json objects.", 5 | "version": "1.0.0", 6 | "maintainer": [ 7 | "Andrew Dunstan " 8 | ], 9 | "license": "postgresql", 10 | "provides": { 11 | "json_build": { 12 | "abstract": "Functions to help build JSON objects", 13 | "file": "sql/json_build.sql", 14 | "docfile": "doc/json_build.md", 15 | "version": "1.0.0" 16 | } 17 | }, 18 | "prereqs": { 19 | "runtime": { 20 | "requires": { 21 | "PostgreSQL": ">= 9.2.0" 22 | } 23 | } 24 | }, 25 | "resources": { 26 | "repository": { 27 | "url": "https://github.com/pgexperts/json_build.git", 28 | "web": "https://github.com/pgexperts/json_build", 29 | "type": "git" 30 | }, 31 | "bugtracker": { 32 | "web": "https://github.com/pgexperts/json_build/issues" 33 | } 34 | }, 35 | "generated_by": "Andrew Dunstan", 36 | "meta-spec": { 37 | "version": "1.0.0", 38 | "url": "http://pgxn.org/meta/spec.txt" 39 | }, 40 | "tags": [ 41 | "json", 42 | "build", 43 | "array", 44 | "object" 45 | ] 46 | } 47 | -------------------------------------------------------------------------------- /Makefile: -------------------------------------------------------------------------------- 1 | EXTENSION = json_build 2 | 3 | ifeq ($(wildcard vpath.mk),vpath.mk) 4 | include vpath.mk 5 | else 6 | ext_srcdir = . 7 | endif 8 | 9 | EXTVERSION = $(shell grep default_version $(EXTENSION).control | sed -e "s/default_version[[:space:]]*=[[:space:]]*'\([^']*\)'/\1/") 10 | DATA = $(filter-out $(wildcard sql/*--*.sql),$(wildcard sql/*.sql)) 11 | DOCS = $(wildcard $(ext_srcdir)/doc/*.md) 12 | USE_MODULE_DB = 1 13 | TESTS = $(wildcard $(ext_srcdir)/test/sql/*.sql) 14 | REGRESS_OPTS = --inputdir=$(ext_srcdir)/test --outputdir=test \ 15 | --load-extension=$(EXTENSION) 16 | REGRESS = $(patsubst $(ext_srcdir)/test/sql/%.sql,%,$(TESTS)) 17 | MODULE_big = $(EXTENSION) 18 | OBJS = $(patsubst $(ext_srcdir)/src/%.c,src/%.o,$(wildcard $(ext_srcdir)/src/*.c)) 19 | PG_CONFIG = pg_config 20 | 21 | all: sql/$(EXTENSION)--$(EXTVERSION).sql 22 | 23 | sql/$(EXTENSION)--$(EXTVERSION).sql: $(ext_srcdir)/sql/$(EXTENSION).sql 24 | cp $< $@ 25 | 26 | DATA_built = sql/$(EXTENSION)--$(EXTVERSION).sql 27 | DATA = $(filter-out $(ext_srcdir)/sql/$(EXTENSION)--$(EXTVERSION).sql, $(wildcard $(ext_srcdir)/sql/*--*.sql)) 28 | EXTRA_CLEAN = sql/$(EXTENSION)--$(EXTVERSION).sql 29 | 30 | PGXS := $(shell $(PG_CONFIG) --pgxs) 31 | include $(PGXS) 32 | 33 | # we put all the tests in a test subdir, but pgxs expects us not to, darn it 34 | override pg_regress_clean_files = test/results/ test/regression.diffs test/regression.out tmp_check/ log/ 35 | -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | # json_build extension 2 | 3 | This PostgreSQL extension provides functions to help in building 4 | JSON of arbitrary complexity. 5 | 6 | The functions are: 7 | 8 | * `build_json_object (VARIADIC "any")` 9 | * `build_json_array (VARIADIC "any")` 10 | * `json_object_agg ("any", "any")` 11 | 12 | All the functions return JSON. They can be called nested and combined, to build 13 | up complex tree structured JSON. 14 | 15 | `VARIADIC "any"` means that the functions will accept any number of arguments 16 | of any type, and Postgres will accept the call, although the functions 17 | themselves do enforce certain rules. If called with no arguments an empty 18 | object or array is returned. 19 | 20 | If an argument is an array, it is converted to a JSON array, if it is a record, 21 | it is converted to a JSON object, if it is JSON it is passed through as is. 22 | 23 | Object keys must be not null and scalar - use of arrays, records or JSON values 24 | as keys is forbidden. 25 | 26 | `build_json_object` must get an even number of arguments - the odd numbered 27 | arguments (counting from 1) are the keys and the following even numbered 28 | arguments are the corresponding values. 29 | 30 | `json_object_agg` aggregates any two columns into a json object. 31 | 32 | Examples: 33 | 34 | SELECT build_json_object( 35 | 'a', build_json_object('b',false,'c',99), 36 | 'd', build_json_object('e',array[9,8,7]::int[], 37 | 'f', (select row_to_json(r) from ( SELECT relkind, oid::regclass as name 38 | FROM pg_class WHERE relname = 'pg_class') r))); 39 | build_json_object 40 | ------------------------------------------------------------------------------------------------- 41 | {"a" : {"b" : false, "c" : 99}, "d" : {"e" : [9,8,7], "f" : {"relkind":"r","name":"pg_class"}}} 42 | (1 row) 43 | 44 | SELECT build_json_array('a',1,'b',1.2,'c',true,'d',null,'e',json '{"x": 3, "y": [1,2,3]}'); 45 | build_json_array 46 | ----------------------------------------------------------------------- 47 | ["a", 1, "b", 1.2, "c", true, "d", null, "e", {"x": 3, "y": [1,2,3]}] 48 | (1 row) 49 | 50 | SELECT build_json_object('stuff',json_object_agg(k,v)) 51 | FROM (values ('k1','v1'),('k2','v2')) AS x(k,v); 52 | build_json_object 53 | ------------------------------------------ 54 | {"stuff" : { "k1" : "v1", "k2" : "v2" }} 55 | 56 | 57 | 58 | -------------------------------------------------------------------------------- /doc/json_build.md: -------------------------------------------------------------------------------- 1 | ../README.md -------------------------------------------------------------------------------- /json_build.control: -------------------------------------------------------------------------------- 1 | # json_build extension 2 | comment = 'json_build extension' 3 | default_version = '1.1.0' 4 | module_pathname = '$libdir/json_build' 5 | relocatable = true 6 | -------------------------------------------------------------------------------- /sql/json_build--1.0.0--1.1.0.sql: -------------------------------------------------------------------------------- 1 | -- complain if script is sourced in psql, rather than via ALTER EXTENSION 2 | \echo Use "ALTER EXTENSION json_build UPDATE TO '1.1.0'" to load this file. \quit 3 | 4 | 5 | CREATE FUNCTION json_object_agg_transfn(internal, "any", "any") 6 | RETURNS internal 7 | AS 'MODULE_PATHNAME' 8 | LANGUAGE C IMMUTABLE; 9 | 10 | CREATE FUNCTION json_object_agg_finalfn(internal) 11 | RETURNS json 12 | AS 'MODULE_PATHNAME' 13 | LANGUAGE C IMMUTABLE; 14 | 15 | CREATE AGGREGATE json_object_agg("any", "any") ( 16 | SFUNC = json_object_agg_transfn, 17 | FINALFUNC = json_object_agg_finalfn, 18 | STYPE = internal 19 | ); 20 | 21 | 22 | -------------------------------------------------------------------------------- /sql/json_build--1.1.0.sql: -------------------------------------------------------------------------------- 1 | -- complain if script is sourced in psql, rather than via CREATE EXTENSION 2 | \echo Use "CREATE EXTENSION json_build" to load this file. \quit 3 | 4 | CREATE FUNCTION build_json_object(VARIADIC "any") 5 | RETURNS json 6 | AS 'MODULE_PATHNAME' 7 | LANGUAGE C IMMUTABLE; 8 | 9 | -- degenerate case - return empty object 10 | CREATE FUNCTION build_json_object() 11 | RETURNS json 12 | AS 'select json $${}$$ ' 13 | LANGUAGE SQL IMMUTABLE; 14 | 15 | CREATE FUNCTION build_json_array(VARIADIC "any") 16 | RETURNS json 17 | AS 'MODULE_PATHNAME' 18 | LANGUAGE C IMMUTABLE; 19 | 20 | -- degenerate case - return empty array 21 | CREATE FUNCTION build_json_array() 22 | RETURNS json 23 | AS 'select json $$[]$$ ' 24 | LANGUAGE SQL IMMUTABLE; 25 | 26 | 27 | CREATE FUNCTION json_object_agg_transfn(internal, "any", "any") 28 | RETURNS internal 29 | AS 'MODULE_PATHNAME' 30 | LANGUAGE C IMMUTABLE; 31 | 32 | CREATE FUNCTION json_object_agg_finalfn(internal) 33 | RETURNS json 34 | AS 'MODULE_PATHNAME' 35 | LANGUAGE C IMMUTABLE; 36 | 37 | CREATE AGGREGATE json_object_agg("any", "any") ( 38 | SFUNC = json_object_agg_transfn, 39 | FINALFUNC = json_object_agg_finalfn, 40 | STYPE = internal 41 | ); 42 | -------------------------------------------------------------------------------- /sql/json_build.sql: -------------------------------------------------------------------------------- 1 | -- complain if script is sourced in psql, rather than via CREATE EXTENSION 2 | \echo Use "CREATE EXTENSION json_build" to load this file. \quit 3 | 4 | CREATE FUNCTION build_json_object(VARIADIC "any") 5 | RETURNS json 6 | AS 'MODULE_PATHNAME' 7 | LANGUAGE C IMMUTABLE; 8 | 9 | -- degenerate case - return empty object 10 | CREATE FUNCTION build_json_object() 11 | RETURNS json 12 | AS 'select json $${}$$ ' 13 | LANGUAGE SQL IMMUTABLE; 14 | 15 | CREATE FUNCTION build_json_array(VARIADIC "any") 16 | RETURNS json 17 | AS 'MODULE_PATHNAME' 18 | LANGUAGE C IMMUTABLE; 19 | 20 | -- degenerate case - return empty array 21 | CREATE FUNCTION build_json_array() 22 | RETURNS json 23 | AS 'select json $$[]$$ ' 24 | LANGUAGE SQL IMMUTABLE; 25 | 26 | 27 | CREATE FUNCTION json_object_agg_transfn(internal, "any", "any") 28 | RETURNS internal 29 | AS 'MODULE_PATHNAME' 30 | LANGUAGE C IMMUTABLE; 31 | 32 | CREATE FUNCTION json_object_agg_finalfn(internal) 33 | RETURNS json 34 | AS 'MODULE_PATHNAME' 35 | LANGUAGE C IMMUTABLE; 36 | 37 | CREATE AGGREGATE json_object_agg("any", "any") ( 38 | SFUNC = json_object_agg_transfn, 39 | FINALFUNC = json_object_agg_finalfn, 40 | STYPE = internal 41 | ); 42 | -------------------------------------------------------------------------------- /src/json_build.c: -------------------------------------------------------------------------------- 1 | /*------------------------------------------------------------------------- 2 | * 3 | * json_build.c 4 | * Helper functions for building up JSON 5 | * 6 | * Portions Copyright (c) 1996-2012, PostgreSQL Global Development Group 7 | * Portions Copyright (c) 1994, Regents of the University of California 8 | * 9 | *------------------------------------------------------------------------- 10 | */ 11 | 12 | #include "postgres.h" 13 | 14 | #include "fmgr.h" 15 | #if PG_VERSION_NUM >= 90300 16 | #include "access/htup_details.h" 17 | #endif 18 | #include "access/transam.h" 19 | #include "catalog/pg_cast.h" 20 | #include "catalog/pg_type.h" 21 | #include "parser/parse_coerce.h" 22 | #include "utils/array.h" 23 | #include "utils/builtins.h" 24 | #include "utils/json.h" 25 | #include "utils/typcache.h" 26 | #include "utils/syscache.h" 27 | #include "utils/lsyscache.h" 28 | 29 | PG_MODULE_MAGIC; 30 | 31 | /* functions copied from core PG because they are not exposed there */ 32 | 33 | static void composite_to_json(Datum composite, StringInfo result, 34 | bool use_line_feeds); 35 | static void array_dim_to_json(StringInfo result, int dim, int ndims, int *dims, 36 | Datum *vals, bool *nulls, int *valcount, 37 | TYPCATEGORY tcategory, Oid typoutputfunc, 38 | bool use_line_feeds); 39 | static void array_to_json_internal(Datum array, StringInfo result, 40 | bool use_line_feeds); 41 | 42 | /* 43 | * All the defined type categories are upper case , so use lower case here 44 | * so we avoid any possible clash. 45 | */ 46 | /* fake type category for JSON so we can distinguish it in datum_to_json */ 47 | #define TYPCATEGORY_JSON 'j' 48 | /* fake category for types that have a cast to json */ 49 | #define TYPCATEGORY_JSON_CAST 'c' 50 | /* letters appearing in numeric output that aren't valid in a JSON number */ 51 | #define NON_NUMERIC_LETTER "NnAaIiFfTtYy" 52 | 53 | /* 54 | * Turn a scalar Datum into JSON, appending the string to "result". 55 | * 56 | * Hand off a non-scalar datum to composite_to_json or array_to_json_internal 57 | * as appropriate. 58 | */ 59 | static void 60 | datum_to_json(Datum val, bool is_null, StringInfo result, 61 | TYPCATEGORY tcategory, Oid typoutputfunc, bool key_scalar) 62 | { 63 | char *outputstr; 64 | text *jsontext; 65 | 66 | if (is_null) 67 | { 68 | appendStringInfoString(result, "null"); 69 | return; 70 | } 71 | 72 | switch (tcategory) 73 | { 74 | case TYPCATEGORY_ARRAY: 75 | array_to_json_internal(val, result, false); 76 | break; 77 | case TYPCATEGORY_COMPOSITE: 78 | composite_to_json(val, result, false); 79 | break; 80 | case TYPCATEGORY_BOOLEAN: 81 | if (!key_scalar) 82 | appendStringInfoString(result, DatumGetBool(val) ? "true" : "false"); 83 | else 84 | escape_json(result, DatumGetBool(val) ? "true" : "false"); 85 | break; 86 | case TYPCATEGORY_NUMERIC: 87 | outputstr = OidOutputFunctionCall(typoutputfunc, val); 88 | 89 | /* 90 | * Don't call escape_json here if it's a valid JSON number. 91 | * Numeric output should usually be a valid JSON number and JSON 92 | * numbers shouldn't be quoted. Quote cases like "Nan" and 93 | * "Infinity", however. 94 | */ 95 | if (strpbrk(outputstr, NON_NUMERIC_LETTER) == NULL && ! key_scalar) 96 | appendStringInfoString(result, outputstr); 97 | else 98 | escape_json(result, outputstr); 99 | pfree(outputstr); 100 | break; 101 | case TYPCATEGORY_JSON: 102 | /* JSON will already be escaped */ 103 | outputstr = OidOutputFunctionCall(typoutputfunc, val); 104 | appendStringInfoString(result, outputstr); 105 | pfree(outputstr); 106 | break; 107 | case TYPCATEGORY_JSON_CAST: 108 | jsontext = DatumGetTextP(OidFunctionCall1(typoutputfunc, val)); 109 | outputstr = text_to_cstring(jsontext); 110 | appendStringInfoString(result, outputstr); 111 | pfree(outputstr); 112 | pfree(jsontext); 113 | break; 114 | default: 115 | outputstr = OidOutputFunctionCall(typoutputfunc, val); 116 | if (key_scalar && *outputstr == '\0') 117 | ereport(ERROR, 118 | (errcode(ERRCODE_INVALID_PARAMETER_VALUE), 119 | errmsg("key value must not be empty"))); 120 | escape_json(result, outputstr); 121 | pfree(outputstr); 122 | break; 123 | } 124 | } 125 | 126 | /* 127 | * Process a single dimension of an array. 128 | * If it's the innermost dimension, output the values, otherwise call 129 | * ourselves recursively to process the next dimension. 130 | */ 131 | static void 132 | array_dim_to_json(StringInfo result, int dim, int ndims, int *dims, Datum *vals, 133 | bool *nulls, int *valcount, TYPCATEGORY tcategory, 134 | Oid typoutputfunc, bool use_line_feeds) 135 | { 136 | int i; 137 | const char *sep; 138 | 139 | Assert(dim < ndims); 140 | 141 | sep = use_line_feeds ? ",\n " : ","; 142 | 143 | appendStringInfoChar(result, '['); 144 | 145 | for (i = 1; i <= dims[dim]; i++) 146 | { 147 | if (i > 1) 148 | appendStringInfoString(result, sep); 149 | 150 | if (dim + 1 == ndims) 151 | { 152 | datum_to_json(vals[*valcount], nulls[*valcount], result, tcategory, 153 | typoutputfunc, false); 154 | (*valcount)++; 155 | } 156 | else 157 | { 158 | /* 159 | * Do we want line feeds on inner dimensions of arrays? For now 160 | * we'll say no. 161 | */ 162 | array_dim_to_json(result, dim + 1, ndims, dims, vals, nulls, 163 | valcount, tcategory, typoutputfunc, false); 164 | } 165 | } 166 | 167 | appendStringInfoChar(result, ']'); 168 | } 169 | 170 | /* 171 | * Turn an array into JSON. 172 | */ 173 | static void 174 | array_to_json_internal(Datum array, StringInfo result, bool use_line_feeds) 175 | { 176 | ArrayType *v = DatumGetArrayTypeP(array); 177 | Oid element_type = ARR_ELEMTYPE(v); 178 | int *dim; 179 | int ndim; 180 | int nitems; 181 | int count = 0; 182 | Datum *elements; 183 | bool *nulls; 184 | int16 typlen; 185 | bool typbyval; 186 | char typalign, 187 | typdelim; 188 | Oid typioparam; 189 | Oid typoutputfunc; 190 | TYPCATEGORY tcategory; 191 | Oid castfunc = InvalidOid; 192 | 193 | ndim = ARR_NDIM(v); 194 | dim = ARR_DIMS(v); 195 | nitems = ArrayGetNItems(ndim, dim); 196 | 197 | if (nitems <= 0) 198 | { 199 | appendStringInfoString(result, "[]"); 200 | return; 201 | } 202 | 203 | get_type_io_data(element_type, IOFunc_output, 204 | &typlen, &typbyval, &typalign, 205 | &typdelim, &typioparam, &typoutputfunc); 206 | 207 | if (element_type > FirstNormalObjectId) 208 | { 209 | HeapTuple tuple; 210 | Form_pg_cast castForm; 211 | 212 | tuple = SearchSysCache2(CASTSOURCETARGET, 213 | ObjectIdGetDatum(element_type), 214 | ObjectIdGetDatum(JSONOID)); 215 | if (HeapTupleIsValid(tuple)) 216 | { 217 | castForm = (Form_pg_cast) GETSTRUCT(tuple); 218 | 219 | if (castForm->castmethod == COERCION_METHOD_FUNCTION) 220 | castfunc = typoutputfunc = castForm->castfunc; 221 | 222 | ReleaseSysCache(tuple); 223 | } 224 | } 225 | 226 | deconstruct_array(v, element_type, typlen, typbyval, 227 | typalign, &elements, &nulls, 228 | &nitems); 229 | 230 | if (castfunc != InvalidOid) 231 | tcategory = TYPCATEGORY_JSON_CAST; 232 | else if (element_type == RECORDOID) 233 | tcategory = TYPCATEGORY_COMPOSITE; 234 | else if (element_type == JSONOID) 235 | tcategory = TYPCATEGORY_JSON; 236 | else 237 | tcategory = TypeCategory(element_type); 238 | 239 | array_dim_to_json(result, 0, ndim, dim, elements, nulls, &count, tcategory, 240 | typoutputfunc, use_line_feeds); 241 | 242 | pfree(elements); 243 | pfree(nulls); 244 | } 245 | 246 | /* 247 | * Turn a composite / record into JSON. 248 | */ 249 | static void 250 | composite_to_json(Datum composite, StringInfo result, bool use_line_feeds) 251 | { 252 | HeapTupleHeader td; 253 | Oid tupType; 254 | int32 tupTypmod; 255 | TupleDesc tupdesc; 256 | HeapTupleData tmptup, 257 | *tuple; 258 | int i; 259 | bool needsep = false; 260 | const char *sep; 261 | 262 | sep = use_line_feeds ? ",\n " : ","; 263 | 264 | td = DatumGetHeapTupleHeader(composite); 265 | 266 | /* Extract rowtype info and find a tupdesc */ 267 | tupType = HeapTupleHeaderGetTypeId(td); 268 | tupTypmod = HeapTupleHeaderGetTypMod(td); 269 | tupdesc = lookup_rowtype_tupdesc(tupType, tupTypmod); 270 | 271 | /* Build a temporary HeapTuple control structure */ 272 | tmptup.t_len = HeapTupleHeaderGetDatumLength(td); 273 | tmptup.t_data = td; 274 | tuple = &tmptup; 275 | 276 | appendStringInfoChar(result, '{'); 277 | 278 | for (i = 0; i < tupdesc->natts; i++) 279 | { 280 | Datum val, 281 | origval; 282 | bool isnull; 283 | char *attname; 284 | TYPCATEGORY tcategory; 285 | Oid typoutput; 286 | bool typisvarlena; 287 | Oid castfunc = InvalidOid; 288 | 289 | if (tupdesc->attrs[i]->attisdropped) 290 | continue; 291 | 292 | if (needsep) 293 | appendStringInfoString(result, sep); 294 | needsep = true; 295 | 296 | attname = NameStr(tupdesc->attrs[i]->attname); 297 | escape_json(result, attname); 298 | appendStringInfoChar(result, ':'); 299 | 300 | origval = heap_getattr(tuple, i + 1, tupdesc, &isnull); 301 | 302 | getTypeOutputInfo(tupdesc->attrs[i]->atttypid, 303 | &typoutput, &typisvarlena); 304 | 305 | if (tupdesc->attrs[i]->atttypid > FirstNormalObjectId) 306 | { 307 | HeapTuple cast_tuple; 308 | Form_pg_cast castForm; 309 | 310 | cast_tuple = SearchSysCache2(CASTSOURCETARGET, 311 | ObjectIdGetDatum(tupdesc->attrs[i]->atttypid), 312 | ObjectIdGetDatum(JSONOID)); 313 | if (HeapTupleIsValid(cast_tuple)) 314 | { 315 | castForm = (Form_pg_cast) GETSTRUCT(cast_tuple); 316 | 317 | if (castForm->castmethod == COERCION_METHOD_FUNCTION) 318 | castfunc = typoutput = castForm->castfunc; 319 | 320 | ReleaseSysCache(cast_tuple); 321 | } 322 | } 323 | 324 | if (castfunc != InvalidOid) 325 | tcategory = TYPCATEGORY_JSON_CAST; 326 | else if (tupdesc->attrs[i]->atttypid == RECORDARRAYOID) 327 | tcategory = TYPCATEGORY_ARRAY; 328 | else if (tupdesc->attrs[i]->atttypid == RECORDOID) 329 | tcategory = TYPCATEGORY_COMPOSITE; 330 | else if (tupdesc->attrs[i]->atttypid == JSONOID) 331 | tcategory = TYPCATEGORY_JSON; 332 | else 333 | tcategory = TypeCategory(tupdesc->attrs[i]->atttypid); 334 | 335 | /* 336 | * If we have a toasted datum, forcibly detoast it here to avoid 337 | * memory leakage inside the type's output routine. 338 | */ 339 | if (typisvarlena && !isnull) 340 | val = PointerGetDatum(PG_DETOAST_DATUM(origval)); 341 | else 342 | val = origval; 343 | 344 | datum_to_json(val, isnull, result, tcategory, typoutput, false); 345 | 346 | /* Clean up detoasted copy, if any */ 347 | if (val != origval) 348 | pfree(DatumGetPointer(val)); 349 | } 350 | 351 | appendStringInfoChar(result, '}'); 352 | ReleaseTupleDesc(tupdesc); 353 | } 354 | 355 | static void 356 | add_json(Datum orig_val, bool is_null, StringInfo result, Oid val_type, bool key_scalar) 357 | { 358 | Datum val; 359 | TYPCATEGORY tcategory; 360 | Oid typoutput; 361 | bool typisvarlena; 362 | Oid castfunc = InvalidOid; 363 | 364 | if (val_type == InvalidOid) 365 | ereport(ERROR, 366 | (errcode(ERRCODE_INVALID_PARAMETER_VALUE), 367 | errmsg("could not determine input data type"))); 368 | 369 | 370 | getTypeOutputInfo(val_type, &typoutput, &typisvarlena); 371 | 372 | if (val_type > FirstNormalObjectId) 373 | { 374 | HeapTuple tuple; 375 | Form_pg_cast castForm; 376 | 377 | tuple = SearchSysCache2(CASTSOURCETARGET, 378 | ObjectIdGetDatum(val_type), 379 | ObjectIdGetDatum(JSONOID)); 380 | if (HeapTupleIsValid(tuple)) 381 | { 382 | castForm = (Form_pg_cast) GETSTRUCT(tuple); 383 | 384 | if (castForm->castmethod == COERCION_METHOD_FUNCTION) 385 | castfunc = typoutput = castForm->castfunc; 386 | 387 | ReleaseSysCache(tuple); 388 | } 389 | } 390 | 391 | if (castfunc != InvalidOid) 392 | tcategory = TYPCATEGORY_JSON_CAST; 393 | else if (val_type == RECORDARRAYOID) 394 | tcategory = TYPCATEGORY_ARRAY; 395 | else if (val_type == RECORDOID) 396 | tcategory = TYPCATEGORY_COMPOSITE; 397 | else if (val_type == JSONOID) 398 | tcategory = TYPCATEGORY_JSON; 399 | else 400 | tcategory = TypeCategory(val_type); 401 | 402 | if (key_scalar && 403 | (tcategory == TYPCATEGORY_ARRAY || 404 | tcategory == TYPCATEGORY_COMPOSITE || 405 | tcategory == TYPCATEGORY_JSON || 406 | tcategory == TYPCATEGORY_JSON_CAST)) 407 | ereport(ERROR, 408 | (errcode(ERRCODE_INVALID_PARAMETER_VALUE), 409 | errmsg("key value must be scalar, not array, composite or json"))); 410 | 411 | /* 412 | * If we have a toasted datum, forcibly detoast it here to avoid 413 | * memory leakage inside the type's output routine. 414 | */ 415 | if (typisvarlena && orig_val != (Datum) 0) 416 | val = PointerGetDatum(PG_DETOAST_DATUM(orig_val)); 417 | else 418 | val = orig_val; 419 | 420 | datum_to_json(val, is_null, result, tcategory, typoutput, key_scalar); 421 | 422 | /* Clean up detoasted copy, if any */ 423 | if (val != orig_val) 424 | pfree(DatumGetPointer(val)); 425 | } 426 | 427 | 428 | /* 429 | * SQL function build_json_object(variadic "any") 430 | */ 431 | extern Datum build_json_object(PG_FUNCTION_ARGS); 432 | 433 | PG_FUNCTION_INFO_V1(build_json_object); 434 | 435 | Datum 436 | build_json_object(PG_FUNCTION_ARGS) 437 | { 438 | int nargs = PG_NARGS(); 439 | int i; 440 | Datum arg; 441 | char *sep = ""; 442 | StringInfo result; 443 | Oid val_type; 444 | 445 | 446 | if (nargs % 2 != 0) 447 | ereport(ERROR, 448 | (errcode(ERRCODE_INVALID_PARAMETER_VALUE), 449 | errmsg("invalid number or arguments: object must be matched key value pairs"))); 450 | 451 | result = makeStringInfo(); 452 | 453 | appendStringInfoChar(result,'{'); 454 | 455 | for (i = 0; i < nargs; i += 2) 456 | { 457 | 458 | /* process key */ 459 | 460 | if (PG_ARGISNULL(i)) 461 | ereport(ERROR, 462 | (errcode(ERRCODE_INVALID_PARAMETER_VALUE), 463 | errmsg("arg %d: key cannot be null", i+1))); 464 | val_type = get_fn_expr_argtype(fcinfo->flinfo, i); 465 | /* 466 | * turn a constant (more or less literal) value that's of unknown 467 | * type into text. Unknowns come in as a cstring pointer. 468 | */ 469 | if (val_type == UNKNOWNOID && get_fn_expr_arg_stable(fcinfo->flinfo, i)) 470 | { 471 | val_type = TEXTOID; 472 | if (PG_ARGISNULL(i)) 473 | arg = (Datum)0; 474 | else 475 | arg = CStringGetTextDatum(PG_GETARG_POINTER(i)); 476 | } 477 | else 478 | { 479 | arg = PG_GETARG_DATUM(i); 480 | } 481 | if (val_type == InvalidOid || val_type == UNKNOWNOID) 482 | ereport(ERROR, 483 | (errcode(ERRCODE_INVALID_PARAMETER_VALUE), 484 | errmsg("arg %d: could not determine data type",i+1))); 485 | appendStringInfoString(result,sep); 486 | sep = ", "; 487 | add_json(arg, false, result, val_type, true); 488 | 489 | appendStringInfoString(result," : "); 490 | 491 | /* process value */ 492 | 493 | val_type = get_fn_expr_argtype(fcinfo->flinfo, i+1); 494 | /* see comments above */ 495 | if (val_type == UNKNOWNOID && get_fn_expr_arg_stable(fcinfo->flinfo, i+1)) 496 | { 497 | val_type = TEXTOID; 498 | if (PG_ARGISNULL(i+1)) 499 | arg = (Datum)0; 500 | else 501 | arg = CStringGetTextDatum(PG_GETARG_POINTER(i+1)); 502 | } 503 | else 504 | { 505 | arg = PG_GETARG_DATUM(i+1); 506 | } 507 | if (val_type == InvalidOid || val_type == UNKNOWNOID) 508 | ereport(ERROR, 509 | (errcode(ERRCODE_INVALID_PARAMETER_VALUE), 510 | errmsg("arg %d: could not determine data type",i+2))); 511 | add_json(arg, PG_ARGISNULL(i+1), result, val_type, false); 512 | 513 | } 514 | appendStringInfoChar(result,'}'); 515 | 516 | PG_RETURN_TEXT_P(cstring_to_text_with_len(result->data, result->len)); 517 | 518 | } 519 | 520 | /* 521 | * SQL function build_json_array(variadic "any") 522 | */ 523 | extern Datum build_json_array(PG_FUNCTION_ARGS); 524 | 525 | PG_FUNCTION_INFO_V1(build_json_array); 526 | 527 | Datum 528 | build_json_array(PG_FUNCTION_ARGS) 529 | { 530 | int nargs = PG_NARGS(); 531 | int i; 532 | Datum arg; 533 | char *sep = ""; 534 | StringInfo result; 535 | Oid val_type; 536 | 537 | 538 | result = makeStringInfo(); 539 | 540 | appendStringInfoChar(result,'['); 541 | 542 | for (i = 0; i < nargs; i ++) 543 | { 544 | val_type = get_fn_expr_argtype(fcinfo->flinfo, i); 545 | arg = PG_GETARG_DATUM(i+1); 546 | /* see comments in build_json_object above */ 547 | if (val_type == UNKNOWNOID && get_fn_expr_arg_stable(fcinfo->flinfo, i)) 548 | { 549 | val_type = TEXTOID; 550 | if (PG_ARGISNULL(i)) 551 | arg = (Datum)0; 552 | else 553 | arg = CStringGetTextDatum(PG_GETARG_POINTER(i)); 554 | } 555 | else 556 | { 557 | arg = PG_GETARG_DATUM(i); 558 | } 559 | if (val_type == InvalidOid || val_type == UNKNOWNOID) 560 | ereport(ERROR, 561 | (errcode(ERRCODE_INVALID_PARAMETER_VALUE), 562 | errmsg("arg %d: could not determine data type",i+1))); 563 | appendStringInfoString(result,sep); 564 | sep = ", "; 565 | add_json(arg, PG_ARGISNULL(i), result, val_type, false); 566 | } 567 | appendStringInfoChar(result,']'); 568 | 569 | PG_RETURN_TEXT_P(cstring_to_text_with_len(result->data, result->len)); 570 | 571 | } 572 | 573 | extern Datum json_object_agg_transfn(PG_FUNCTION_ARGS); 574 | 575 | PG_FUNCTION_INFO_V1(json_object_agg_transfn); 576 | 577 | Datum 578 | json_object_agg_transfn(PG_FUNCTION_ARGS) 579 | { 580 | Oid val_type; 581 | MemoryContext aggcontext, 582 | oldcontext; 583 | StringInfo state; 584 | Datum arg; 585 | 586 | if (!AggCheckCallContext(fcinfo, &aggcontext)) 587 | { 588 | /* cannot be called directly because of internal-type argument */ 589 | elog(ERROR, "json_agg_transfn called in non-aggregate context"); 590 | } 591 | 592 | if (PG_ARGISNULL(0)) 593 | { 594 | /* 595 | * Make this StringInfo in a context where it will persist for the 596 | * duration off the aggregate call. It's only needed for this initial 597 | * piece, as the StringInfo routines make sure they use the right 598 | * context to enlarge the object if necessary. 599 | */ 600 | oldcontext = MemoryContextSwitchTo(aggcontext); 601 | state = makeStringInfo(); 602 | MemoryContextSwitchTo(oldcontext); 603 | 604 | appendStringInfoString(state, "{ "); 605 | } 606 | else 607 | { 608 | state = (StringInfo) PG_GETARG_POINTER(0); 609 | appendStringInfoString(state, ", "); 610 | } 611 | 612 | if (PG_ARGISNULL(1)) 613 | ereport(ERROR, 614 | (errcode(ERRCODE_INVALID_PARAMETER_VALUE), 615 | errmsg("field name must not be null"))); 616 | 617 | 618 | val_type = get_fn_expr_argtype(fcinfo->flinfo, 1); 619 | /* 620 | * turn a constant (more or less literal) value that's of unknown 621 | * type into text. Unknowns come in as a cstring pointer. 622 | */ 623 | if (val_type == UNKNOWNOID && get_fn_expr_arg_stable(fcinfo->flinfo, 1)) 624 | { 625 | val_type = TEXTOID; 626 | arg = CStringGetTextDatum(PG_GETARG_POINTER(1)); 627 | } 628 | else 629 | { 630 | arg = PG_GETARG_DATUM(1); 631 | } 632 | 633 | if (val_type == InvalidOid || val_type == UNKNOWNOID) 634 | ereport(ERROR, 635 | (errcode(ERRCODE_INVALID_PARAMETER_VALUE), 636 | errmsg("arg 1: could not determine data type"))); 637 | 638 | add_json(arg, false, state, val_type, true); 639 | 640 | appendStringInfoString(state," : "); 641 | 642 | val_type = get_fn_expr_argtype(fcinfo->flinfo, 2); 643 | /* see comments above */ 644 | if (val_type == UNKNOWNOID && get_fn_expr_arg_stable(fcinfo->flinfo, 2)) 645 | { 646 | val_type = TEXTOID; 647 | if (PG_ARGISNULL(2)) 648 | arg = (Datum)0; 649 | else 650 | arg = CStringGetTextDatum(PG_GETARG_POINTER(2)); 651 | } 652 | else 653 | { 654 | arg = PG_GETARG_DATUM(2); 655 | } 656 | 657 | if (val_type == InvalidOid || val_type == UNKNOWNOID) 658 | ereport(ERROR, 659 | (errcode(ERRCODE_INVALID_PARAMETER_VALUE), 660 | errmsg("arg 2: could not determine data type"))); 661 | 662 | add_json(arg, PG_ARGISNULL(2), state, val_type, false); 663 | 664 | PG_RETURN_POINTER(state); 665 | } 666 | 667 | extern Datum json_object_agg_finalfn(PG_FUNCTION_ARGS); 668 | 669 | PG_FUNCTION_INFO_V1(json_object_agg_finalfn); 670 | 671 | Datum 672 | json_object_agg_finalfn(PG_FUNCTION_ARGS) 673 | { 674 | StringInfo state; 675 | 676 | /* cannot be called directly because of internal-type argument */ 677 | Assert(AggCheckCallContext(fcinfo, NULL)); 678 | 679 | state = PG_ARGISNULL(0) ? NULL : (StringInfo) PG_GETARG_POINTER(0); 680 | 681 | if (state == NULL) 682 | PG_RETURN_TEXT_P(cstring_to_text("{}")); 683 | 684 | appendStringInfoString(state, " }"); 685 | 686 | PG_RETURN_TEXT_P(cstring_to_text(state->data)); 687 | } 688 | 689 | 690 | -------------------------------------------------------------------------------- /test/expected/json_build.out: -------------------------------------------------------------------------------- 1 | SELECT build_json_array('a',1,'b',1.2,'c',true,'d',null,'e',json '{"x": 3, "y": [1,2,3]}'); 2 | build_json_array 3 | ----------------------------------------------------------------------- 4 | ["a", 1, "b", 1.2, "c", true, "d", null, "e", {"x": 3, "y": [1,2,3]}] 5 | (1 row) 6 | 7 | SELECT build_json_object('a',1,'b',1.2,'c',true,'d',null,'e',json '{"x": 3, "y": [1,2,3]}'); 8 | build_json_object 9 | ---------------------------------------------------------------------------- 10 | {"a" : 1, "b" : 1.2, "c" : true, "d" : null, "e" : {"x": 3, "y": [1,2,3]}} 11 | (1 row) 12 | 13 | SELECT build_json_object( 14 | 'a', build_json_object('b',false,'c',99), 15 | 'd', build_json_object('e',array[9,8,7]::int[], 16 | 'f', (select row_to_json(r) from ( select relkind, oid::regclass as name from pg_class where relname = 'pg_class') r))); 17 | build_json_object 18 | ------------------------------------------------------------------------------------------------- 19 | {"a" : {"b" : false, "c" : 99}, "d" : {"e" : [9,8,7], "f" : {"relkind":"r","name":"pg_class"}}} 20 | (1 row) 21 | 22 | -- empty objects/arrays 23 | SELECT build_json_array(); 24 | build_json_array 25 | ------------------ 26 | [] 27 | (1 row) 28 | 29 | SELECT build_json_object(); 30 | build_json_object 31 | ------------------- 32 | {} 33 | (1 row) 34 | 35 | -- make sure keys are quoted 36 | SELECT build_json_object(1,2); 37 | build_json_object 38 | ------------------- 39 | {"1" : 2} 40 | (1 row) 41 | 42 | -- keys must be scalar and not null 43 | SELECT build_json_object(null,2); 44 | ERROR: arg 1: key cannot be null 45 | SELECT build_json_object(r,2) FROM (SELECT 1 AS a, 2 AS b) r; 46 | ERROR: key value must be scalar, not array, composite or json 47 | SELECT build_json_object(json '{"a":1,"b":2}', 3); 48 | ERROR: key value must be scalar, not array, composite or json 49 | SELECT build_json_object('{1,2,3}'::int[], 3); 50 | ERROR: key value must be scalar, not array, composite or json 51 | CREATE TEMP TABLE foo (serial int, name text, type text); 52 | INSERT INTO foo VALUES (847001,'t15','GE1043'); 53 | INSERT INTO foo VALUES (847002,'t16','GE1043'); 54 | INSERT INTO foo VALUES (847003,'sub-alpha','GESS90'); 55 | SELECT build_json_object('turbines',json_object_agg(serial,build_json_object('name',name,'type',type))) 56 | FROM foo; 57 | build_json_object 58 | ------------------------------------------------------------------------------------------------------------------------------------------------------------------------- 59 | {"turbines" : { "847001" : {"name" : "t15", "type" : "GE1043"}, "847002" : {"name" : "t16", "type" : "GE1043"}, "847003" : {"name" : "sub-alpha", "type" : "GESS90"} }} 60 | (1 row) 61 | 62 | -------------------------------------------------------------------------------- /test/sql/json_build.sql: -------------------------------------------------------------------------------- 1 | 2 | SELECT build_json_array('a',1,'b',1.2,'c',true,'d',null,'e',json '{"x": 3, "y": [1,2,3]}'); 3 | 4 | SELECT build_json_object('a',1,'b',1.2,'c',true,'d',null,'e',json '{"x": 3, "y": [1,2,3]}'); 5 | 6 | SELECT build_json_object( 7 | 'a', build_json_object('b',false,'c',99), 8 | 'd', build_json_object('e',array[9,8,7]::int[], 9 | 'f', (select row_to_json(r) from ( select relkind, oid::regclass as name from pg_class where relname = 'pg_class') r))); 10 | 11 | 12 | -- empty objects/arrays 13 | SELECT build_json_array(); 14 | 15 | SELECT build_json_object(); 16 | 17 | -- make sure keys are quoted 18 | SELECT build_json_object(1,2); 19 | 20 | -- keys must be scalar and not null 21 | SELECT build_json_object(null,2); 22 | 23 | SELECT build_json_object(r,2) FROM (SELECT 1 AS a, 2 AS b) r; 24 | 25 | SELECT build_json_object(json '{"a":1,"b":2}', 3); 26 | 27 | SELECT build_json_object('{1,2,3}'::int[], 3); 28 | 29 | CREATE TEMP TABLE foo (serial int, name text, type text); 30 | INSERT INTO foo VALUES (847001,'t15','GE1043'); 31 | INSERT INTO foo VALUES (847002,'t16','GE1043'); 32 | INSERT INTO foo VALUES (847003,'sub-alpha','GESS90'); 33 | 34 | SELECT build_json_object('turbines',json_object_agg(serial,build_json_object('name',name,'type',type))) 35 | FROM foo; 36 | 37 | --------------------------------------------------------------------------------