json_typeof function.

Andrew Tipton.
This commit is contained in:
Andrew Dunstan 2013-10-10 12:21:59 -04:00
parent 4b7b9a7904
commit 4d212bac17
8 changed files with 158 additions and 4 deletions

View File

@ -10095,7 +10095,7 @@ table2-mapping
</entry>
<entry><type>json</type></entry>
<entry>
Returns JSON object pointed to by <parameter>path_elems</parameter>.
Returns JSON value pointed to by <parameter>path_elems</parameter>.
</entry>
<entry><literal>json_extract_path('{"f2":{"f3":1},"f4":{"f5":99,"f6":"foo"}}','f4')</literal></entry>
<entry><literal>{"f5":99,"f6":"foo"}</literal></entry>
@ -10109,7 +10109,7 @@ table2-mapping
</entry>
<entry><type>text</type></entry>
<entry>
Returns JSON object pointed to by <parameter>path_elems</parameter>.
Returns JSON value pointed to by <parameter>path_elems</parameter>.
</entry>
<entry><literal>json_extract_path_text('{"f2":{"f3":1},"f4":{"f5":99,"f6":"foo"}}','f4', 'f6')</literal></entry>
<entry><literal>foo</literal></entry>
@ -10192,7 +10192,7 @@ table2-mapping
</entry>
<entry><type>SETOF json</type></entry>
<entry>
Expands a JSON array to a set of JSON elements.
Expands a JSON array to a set of JSON values.
</entry>
<entry><literal>json_array_elements('[1,true, [2,false]]')</literal></entry>
<entry>
@ -10205,6 +10205,23 @@ table2-mapping
</programlisting>
</entry>
</row>
<row>
<entry>
<indexterm>
<primary>json_typeof</primary>
</indexterm>
<literal>json_typeof(json)</literal>
</entry>
<entry><type>text</type></entry>
<entry>
Returns the type of the outermost JSON value as a text string. The types are
<literal>object</>, <literal>array</>, <literal>string</>, <literal>number</>,
<literal>boolean</>, and <literal>null</>. (See note below regarding the
distinction between a JSON <literal>null</> and a SQL NULL.)
</entry>
<entry><literal>json_typeof('-123.4')</literal></entry>
<entry><literal>number</literal></entry>
</row>
</tbody>
</tgroup>
</table>
@ -10237,6 +10254,14 @@ table2-mapping
</para>
</note>
<note>
<para>
The <literal>json_typeof</> function's <literal>null</> return value should not be confused
with a SQL NULL. While calling <literal>json_typeof('null'::json)</> will return <literal>null</>,
calling <literal>json_typeof(NULL::json)</> will return a SQL NULL.
</para>
</note>
<para>
See also <xref linkend="functions-aggregate"> about the aggregate
function <function>json_agg</function> which aggregates record

View File

@ -1826,3 +1826,55 @@ escape_json(StringInfo buf, const char *str)
}
appendStringInfoCharMacro(buf, '\"');
}
/*
* SQL function json_typeof(json) -> text
*
* Returns the type of the outermost JSON value as TEXT. Possible types are
* "object", "array", "string", "number", "boolean", and "null".
*
* Performs a single call to json_lex() to get the first token of the supplied
* value. This initial token uniquely determines the value's type. As our
* input must already have been validated by json_in() or json_recv(), the
* initial token should never be JSON_TOKEN_OBJECT_END, JSON_TOKEN_ARRAY_END,
* JSON_TOKEN_COLON, JSON_TOKEN_COMMA, or JSON_TOKEN_END.
*/
Datum
json_typeof(PG_FUNCTION_ARGS)
{
text *json = PG_GETARG_TEXT_P(0);
JsonLexContext *lex = makeJsonLexContext(json, false);
JsonTokenType tok;
char *type;
/* Lex exactly one token from the input and check its type. */
json_lex(lex);
tok = lex_peek(lex);
switch (tok)
{
case JSON_TOKEN_OBJECT_START:
type = "object";
break;
case JSON_TOKEN_ARRAY_START:
type = "array";
break;
case JSON_TOKEN_STRING:
type = "string";
break;
case JSON_TOKEN_NUMBER:
type = "number";
break;
case JSON_TOKEN_TRUE:
case JSON_TOKEN_FALSE:
type = "boolean";
break;
case JSON_TOKEN_NULL:
type = "null";
break;
default:
elog(ERROR, "unexpected json token: %d", tok);
}
PG_RETURN_TEXT_P(cstring_to_text(type));
}

