Commit 5384a73f authored by Robert Haas's avatar Robert Haas

Built-in JSON data type.

Like the XML data type, we simply store JSON data as text, after checking
that it is valid.  More complex operations such as canonicalization and
comparison may come later, but this is enough for not.

There are a few open issues here, such as whether we should attempt to
detect UTF-8 surrogate pairs represented as \uXXXX\uYYYY, but this gets
the basic framework in place.
parent 4c6cedd1
...@@ -269,6 +269,12 @@ ...@@ -269,6 +269,12 @@
<entry></entry> <entry></entry>
<entry>XML data</entry> <entry>XML data</entry>
</row> </row>
<row>
<entry><type>json</type></entry>
<entry></entry>
<entry>JSON data</entry>
</row>
</tbody> </tbody>
</tgroup> </tgroup>
</table> </table>
...@@ -4169,6 +4175,32 @@ SET xmloption TO { DOCUMENT | CONTENT }; ...@@ -4169,6 +4175,32 @@ SET xmloption TO { DOCUMENT | CONTENT };
</sect2> </sect2>
</sect1> </sect1>
<sect1 id="datatype-json">
<title><acronym>JSON</> Type</title>
<indexterm zone="datatype-json">
<primary>JSON</primary>
</indexterm>
<para>
The <type>json</type> data type can be used to store JSON data. Such
data can also be stored as <type>text</type>, but the
<type>json</type> data type has the advantage of checking that each
stored value is a valid JSON value.
</para>
<para>
<productname>PostgreSQL</productname> allows only one server encoding
per database. It is therefore not possible for JSON to conform rigidly
to the specification unless the server encoding is UTF-8. Attempts to
directly include characters which cannot be represented in the server
encoding will fail; conversely, characters which can be represented in
the server encoding but not in UTF-8 will be allowed.
<literal>\uXXXX</literal> escapes are allowed regardless of the server
encoding, and are checked only for syntactic correctness.
</para>
</sect1>
&array; &array;
&rowtypes; &rowtypes;
......
...@@ -242,7 +242,7 @@ ExplainResultDesc(ExplainStmt *stmt) ...@@ -242,7 +242,7 @@ ExplainResultDesc(ExplainStmt *stmt)
{ {
TupleDesc tupdesc; TupleDesc tupdesc;
ListCell *lc; ListCell *lc;
bool xml = false; Oid result_type = TEXTOID;
/* Check for XML format option */ /* Check for XML format option */
foreach(lc, stmt->options) foreach(lc, stmt->options)
...@@ -253,7 +253,12 @@ ExplainResultDesc(ExplainStmt *stmt) ...@@ -253,7 +253,12 @@ ExplainResultDesc(ExplainStmt *stmt)
{ {
char *p = defGetString(opt); char *p = defGetString(opt);
xml = (strcmp(p, "xml") == 0); if (strcmp(p, "xml") == 0)
result_type = XMLOID;
else if (strcmp(p, "json") == 0)
result_type = JSONOID;
else
result_type = TEXTOID;
/* don't "break", as ExplainQuery will use the last value */ /* don't "break", as ExplainQuery will use the last value */
} }
} }
...@@ -261,7 +266,7 @@ ExplainResultDesc(ExplainStmt *stmt) ...@@ -261,7 +266,7 @@ ExplainResultDesc(ExplainStmt *stmt)
/* Need a tuple descriptor representing a single TEXT or XML column */ /* Need a tuple descriptor representing a single TEXT or XML column */
tupdesc = CreateTemplateTupleDesc(1, false); tupdesc = CreateTemplateTupleDesc(1, false);
TupleDescInitEntry(tupdesc, (AttrNumber) 1, "QUERY PLAN", TupleDescInitEntry(tupdesc, (AttrNumber) 1, "QUERY PLAN",
xml ? XMLOID : TEXTOID, -1, 0); result_type, -1, 0);
return tupdesc; return tupdesc;
} }
......
...@@ -18,7 +18,7 @@ endif ...@@ -18,7 +18,7 @@ endif
OBJS = acl.o arrayfuncs.o array_userfuncs.o arrayutils.o bool.o \ OBJS = acl.o arrayfuncs.o array_userfuncs.o arrayutils.o bool.o \
cash.o char.o date.o datetime.o datum.o domains.o \ cash.o char.o date.o datetime.o datum.o domains.o \
enum.o float.o format_type.o \ enum.o float.o format_type.o \
geo_ops.o geo_selfuncs.o int.o int8.o like.o lockfuncs.o \ geo_ops.o geo_selfuncs.o int.o int8.o json.o like.o lockfuncs.o \
misc.o nabstime.o name.o numeric.o numutils.o \ misc.o nabstime.o name.o numeric.o numutils.o \
oid.o oracle_compat.o pseudotypes.o rangetypes.o rangetypes_gist.o \ oid.o oracle_compat.o pseudotypes.o rangetypes.o rangetypes_gist.o \
rowtypes.o regexp.o regproc.o ruleutils.o selfuncs.o \ rowtypes.o regexp.o regproc.o ruleutils.o selfuncs.o \
......
This diff is collapsed.
...@@ -4022,6 +4022,16 @@ DESCR("determine if a string is well formed XML document"); ...@@ -4022,6 +4022,16 @@ DESCR("determine if a string is well formed XML document");
DATA(insert OID = 3053 ( xml_is_well_formed_content PGNSP PGUID 12 1 0 0 0 f f f t f i 1 0 16 "25" _null_ _null_ _null_ _null_ xml_is_well_formed_content _null_ _null_ _null_ )); DATA(insert OID = 3053 ( xml_is_well_formed_content PGNSP PGUID 12 1 0 0 0 f f f t f i 1 0 16 "25" _null_ _null_ _null_ _null_ xml_is_well_formed_content _null_ _null_ _null_ ));
DESCR("determine if a string is well formed XML content"); DESCR("determine if a string is well formed XML content");
/* json */
DATA(insert OID = 321 ( json_in PGNSP PGUID 12 1 0 0 0 f f f t f s 1 0 114 "2275" _null_ _null_ _null_ _null_ json_in _null_ _null_ _null_ ));
DESCR("I/O");
DATA(insert OID = 322 ( json_out PGNSP PGUID 12 1 0 0 0 f f f t f i 1 0 2275 "114" _null_ _null_ _null_ _null_ json_out _null_ _null_ _null_ ));
DESCR("I/O");
DATA(insert OID = 323 ( json_recv PGNSP PGUID 12 1 0 0 0 f f f t f s 1 0 114 "2281" _null_ _null_ _null_ _null_ json_recv _null_ _null_ _null_ ));
DESCR("I/O");
DATA(insert OID = 324 ( json_send PGNSP PGUID 12 1 0 0 0 f f f t f s 1 0 17 "114" _null_ _null_ _null_ _null_ json_send _null_ _null_ _null_ ));
DESCR("I/O");
/* uuid */ /* uuid */
DATA(insert OID = 2952 ( uuid_in PGNSP PGUID 12 1 0 0 0 f f f t f i 1 0 2950 "2275" _null_ _null_ _null_ _null_ uuid_in _null_ _null_ _null_ )); DATA(insert OID = 2952 ( uuid_in PGNSP PGUID 12 1 0 0 0 f f f t f i 1 0 2950 "2275" _null_ _null_ _null_ _null_ uuid_in _null_ _null_ _null_ ));
DESCR("I/O"); DESCR("I/O");
......
...@@ -352,10 +352,13 @@ DATA(insert OID = 81 ( pg_proc PGNSP PGUID -1 f c C f t \054 1255 0 0 record_i ...@@ -352,10 +352,13 @@ DATA(insert OID = 81 ( pg_proc PGNSP PGUID -1 f c C f t \054 1255 0 0 record_i
DATA(insert OID = 83 ( pg_class PGNSP PGUID -1 f c C f t \054 1259 0 0 record_in record_out record_recv record_send - - - d x f 0 -1 0 0 _null_ _null_ _null_ )); DATA(insert OID = 83 ( pg_class PGNSP PGUID -1 f c C f t \054 1259 0 0 record_in record_out record_recv record_send - - - d x f 0 -1 0 0 _null_ _null_ _null_ ));
/* OIDS 100 - 199 */ /* OIDS 100 - 199 */
DATA(insert OID = 114 ( json PGNSP PGUID -1 f b U f t \054 0 0 199 json_in json_out json_recv json_send - - - i x f 0 -1 0 0 _null_ _null_ _null_ ));
#define JSONOID 114
DATA(insert OID = 142 ( xml PGNSP PGUID -1 f b U f t \054 0 0 143 xml_in xml_out xml_recv xml_send - - - i x f 0 -1 0 0 _null_ _null_ _null_ )); DATA(insert OID = 142 ( xml PGNSP PGUID -1 f b U f t \054 0 0 143 xml_in xml_out xml_recv xml_send - - - i x f 0 -1 0 0 _null_ _null_ _null_ ));
DESCR("XML content"); DESCR("XML content");
#define XMLOID 142 #define XMLOID 142
DATA(insert OID = 143 ( _xml PGNSP PGUID -1 f b A f t \054 0 142 0 array_in array_out array_recv array_send - - - i x f 0 -1 0 0 _null_ _null_ _null_ )); DATA(insert OID = 143 ( _xml PGNSP PGUID -1 f b A f t \054 0 142 0 array_in array_out array_recv array_send - - - i x f 0 -1 0 0 _null_ _null_ _null_ ));
DATA(insert OID = 199 ( _json PGNSP PGUID -1 f b A f t \054 0 114 0 array_in array_out array_recv array_send - - - i x f 0 -1 0 0 _null_ _null_ _null_ ));
DATA(insert OID = 194 ( pg_node_tree PGNSP PGUID -1 f b S f t \054 0 0 0 pg_node_tree_in pg_node_tree_out pg_node_tree_recv pg_node_tree_send - - - i x f 0 -1 0 100 _null_ _null_ _null_ )); DATA(insert OID = 194 ( pg_node_tree PGNSP PGUID -1 f b S f t \054 0 0 0 pg_node_tree_in pg_node_tree_out pg_node_tree_recv pg_node_tree_send - - - i x f 0 -1 0 100 _null_ _null_ _null_ ));
DESCR("string representing an internal node tree"); DESCR("string representing an internal node tree");
......
/*-------------------------------------------------------------------------
*
* json.h
* Declarations for JSON data type support.
*
* Portions Copyright (c) 1996-2012, PostgreSQL Global Development Group
* Portions Copyright (c) 1994, Regents of the University of California
*
* src/include/utils/json.h
*
*-------------------------------------------------------------------------
*/
#ifndef JSON_H
#define JSON_H
#include "fmgr.h"
extern Datum json_in(PG_FUNCTION_ARGS);
extern Datum json_out(PG_FUNCTION_ARGS);
extern Datum json_recv(PG_FUNCTION_ARGS);
extern Datum json_send(PG_FUNCTION_ARGS);
#endif /* XML_H */
-- Strings.
SELECT '""'::json; -- OK.
json
------
""
(1 row)
SELECT $$''$$::json; -- ERROR, single quotes are not allowed
ERROR: invalid input syntax for type json
LINE 1: SELECT $$''$$::json;
^
DETAIL: line 1: Token "'" is invalid.
SELECT '"abc"'::json; -- OK
json
-------
"abc"
(1 row)
SELECT '"abc'::json; -- ERROR, quotes not closed
ERROR: invalid input syntax for type json
LINE 1: SELECT '"abc'::json;
^
DETAIL: line 1: Token ""abc" is invalid.
SELECT '"abc
def"'::json; -- ERROR, unescaped newline in string constant
ERROR: invalid input syntax for type json
LINE 1: SELECT '"abc
^
DETAIL: line 1: Character "
" must be escaped.
SELECT '"\n\"\\"'::json; -- OK, legal escapes
json
----------
"\n\"\\"
(1 row)
SELECT '"\v"'::json; -- ERROR, not a valid JSON escape
ERROR: invalid input syntax for type json
LINE 1: SELECT '"\v"'::json;
^
DETAIL: line 1: Invalid escape "\v".
SELECT '"\u"'::json; -- ERROR, incomplete escape
ERROR: invalid input syntax for type json
LINE 1: SELECT '"\u"'::json;
^
DETAIL: line 1: "\u" must be followed by four hexadecimal digits.
SELECT '"\u00"'::json; -- ERROR, incomplete escape
ERROR: invalid input syntax for type json
LINE 1: SELECT '"\u00"'::json;
^
DETAIL: line 1: "\u" must be followed by four hexadecimal digits.
SELECT '"\u000g"'::json; -- ERROR, g is not a hex digit
ERROR: invalid input syntax for type json
LINE 1: SELECT '"\u000g"'::json;
^
DETAIL: line 1: "\u" must be followed by four hexadecimal digits.
SELECT '"\u0000"'::json; -- OK, legal escape
json
----------
"\u0000"
(1 row)
SELECT '"\uaBcD"'::json; -- OK, uppercase and lower case both OK
json
----------
"\uaBcD"
(1 row)
-- Numbers.
SELECT '1'::json; -- OK
json
------
1
(1 row)
SELECT '0'::json; -- OK
json
------
0
(1 row)
SELECT '01'::json; -- ERROR, not valid according to JSON spec
ERROR: invalid input syntax for type json
LINE 1: SELECT '01'::json;
^
DETAIL: line 1: Token "01" is invalid.
SELECT '0.1'::json; -- OK
json
------
0.1
(1 row)
SELECT '9223372036854775808'::json; -- OK, even though it's too large for int8
json
---------------------
9223372036854775808
(1 row)
SELECT '1e100'::json; -- OK
json
-------
1e100
(1 row)
SELECT '1.3e100'::json; -- OK
json
---------
1.3e100
(1 row)
SELECT '1f2'::json; -- ERROR
ERROR: invalid input syntax for type json
LINE 1: SELECT '1f2'::json;
^
DETAIL: line 1: Token "1f2" is invalid.
-- Arrays.
SELECT '[]'::json; -- OK
json
------
[]
(1 row)
SELECT '[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]'::json; -- OK
json
----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]
(1 row)
SELECT '[1,2]'::json; -- OK
json
-------
[1,2]
(1 row)
SELECT '[1,2,]'::json; -- ERROR, trailing comma
ERROR: invalid input syntax for type json: "[1,2,]"
LINE 1: SELECT '[1,2,]'::json;
^
DETAIL: line 1: Expected string, number, object, array, true, false, or null, but found "]".
SELECT '[1,2'::json; -- ERROR, no closing bracket
ERROR: invalid input syntax for type json: "[1,2"
LINE 1: SELECT '[1,2'::json;
^
DETAIL: The input string ended unexpectedly.
SELECT '[1,[2]'::json; -- ERROR, no closing bracket
ERROR: invalid input syntax for type json: "[1,[2]"
LINE 1: SELECT '[1,[2]'::json;
^
DETAIL: The input string ended unexpectedly.
-- Objects.
SELECT '{}'::json; -- OK
json
------
{}
(1 row)
SELECT '{"abc"}'::json; -- ERROR, no value
ERROR: invalid input syntax for type json: "{"abc"}"
LINE 1: SELECT '{"abc"}'::json;
^
DETAIL: line 1: Expected ":", but found "}".
SELECT '{"abc":1}'::json; -- OK
json
-----------
{"abc":1}
(1 row)
SELECT '{1:"abc"}'::json; -- ERROR, keys must be strings
ERROR: invalid input syntax for type json: "{1:"abc"}"
LINE 1: SELECT '{1:"abc"}'::json;
^
DETAIL: line 1: Expected string or "}", but found "1".
SELECT '{"abc",1}'::json; -- ERROR, wrong separator
ERROR: invalid input syntax for type json: "{"abc",1}"
LINE 1: SELECT '{"abc",1}'::json;
^
DETAIL: line 1: Expected ":", but found ",".
SELECT '{"abc"=1}'::json; -- ERROR, totally wrong separator
ERROR: invalid input syntax for type json
LINE 1: SELECT '{"abc"=1}'::json;
^
DETAIL: line 1: Token "=" is invalid.
SELECT '{"abc"::1}'::json; -- ERROR, another wrong separator
ERROR: invalid input syntax for type json: "{"abc"::1}"
LINE 1: SELECT '{"abc"::1}'::json;
^
DETAIL: line 1: Expected string, number, object, array, true, false, or null, but found ":".
SELECT '{"abc":1,"def":2,"ghi":[3,4],"hij":{"klm":5,"nop":[6]}}'::json; -- OK
json
---------------------------------------------------------
{"abc":1,"def":2,"ghi":[3,4],"hij":{"klm":5,"nop":[6]}}
(1 row)
SELECT '{"abc":1:2}'::json; -- ERROR, colon in wrong spot
ERROR: invalid input syntax for type json: "{"abc":1:2}"
LINE 1: SELECT '{"abc":1:2}'::json;
^
DETAIL: line 1: Expected "," or "}", but found ":".
SELECT '{"abc":1,3}'::json; -- ERROR, no value
ERROR: invalid input syntax for type json: "{"abc":1,3}"
LINE 1: SELECT '{"abc":1,3}'::json;
^
DETAIL: line 1: Expected string, but found "3".
-- Miscellaneous stuff.
SELECT 'true'::json; -- OK
json
------
true
(1 row)
SELECT 'false'::json; -- OK
json
-------
false
(1 row)
SELECT 'null'::json; -- OK
json
------
null
(1 row)
SELECT ' true '::json; -- OK, even with extra whitespace
json
--------
true
(1 row)
SELECT 'true false'::json; -- ERROR, too many values
ERROR: invalid input syntax for type json: "true false"
LINE 1: SELECT 'true false'::json;
^
DETAIL: line 1: Expected end of input, but found "false".
SELECT 'true, false'::json; -- ERROR, too many values
ERROR: invalid input syntax for type json: "true, false"
LINE 1: SELECT 'true, false'::json;
^
DETAIL: line 1: Expected end of input, but found ",".
SELECT 'truf'::json; -- ERROR, not a keyword
ERROR: invalid input syntax for type json
LINE 1: SELECT 'truf'::json;
^
DETAIL: line 1: Token "truf" is invalid.
SELECT 'trues'::json; -- ERROR, not a keyword
ERROR: invalid input syntax for type json
LINE 1: SELECT 'trues'::json;
^
DETAIL: line 1: Token "trues" is invalid.
SELECT ''::json; -- ERROR, no value
ERROR: invalid input syntax for type json: ""
LINE 1: SELECT ''::json;
^
DETAIL: The input string ended unexpectedly.
SELECT ' '::json; -- ERROR, no value
ERROR: invalid input syntax for type json: " "
LINE 1: SELECT ' '::json;
^
DETAIL: The input string ended unexpectedly.
...@@ -92,7 +92,7 @@ test: rules ...@@ -92,7 +92,7 @@ test: rules
# ---------- # ----------
# Another group of parallel tests # Another group of parallel tests
# ---------- # ----------
test: select_views portals_p2 foreign_key cluster dependency guc bitmapops combocid tsearch tsdicts foreign_data window xmlmap functional_deps advisory_lock test: select_views portals_p2 foreign_key cluster dependency guc bitmapops combocid tsearch tsdicts foreign_data window xmlmap functional_deps advisory_lock json
# ---------- # ----------
# Another group of parallel tests # Another group of parallel tests
......
...@@ -109,6 +109,7 @@ test: window ...@@ -109,6 +109,7 @@ test: window
test: xmlmap test: xmlmap
test: functional_deps test: functional_deps
test: advisory_lock test: advisory_lock
test: json
test: plancache test: plancache
test: limit test: limit
test: plpgsql test: plpgsql
......
-- Strings.
SELECT '""'::json; -- OK.
SELECT $$''$$::json; -- ERROR, single quotes are not allowed
SELECT '"abc"'::json; -- OK
SELECT '"abc'::json; -- ERROR, quotes not closed
SELECT '"abc
def"'::json; -- ERROR, unescaped newline in string constant
SELECT '"\n\"\\"'::json; -- OK, legal escapes
SELECT '"\v"'::json; -- ERROR, not a valid JSON escape
SELECT '"\u"'::json; -- ERROR, incomplete escape
SELECT '"\u00"'::json; -- ERROR, incomplete escape
SELECT '"\u000g"'::json; -- ERROR, g is not a hex digit
SELECT '"\u0000"'::json; -- OK, legal escape
SELECT '"\uaBcD"'::json; -- OK, uppercase and lower case both OK
-- Numbers.
SELECT '1'::json; -- OK
SELECT '0'::json; -- OK
SELECT '01'::json; -- ERROR, not valid according to JSON spec
SELECT '0.1'::json; -- OK
SELECT '9223372036854775808'::json; -- OK, even though it's too large for int8
SELECT '1e100'::json; -- OK
SELECT '1.3e100'::json; -- OK
SELECT '1f2'::json; -- ERROR
-- Arrays.
SELECT '[]'::json; -- OK
SELECT '[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]'::json; -- OK
SELECT '[1,2]'::json; -- OK
SELECT '[1,2,]'::json; -- ERROR, trailing comma
SELECT '[1,2'::json; -- ERROR, no closing bracket
SELECT '[1,[2]'::json; -- ERROR, no closing bracket
-- Objects.
SELECT '{}'::json; -- OK
SELECT '{"abc"}'::json; -- ERROR, no value
SELECT '{"abc":1}'::json; -- OK
SELECT '{1:"abc"}'::json; -- ERROR, keys must be strings
SELECT '{"abc",1}'::json; -- ERROR, wrong separator
SELECT '{"abc"=1}'::json; -- ERROR, totally wrong separator
SELECT '{"abc"::1}'::json; -- ERROR, another wrong separator
SELECT '{"abc":1,"def":2,"ghi":[3,4],"hij":{"klm":5,"nop":[6]}}'::json; -- OK
SELECT '{"abc":1:2}'::json; -- ERROR, colon in wrong spot
SELECT '{"abc":1,3}'::json; -- ERROR, no value
-- Miscellaneous stuff.
SELECT 'true'::json; -- OK
SELECT 'false'::json; -- OK
SELECT 'null'::json; -- OK
SELECT ' true '::json; -- OK, even with extra whitespace
SELECT 'true false'::json; -- ERROR, too many values
SELECT 'true, false'::json; -- ERROR, too many values
SELECT 'truf'::json; -- ERROR, not a keyword
SELECT 'trues'::json; -- ERROR, not a keyword
SELECT ''::json; -- ERROR, no value
SELECT ' '::json; -- ERROR, no value
Markdown is supported
0% or
You are about to add 0 people to the discussion. Proceed with caution.
Finish editing this message first!
Please register or to comment