Output timestamps in ISO 8601 format when rendering JSON.

Many JSON processors require timestamp strings in ISO 8601 format in
order to convert the strings. When converting a timestamp, with or
without timezone, to a JSON datum we therefore now use such a format
rather than the type's default text output, in functions such as
to_json().

This is a change in behaviour from 9.2 and 9.3, as noted in the release
notes.
This commit is contained in:
Andrew Dunstan 2014-06-03 13:56:53 -04:00
parent 2dfa15de55
commit f30015b6d7
5 changed files with 116 additions and 0 deletions

View File

@ -162,6 +162,24 @@
</para>
</listitem>
<listitem>
<para>
Values of type
<link linkend="datatype-datetime"><type>timestamp</></link> and
<link linkend="datatype-datetime"><type>timestamptz</></link> are now
rendered in a string format compliant with ISO 8601 rather than the
default output format when converting to or used in
<link linkend="datatype-json"><type>JSON</type></link>.
(Andrew Dunstan)
</para>
<para>
Previously these were rendered in the default text output format
for the type, but many JSON processors require timestamps in ISO 8601
format.
</para>
</listitem>
<listitem>
<para>
Rename <link linkend="SQL-EXPLAIN"><command>EXPLAIN

View File

@ -24,6 +24,7 @@
#include "parser/parse_coerce.h"
#include "utils/array.h"
#include "utils/builtins.h"
#include "utils/formatting.h"
#include "utils/lsyscache.h"
#include "utils/json.h"
#include "utils/jsonapi.h"
@ -53,6 +54,8 @@ typedef enum /* type categories for datum_to_json */
JSONTYPE_NULL, /* null, so we didn't bother to identify */
JSONTYPE_BOOL, /* boolean (built-in types only) */
JSONTYPE_NUMERIC, /* numeric (ditto) */
JSONTYPE_TIMESTAMP, /* we use special formatting for timestamp */
JSONTYPE_TIMESTAMPTZ, /* ... and timestamptz */
JSONTYPE_JSON, /* JSON itself (and JSONB) */
JSONTYPE_ARRAY, /* array */
JSONTYPE_COMPOSITE, /* composite */
@ -60,6 +63,13 @@ typedef enum /* type categories for datum_to_json */
JSONTYPE_OTHER /* all else */
} JsonTypeCategory;
/*
* to_char formats to turn timestamps and timpstamptzs into json strings
* that are ISO 8601 compliant
*/
#define TS_ISO8601_FMT "\\\"YYYY-MM-DD\"T\"HH24:MI:SS.US\\\""
#define TSTZ_ISO8601_FMT "\\\"YYYY-MM-DD\"T\"HH24:MI:SS.USOF\\\""
static inline void json_lex(JsonLexContext *lex);
static inline void json_lex_string(JsonLexContext *lex);
static inline void json_lex_number(JsonLexContext *lex, char *s, bool *num_err);
@ -1262,6 +1272,14 @@ json_categorize_type(Oid typoid,
*tcategory = JSONTYPE_NUMERIC;
break;
case TIMESTAMPOID:
*tcategory = JSONTYPE_TIMESTAMP;
break;
case TIMESTAMPTZOID:
*tcategory = JSONTYPE_TIMESTAMPTZ;
break;
case JSONOID:
case JSONBOID:
*tcategory = JSONTYPE_JSON;
@ -1375,6 +1393,29 @@ datum_to_json(Datum val, bool is_null, StringInfo result,
}
pfree(outputstr);
break;
case JSONTYPE_TIMESTAMP:
/*
* The timestamp format used here provides for quoting the string,
* so no escaping is required.
*/
jsontext = DatumGetTextP(
DirectFunctionCall2(timestamp_to_char, val,
CStringGetTextDatum(TS_ISO8601_FMT)));
outputstr = text_to_cstring(jsontext);
appendStringInfoString(result, outputstr);
pfree(outputstr);
pfree(jsontext);
break;
case JSONTYPE_TIMESTAMPTZ:
/* same comment as for timestamp above */
jsontext = DatumGetTextP(
DirectFunctionCall2(timestamptz_to_char, val,
CStringGetTextDatum(TSTZ_ISO8601_FMT)));
outputstr = text_to_cstring(jsontext);
appendStringInfoString(result, outputstr);
pfree(outputstr);
pfree(jsontext);
break;
case JSONTYPE_JSON:
/* JSON and JSONB output will already be escaped */
outputstr = OidOutputFunctionCall(outfuncoid, val);

View File

@ -403,6 +403,29 @@ SELECT row_to_json(row((select array_agg(x) as d from generate_series(5,10) x)),
{"f1":[5,6,7,8,9,10]}
(1 row)
-- to_json, timestamps
select to_json(timestamp '2014-05-28 12:22:35.614298');
to_json
------------------------------
"2014-05-28T12:22:35.614298"
(1 row)
BEGIN;
SET LOCAL TIME ZONE 10.5;
select to_json(timestamptz '2014-05-28 12:22:35.614298-04');
to_json
------------------------------------
"2014-05-29T02:52:35.614298+10:30"
(1 row)
SET LOCAL TIME ZONE -8;
select to_json(timestamptz '2014-05-28 12:22:35.614298-04');
to_json
---------------------------------
"2014-05-28T08:22:35.614298-08"
(1 row)
COMMIT;
--json_agg
SELECT json_agg(q)
FROM ( SELECT $$a$$ || x AS b, y AS c,

View File

@ -403,6 +403,29 @@ SELECT row_to_json(row((select array_agg(x) as d from generate_series(5,10) x)),
{"f1":[5,6,7,8,9,10]}
(1 row)
-- to_json, timestamps
select to_json(timestamp '2014-05-28 12:22:35.614298');
to_json
------------------------------
"2014-05-28T12:22:35.614298"
(1 row)
BEGIN;
SET LOCAL TIME ZONE 10.5;
select to_json(timestamptz '2014-05-28 12:22:35.614298-04');
to_json
------------------------------------
"2014-05-29T02:52:35.614298+10:30"
(1 row)
SET LOCAL TIME ZONE -8;
select to_json(timestamptz '2014-05-28 12:22:35.614298-04');
to_json
---------------------------------
"2014-05-28T08:22:35.614298-08"
(1 row)
COMMIT;
--json_agg
SELECT json_agg(q)
FROM ( SELECT $$a$$ || x AS b, y AS c,

View File

@ -100,6 +100,17 @@ FROM rows q;
SELECT row_to_json(row((select array_agg(x) as d from generate_series(5,10) x)),false);
-- to_json, timestamps
select to_json(timestamp '2014-05-28 12:22:35.614298');
BEGIN;
SET LOCAL TIME ZONE 10.5;
select to_json(timestamptz '2014-05-28 12:22:35.614298-04');
SET LOCAL TIME ZONE -8;
select to_json(timestamptz '2014-05-28 12:22:35.614298-04');
COMMIT;
--json_agg
SELECT json_agg(q)