View File

@ -53,6 +53,6 @@
*/
/* yyyymmddN */
#define CATALOG_VERSION_NO 201310091
#define CATALOG_VERSION_NO 201310101
#endif

View File

@ -4150,6 +4150,8 @@ DATA(insert OID = 3960 ( json_populate_record PGNSP PGUID 12 1 0 0 0 f f f f
DESCR("get record fields from a json object");
DATA(insert OID = 3961 ( json_populate_recordset PGNSP PGUID 12 1 100 0 0 f f f f f t s 3 0 2283 "2283 114 16" _null_ _null_ _null_ _null_ json_populate_recordset _null_ _null_ _null_ ));
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");
/* 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_ ));

View File

@ -33,6 +33,8 @@ extern Datum json_agg_finalfn(PG_FUNCTION_ARGS);
extern void escape_json(StringInfo buf, const char *str);
extern Datum json_typeof(PG_FUNCTION_ARGS);
/* functions in jsonfuncs.c */
extern Datum json_object_field(PG_FUNCTION_ARGS);
extern Datum json_object_field_text(PG_FUNCTION_ARGS);

View File

@ -962,3 +962,32 @@ select json '{ "a": "null \u0000 escape" }' ->> 'a' as not_unescaped;
null \u0000 escape
(1 row)
--json_typeof() function
select value, json_typeof(value)
from (values (json '123.4'),
(json '-1'),
(json '"foo"'),
(json 'true'),
(json 'false'),
(json 'null'),
(json '[1, 2, 3]'),
(json '[]'),
(json '{"x":"foo", "y":123}'),
(json '{}'),
(NULL::json))
as data(value);
value | json_typeof
----------------------+-------------
123.4 | number
-1 | number
"foo" | string
true | boolean
false | boolean
null | null
[1, 2, 3] | array
[] | array
{"x":"foo", "y":123} | object
{} | object
|
(11 rows)

View File

@ -958,3 +958,32 @@ select json '{ "a": "null \u0000 escape" }' ->> 'a' as not_unescaped;
null \u0000 escape
(1 row)
--json_typeof() function
select value, json_typeof(value)
from (values (json '123.4'),
(json '-1'),
(json '"foo"'),
(json 'true'),
(json 'false'),
(json 'null'),
(json '[1, 2, 3]'),
(json '[]'),
(json '{"x":"foo", "y":123}'),
(json '{}'),
(NULL::json))
as data(value);
value | json_typeof
----------------------+-------------
123.4 | number
-1 | number
"foo" | string
true | boolean
false | boolean
null | null
[1, 2, 3] | array
[] | array
{"x":"foo", "y":123} | object
{} | object
|
(11 rows)

View File

@ -310,3 +310,18 @@ select json '{ "a": "\ude04X" }' -> 'a'; -- orphan low surrogate
select json '{ "a": "the Copyright \u00a9 sign" }' ->> 'a' as correct_in_utf8;
select json '{ "a": "dollar \u0024 character" }' ->> 'a' as correct_everywhere;
select json '{ "a": "null \u0000 escape" }' ->> 'a' as not_unescaped;
--json_typeof() function
select value, json_typeof(value)
from (values (json '123.4'),
(json '-1'),
(json '"foo"'),
(json 'true'),
(json 'false'),
(json 'null'),
(json '[1, 2, 3]'),
(json '[]'),
(json '{"x":"foo", "y":123}'),
(json '{}'),
(NULL::json))
as data(value);