]> granicus.if.org Git - postgresql/commitdiff
Add json_array_elements_text function.
authorAndrew Dunstan <andrew@dunslane.net>
Wed, 29 Jan 2014 20:39:01 +0000 (15:39 -0500)
committerAndrew Dunstan <andrew@dunslane.net>
Wed, 29 Jan 2014 20:39:01 +0000 (15:39 -0500)
This was a notable omission from the json functions added in 9.3 and
there have been numerous complaints about its absence.

Laurence Rowe.

doc/src/sgml/func.sgml
src/backend/utils/adt/jsonfuncs.c
src/include/catalog/pg_proc.h
src/include/utils/json.h
src/test/regress/expected/json.out
src/test/regress/expected/json_1.out
src/test/regress/sql/json.sql

index cd886ab71a74a906169f4f673436bc22c46e8cec..9816163354d9557bc60d0230416f01121ddf16f8 100644 (file)
@@ -10280,6 +10280,27 @@ table2-mapping
  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>
index 60ed0bb4dcd472b26e525b432790909d37fef63c..16d584f19006554ba192227c6e01bb6143d838e8 100644 (file)
@@ -66,6 +66,9 @@ static void each_object_field_end(void *state, char *fname, bool isnull);
 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);
@@ -165,6 +168,9 @@ typedef struct ElementsState
        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 */
@@ -1069,7 +1075,7 @@ each_scalar(void *state, char *token, JsonTokenType tokentype)
 }
 
 /*
- * SQL function json_array_elements
+ * SQL functions json_array_elements and json_array_elements_text
  *
  * get the elements from a json array
  *
@@ -1077,11 +1083,23 @@ each_scalar(void *state, char *token, JsonTokenType tokentype)
  */
 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;
@@ -1124,6 +1142,9 @@ json_array_elements(PG_FUNCTION_ARGS)
        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",
@@ -1146,7 +1167,17 @@ elements_array_element_start(void *state, bool isnull)
 
        /* 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
@@ -1158,7 +1189,7 @@ elements_array_element_end(void *state, bool isnull)
        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)
@@ -1167,10 +1198,23 @@ elements_array_element_end(void *state, bool isnull)
        /* 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);
 
@@ -1204,10 +1248,9 @@ elements_scalar(void *state, char *token, JsonTokenType tokentype)
                                (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;
 }
 
 /*
index b7c0d8fbd339479e16e42a252d3e7bc19935622e..9fc61ebed62237b8adb0d080c192581bd6ec53be 100644 (file)
@@ -4185,6 +4185,8 @@ DATA(insert OID = 3205 (  json_to_recordset  PGNSP PGUID 12 1 100 0 0 f f f f f
 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_ ));
index ed96a62f6358a53e3f79d2bdd9f7e5857345ba6a..baf751e99915bdb398cb8787378b70622bb8b36a 100644 (file)
@@ -58,6 +58,7 @@ extern Datum json_array_length(PG_FUNCTION_ARGS);
 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);
index 64613313df049a7a2c06efb343fa6bffbb2ae52e..04b969ae101518498f5f85fff69c8e38b10abfff 100644 (file)
@@ -801,7 +801,7 @@ select '{"f2":["f3",1],"f4":{"f5":99,"f6":"stringy"}}'::json#>>'{f2,1}';
 (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
@@ -810,9 +810,10 @@ select json_array_elements('[1,true,[1,[2,3]],null,{"f1":1,"f2":[7,8,9]},false]'
  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
@@ -821,7 +822,32 @@ select * from json_array_elements('[1,true,[1,[2,3]],null,{"f1":1,"f2":[7,8,9]},
  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);
index 37d5bc07ae8e6b33af6f8555994337cfbe46b12f..07b25ca96c61a2d7ccf44540a9f7968e1002631d 100644 (file)
@@ -801,7 +801,7 @@ select '{"f2":["f3",1],"f4":{"f5":99,"f6":"stringy"}}'::json#>>'{f2,1}';
 (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
@@ -810,9 +810,10 @@ select json_array_elements('[1,true,[1,[2,3]],null,{"f1":1,"f2":[7,8,9]},false]'
  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
@@ -821,7 +822,32 @@ select * from json_array_elements('[1,true,[1,[2,3]],null,{"f1":1,"f2":[7,8,9]},
  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);
index 67e97cba9e52c80aee415f3a29885b3cd7576775..2d3f0bcc612d69deb8f24047f688fa1839931174 100644 (file)
@@ -265,8 +265,10 @@ select '{"f2":["f3",1],"f4":{"f5":99,"f6":"stringy"}}'::json#>>'{f2,1}';
 
 -- 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);