1
true
[2,false]
+</programlisting>
+ </entry>
+ </row>
+ <row>
+ <entry>
+ <indexterm>
+ <primary>json_array_elements_text</primary>
+ </indexterm>
+ <literal>json_array_elements_text(json)</literal>
+ </entry>
+ <entry><type>SETOF json</type></entry>
+ <entry>
+ Expands a JSON array to a set of text values.
+ </entry>
+ <entry><literal>json_array_elements_text('["foo", "bar"]')</literal></entry>
+ <entry>
+<programlisting>
+ value
+-----------
+ foo
+ bar
</programlisting>
</entry>
</row>
static void each_array_start(void *state);
static void each_scalar(void *state, char *token, JsonTokenType tokentype);
+/* common worker for json_each* functions */
+static inline Datum elements_worker(PG_FUNCTION_ARGS, bool as_text);
+
/* semantic action functions for json_array_elements */
static void elements_object_start(void *state);
static void elements_array_element_start(void *state, bool isnull);
TupleDesc ret_tdesc;
MemoryContext tmp_cxt;
char *result_start;
+ bool normalize_results;
+ bool next_scalar;
+ char *normalized_scalar;
} ElementsState;
/* state for get_json_object_as_hash */
}
/*
- * SQL function json_array_elements
+ * SQL functions json_array_elements and json_array_elements_text
*
* get the elements from a json array
*
*/
Datum
json_array_elements(PG_FUNCTION_ARGS)
+{
+ return elements_worker(fcinfo, false);
+}
+
+Datum
+json_array_elements_text(PG_FUNCTION_ARGS)
+{
+ return elements_worker(fcinfo, true);
+}
+
+static inline Datum
+elements_worker(PG_FUNCTION_ARGS, bool as_text)
{
text *json = PG_GETARG_TEXT_P(0);
- /* elements doesn't need any escaped strings, so use false here */
- JsonLexContext *lex = makeJsonLexContext(json, false);
+ /* elements only needs escaped strings when as_text */
+ JsonLexContext *lex = makeJsonLexContext(json, as_text);
JsonSemAction *sem;
ReturnSetInfo *rsi;
MemoryContext old_cxt;
sem->array_element_start = elements_array_element_start;
sem->array_element_end = elements_array_element_end;
+ state->normalize_results = as_text;
+ state->next_scalar = false;
+
state->lex = lex;
state->tmp_cxt = AllocSetContextCreate(CurrentMemoryContext,
"json_array_elements temporary cxt",
/* save a pointer to where the value starts */
if (_state->lex->lex_level == 1)
- _state->result_start = _state->lex->token_start;
+ {
+ /*
+ * next_scalar will be reset in the array_element_end handler, and
+ * since we know the value is a scalar there is no danger of it being
+ * on while recursing down the tree.
+ */
+ if (_state->normalize_results && _state->lex->token_type == JSON_TOKEN_STRING)
+ _state->next_scalar = true;
+ else
+ _state->result_start = _state->lex->token_start;
+ }
}
static void
text *val;
HeapTuple tuple;
Datum values[1];
- static bool nulls[1] = {false};
+ bool nulls[1] = {false};
/* skip over nested objects */
if (_state->lex->lex_level != 1)
/* use the tmp context so we can clean up after each tuple is done */
old_cxt = MemoryContextSwitchTo(_state->tmp_cxt);
- len = _state->lex->prev_token_terminator - _state->result_start;
- val = cstring_to_text_with_len(_state->result_start, len);
+ if (isnull && _state->normalize_results)
+ {
+ nulls[0] = true;
+ values[0] = (Datum) NULL;
+ }
+ else if (_state->next_scalar)
+ {
+ values[0] = CStringGetTextDatum(_state->normalized_scalar);
+ _state->next_scalar = false;
+ }
+ else
+ {
+ len = _state->lex->prev_token_terminator - _state->result_start;
+ val = cstring_to_text_with_len(_state->result_start, len);
+ values[0] = PointerGetDatum(val);
+ }
- values[0] = PointerGetDatum(val);
tuple = heap_form_tuple(_state->ret_tdesc, values, nulls);
(errcode(ERRCODE_INVALID_PARAMETER_VALUE),
errmsg("cannot call json_array_elements on a scalar")));
- /*
- * json_array_elements always returns json, so there's no need to think
- * about de-escaped values here.
- */
+ /* supply de-escaped value if required */
+ if (_state->next_scalar)
+ _state->normalized_scalar = token;
}
/*
DESCR("get set of records with fields from a json array of objects");
DATA(insert OID = 3968 ( json_typeof PGNSP PGUID 12 1 0 0 0 f f f f t f i 1 0 25 "114" _null_ _null_ _null_ _null_ json_typeof _null_ _null_ _null_ ));
DESCR("get the type of a json value");
+DATA(insert OID = 3969 ( json_array_elements_text PGNSP PGUID 12 1 100 0 0 f f f f t t i 1 0 25 "114" "{114,25}" "{i,o}" "{from_json,value}" _null_ json_array_elements_text _null_ _null_ _null_ ));
+DESCR("elements of json array");
/* uuid */
DATA(insert OID = 2952 ( uuid_in PGNSP PGUID 12 1 0 0 0 f f f f t f i 1 0 2950 "2275" _null_ _null_ _null_ _null_ uuid_in _null_ _null_ _null_ ));
extern Datum json_each(PG_FUNCTION_ARGS);
extern Datum json_each_text(PG_FUNCTION_ARGS);
extern Datum json_array_elements(PG_FUNCTION_ARGS);
+extern Datum json_array_elements_text(PG_FUNCTION_ARGS);
extern Datum json_populate_record(PG_FUNCTION_ARGS);
extern Datum json_populate_recordset(PG_FUNCTION_ARGS);
extern Datum json_to_record(PG_FUNCTION_ARGS);
(1 row)
-- array_elements
-select json_array_elements('[1,true,[1,[2,3]],null,{"f1":1,"f2":[7,8,9]},false]');
+select json_array_elements('[1,true,[1,[2,3]],null,{"f1":1,"f2":[7,8,9]},false,"stringy"]');
json_array_elements
-----------------------
1
null
{"f1":1,"f2":[7,8,9]}
false
-(6 rows)
+ "stringy"
+(7 rows)
-select * from json_array_elements('[1,true,[1,[2,3]],null,{"f1":1,"f2":[7,8,9]},false]') q;
+select * from json_array_elements('[1,true,[1,[2,3]],null,{"f1":1,"f2":[7,8,9]},false,"stringy"]') q;
value
-----------------------
1
null
{"f1":1,"f2":[7,8,9]}
false
-(6 rows)
+ "stringy"
+(7 rows)
+
+select json_array_elements_text('[1,true,[1,[2,3]],null,{"f1":1,"f2":[7,8,9]},false,"stringy"]');
+ json_array_elements_text
+--------------------------
+ 1
+ true
+ [1,[2,3]]
+
+ {"f1":1,"f2":[7,8,9]}
+ false
+ stringy
+(7 rows)
+
+select * from json_array_elements_text('[1,true,[1,[2,3]],null,{"f1":1,"f2":[7,8,9]},false,"stringy"]') q;
+ value
+-----------------------
+ 1
+ true
+ [1,[2,3]]
+
+ {"f1":1,"f2":[7,8,9]}
+ false
+ stringy
+(7 rows)
-- populate_record
create type jpop as (a text, b int, c timestamp);
(1 row)
-- array_elements
-select json_array_elements('[1,true,[1,[2,3]],null,{"f1":1,"f2":[7,8,9]},false]');
+select json_array_elements('[1,true,[1,[2,3]],null,{"f1":1,"f2":[7,8,9]},false,"stringy"]');
json_array_elements
-----------------------
1
null
{"f1":1,"f2":[7,8,9]}
false
-(6 rows)
+ "stringy"
+(7 rows)
-select * from json_array_elements('[1,true,[1,[2,3]],null,{"f1":1,"f2":[7,8,9]},false]') q;
+select * from json_array_elements('[1,true,[1,[2,3]],null,{"f1":1,"f2":[7,8,9]},false,"stringy"]') q;
value
-----------------------
1
null
{"f1":1,"f2":[7,8,9]}
false
-(6 rows)
+ "stringy"
+(7 rows)
+
+select json_array_elements_text('[1,true,[1,[2,3]],null,{"f1":1,"f2":[7,8,9]},false,"stringy"]');
+ json_array_elements_text
+--------------------------
+ 1
+ true
+ [1,[2,3]]
+
+ {"f1":1,"f2":[7,8,9]}
+ false
+ stringy
+(7 rows)
+
+select * from json_array_elements_text('[1,true,[1,[2,3]],null,{"f1":1,"f2":[7,8,9]},false,"stringy"]') q;
+ value
+-----------------------
+ 1
+ true
+ [1,[2,3]]
+
+ {"f1":1,"f2":[7,8,9]}
+ false
+ stringy
+(7 rows)
-- populate_record
create type jpop as (a text, b int, c timestamp);
-- array_elements
-select json_array_elements('[1,true,[1,[2,3]],null,{"f1":1,"f2":[7,8,9]},false]');
-select * from json_array_elements('[1,true,[1,[2,3]],null,{"f1":1,"f2":[7,8,9]},false]') q;
+select json_array_elements('[1,true,[1,[2,3]],null,{"f1":1,"f2":[7,8,9]},false,"stringy"]');
+select * from json_array_elements('[1,true,[1,[2,3]],null,{"f1":1,"f2":[7,8,9]},false,"stringy"]') q;
+select json_array_elements_text('[1,true,[1,[2,3]],null,{"f1":1,"f2":[7,8,9]},false,"stringy"]');
+select * from json_array_elements_text('[1,true,[1,[2,3]],null,{"f1":1,"f2":[7,8,9]},false,"stringy"]') q;
-- populate_record
create type jpop as (a text, b int, c timestamp);