Add 'ignore_nulls' option to row_to_json

Provide an option to skip NULL values in a row when generating a JSON
object from that row with row_to_json.  This can reduce the size of the
JSON object in cases where columns are NULL without really reducing the
information in the JSON object.

This also makes row_to_json into a single function with default values,
rather than having multiple functions.  In passing, change array_to_json
to also be a single function with default values (we don't add an
'ignore_nulls' option yet- it's not clear that there is a sensible
use-case there, and it hasn't been asked for in any case).

Pavel Stehule
This commit is contained in:
Stephen Frost 2014-09-11 21:23:51 -04:00
parent c3c75fcd7a
commit 95d737ff45
8 changed files with 118 additions and 51 deletions

View File

@ -10309,11 +10309,13 @@ table2-mapping
</row>
<row>
<entry>
<literal>row_to_json(record [, pretty_bool])</literal>
<literal>row_to_json(rowval record [, pretty bool [, ignore_nulls bool] ])</literal>
</entry>
<entry>
Returns the row as a JSON object. Line feeds will be added between
level-1 elements if <parameter>pretty_bool</parameter> is true.
level-1 elements if <parameter>pretty_bool</parameter> is true. Elements
with NULL values will be skipped when <parameter>ignore_nulls</parameter>
is true.
</entry>
<entry><literal>row_to_json(row(1,'foo'))</literal></entry>
<entry><literal>{"f1":1,"f2":"foo"}</literal></entry>

View File

@ -867,3 +867,17 @@ RETURNS interval
LANGUAGE INTERNAL
STRICT IMMUTABLE
AS 'make_interval';
CREATE OR REPLACE FUNCTION
row_to_json(rowval record, pretty boolean DEFAULT false, ignore_nulls boolean DEFAULT false)
RETURNS json
LANGUAGE INTERNAL
STRICT STABLE
AS 'row_to_json';
CREATE OR REPLACE FUNCTION
array_to_json(arrayval anyarray, pretty boolean DEFAULT false)
RETURNS json
LANGUAGE INTERNAL
STRICT STABLE
AS 'array_to_json';

View File

@ -79,7 +79,8 @@ static void report_invalid_token(JsonLexContext *lex);
static int report_json_context(JsonLexContext *lex);
static char *extract_mb_char(char *s);
static void composite_to_json(Datum composite, StringInfo result,
bool use_line_feeds);
bool use_line_feeds,
bool ignore_nulls);
static void array_dim_to_json(StringInfo result, int dim, int ndims, int *dims,
Datum *vals, bool *nulls, int *valcount,
JsonTypeCategory tcategory, Oid outfuncoid,
@ -1362,7 +1363,7 @@ datum_to_json(Datum val, bool is_null, StringInfo result,
array_to_json_internal(val, result, false);
break;
case JSONTYPE_COMPOSITE:
composite_to_json(val, result, false);
composite_to_json(val, result, false, false);
break;
case JSONTYPE_BOOL:
outputstr = DatumGetBool(val) ? "true" : "false";
@ -1591,7 +1592,8 @@ array_to_json_internal(Datum array, StringInfo result, bool use_line_feeds)
* Turn a composite / record into JSON.
*/
static void
composite_to_json(Datum composite, StringInfo result, bool use_line_feeds)
composite_to_json(Datum composite, StringInfo result, bool use_line_feeds,
bool ignore_nulls)
{
HeapTupleHeader td;
Oid tupType;
@ -1630,6 +1632,12 @@ composite_to_json(Datum composite, StringInfo result, bool use_line_feeds)
if (tupdesc->attrs[i]->attisdropped)
continue;
val = heap_getattr(tuple, i + 1, tupdesc, &isnull);
/* Don't serialize NULL field when we don't want it */
if (isnull && ignore_nulls)
continue;
if (needsep)
appendStringInfoString(result, sep);
needsep = true;
@ -1638,8 +1646,6 @@ composite_to_json(Datum composite, StringInfo result, bool use_line_feeds)
escape_json(result, attname);
appendStringInfoChar(result, ':');
val = heap_getattr(tuple, i + 1, tupdesc, &isnull);
if (isnull)
{
tcategory = JSONTYPE_NULL;
@ -1687,27 +1693,11 @@ add_json(Datum val, bool is_null, StringInfo result,
datum_to_json(val, is_null, result, tcategory, outfuncoid, key_scalar);
}
/*
* SQL function array_to_json(row)
*/
extern Datum
array_to_json(PG_FUNCTION_ARGS)
{
Datum array = PG_GETARG_DATUM(0);
StringInfo result;
result = makeStringInfo();
array_to_json_internal(array, result, false);
PG_RETURN_TEXT_P(cstring_to_text_with_len(result->data, result->len));
}
/*
* SQL function array_to_json(row, prettybool)
*/
extern Datum
array_to_json_pretty(PG_FUNCTION_ARGS)
array_to_json(PG_FUNCTION_ARGS)
{
Datum array = PG_GETARG_DATUM(0);
bool use_line_feeds = PG_GETARG_BOOL(1);
@ -1721,34 +1711,19 @@ array_to_json_pretty(PG_FUNCTION_ARGS)
}
/*
* SQL function row_to_json(row)
* SQL function row_to_json(rowval record, pretty bool, ignore_nulls bool)
*/
extern Datum
row_to_json(PG_FUNCTION_ARGS)
{
Datum array = PG_GETARG_DATUM(0);
StringInfo result;
result = makeStringInfo();
composite_to_json(array, result, false);
PG_RETURN_TEXT_P(cstring_to_text_with_len(result->data, result->len));
}
/*
* SQL function row_to_json(row, prettybool)
*/
extern Datum
row_to_json_pretty(PG_FUNCTION_ARGS)
{
Datum array = PG_GETARG_DATUM(0);
bool use_line_feeds = PG_GETARG_BOOL(1);
bool ignore_nulls = PG_GETARG_BOOL(2);
StringInfo result;
result = makeStringInfo();
composite_to_json(array, result, use_line_feeds);
composite_to_json(array, result, use_line_feeds, ignore_nulls);
PG_RETURN_TEXT_P(cstring_to_text_with_len(result->data, result->len));
}

View File

@ -53,6 +53,6 @@
*/
/* yyyymmddN */
#define CATALOG_VERSION_NO 201409101
#define CATALOG_VERSION_NO 201409111
#endif

View File

@ -4203,14 +4203,10 @@ DATA(insert OID = 323 ( json_recv PGNSP PGUID 12 1 0 0 0 f f f f t f i 1 0
DESCR("I/O");
DATA(insert OID = 324 ( json_send PGNSP PGUID 12 1 0 0 0 f f f f t f i 1 0 17 "114" _null_ _null_ _null_ _null_ json_send _null_ _null_ _null_ ));
DESCR("I/O");
DATA(insert OID = 3153 ( array_to_json PGNSP PGUID 12 1 0 0 0 f f f f t f s 1 0 114 "2277" _null_ _null_ _null_ _null_ array_to_json _null_ _null_ _null_ ));
DATA(insert OID = 3153 ( array_to_json PGNSP PGUID 12 1 0 0 0 f f f f t f s 2 0 114 "2277 16" _null_ _null_ "{arrayval,pretty}" _null_ array_to_json _null_ _null_ _null_ ));
DESCR("map array to json");
DATA(insert OID = 3154 ( array_to_json PGNSP PGUID 12 1 0 0 0 f f f f t f s 2 0 114 "2277 16" _null_ _null_ _null_ _null_ array_to_json_pretty _null_ _null_ _null_ ));
DESCR("map array to json with optional pretty printing");
DATA(insert OID = 3155 ( row_to_json PGNSP PGUID 12 1 0 0 0 f f f f t f s 1 0 114 "2249" _null_ _null_ _null_ _null_ row_to_json _null_ _null_ _null_ ));
DATA(insert OID = 3155 ( row_to_json PGNSP PGUID 12 1 0 0 0 f f f f t f s 3 0 114 "2249 16 16" _null_ _null_ "{rowval,pretty,ignore_nulls}" _null_ row_to_json _null_ _null_ _null_ ));
DESCR("map row to json");
DATA(insert OID = 3156 ( row_to_json PGNSP PGUID 12 1 0 0 0 f f f f t f s 2 0 114 "2249 16" _null_ _null_ _null_ _null_ row_to_json_pretty _null_ _null_ _null_ ));
DESCR("map row to json with optional pretty printing");
DATA(insert OID = 3173 ( json_agg_transfn PGNSP PGUID 12 1 0 0 0 f f f f f f i 2 0 2281 "2281 2283" _null_ _null_ _null_ _null_ json_agg_transfn _null_ _null_ _null_ ));
DESCR("json aggregate transition function");
DATA(insert OID = 3174 ( json_agg_finalfn PGNSP PGUID 12 1 0 0 0 f f f f f f i 1 0 114 "2281" _null_ _null_ _null_ _null_ json_agg_finalfn _null_ _null_ _null_ ));

View File

@ -23,9 +23,7 @@ extern Datum json_out(PG_FUNCTION_ARGS);
extern Datum json_recv(PG_FUNCTION_ARGS);
extern Datum json_send(PG_FUNCTION_ARGS);
extern Datum array_to_json(PG_FUNCTION_ARGS);
extern Datum array_to_json_pretty(PG_FUNCTION_ARGS);
extern Datum row_to_json(PG_FUNCTION_ARGS);
extern Datum row_to_json_pretty(PG_FUNCTION_ARGS);
extern Datum to_json(PG_FUNCTION_ARGS);
extern Datum json_agg_transfn(PG_FUNCTION_ARGS);

View File

@ -397,12 +397,70 @@ FROM rows q;
"y":"txt3"}
(3 rows)
SELECT row_to_json(q,pretty := true)
FROM rows q;
row_to_json
--------------
{"x":1, +
"y":"txt1"}
{"x":2, +
"y":"txt2"}
{"x":3, +
"y":"txt3"}
(3 rows)
SELECT row_to_json(row((select array_agg(x) as d from generate_series(5,10) x)),false);
row_to_json
-----------------------
{"f1":[5,6,7,8,9,10]}
(1 row)
WITH x AS (SELECT a,b,c FROM (VALUES(10,20,30),
(10,NULL, NULL),
(NULL, NULL, NULL)) g(a,b,c))
SELECT row_to_json(x, false, false) FROM x;
row_to_json
------------------------------
{"a":10,"b":20,"c":30}
{"a":10,"b":null,"c":null}
{"a":null,"b":null,"c":null}
(3 rows)
WITH x AS (SELECT a,b,c FROM (VALUES(10,20,30),
(10,NULL, NULL),
(NULL, NULL, NULL)) g(a,b,c))
SELECT row_to_json(x, false, true) FROM x;
row_to_json
------------------------
{"a":10,"b":20,"c":30}
{"a":10}
{}
(3 rows)
WITH x AS (SELECT a,b,c FROM (VALUES(10,20,30),
(10,NULL, NULL),
(NULL, NULL, NULL)) g(a,b,c))
SELECT row_to_json(x, ignore_nulls := true) FROM x;
row_to_json
------------------------
{"a":10,"b":20,"c":30}
{"a":10}
{}
(3 rows)
WITH x AS (SELECT a,b,c FROM (VALUES(10,20,30),
(10,NULL, NULL),
(NULL, NULL, NULL)) g(a,b,c))
SELECT row_to_json(x, ignore_nulls := true, pretty := true) FROM x;
row_to_json
-------------
{"a":10, +
"b":20, +
"c":30}
{"a":10}
{}
(3 rows)
-- to_json, timestamps
select to_json(timestamp '2014-05-28 12:22:35.614298');
to_json

View File

@ -98,8 +98,32 @@ FROM generate_series(1,3) AS x;
SELECT row_to_json(q,true)
FROM rows q;
SELECT row_to_json(q,pretty := true)
FROM rows q;
SELECT row_to_json(row((select array_agg(x) as d from generate_series(5,10) x)),false);
WITH x AS (SELECT a,b,c FROM (VALUES(10,20,30),
(10,NULL, NULL),
(NULL, NULL, NULL)) g(a,b,c))
SELECT row_to_json(x, false, false) FROM x;
WITH x AS (SELECT a,b,c FROM (VALUES(10,20,30),
(10,NULL, NULL),
(NULL, NULL, NULL)) g(a,b,c))
SELECT row_to_json(x, false, true) FROM x;
WITH x AS (SELECT a,b,c FROM (VALUES(10,20,30),
(10,NULL, NULL),
(NULL, NULL, NULL)) g(a,b,c))
SELECT row_to_json(x, ignore_nulls := true) FROM x;
WITH x AS (SELECT a,b,c FROM (VALUES(10,20,30),
(10,NULL, NULL),
(NULL, NULL, NULL)) g(a,b,c))
SELECT row_to_json(x, ignore_nulls := true, pretty := true) FROM x;
-- to_json, timestamps
select to_json(timestamp '2014-05-28 12:22:35.614298');