</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
#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"
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 */
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);
*tcategory = JSONTYPE_NUMERIC;
break;
+ case TIMESTAMPOID:
+ *tcategory = JSONTYPE_TIMESTAMP;
+ break;
+
+ case TIMESTAMPTZOID:
+ *tcategory = JSONTYPE_TIMESTAMPTZ;
+ break;
+
case JSONOID:
case JSONBOID:
*tcategory = JSONTYPE_JSON;
}
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);
{"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,
{"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,